Anusha Murali

Logo

Please see github.com/anusha-murali for all of my repositories.

View GitHub Profile

46. Contest Leaderboard: Solution


You did such a great job helping Julia with her last coding contest challenge that she wants you to work on this one, too!

The total score of a hacker is the sum of their maximum scores for all of the challenges. Write a query to print the hacker_id, name, and total score of the hackers ordered by the descending score. If more than one hacker achieved the same total score, then sort the result by ascending hacker_id. Exclude all hackers with a total score of 0 from your result.

The following tables contain contest data:

HACKERS: The hacker_id is the id of the hacker, and name is the name of the hacker.

44_1

SUBMISSIONS: The submission_id is the id of the submission, hacker_id is the id of the hacker who made the submission, challenge_id is the id of the challenge that the submission belongs to, and score is the score of the submission.

44_4

Sample Input

46_3

46_4

Sample Output

4071 Rose 191
74842 Lisa 174
84072 Bonnie 100
4806 Angela 89
26071 Frank 85
80305 Kimberly 67
49438 Patrick 43

Explanation

Hacker 4071 submitted solutions for challenges 19797 and 49593, so the total score = 95 + max(43, 96) = 191.

Hacker 74842 submitted solutions for challenges 19797 and 63132, so the total score = max(98, 5) + 76 = 174.

Hacker 84072 submitted solutions for challenges 49593 and 63132, so the total score = 100 + 0 = 100.

The total scores for hackers 4806, 26071, 80305, and 49438 can be similarly calculated.

solution_image5

We will build the solution to this problem gradually in three steps as follows:

Step 1: For each hacker, we will first find the maximum score for each of the CHALLENGE_ID that they participated. This can be obtained by the following query:

SELECT HACKER_ID, CHALLENGE_ID, MAX(SCORE) M_SCORE
FROM SUBMISSIONS
GROUP BY HACKER_ID, CHALLENGE_ID;

As indicated in the last sentence of the problem statement, we will exclude all hackers with a total score of 0. So, the above query becomes:

SELECT HACKER_ID, CHALLENGE_ID, MAX(SCORE) M_SCORE
FROM SUBMISSIONS
GROUP BY HACKER_ID, CHALLENGE_ID
HAVING MAX(SCORE) > 0;

Step 2: Now we can sum up the maximum scores received on all the challenges for each hacker as follows:

SELECT H.HACKER_ID, H.NAME, SUM(IV.M_SCORE) SUM_SCORE
FROM HACKERS H, 
       (SELECT HACKER_ID, CHALLENGE_ID, MAX(SCORE) M_SCORE
        FROM SUBMISSIONS
        GROUP BY HACKER_ID, CHALLENGE_ID
        HAVING MAX(SCORE) > 0) IV
WHERE H.HACKER_ID = IV.HACKER_ID
GROUP BY H.HACKER_ID, H.NAME;

As can be seen, we have embedded the first query as an inline view in the above query so that we can sum up all the maximum scores for each hacker.

Step 3: Since the problem statement is asking as to order the results by descending score, and to also order the results by hacker_id if more than one hacker achieved the same total score, we obtain the final query as follows:

SELECT H.HACKER_ID, H.NAME, SUM(IV.M_SCORE) SUM_SCORE
FROM HACKERS H, 
       (SELECT HACKER_ID, CHALLENGE_ID, MAX(SCORE) M_SCORE
        FROM SUBMISSIONS
        GROUP BY HACKER_ID, CHALLENGE_ID
        HAVING MAX(SCORE) > 0) IV
WHERE H.HACKER_ID = IV.HACKER_ID
GROUP BY H.HACKER_ID, H.NAME
ORDER BY SUM_SCORE DESC, H.HACKER_ID;

Back to problems


anusha-murali.github.io