The entirety of these exercises will be in SQLite.
SQL Movie-Rating Query Exercises
Q1
Find the titles of all movies directed by Steven Spielberg.
A1
select title
from Movie
where director = 'Steven Spielberg';
Q2
Find all years that have a movie that received a rating of 4 or 5, and sort them in increasing order.
A2
select year
from Movie
where mID in (select distinct mID from Rating where stars >= 4)
order by year;
Q3
Find the titles of all movies that have no ratings.
A3
select title
from Movie
where mID not in (select mID from Rating);
Q4
Some reviewers didn't provide a date with their rating. Find the names of all reviewers who have ratings with a NULL value for the date.
A4
select name
from Reviewer
where rID in (select rID from Rating where ratingDate is null);
Q5
Write a query to return the ratings data in a more readable format: reviewer name, movie title, stars, and ratingDate. Also, sort the data, first by reviewer name, then by movie title, and lastly by number of stars.
A5
select name, title, stars, ratingDate
from Movie join Rating using(mID) join Reviewer using(rID)
order by name, title, stars;
Q6
For all cases where the same reviewer rated the same movie twice and gave it a higher rating the second time, return the reviewer's name and the title of the movie.
A6
select r.name, m.title
from Reviewer as r, Movie as m,
(select r1.rID, r1.mID
from Rating r1 , Rating r2
where r1.rID = r2.rID and r1.mID = r2.mID
and r1.stars > r2.stars
and r1.ratingDate > r2.ratingDate) as a
where r.rID = a.rID and m.mID = a.mID
Q7
For each movie that has at least one rating, find the highest number of stars that movie received. Return the movie title and number of stars. Sort by movie title.
A7
select distinct r1.title,r1.stars
from (Rating join Movie using(mID)) as r1
where not exists (select stars from Rating r2
where r1.stars<r2.stars and r1.mID = r2.mID)
order by r1.title
Q8
For each movie, return the title and the 'rating spread', that is, the difference between highest and lowest ratings given to that movie. Sort by rating spread from highest to lowest, then by movie title.
A8
select title, rating_spread
from Movie m join (select mID, max(stars)-min(stars) as rating_spread
from Rating r group by mID) using (mID)
order by rating_spread desc, title
Q9
Find the difference between the average rating of movies released before 1980 and the average rating of movies released after 1980. (Make sure to calculate the average rating for each movie, then the average of those averages for movies before 1980 and movies after. Don't just calculate the overall average rating before and after 1980.)
A9
select avg(early.avgStar)-avg(late.avgStar)
from (select avg(stars) as avgStar
from Movie join Rating using(mID)
group by mID
having year < 1980) as early,
(select avg(stars) as avgStar
from Movie join Rating using(mID)
group by mID
having year > 1980) as late
SQL Movie-Rating Query Exercises Extras (in SQLite)
Q1
Find the names of all reviewers who rated Gone with the Wind.
A1
select name
from (select distinct rID from Rating join Movie using(mID)
where title = 'Gone with the Wind')
join Reviewer using(rID)
Q2
For any rating where the reviewer is the same as the director of the movie, return the reviewer name, movie title, and number of stars.
A2
select name, title, stars
from Rating join Reviewer using(rID) join Movie using (mID)
where name = director
Q3
Return all reviewer names and movie names together in a single list, alphabetized. (Sorting by the first name of the reviewer and first word in the title is fine; no need for special processing on last names or removing "The".)
A3
select name from Reviewer
union
select title from Movie
Q4
Find the titles of all movies not reviewed by Chris Jackson.
A4
select title
from Movie
where mID not in (select mID from Reviewer join Rating using(rID)
where name = 'Chris Jackson')
Q5
For all pairs of reviewers such that both reviewers gave a rating to the same movie, return the names of both reviewers. Eliminate duplicates, don't pair reviewers with themselves, and include each pair only once. For each pair, return the names in the pair in alphabetical order.
A5
select distinct r1.name,r2.name
from (Rating join Reviewer using(rID)) as r1, (Rating join Reviewer using(rID)) as r2
where r1.name < r2.name and r1.mID = r2.mID
Q6
For each rating that is the lowest (fewest stars) currently in the database, return the reviewer name, movie title, and number of stars.
A6
select name, title, stars
from (Reviewer join Rating using(rID) join Movie using(mID)) as r1
where not exists (select stars from Rating r2 where r1.stars > r2.stars)
Q7
List movie titles and average ratings, from highest-rated to lowest-rated. If two or more movies have the same average rating, list them in alphabetical order.
A7
select title, avg(stars) as avgStars
from Rating join Movie using(mID)
group by mID
order by avgStars desc, title
Q8
Find the names of all reviewers who have contributed three or more ratings. (As an extra challenge, try writing the query without HAVING or without COUNT.)
A8
select name
from Reviewer
where rID in (select rID from Rating group by rID having count(stars)>2);
Q9
Some directors directed more than one movie. For all such directors, return the titles of all movies directed by them, along with the director name. Sort by director name, then movie title.
A9
select title,director
from Movie
where director in (select director from Movie group by director
having count(director)>1)
order by director,title
(As an extra challenge, try writing the query both with and without COUNT.)
select distinct m1.title,m1.director
from Movie m1, Movie m2
where m1.director = m2.director and m1.title <> m2.title
order by m1.director,m1.title
Q10
Find the movie(s) with the highest average rating. Return the movie title(s) and average rating. (Hint: This query is more difficult to write in SQLite than other systems; you might think of it as finding the highest average rating and then choosing the movie(s) with that average rating.)
A10
select M.title, M.avgStars
from (select title, avg(stars) as avgStars from Movie join Rating using(mID)
group by mID) as M
where M.avgStars = (select max(avgStars)
from (select avg(stars) as avgStars from Rating
group by mID))
Q11
Find the movie(s) with the lowest average rating. Return the movie title(s) and average rating. (Hint: This query may be more difficult to write in SQLite than other systems; you might think of it as finding the lowest average rating and then choosing the movie(s) with that average rating.)
A11
select M.title, M.avgStars
from (select title, avg(stars) as avgStars from Movie join Rating using(mID)
group by mID) as M
where M.avgStars = (select min(avgStars)
from (select avg(stars) as avgStars from Rating
group by mID))
Q12
For each director, return the director's name together with the title(s) of the movie(s) they directed that received the highest rating among all of their movies, and the value of that rating. Ignore movies whose director is NULL.
A12
select distinct m1.director, m1.title, m1.stars
from (Movie join Rating using(mID)) as m1
where m1.director is not null and
not exists (select stars from (Movie join Rating using(mID)) as m2
where m1.stars<m2.stars and m1.director = m2.director)
SQL Movie-Rating Modification Exercises (in SQLite)
Q1
Add the reviewer Roger Ebert to your database, with an rID of 209.
A1
insert into Reviewer values (209,'Roger Ebert');
Q2
Insert 5-star ratings by James Cameron for all movies in the database. Leave the review date as NULL.
A2
insert into Rating
select rID, mID, 5, null
from (select rID from Reviewer
where name = 'James Cameron') as JC, Movie
Q3
For all movies that have an average rating of 4 stars or higher, add 25 to the release year. (Update the existing tuples; don't insert new tuples.)
A3
update Movie
set year = year+25
where mID in (select mID
from (select mID, avg(stars) as avgStars
from Rating group by mID)
where avgStars>=4)
Q4
Remove all ratings where the movie's year is before 1970 or after 2000, and the rating is fewer than 4 stars.
A4
delete from Rating
where mID in (select mID from Movie where year<1970 or year>2000)
and stars<4