SQL exercises on movie Database: Find the name of the director who directed a movie that casted a role for 'Eyes Wide Shut'
SQL movie Database: Subquery Exercise-2 with Solution
2. From the following tables, write a SQL query to find the director of a film that cast a role in 'Eyes Wide Shut'. Return director first name, last name.
Sample table: directordir_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 | JacksonSample 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 | 923Sample 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 BordenSample 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 Solution:
-- Selecting 'dir_fname' and 'dir_lname' from the 'director' table
-- Filtering results where 'dir_id' is in the subquery result
SELECT dir_fname, dir_lname
FROM director
WHERE dir_id IN (
-- Selecting 'dir_id' from 'movie_direction' where 'mov_id' is in the subquery result
SELECT dir_id
FROM movie_direction
WHERE mov_id IN (
-- Selecting 'mov_id' from 'movie_cast' where 'role' is any value in the subquery result
SELECT mov_id
FROM movie_cast
WHERE role = ANY (
-- Selecting 'role' from 'movie_cast' where 'mov_id' is in the subquery result
SELECT role
FROM movie_cast
WHERE mov_id IN (
-- Selecting 'mov_id' from 'movie' where 'mov_title' is 'Eyes Wide Shut'
SELECT mov_id
FROM movie
WHERE mov_title='Eyes Wide Shut'
)
)
)
);
Sample Output:
dir_fname | dir_lname ----------------------+---------------------- Stanley | Kubrick (1 row)
Code Explanation:
The said query in SQL that retrieves the first and last name of the
director(s) who directed a movie in which any actor played
a role that was also played in the movie 'Eyes Wide Shut'.
1. In the innermost subquery, it selects the mov_id of the movie 'Eyes Wide Shut' from the movie table.
Then, it uses that mov_id to select all roles played in
that movie from the movie_cast table.
2. Then that list of roles are use to select all mov_id values from the movie_cast table where the same
roles were played. This effectively finds all movies that have at
least one actor playing the same roles as in 'Eyes Wide Shut'.
3. Then, it selects the dir_id values from the movie_direction table for each of those movies found in the step 2.
4. Then the outermost query selects the first and last names of
the director(s) whose dir_id values were found in the step 3.
Alternative Solutions:
Alternative 1:
SELECT d.dir_fname, d.dir_lname
FROM director d
JOIN movie_direction md ON d.dir_id = md.dir_id
JOIN movie_cast mc ON md.mov_id = mc.mov_id
WHERE mc.role = ANY (
SELECT mc2.role
FROM movie_cast mc2
JOIN movie m ON mc2.mov_id = m.mov_id
WHERE m.mov_title = 'Eyes Wide Shut'
);
Explanation:
This query retrieves directors who have worked on the movie "Eyes Wide Shut" by navigating through the relationships between the director, movie_direction, and movie_cast tables, filtering based on the role of cast members.
Alternative 2:
SELECT d.dir_fname, d.dir_lname
FROM director d
JOIN movie_direction md ON d.dir_id = md.dir_id
JOIN movie_cast mc ON md.mov_id = mc.mov_id
JOIN movie m ON mc.mov_id = m.mov_id
WHERE m.mov_title = 'Eyes Wide Shut';
Explanation:
This SQL query retrieves the first and last names of directors (dir_fname and dir_lname) who have worked on the movie "Eyes Wide Shut". It joins the director table with the movie_direction table based on the director IDs (dir_id). This allows us to associate directors with movies.
Alternative 3:
SELECT d.dir_fname, d.dir_lname
FROM director d
WHERE EXISTS (
SELECT 1
FROM movie_direction md
JOIN movie_cast mc ON md.mov_id = mc.mov_id
WHERE md.dir_id = d.dir_id
AND mc.role = ANY (
SELECT mc2.role
FROM movie_cast mc2
JOIN movie m ON mc2.mov_id = m.mov_id
WHERE m.mov_title = 'Eyes Wide Shut'
)
);
Explanation:
This query retrieves directors who have worked on the movie "Eyes Wide Shut" by checking if there exists a connection between the director, movie direction, and movie cast tables for that specific movie title.
Alternative 4:
SELECT d.dir_fname, d.dir_lname
FROM director d, movie_direction md, movie_cast mc, movie m
WHERE d.dir_id = md.dir_id
AND md.mov_id = mc.mov_id
AND mc.mov_id = m.mov_id
AND mc.role = ANY (
SELECT mc2.role
FROM movie_cast mc2
WHERE mc2.mov_id = (
SELECT mov_id
FROM movie
WHERE mov_title = 'Eyes Wide Shut'
)
);
Explanation:
This query retrieves directors who have worked on the movie "Eyes Wide Shut" by joining multiple tables ('director', 'movie_direction', 'movie_cast', and 'movie') and applying conditions to establish the relationships and filter the results based on roles.
Practice Online
Query Visualization:
Duration:
Rows:
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 the actors who played a role in the movie 'Annie Hall'. Return all the fields of actor table.
Next: 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.
What is the difficulty level of this exercise?
Test your Programming skills with w3resource's quiz.
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://www.w3resource.com/sql-exercises/movie-database-exercise/sql-exercise-movie-database-15.php
- Weekly Trends and Language Statistics
- Weekly Trends and Language Statistics