w3resource

SQL exercises on movie Database: Find the movie title, year, date of release, director and actor for those movies which reviewer is unknown

SQL movie Database: Subquery Exercise-4 with Solution

4. From the following tables, write a SQL query to find for movies whose reviewer is unknown. Return movie title, year, release date, director first name, last name, actor first name, last name.

Sample table: movie
 mov_id |                     mov_title                      | mov_year | mov_time |    mov_lang     | mov_dt_rel | mov_rel_country
--------+----------------------------------------------------+----------+----------+-----------------+------------+-----------------
    901 | Vertigo                                            |     1958 |      128 | English         | 1958-08-24 | UK
    902 | The Innocents                                      |     1961 |      100 | English         | 1962-02-19 | SW
    903 | Lawrence of Arabia                                 |     1962 |      216 | English         | 1962-12-11 | UK
    904 | The Deer Hunter                                    |     1978 |      183 | English         | 1979-03-08 | UK
    905 | Amadeus                                            |     1984 |      160 | English         | 1985-01-07 | UK
    906 | Blade Runner                                       |     1982 |      117 | English         | 1982-09-09 | UK
    907 | Eyes Wide Shut                                     |     1999 |      159 | English         |            | UK
    908 | The Usual Suspects                                 |     1995 |      106 | English         | 1995-08-25 | UK
    909 | Chinatown                                          |     1974 |      130 | English         | 1974-08-09 | UK
    910 | Boogie Nights                                      |     1997 |      155 | English         | 1998-02-16 | UK
    911 | Annie Hall                                         |     1977 |       93 | English         | 1977-04-20 | USA
    912 | Princess Mononoke                                  |     1997 |      134 | Japanese        | 2001-10-19 | UK
    913 | The Shawshank Redemption                           |     1994 |      142 | English         | 1995-02-17 | UK
    914 | American Beauty                                    |     1999 |      122 | English         |            | UK
    915 | Titanic                                            |     1997 |      194 | English         | 1998-01-23 | UK
    916 | Good Will Hunting                                  |     1997 |      126 | English         | 1998-06-03 | UK
    917 | Deliverance                                        |     1972 |      109 | English         | 1982-10-05 | UK
    918 | Trainspotting                                      |     1996 |       94 | English         | 1996-02-23 | UK
    919 | The Prestige                                       |     2006 |      130 | English         | 2006-11-10 | UK
    920 | Donnie Darko                                       |     2001 |      113 | English         |            | UK
    921 | Slumdog Millionaire                                |     2008 |      120 | English         | 2009-01-09 | UK
    922 | Aliens                                             |     1986 |      137 | English         | 1986-08-29 | UK
    923 | Beyond the Sea                                     |     2004 |      118 | English         | 2004-11-26 | UK
    924 | Avatar                                             |     2009 |      162 | English         | 2009-12-17 | UK
    926 | Seven Samurai                                      |     1954 |      207 | Japanese        | 1954-04-26 | JP
    927 | Spirited Away                                      |     2001 |      125 | Japanese        | 2003-09-12 | UK
    928 | Back to the Future                                 |     1985 |      116 | English         | 1985-12-04 | UK
    925 | Braveheart                                         |     1995 |      178 | English         | 1995-09-08 | UK
Sample table: actor
 act_id |      act_fname       |      act_lname       | act_gender
--------+----------------------+----------------------+------------
    101 | James                | Stewart              | M
    102 | Deborah              | Kerr                 | F
    103 | Peter                | OToole               | M
    104 | Robert               | De Niro              | M
    105 | F. Murray            | Abraham              | M
    106 | Harrison             | Ford                 | M
    107 | Nicole               | Kidman               | F
    108 | Stephen              | Baldwin              | M
    109 | Jack                 | Nicholson            | M
    110 | Mark                 | Wahlberg             | M
    111 | Woody                | Allen                | M
    112 | Claire               | Danes                | F
    113 | Tim                  | Robbins              | M
    114 | Kevin                | Spacey               | M
    115 | Kate                 | Winslet              | F
    116 | Robin                | Williams             | M
    117 | Jon                  | Voight               | M
    118 | Ewan                 | McGregor             | M
    119 | Christian            | Bale                 | M
    120 | Maggie               | Gyllenhaal           | F
    121 | Dev                  | Patel                | M
    122 | Sigourney            | Weaver               | F
    123 | David                | Aston                | M
    124 | Ali                  | Astin                | F
Sample table: director
 dir_id |      dir_fname       |      dir_lname
--------+----------------------+----------------------
    201 | Alfred               | Hitchcock
    202 | Jack                 | Clayton
    203 | David                | Lean
    204 | Michael              | Cimino
    205 | Milos                | Forman
    206 | Ridley               | Scott
    207 | Stanley              | Kubrick
    208 | Bryan                | Singer
    209 | Roman                | Polanski
    210 | Paul                 | Thomas Anderson
    211 | Woody                | Allen
    212 | Hayao                | Miyazaki
    213 | Frank                | Darabont
    214 | Sam                  | Mendes
    215 | James                | Cameron
    216 | Gus                  | Van Sant
    217 | John                 | Boorman
    218 | Danny                | Boyle
    219 | Christopher          | Nolan
    220 | Richard              | Kelly
    221 | Kevin                | Spacey
    222 | Andrei               | Tarkovsky
    223 | Peter                | Jackson
Sample table: movie_direction
 dir_id | mov_id
--------+--------
    201 |    901
    202 |    902
    203 |    903
    204 |    904
    205 |    905
    206 |    906
    207 |    907
    208 |    908
    209 |    909
    210 |    910
    211 |    911
    212 |    912
    213 |    913
    214 |    914
    215 |    915
    216 |    916
    217 |    917
    218 |    918
    219 |    919
    220 |    920
    218 |    921
    215 |    922
    221 |    923
Sample table: movie_cast
 act_id | mov_id |              role
--------+--------+--------------------------------
    101 |    901 | John Scottie Ferguson
    102 |    902 | Miss Giddens
    103 |    903 | T.E. Lawrence
    104 |    904 | Michael
    105 |    905 | Antonio Salieri
    106 |    906 | Rick Deckard
    107 |    907 | Alice Harford
    108 |    908 | McManus
    110 |    910 | Eddie Adams
    111 |    911 | Alvy Singer
    112 |    912 | San
    113 |    913 | Andy Dufresne
    114 |    914 | Lester Burnham
    115 |    915 | Rose DeWitt Bukater
    116 |    916 | Sean Maguire
    117 |    917 | Ed
    118 |    918 | Renton
    120 |    920 | Elizabeth Darko
    121 |    921 | Older Jamal
    122 |    922 | Ripley
    114 |    923 | Bobby Darin
    109 |    909 | J.J. Gittes
    119 |    919 | Alfred Borden
Sample table: reviewer
 rev_id |            rev_name
--------+--------------------------------
   9001 | Righty Sock
   9002 | Jack Malvern
   9003 | Flagrant Baronessa
   9004 | Alec Shaw
   9005 |
   9006 | Victor Woeltjen
   9007 | Simon Wright
   9008 | Neal Wruck
   9009 | Paul Monks
   9010 | Mike Salvati
   9011 |
   9012 | Wesley S. Walker
   9013 | Sasha Goldshtein
   9014 | Josh Cates
   9015 | Krug Stillo
   9016 | Scott LeBrun
   9017 | Hannah Steele
   9018 | Vincent Cadena
   9019 | Brandt Sponseller
   9020 | Richard Adams
Sample table: rating
 mov_id | rev_id | rev_stars | num_o_ratings
--------+--------+-----------+---------------
    901 |   9001 |      8.40 |        263575
    902 |   9002 |      7.90 |         20207
    903 |   9003 |      8.30 |        202778
    906 |   9005 |      8.20 |        484746
    924 |   9006 |      7.30 |
    908 |   9007 |      8.60 |        779489
    909 |   9008 |           |        227235
    910 |   9009 |      3.00 |        195961
    911 |   9010 |      8.10 |        203875
    912 |   9011 |      8.40 |
    914 |   9013 |      7.00 |        862618
    915 |   9001 |      7.70 |        830095
    916 |   9014 |      4.00 |        642132
    925 |   9015 |      7.70 |         81328
    918 |   9016 |           |        580301
    920 |   9017 |      8.10 |        609451
    921 |   9018 |      8.00 |        667758
    922 |   9019 |      8.40 |        511613
    923 |   9020 |      6.70 |         13091

Sample Solution:

-- Selecting specific columns from various tables (movie, movie_direction, director, rating, reviewer, actor, movie_cast)
-- Using aliases (a, b, c, d, e, f, g) for better readability
SELECT mov_title, mov_year, mov_dt_rel, dir_fname, dir_lname, 
       act_fname, act_lname
FROM movie a, movie_direction b, director c, 
                rating d, reviewer e, actor f, movie_cast g
-- Joining tables based on their relationships using specified conditions
-- Combining data from multiple tables to retrieve relevant information
WHERE a.mov_id=b.mov_id
  AND b.dir_id=c.dir_id 
  AND a.mov_id=d.mov_id 
  AND d.rev_id=e.rev_id 
  AND a.mov_id=g.mov_id 
  AND g.act_id=f.act_id 
  AND e.rev_name IS NULL;

Sample Output:

                     mov_title                      | mov_year | mov_dt_rel |      dir_fname       |      dir_lname       |      act_fname       |      act_lname
----------------------------------------------------+----------+------------+----------------------+----------------------+----------------------+----------------------
 Blade Runner                                       |     1982 | 1982-09-09 | Ridley               | Scott                | Harrison             | Ford
 Princess Mononoke                                  |     1997 | 2001-10-19 | Hayao                | Miyazaki             | Claire              | Danes
(2 rows)

Code Explanation:

The said query in SQL that selects various information about movies, directors, actors, and reviewers
from several tables in the movie database, but only for movies that have not been reviewed.
This query retrieve columns movie title, year,
date of release, director first and last names, actor first and last names from the tables join together are 'movie', 'movie_direction', 'director', 'rating', 'reviewer', 'actor', and 'movie_cast'.
The JOIN clause joins the 'movie' and 'movie_direction' table on "mov_id" column the 'movie_direction' and 'director' tables on "dir_id" column, the 'movie' and 'rating' tables on "mov_id" column, the 'rating' and 'reviewer' tables on "rev_id" column the 'movie' and 'movie_cast' tables on "mov_id" column , the 'movie_cast' and 'actor' tables on "act_id" column, and the "rev_name" column in 'reviewer' must be NULL (i.e., the movie has not been reviewed).

Alternative Solutions:

Using Explicit JOIN Syntax:


SELECT a.mov_title, a.mov_year, a.mov_dt_rel, 
       c.dir_fname, c.dir_lname, f.act_fname, f.act_lname
FROM movie a
JOIN movie_direction b ON a.mov_id = b.mov_id
JOIN director c ON b.dir_id = c.dir_id
JOIN rating d ON a.mov_id = d.mov_id
JOIN reviewer e ON d.rev_id = e.rev_id
JOIN movie_cast g ON a.mov_id = g.mov_id
JOIN actor f ON g.act_id = f.act_id
WHERE e.rev_name IS NULL;

Explanation:

This solution uses the explicit JOIN syntax to join the necessary tables based on their respective keys. It selects the specified columns and applies the condition for rev_name being NULL.

Using INNER JOIN with ON Clause:


SELECT a.mov_title, a.mov_year, a.mov_dt_rel, 
       c.dir_fname, c.dir_lname, f.act_fname, f.act_lname
FROM movie a
INNER JOIN movie_direction b ON a.mov_id = b.mov_id
INNER JOIN director c ON b.dir_id = c.dir_id
INNER JOIN rating d ON a.mov_id = d.mov_id
INNER JOIN reviewer e ON d.rev_id = e.rev_id
INNER JOIN movie_cast g ON a.mov_id = g.mov_id
INNER JOIN actor f ON g.act_id = f.act_id
WHERE e.rev_name IS NULL;

Explanation:

This solution also uses the explicit JOIN syntax with the ON clause to specify the join conditions. It selects the specified columns and applies the condition for rev_name being NULL.

Relational Algebra Expression:

Relational Algebra Expression: Find the movie title, year, date of release, director and actor for those movies which reviewer is unknown.

Relational Algebra Tree:

Relational Algebra Tree: Find the movie title, year, date of release, director and actor for those movies which reviewer is unknown.

Practice Online


Movie database model

Query Visualization:

Duration:

Query visualization of Find the movie title, year, date of release, director and actor for those movies which reviewer is unknown - Duration

Rows:

Query visualization of Find the movie title, year, date of release, director and actor for those movies which reviewer is unknown - Rows

Cost:

Query visualization of Find the movie title, year, date of release, director and actor for those movies which reviewer is unknown - Cost

Have another way to solve this solution? Contribute your code (and comments) through Disqus.

Previous: From the following table, write a SQL query to find those movies, which released in the country besides UK. Return movie title, movie year, movie time, date of release, releasing country.
Next: From the following tables, write a SQL query to find those movies directed by the director whose first name is ‘Woddy’ and last name is ‘Allen’. Return movie title.

What is the difficulty level of this exercise?

Test your Programming skills with w3resource's quiz.



Become a Patron!

Follow us on Facebook and Twitter for latest update.

It will be nice if you may share this link in any developer community or anywhere else, from where other developers may find this content. Thanks.

https://w3resource.com/sql-exercises/movie-database-exercise/sql-exercise-movie-database-25.php