請統計各年份的電影評分(rev_stars)的平均,並列出所有高於該年份的評分平均的電影當中,英國、非英國各有幾部
例如:1997年的電影平均比分為5.8分,評分高於平均的電影當中,英國有2部電影,非英國則有0部電影
| mov_year | average | uk_count | not_uk_count |
| ---------|---------------------|---------------|
| 1962 | 8.3 | 1 | 0 |
| 1982 | 8.2 | 1 | 0 |
| 1999 | 7.0 | 1 | 0 |
| 1996 | 0.0 | 0 | 0 |
| 2009 | 7.3 | 1 | 0 |
| 1986 | 8.4 | 1 | 0 |
| 2004 | 6.7 | 1 | 0 |
| 1974 | 0.0 | 0 | 0 |
| 1995 | 8.2 | 1 | 0 |
| 1961 | 7.9 | 0 | 1 |
| 1977 | 8.1 | 0 | 1 |
| 2001 | 8.1 | 1 | 0 |
| 1997 | 5.8 | 2 | 0 |
| 2008 | 8.0 | 1 | 0 |
| 1958 | 8.4 | 1 | 0 |
SELECT mov_year,
ROUND(AVG_result.average, 1) AS average,
(
SELECT COUNT(movie.mov_id)
FROM movie
INNER JOIN rating
ON movie.mov_id = rating.mov_id
WHERE rating.rev_stars >= AVG_result.average AND
movie.mov_year = AVG_result.mov_year AND
mov_rel_country = 'UK'
) AS UK_Count ,
(
SELECT COUNT(movie.mov_id)
FROM movie
INNER JOIN rating
ON movie.mov_id = rating.mov_id
WHERE rating.rev_stars >= AVG_result.average AND
movie.mov_year = AVG_result.mov_year AND
mov_rel_country <> 'UK'
) AS NOT_UK_Count
FROM (SELECT mov_year,
(
CASE
WHEN AVG(rev_stars) IS NULL THEN 0
ELSE AVG(rev_stars)
END
) AS average
FROM movie
INNER JOIN rating
ON movie.mov_id = rating.mov_id
GROUP BY mov_year) AS AVG_result
FROM (SELECT mov_year,
(
CASE
WHEN AVG(rev_stars) IS NULL THEN 0
ELSE AVG(rev_stars)
END
) AS average
FROM movie
INNER JOIN rating
ON movie.mov_id = rating.mov_id
GROUP BY mov_year) AS AVG_result
mov_year | average |
---|---|
1962 | 8.3 |
1982 | 8.2 |
1999 | 7.0 |
1996 | 0.0 |
2009 | 7.3 |
1986 | 8.4 |
2004 | 6.7 |
1974 | 0.0 |
1995 | 8.2 |
1961 | 7.9 |
1977 | 8.1 |
2001 | 8.1 |
1997 | 5.8 |
2008 | 8.0 |
1958 | 8.4 |
SELECT mov_year,
ROUND(AVG_result.average, 1) AS average,
(
SELECT COUNT(movie.mov_id)
FROM movie
INNER JOIN rating
ON movie.mov_id = rating.mov_id
WHERE rating.rev_stars >= AVG_result.average AND
movie.mov_year = AVG_result.mov_year AND
mov_rel_country = 'UK'
) AS UK_Count ,
(
SELECT COUNT(movie.mov_id)
FROM movie
INNER JOIN rating
ON movie.mov_id = rating.mov_id
WHERE rating.rev_stars >= AVG_result.average AND
movie.mov_year = AVG_result.mov_year AND
mov_rel_country <> 'UK'
) AS NOT_UK_Count
| mov_year | average | uk_count | not_uk_count |
| ---------|---------------------|---------------|
| 1962 | 8.3 | 1 | 0 |
| 1982 | 8.2 | 1 | 0 |
| 1999 | 7.0 | 1 | 0 |
| 1996 | 0.0 | 0 | 0 |
| 2009 | 7.3 | 1 | 0 |
| 1986 | 8.4 | 1 | 0 |
| 2004 | 6.7 | 1 | 0 |
| 1974 | 0.0 | 0 | 0 |
| 1995 | 8.2 | 1 | 0 |
| 1961 | 7.9 | 0 | 1 |
| 1977 | 8.1 | 0 | 1 |
| 2001 | 8.1 | 1 | 0 |
| 1997 | 5.8 | 2 | 0 |
| 2008 | 8.0 | 1 | 0 |
| 1958 | 8.4 | 1 | 0 |
ROUND(數字, 1) =>將數字四捨五入到小數點第1位
請分別統計2000年以前(不包含2000年)與2000年以後(包含2000年)
片長低於該區間的平均時數的所有電影當中,片長前3長的的影片導演、影片名稱、影片年分、影片時間、所屬的區間影片平均時數、排名結果
例如:
category | director_fullname | mov_title | mov_year | mov_time | average_time | rank |
---|---|---|---|---|---|---|
AFTER 2000 Below time average Rank | Danny Boyle | Slumdog Millionaire | 2008 | 120 | 128 | 1 |
AFTER 2000 Below time average Rank | Kevin Spacey | Beyond the Sea | 2004 | 118 | 128 | 2 |
AFTER 2000 Below time average Rank | Richard Kelly | Donnie Darko | 2001 | 113 | 128 | 3 |
BEFORE 2000 Below time average Rank | James Cameron | Aliens | 1986 | 137 | 141 | 1 |
BEFORE 2000 Below time average Rank | Hayao Miyazaki | Princess Mononoke | 1997 | 134 | 141 | 2 |
BEFORE 2000 Below time average Rank | Roman Polanski | Chinatown | 1974 | 130 | 141 | 3 |
SELECT *
FROM (SELECT 'AFTER 2000 Below time average Rank' AS Category,
CONCAT(director.dir_fname, ' ', director.dir_lname) AS director_fullname,
movie.mov_title,
movie.mov_year,
movie.mov_time,
avg_before2000.average_time,
RANK() OVER(ORDER BY movie.mov_time DESC) AS Rank
FROM movie
INNER JOIN movie_direction
ON movie.mov_id = movie_direction.mov_id
INNER JOIN director
ON movie_direction.dir_id = director.dir_id
INNER JOIN (SELECT ROUND(AVG(mov_time)) AS average_time
FROM movie
WHERE mov_year >= 2000 ) AS avg_before2000
ON 1=1
WHERE mov_time <= avg_before2000.average_time AND
mov_year >= 2000
UNION (SELECT 'BEFORE 2000 Below time average Rank' AS Category,
CONCAT(director.dir_fname, ' ', director.dir_lname) AS director_fullname,
movie.mov_title,
movie.mov_year,
movie.mov_time,
avg_before2000.average_time,
RANK() OVER(ORDER BY movie.mov_time DESC) AS Rank
FROM movie
INNER JOIN movie_direction
ON movie.mov_id = movie_direction.mov_id
INNER JOIN director
ON movie_direction.dir_id = director.dir_id
INNER JOIN (SELECT ROUND(AVG(mov_time)) AS average_time
FROM movie
WHERE mov_year < 2000 ) AS avg_before2000
ON 1=1
WHERE mov_time <= avg_before2000.average_time AND
mov_year < 2000)) AS All_Rank
WHERE rank <= 3
ORDER BY mov_year,
rank
2000年以後:
SELECT ROUND(AVG(mov_time)) AS average_time
FROM movie
WHERE mov_year >= 2000
average_time |
---|
128 |
2000年以前:
SELECT ROUND(AVG(mov_time)) AS average_time
FROM movie
WHERE mov_year < 2000
average_time |
---|
141 |
2000年以後:
SELECT movie.mov_title,
movie.mov_year,
movie.mov_time,
avg_before2000.average_time
FROM movie
INNER JOIN (SELECT ROUND(AVG(mov_time)) AS average_time
FROM movie
WHERE mov_year >= 2000 ) AS avg_before2000
ON 1=1
WHERE mov_time <= avg_before2000.average_time AND
mov_year >= 2000
mov_title | mov_year | mov_time | average_time |
---|---|---|---|
Donnie Darko | 2001 | 113 | 128 |
Slumdog Millionaire | 2008 | 120 | 128 |
Beyond the Sea | 2004 | 118 | 128 |
Spirited Away | 2001 | 125 | 128 |
2000年以前:
SELECT movie.mov_title,
movie.mov_year,
movie.mov_time,
avg_before2000.average_time
FROM movie
INNER JOIN (SELECT ROUND(AVG(mov_time)) AS average_time
FROM movie
WHERE mov_year < 2000 ) AS avg_before2000
ON 1=1
WHERE mov_time <= avg_before2000.average_time AND
mov_year < 2000
mov_title | mov_year | mov_time | average_time |
---|---|---|---|
Vertigo | 1958 | 128 | 141 |
The Innocents | 1961 | 100 | 141 |
Blade Runner | 1982 | 117 | 141 |
The Usual Suspects | 1995 | 106 | 141 |
Chinatown | 1974 | 130 | 141 |
Annie Hall | 1977 | 93 | 141 |
Princess Mononoke | 1997 | 134 | 141 |
American Beauty | 1999 | 122 | 141 |
Good Will Hunting | 1997 | 126 | 141 |
Deliverance | 1972 | 109 | 141 |
Trainspotting | 1996 | 94 | 141 |
Aliens | 1986 | 137 | 141 |
Back to the Future | 1985 | 116 | 141 |
2000年之後:
SELECT 'AFTER 2000 Below time average Rank' AS Category,
CONCAT(director.dir_fname, ' ', director.dir_lname) AS director_fullname,
movie.mov_title,
movie.mov_year,
movie.mov_time,
avg_before2000.average_time,
RANK() OVER(ORDER BY movie.mov_time DESC) AS Rank
FROM movie
INNER JOIN movie_direction
ON movie.mov_id = movie_direction.mov_id
INNER JOIN director
ON movie_direction.dir_id = director.dir_id
INNER JOIN (SELECT ROUND(AVG(mov_time)) AS average_time
FROM movie
WHERE mov_year >= 2000 ) AS avg_before2000
ON 1=1
WHERE mov_time <= avg_before2000.average_time AND
mov_year >= 2000
category | director_fullname | mov_title | mov_year | mov_time | average_time | rank |
---|---|---|---|---|---|---|
AFTER 2000 Below time average Rank | Danny Boyle | Slumdog Millionaire | 2008 | 120 | 128 | 1 |
AFTER 2000 Below time average Rank | Kevin Spacey | Beyond the Sea | 2004 | 118 | 128 | 2 |
AFTER 2000 Below time average Rank | Richard Kelly | Donnie Darko | 2001 | 113 | 128 | 3 |
2000年以前
SELECT 'BEFORE 2000 Below time average Rank' AS Category,
CONCAT(director.dir_fname, ' ', director.dir_lname) AS director_fullname,
movie.mov_title,
movie.mov_year,
movie.mov_time,
avg_before2000.average_time,
RANK() OVER(ORDER BY movie.mov_time DESC) AS Rank
FROM movie
INNER JOIN movie_direction
ON movie.mov_id = movie_direction.mov_id
INNER JOIN director
ON movie_direction.dir_id = director.dir_id
INNER JOIN (SELECT ROUND(AVG(mov_time)) AS average_time
FROM movie
WHERE mov_year < 2000 ) AS avg_before2000
ON 1=1
WHERE mov_time <= avg_before2000.average_time AND
mov_year < 2000
category | director_fullname | mov_title | mov_year | mov_time | average_time | rank |
---|---|---|---|---|---|---|
BEFORE 2000 Below time average Rank | James Cameron | Aliens | 1986 | 137 | 141 | 1 |
BEFORE 2000 Below time average Rank | Hayao Miyazaki | Princess Mononoke | 1997 | 134 | 141 | 2 |
BEFORE 2000 Below time average Rank | Roman Polanski | Chinatown | 1974 | 130 | 141 | 3 |
BEFORE 2000 Below time average Rank | Alfred Hitchcock | Vertigo | 1958 | 128 | 141 | 4 |
BEFORE 2000 Below time average Rank | Gus Van Sant | Good Will Hunting | 1997 | 126 | 141 | 5 |
BEFORE 2000 Below time average Rank | Sam Mendes | American Beauty | 1999 | 122 | 141 | 6 |
BEFORE 2000 Below time average Rank | Ridley Scott | Blade Runner | 1982 | 117 | 141 | 7 |
BEFORE 2000 Below time average Rank | John Boorman | Deliverance | 1972 | 109 | 141 | 8 |
BEFORE 2000 Below time average Rank | Bryan Singer | The Usual Suspects | 1995 | 106 | 141 | 9 |
BEFORE 2000 Below time average Rank | Jack Clayton | The Innocents | 196 | 1 100 | 141 | 10 |
BEFORE 2000 Below time average Rank | Danny Boyle | Trainspotting | 1996 | 94 | 141 | 11 |
BEFORE 2000 Below time average Rank | Woody Allen | Annie Hall | 1977 | 93 | 141 | 12 |
SELECT *
FROM (SELECT 'AFTER 2000 Below time average Rank' AS Category,
CONCAT(director.dir_fname, ' ', director.dir_lname) AS director_fullname,
movie.mov_title,
movie.mov_year,
movie.mov_time,
avg_before2000.average_time,
RANK() OVER(ORDER BY movie.mov_time DESC) AS Rank
FROM movie
INNER JOIN movie_direction
ON movie.mov_id = movie_direction.mov_id
INNER JOIN director
ON movie_direction.dir_id = director.dir_id
INNER JOIN (SELECT ROUND(AVG(mov_time)) AS average_time
FROM movie
WHERE mov_year >= 2000 ) AS avg_before2000
ON 1=1
WHERE mov_time <= avg_before2000.average_time AND
mov_year >= 2000
UNION (SELECT 'BEFORE 2000 Below time average Rank' AS Category,
CONCAT(director.dir_fname, ' ', director.dir_lname) AS director_fullname,
movie.mov_title,
movie.mov_year,
movie.mov_time,
avg_before2000.average_time,
RANK() OVER(ORDER BY movie.mov_time DESC) AS Rank
FROM movie
INNER JOIN movie_direction
ON movie.mov_id = movie_direction.mov_id
INNER JOIN director
ON movie_direction.dir_id = director.dir_id
INNER JOIN (SELECT ROUND(AVG(mov_time)) AS average_time
FROM movie
WHERE mov_year < 2000 ) AS avg_before2000
ON 1=1
WHERE mov_time <= avg_before2000.average_time AND
mov_year < 2000)) AS All_Rank
WHERE rank <= 3
ORDER BY category,
rank
category | director_fullname | mov_title | mov_year | mov_time | average_time | rank |
---|---|---|---|---|---|---|
AFTER 2000 Below time average Rank | Danny Boyle | Slumdog Millionaire | 2008 | 120 | 128 | 1 |
AFTER 2000 Below time average Rank | Kevin Spacey | Beyond the Sea | 2004 | 118 | 128 | 2 |
AFTER 2000 Below time average Rank | Richard Kelly | Donnie Darko | 2001 | 113 | 128 | 3 |
BEFORE 2000 Below time average Rank | James Cameron | Aliens | 1986 | 137 | 141 | 1 |
BEFORE 2000 Below time average Rank | Hayao Miyazaki | Princess Mononoke | 1997 | 134 | 141 | 2 |
BEFORE 2000 Below time average Rank | Roman Polanski | Chinatown | 1974 | 130 | 141 | 3 |