w3resource

SQL Exercise: Identify countries where referees managed most matches

SQL soccer Database: Joins Exercise-50 with Solution

50. From the following tables, write a SQL query to find the countries from where the referees managed most of the matches. Return country name, number of matches.

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
       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 table: referee_mast
 referee_id |      referee_name       | country_id
------------+-------------------------+------------
      70001 | Damir Skomina           |       1225
      70002 | Martin Atkinson         |       1206
      70003 | Felix Brych             |       1208
      70004 | Cuneyt Cakir            |       1222
      70005 | Mark Clattenburg        |       1206
      70006 | Jonas Eriksson          |       1220
      70007 | Viktor Kassai           |       1209
      70008 | Bjorn Kuipers           |       1226
      70009 | Szymon Marciniak        |       1213
      70010 | Milorad Mazic           |       1227
      70011 | Nicola Rizzoli          |       1211
      70012 | Carlos Velasco Carballo |       1219
      70013 | William Collum          |       1228
      70014 | Ovidiu Hategan          |       1216
      70015 | Sergei Karasev          |       1217
      70016 | Pavel Kralovec          |       1205
      70017 | Svein Oddvar Moen       |       1229
      70018 | Clement Turpin          |       1207
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
       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          | Norway

Sample Solution:

SQL Code:

-- Selecting the country name and the count of matches officiated by referees from each country
SELECT 
    country_name, -- Selecting the country name
    COUNT(match_no) -- Counting the number of matches for each country
FROM 
    match_mast a -- Specifying the match_mast table with alias 'a'
JOIN 
    referee_mast c ON a.referee_id = c.referee_id -- Joining the match_mast table with the referee_mast table based on referee ID
JOIN 
    soccer_country b ON c.country_id = b.country_id -- Joining the referee_mast table with the soccer_country table based on country ID
GROUP BY 
    country_name -- Grouping the results by country name
HAVING 
    COUNT(match_no) = (
        SELECT 
            MAX(mm) -- Selecting the maximum count of matches
        FROM 
            (
                SELECT 
                    COUNT(match_no) AS mm -- Counting the matches for each country
                FROM 
                    match_mast a
                JOIN 
                    referee_mast c ON a.referee_id = c.referee_id
                JOIN 
                    soccer_country b ON c.country_id = b.country_id
                GROUP BY 
                    country_name -- Grouping by country name
            ) hh -- Subquery alias
    );

Sample Output:

 country_name | count
--------------+-------
 England      |     7
(1 row)

Code Explanation:

The said query in SQL that selects the name of countries and the count of match numbers in the match_mast table for each country.
The JOIN clause in this query then joins the match_mast and referee_mast tables based on the referee_id column and joins the results with soccer_country tables based on the country_id column.
The query groups the results by country name using the GROUP BY clause and applies an aggregate function, count(), to count the number of match numbers for each country. The HAVING clause filters the results to only show the countries whose count of match numbers is equal to the maximum count of match numbers among all countries. The maximum count of match numbers is obtained by a subquery that selects the count of match numbers for each country and then selects the maximum count from those results.

Alternative Solutions:

Using Window Functions:

-- Selecting the country name and the match count for the top-ranked country in terms of the number of matches officiated by referees from each country
SELECT 
    country_name, -- Selecting the country name
    match_count -- Selecting the match count
FROM 
    (
        -- Subquery to calculate the match count and rank for each country
        SELECT 
            b.country_name, -- Selecting the country name
            COUNT(a.match_no) AS match_count, -- Counting the number of matches for each country
            RANK() OVER (ORDER BY COUNT(a.match_no) DESC) AS rank -- Ranking the countries based on match count in descending order
        FROM 
            match_mast a -- Specifying the match_mast table with alias 'a'
        JOIN 
            referee_mast c ON a.referee_id = c.referee_id -- Joining the match_mast table with the referee_mast table based on referee ID
        JOIN 
            soccer_country b ON c.country_id = b.country_id -- Joining the referee_mast table with the soccer_country table based on country ID
        GROUP BY 
            country_name -- Grouping the results by country name
    ) ranked -- Alias for the subquery
	-- Selecting only the rows where the rank is 1, i.e., the top-ranked country
WHERE 
    rank = 1; 

Explanation:

This query uses a window function RANK() to assign a rank to each country based on the count of matches. It then selects the country with rank 1, which corresponds to the country with the highest match count.

Using JOIN with Subquery:

-- Selecting the country name and the count of matches for each country
SELECT 
    b.country_name, -- Selecting the country name
    COUNT(a.match_no) -- Counting the number of matches for each country
FROM 
    match_mast a -- Specifying the match_mast table with alias 'a'
JOIN 
    referee_mast c ON a.referee_id = c.referee_id -- Joining the match_mast table with the referee_mast table based on referee ID
JOIN 
    soccer_country b ON c.country_id = b.country_id -- Joining the referee_mast table with the soccer_country table based on country ID
JOIN 
    (
        -- Subquery to calculate the maximum match count for each country
        SELECT 
            c.country_id, -- Selecting the country ID
            COUNT(a.match_no) AS match_count -- Counting the number of matches for each country
        FROM 
            match_mast a -- Specifying the match_mast table with alias 'a'
        JOIN 
            referee_mast c ON a.referee_id = c.referee_id -- Joining the match_mast table with the referee_mast table based on referee ID
        JOIN 
            soccer_country b ON c.country_id = b.country_id -- Joining the referee_mast table with the soccer_country table based on country ID
        GROUP BY 
            c.country_id -- Grouping the results by country ID
        HAVING 
            COUNT(a.match_no) = (
                -- Subquery to find the maximum match count across all countries
                SELECT 
                    MAX(match_count) -- Selecting the maximum match count
                FROM 
                    (
                        -- Subquery to calculate the match count for each country
                        SELECT 
                            COUNT(a.match_no) AS match_count -- Counting the number of matches for each country
                        FROM 
                            match_mast a -- Specifying the match_mast table with alias 'a'
                        JOIN 
                            referee_mast c ON a.referee_id = c.referee_id -- Joining the match_mast table with the referee_mast table based on referee ID
                        JOIN 
                            soccer_country b ON c.country_id = b.country_id -- Joining the referee_mast table with the soccer_country table based on country ID
                        GROUP BY 
                            c.country_id -- Grouping the results by country ID
                    ) subquery -- Alias for the subquery
            )
    ) max_count ON b.country_id = max_count.country_id -- Joining with the subquery to filter the top-ranked countries
	-- Grouping the results by country name
GROUP BY 
    b.country_name; 

Explanation:

This query first calculates the match count for each country using a subquery. It then joins this result with the main query and filters only the rows where the match count matches the maximum match count found in the subquery.

Practice Online


Sample Database: soccer

soccer database relationship structure

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

Previous SQL Exercise: The number of matches each referee has managed.
Next SQL Exercise: Find the referees managed the number of matches.

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.