|
| 1 | +### Problem Statement |
| 2 | + |
| 3 | +Which SQL query lists every game with the goals scored by each team? |
| 4 | + |
| 5 | +The result set should show: `match_id`, `match_date`, `team1`, `score1`, `team2`, `score2`. |
| 6 | + |
| 7 | +**NOTE**: `goal.teamid` is the team id of the player who scored a goal. |
| 8 | + |
| 9 | + |
| 10 | +### Schema Setup |
| 11 | + |
| 12 | +```sql |
| 13 | +CREATE TABLE game ( |
| 14 | + match_id INT PRIMARY KEY, |
| 15 | + match_date DATE, |
| 16 | + stadium VARCHAR(50), |
| 17 | + team1 VARCHAR(50), |
| 18 | + team2 VARCHAR(50) |
| 19 | +); |
| 20 | + |
| 21 | +CREATE TABLE goal ( |
| 22 | + match_id INT, |
| 23 | + team_id VARCHAR(50), |
| 24 | + player VARCHAR(50), |
| 25 | + goal_time TIMESTAMP, |
| 26 | + FOREIGN KEY (match_id) REFERENCES game(match_id) |
| 27 | +); |
| 28 | + |
| 29 | +INSERT INTO game (match_id, match_date, stadium, team1, team2) VALUES |
| 30 | +(1, '2024-09-20', 'Wembley Stadium', 'Manchester United', 'Liverpool'), |
| 31 | +(2, '2024-09-21', 'Camp Nou', 'Barcelona', 'Real Madrid'), |
| 32 | +(3, '2024-09-22', 'Allianz Arena', 'Bayern Munich', 'Borussia Dortmund'), |
| 33 | +(4, '2024-09-23', 'Santiago Bernabéu', 'Real Madrid', 'Atlético Madrid'), |
| 34 | +(5, '2024-09-24', 'Old Trafford', 'Manchester United', 'Arsenal'), |
| 35 | +(6, '2024-09-25', 'Etihad Stadium', 'Manchester City', 'Liverpool'); |
| 36 | + |
| 37 | +INSERT INTO goal (match_id, team_id, player, goal_time) VALUES |
| 38 | +(1, 'Manchester United', 'Marcus Rashford', '15:30:00'), |
| 39 | +(1, 'Liverpool', 'Mohamed Salah', '20:15:00'), |
| 40 | +(2, 'Barcelona', 'Robert Lewandowski', '10:00:00'), |
| 41 | +(2, 'Real Madrid', 'Karim Benzema', '23:00:00'), |
| 42 | +(3, 'Bayern Munich', 'Thomas Muller', '12:00:00'), |
| 43 | +(3, 'Bayern Munich', 'Joshua Kimmich', '18:30:00'), |
| 44 | +(4, 'Real Madrid', 'Vinícius Júnior', '17:00:00'), |
| 45 | +(4, 'Atlético Madrid', 'Antoine Griezmann', '22:30:00'), |
| 46 | +(5, 'Manchester United', 'Bruno Fernandes', '12:15:00'), |
| 47 | +(5, 'Manchester United', 'Marcus Rashford', '19:00:00'), |
| 48 | +(6, 'Liverpool', 'Mohamed Salah', '10:30:00'), |
| 49 | +(6, 'Liverpool', 'Trent Alexander-Arnold', '15:45:00'), |
| 50 | +(6, 'Liverpool', 'Darwin Núñez', '23:00:00'); |
| 51 | +``` |
| 52 | + |
| 53 | + |
| 54 | +### Expected Output |
| 55 | + |
| 56 | +| match_id | match_date | team1 | team_1_goal | team2 | team_2_goal | |
| 57 | +|---|---|---|---|---|---| |
| 58 | +| 1 | 2024-09-20 | Manchester United | 1 | Liverpool | 1 | |
| 59 | +| 2 | 2024-09-21 | Barcelona | 1 | Real Madrid | 1 | |
| 60 | +| 3 | 2024-09-22 | Bayern Munich | 2 | Borussia Dortmund | 0 | |
| 61 | +| 4 | 2024-09-23 | Real Madrid | 1 | Atlético Madrid | 1 | |
| 62 | +| 5 | 2024-09-24 | Manchester United | 2 | Arsenal | 0 | |
| 63 | +| 6 | 2024-09-25 | Manchester City | 0 | Liverpool | 3 | |
| 64 | + |
| 65 | + |
| 66 | +### Solution |
| 67 | + |
| 68 | +```sql |
| 69 | +SELECT ga.match_id, |
| 70 | + ga.match_date, |
| 71 | + team1, |
| 72 | + SUM(CASE WHEN ga.team1 = go.team_id THEN 1 ELSE 0 END) AS team_1_goal, |
| 73 | + team2, |
| 74 | + SUM(CASE WHEN ga.team2 = go.team_id THEN 1 ELSE 0 END) AS team_2_goal |
| 75 | +FROM game ga LEFT JOIN goal go USING(match_id) |
| 76 | +GROUP BY 1, 2, 3, 5 |
| 77 | +``` |
0 commit comments