w3resource

SQL Exercise: Find the teams who played the heighest audience match


7. From the following tables, write a SQL query to find the highest audience match. Return country name of the teams.

Sample table: soccer_country

 country_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
........
       1229 | NOR          | Norway

View the table

Sample 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
..........
     108 |       51 |    160319 |    1214 |       109 | N         | F          | ET            |         2

View the table

Sample 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
........
       51 | F          | 2016-07-11 | WIN     | N          | 1-0        |    20008 |      70005 |   75868 |       160307 |       161 |       181

View the table

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.

Go to:


PREV : Players scored number of goals in every matches.
NEXT : Player scores last goal for Portugal against Hungary.


Practice Online



Sample Database: soccer

soccer database relationship structure.


Query Visualization:

Duration:

Query visualization of Find the teams who played the heighest audience match - Duration


Rows:

Query visualization of Find the teams who played the heighest audience match - Rows.


Cost:

Query visualization of Find the teams who played the heighest audience match - Cost.


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

What is the difficulty level of this exercise?

Test your Programming skills with w3resource's quiz.



Follow us on Facebook and Twitter for latest update.