SQL Exercise: Find the teams who played the heighest audience match
SQL soccer Database: Subqueries Exercise-7 with Solution
7. From the following tables, write a SQL query to find the highest audience match. Return country name of the teams.
Sample table: soccer_countrycountry_id | country_abbr | country_name ------------+--------------+--------------------- 1201 | ALB | Albania 1202 | AUT | Austria 1203 | BEL | Belgium 1204 | CRO | Croatia 1205 | CZE | Czech Republic 1206 | ENG | England 1207 | FRA | France 1208 | GER | Germany 1209 | HUN | Hungary 1210 | ISL | Iceland 1211 | ITA | Italy 1212 | NIR | Northern Ireland 1213 | POL | Poland 1214 | POR | Portugal 1215 | IRL | Republic of Ireland 1216 | ROU | Romania 1217 | RUS | Russia 1218 | SVK | Slovakia 1219 | ESP | Spain 1220 | SWE | Sweden 1221 | SUI | Switzerland 1222 | TUR | Turkey 1223 | UKR | Ukraine 1224 | WAL | Wales 1225 | SLO | Slovenia 1226 | NED | Netherlands 1227 | SRB | Serbia 1228 | SCO | Scotland 1229 | NOR | NorwaySample table: goal_details
goal_id | match_no | player_id | team_id | goal_time | goal_type | play_stage | goal_schedule | goal_half ---------+----------+-----------+---------+-----------+-----------+------------+---------------+----------- 1 | 1 | 160159 | 1207 | 57 | N | G | NT | 2 2 | 1 | 160368 | 1216 | 65 | P | G | NT | 2 3 | 1 | 160154 | 1207 | 89 | N | G | NT | 2 4 | 2 | 160470 | 1221 | 5 | N | G | NT | 1 5 | 3 | 160547 | 1224 | 10 | N | G | NT | 1 6 | 3 | 160403 | 1218 | 61 | N | G | NT | 2 7 | 3 | 160550 | 1224 | 81 | N | G | NT | 2 8 | 4 | 160128 | 1206 | 73 | N | G | NT | 2 9 | 4 | 160373 | 1217 | 93 | N | G | ST | 2 10 | 5 | 160084 | 1204 | 41 | N | G | NT | 1 11 | 6 | 160298 | 1213 | 51 | N | G | NT | 2 12 | 7 | 160183 | 1208 | 19 | N | G | NT | 1 13 | 7 | 160180 | 1208 | 93 | N | G | ST | 2 14 | 8 | 160423 | 1219 | 87 | N | G | NT | 2 15 | 9 | 160335 | 1215 | 48 | N | G | NT | 2 16 | 9 | 160327 | 1215 | 71 | O | G | NT | 2 17 | 10 | 160244 | 1211 | 32 | N | G | NT | 1 18 | 10 | 160252 | 1211 | 93 | N | G | ST | 2 19 | 11 | 160207 | 1209 | 62 | N | G | NT | 2 20 | 11 | 160200 | 1209 | 87 | N | G | NT | 2 21 | 12 | 160320 | 1214 | 31 | N | G | NT | 1 22 | 12 | 160221 | 1210 | 50 | N | G | NT | 2 23 | 13 | 160411 | 1218 | 32 | N | G | NT | 1 24 | 13 | 160405 | 1218 | 45 | N | G | NT | 1 25 | 13 | 160380 | 1217 | 80 | N | G | NT | 2 26 | 14 | 160368 | 1216 | 18 | P | G | NT | 1 27 | 14 | 160481 | 1221 | 57 | N | G | NT | 2 28 | 15 | 160160 | 1207 | 90 | N | G | NT | 2 29 | 15 | 160154 | 1207 | 96 | N | G | ST | 2 30 | 16 | 160547 | 1224 | 42 | N | G | NT | 1 31 | 16 | 160138 | 1206 | 56 | N | G | NT | 2 32 | 16 | 160137 | 1206 | 93 | N | G | ST | 2 33 | 17 | 160262 | 1212 | 49 | N | G | NT | 2 34 | 17 | 160275 | 1212 | 96 | N | G | ST | 2 35 | 19 | 160248 | 1211 | 88 | N | G | NT | 2 36 | 20 | 160085 | 1204 | 37 | N | G | NT | 1 37 | 20 | 160086 | 1204 | 59 | N | G | NT | 2 38 | 20 | 160115 | 1205 | 76 | N | G | NT | 2 39 | 20 | 160114 | 1205 | 89 | P | G | NT | 2 40 | 21 | 160435 | 1219 | 34 | N | G | NT | 1 41 | 21 | 160436 | 1219 | 37 | N | G | NT | 1 42 | 21 | 160435 | 1219 | 48 | N | G | NT | 2 43 | 22 | 160067 | 1203 | 48 | N | G | NT | 2 44 | 22 | 160064 | 1203 | 61 | N | G | NT | 2 45 | 22 | 160067 | 1203 | 70 | N | G | NT | 2 46 | 23 | 160224 | 1210 | 40 | P | G | NT | 1 47 | 23 | 160216 | 1210 | 88 | O | G | NT | 2 48 | 25 | 160023 | 1201 | 43 | N | G | NT | 1 49 | 27 | 160544 | 1224 | 11 | N | G | NT | 1 50 | 27 | 160538 | 1224 | 20 | N | G | NT | 1 51 | 27 | 160547 | 1224 | 67 | N | G | NT | 2 52 | 29 | 160287 | 1213 | 54 | N | G | NT | 2 53 | 30 | 160182 | 1208 | 30 | N | G | NT | 1 54 | 31 | 160504 | 1222 | 10 | N | G | NT | 1 55 | 31 | 160500 | 1222 | 65 | N | G | NT | 2 56 | 32 | 160435 | 1219 | 7 | N | G | NT | 1 57 | 32 | 160089 | 1204 | 45 | N | G | NT | 1 58 | 32 | 160085 | 1204 | 87 | N | G | NT | 2 59 | 33 | 160226 | 1210 | 18 | N | G | NT | 1 60 | 33 | 160042 | 1202 | 60 | N | G | NT | 2 61 | 33 | 160226 | 1210 | 94 | N | G | ST | 2 62 | 34 | 160203 | 1209 | 19 | N | G | NT | 1 63 | 34 | 160320 | 1214 | 42 | N | G | NT | 1 64 | 34 | 160202 | 1209 | 47 | N | G | NT | 2 65 | 34 | 160322 | 1214 | 50 | N | G | NT | 2 66 | 34 | 160202 | 1209 | 55 | N | G | NT | 2 67 | 34 | 160322 | 1214 | 62 | N | G | NT | 2 68 | 35 | 160333 | 1215 | 85 | N | G | NT | 2 69 | 36 | 160063 | 1203 | 84 | N | G | NT | 2 70 | 37 | 160287 | 1213 | 39 | N | R | NT | 1 71 | 37 | 160476 | 1221 | 82 | N | R | NT | 2 72 | 38 | 160262 | 1212 | 75 | O | R | NT | 2 73 | 39 | 160321 | 1214 | 117 | N | R | ET | 2 74 | 40 | 160333 | 1215 | 2 | P | R | NT | 1 75 | 40 | 160160 | 1207 | 58 | N | R | NT | 2 76 | 40 | 160160 | 1207 | 61 | N | R | NT | 2 77 | 41 | 160165 | 1208 | 8 | N | R | NT | 1 78 | 41 | 160182 | 1208 | 43 | N | R | NT | 1 79 | 41 | 160173 | 1208 | 63 | N | R | NT | 2 80 | 42 | 160050 | 1203 | 10 | N | R | NT | 1 81 | 42 | 160065 | 1203 | 78 | N | R | NT | 2 82 | 42 | 160062 | 1203 | 80 | N | R | NT | 2 83 | 42 | 160058 | 1203 | 90 | N | R | NT | 2 84 | 43 | 160236 | 1211 | 33 | N | R | NT | 1 85 | 43 | 160252 | 1211 | 91 | N | R | ST | 2 86 | 44 | 160136 | 1206 | 4 | P | R | NT | 1 87 | 44 | 160219 | 1210 | 6 | N | R | NT | 1 88 | 44 | 160230 | 1210 | 18 | N | R | NT | 1 89 | 45 | 160297 | 1213 | 2 | N | Q | NT | 1 90 | 45 | 160316 | 1214 | 33 | N | Q | NT | 1 91 | 46 | 160063 | 1203 | 13 | N | Q | NT | 1 92 | 46 | 160539 | 1224 | 31 | N | Q | NT | 1 93 | 46 | 160550 | 1224 | 55 | N | Q | NT | 2 94 | 46 | 160551 | 1224 | 86 | N | Q | NT | 2 95 | 47 | 160177 | 1208 | 65 | N | Q | NT | 2 96 | 47 | 160235 | 1211 | 78 | P | Q | NT | 2 97 | 48 | 160159 | 1207 | 12 | N | Q | NT | 1 98 | 48 | 160155 | 1207 | 20 | N | Q | NT | 1 99 | 48 | 160154 | 1207 | 43 | N | Q | NT | 1 100 | 48 | 160160 | 1207 | 45 | N | Q | NT | 1 101 | 48 | 160230 | 1210 | 56 | N | Q | NT | 2 102 | 48 | 160159 | 1207 | 59 | N | Q | NT | 2 103 | 48 | 160221 | 1210 | 84 | N | Q | NT | 2 104 | 49 | 160322 | 1214 | 50 | N | S | NT | 2 105 | 49 | 160320 | 1214 | 53 | N | S | NT | 2 106 | 50 | 160160 | 1207 | 47 | P | S | ST | 1 107 | 50 | 160160 | 1207 | 72 | N | S | NT | 2 108 | 51 | 160319 | 1214 | 109 | N | F | ET | 2Sample table: match_mast
match_no | play_stage | play_date | results | decided_by | goal_score | venue_id | referee_id | audence | plr_of_match | stop1_sec | stop2_sec ----------+------------+------------+---------+------------+------------+----------+------------+---------+--------------+-----------+----------- 1 | G | 2016-06-11 | WIN | N | 2-1 | 20008 | 70007 | 75113 | 160154 | 131 | 242 2 | G | 2016-06-11 | WIN | N | 0-1 | 20002 | 70012 | 33805 | 160476 | 61 | 182 3 | G | 2016-06-11 | WIN | N | 2-1 | 20001 | 70017 | 37831 | 160540 | 64 | 268 4 | G | 2016-06-12 | DRAW | N | 1-1 | 20005 | 70011 | 62343 | 160128 | 0 | 185 5 | G | 2016-06-12 | WIN | N | 0-1 | 20007 | 70006 | 43842 | 160084 | 125 | 325 6 | G | 2016-06-12 | WIN | N | 1-0 | 20006 | 70014 | 33742 | 160291 | 2 | 246 7 | G | 2016-06-13 | WIN | N | 2-0 | 20003 | 70002 | 43035 | 160176 | 89 | 188 8 | G | 2016-06-13 | WIN | N | 1-0 | 20010 | 70009 | 29400 | 160429 | 360 | 182 9 | G | 2016-06-13 | DRAW | N | 1-1 | 20008 | 70010 | 73419 | 160335 | 67 | 194 10 | G | 2016-06-14 | WIN | N | 0-2 | 20004 | 70005 | 55408 | 160244 | 63 | 189 11 | G | 2016-06-14 | WIN | N | 0-2 | 20001 | 70018 | 34424 | 160197 | 61 | 305 12 | G | 2016-06-15 | DRAW | N | 1-1 | 20009 | 70004 | 38742 | 160320 | 15 | 284 13 | G | 2016-06-15 | WIN | N | 1-2 | 20003 | 70001 | 38989 | 160405 | 62 | 189 14 | G | 2016-06-15 | DRAW | N | 1-1 | 20007 | 70015 | 43576 | 160477 | 74 | 206 15 | G | 2016-06-16 | WIN | N | 2-0 | 20005 | 70013 | 63670 | 160154 | 71 | 374 16 | G | 2016-06-16 | WIN | N | 2-1 | 20002 | 70003 | 34033 | 160540 | 62 | 212 17 | G | 2016-06-16 | WIN | N | 0-2 | 20004 | 70016 | 51043 | 160262 | 7 | 411 18 | G | 2016-06-17 | DRAW | N | 0-0 | 20008 | 70008 | 73648 | 160165 | 6 | 208 19 | G | 2016-06-17 | WIN | N | 1-0 | 20010 | 70007 | 29600 | 160248 | 2 | 264 20 | G | 2016-06-17 | DRAW | N | 2-2 | 20009 | 70005 | 38376 | 160086 | 71 | 280 21 | G | 2016-06-18 | WIN | N | 3-0 | 20006 | 70010 | 33409 | 160429 | 84 | 120 22 | G | 2016-06-18 | WIN | N | 3-0 | 20001 | 70004 | 39493 | 160064 | 11 | 180 23 | G | 2016-06-18 | DRAW | N | 1-1 | 20005 | 70015 | 60842 | 160230 | 61 | 280 24 | G | 2016-06-19 | DRAW | N | 0-0 | 20007 | 70011 | 44291 | 160314 | 3 | 200 25 | G | 2016-06-20 | WIN | N | 0-1 | 20004 | 70016 | 49752 | 160005 | 125 | 328 26 | G | 2016-06-20 | DRAW | N | 0-0 | 20003 | 70001 | 45616 | 160463 | 60 | 122 27 | G | 2016-06-21 | WIN | N | 0-3 | 20010 | 70006 | 28840 | 160544 | 62 | 119 28 | G | 2016-06-21 | DRAW | N | 0-0 | 20009 | 70012 | 39051 | 160392 | 62 | 301 29 | G | 2016-06-21 | WIN | N | 0-1 | 20005 | 70017 | 58874 | 160520 | 29 | 244 30 | G | 2016-06-21 | WIN | N | 0-1 | 20007 | 70018 | 44125 | 160177 | 21 | 195 31 | G | 2016-06-22 | WIN | N | 0-2 | 20002 | 70013 | 32836 | 160504 | 60 | 300 32 | G | 2016-06-22 | WIN | N | 2-1 | 20001 | 70008 | 37245 | 160085 | 70 | 282 33 | G | 2016-06-22 | WIN | N | 2-1 | 20008 | 70009 | 68714 | 160220 | 7 | 244 34 | G | 2016-06-22 | DRAW | N | 3-3 | 20004 | 70002 | 55514 | 160322 | 70 | 185 35 | G | 2016-06-23 | WIN | N | 0-1 | 20003 | 70014 | 44268 | 160333 | 79 | 221 36 | G | 2016-06-23 | WIN | N | 0-1 | 20006 | 70003 | 34011 | 160062 | 63 | 195 37 | R | 2016-06-25 | WIN | P | 1-1 | 20009 | 70005 | 38842 | 160476 | 126 | 243 38 | R | 2016-06-25 | WIN | N | 1-0 | 20007 | 70002 | 44342 | 160547 | 5 | 245 39 | R | 2016-06-26 | WIN | N | 0-1 | 20002 | 70012 | 33523 | 160316 | 61 | 198 40 | R | 2016-06-26 | WIN | N | 2-1 | 20004 | 70011 | 56279 | 160160 | 238 | 203 41 | R | 2016-06-26 | WIN | N | 3-0 | 20003 | 70009 | 44312 | 160173 | 62 | 124 42 | R | 2016-06-27 | WIN | N | 0-4 | 20010 | 70010 | 28921 | 160062 | 3 | 133 43 | R | 2016-06-27 | WIN | N | 2-0 | 20008 | 70004 | 76165 | 160235 | 63 | 243 44 | R | 2016-06-28 | WIN | N | 1-2 | 20006 | 70001 | 33901 | 160217 | 5 | 199 45 | Q | 2016-07-01 | WIN | P | 1-1 | 20005 | 70003 | 62940 | 160316 | 58 | 181 46 | Q | 2016-07-02 | WIN | N | 3-1 | 20003 | 70001 | 45936 | 160550 | 14 | 182 47 | Q | 2016-07-03 | WIN | P | 1-1 | 20001 | 70007 | 38764 | 160163 | 63 | 181 48 | Q | 2016-07-04 | WIN | N | 5-2 | 20008 | 70008 | 76833 | 160159 | 16 | 125 49 | S | 2016-07-07 | WIN | N | 2-0 | 20004 | 70006 | 55679 | 160322 | 2 | 181 50 | S | 2016-07-08 | WIN | N | 2-0 | 20005 | 70011 | 64078 | 160160 | 126 | 275 51 | F | 2016-07-11 | WIN | N | 1-0 | 20008 | 70005 | 75868 | 160307 | 161 | 181
Sample Solution:
SQL Code:
-- This SQL query retrieves the country names from the 'soccer_country' table for specific matches with the highest audience count.
SELECT country_name
-- Selects the 'country_name' column.
FROM soccer_country
-- 'soccer_country' is the name of the table being queried.
WHERE country_id IN (
-- The WHERE clause filters rows where 'country_id' is present in the result of the subquery.
SELECT team_id
-- The subquery selects the 'team_id' column.
FROM goal_details
-- 'goal_details' is the name of the table involved in the subquery.
WHERE match_no = (
-- The WHERE clause filters rows where 'match_no' matches the match number in the subquery.
SELECT match_no
-- The subquery selects the 'match_no' column.
FROM match_mast
-- 'match_mast' is the name of the table involved in the subquery.
WHERE audence = (
-- The WHERE clause filters rows where 'audence' matches the maximum audience count in the subquery.
SELECT max(audence)
-- The subquery calculates the maximum audience count in the 'match_mast' table.
FROM match_mast
)
)
ORDER BY audence DESC
-- Orders the result set based on 'audence' in descending order.
);
Sample Output:
country_name -------------- France Iceland (2 rows)
Code Explanation:
The said query in SQL that selects the name of the countries whose teams have scored in the match with the highest audience. The innermost subquery retrieves the maximum audience from the match_mast table. The middle subquery retrieves the match number corresponding to that maximum audience. Finally, the outermost query retrieves the country names of the teams that scored in that match.
Alternative Solutions:
Using JOIN and WHERE:
SELECT DISTINCT sc.country_name
FROM soccer_country sc
JOIN goal_details gd ON sc.country_id = gd.team_id
WHERE gd.match_no IN (
SELECT mm.match_no
FROM match_mast mm
WHERE mm.audence = (
SELECT MAX(audence)
FROM match_mast
)
);
Explanation:
This query uses INNER JOIN to connect the soccer_country and goal_details tables. It then uses WHERE to filter for matches that have the maximum audience, and selects the corresponding country names.
Using EXISTS:
SELECT country_name
FROM soccer_country sc
WHERE EXISTS (
SELECT 1
FROM goal_details gd
WHERE gd.team_id = sc.country_id
AND gd.match_no = (
SELECT match_no
FROM match_mast
WHERE audence = (
SELECT MAX(audence)
FROM match_mast
)
)
);
Explanation:
This query uses EXISTS with correlated subqueries to find countries that have participated in matches with the maximum audience.
Using INNER JOIN with Subqueries:
SELECT DISTINCT sc.country_name
FROM soccer_country sc
JOIN goal_details gd ON sc.country_id = gd.team_id
WHERE gd.match_no IN (
SELECT match_no
FROM match_mast
WHERE audence = (
SELECT MAX(audence)
FROM match_mast
)
);
Explanation:
This query uses INNER JOIN with subqueries to find countries that have participated in matches with the maximum audience.
Practice Online
Sample Database: soccer
Query Visualization:
Duration:
Rows:
Cost:
Have another way to solve this solution? Contribute your code (and comments) through Disqus.
Previous SQL Exercise: Players scored number of goals in every matches.
Next SQL Exercise: Player scores last goal for Portugal against Hungary.
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://w3resource.com/sql-exercises/soccer-database-exercise/sql-subqueries-exercise-soccer-database-7.php
- Weekly Trends and Language Statistics
- Weekly Trends and Language Statistics