题目描述
(通过次数2,430 | 提交次数4,581,通过率53.05%)
表: Teams +----------------+---------+ | Column Name | Type | +----------------+---------+ | team_id | int | | team_name | varchar | +----------------+---------+ team_id 是该表主键. 每一行都包含了一个参加联赛的队伍信息. 表: Matches +-----------------+---------+ | Column Name | Type | +-----------------+---------+ | home_team_id | int | | away_team_id | int | | home_team_goals | int | | away_team_goals | int | +-----------------+---------+ (home_team_id, away_team_id) 是该表主键. 每一行包含了一次比赛信息. home_team_goals 代表主场队得球数. away_team_goals 代表客场队得球数. 获得球数较多的队伍为胜者队伍. 写一段SQL,用来报告联赛信息. 统计数据应使用已进行的比赛来构建,其中 获胜 球队获得 三分 ,而失败球队获得 零分。如果 打平 ,两支球队都得一分。 result 表的每行应包含以下信息: team_name - Teams 表中的队伍名字 matches_played - 主场与客场球队进行的比赛次数. points - 球队获得的总分数. goal_for - 球队在所有比赛中获取的总进球数 goal_against - 球队在所有比赛中,他的对手球队的所有进球数 goal_diff - goal_for - goal_against. 按 points 降序 返回结果表。如果两队或多队得分相同,则按 goal_diff 降序 排列。如果仍然存在平局,则以team_name 按字典顺序 排列它们。 查询的结果格式如下例所示。 示例 1: 输入: Teams 表: +---------+-----------+ | team_id | team_name | +---------+-----------+ | 1 | Ajax | | 4 | Dortmund | | 6 | Arsenal | +---------+-----------+ Matches 表: +--------------+--------------+-----------------+-----------------+ | home_team_id | away_team_id | home_team_goals | away_team_goals | +--------------+--------------+-----------------+-----------------+ | 1 | 4 | 0 | 1 | | 1 | 6 | 3 | 3 | | 4 | 1 | 5 | 2 | | 6 | 1 | 0 | 0 | +--------------+--------------+-----------------+-----------------+ 输出: +-----------+----------------+--------+----------+--------------+-----------+ | team_name | matches_played | points | goal_for | goal_against | goal_diff | +-----------+----------------+--------+----------+--------------+-----------+ | Dortmund | 2 | 6 | 6 | 2 | 4 | | Arsenal | 2 | 2 | 3 | 3 | 0 | | Ajax | 4 | 2 | 5 | 9 | -4 | +-----------+----------------+--------+----------+--------------+-----------+ 解释: Ajax (team_id=1) 有4场比赛: 2败2平. 总分数 = 0 + 0 + 1 + 1 = 2. Dortmund (team_id=4) 有2场比赛: 2胜. 总分数 = 3 + 3 = 6. Arsenal (team_id=6) 有2场比赛: 2平. 总分数 = 1 + 1 = 2. Dortmund 是积分榜上的第一支球队. Ajax和Arsenal 有同样的分数, 但Arsenal的goal_diff高于Ajax, 所以Arsenal在表中的顺序在Ajaxzhi'qian. 来源:力扣(LeetCode) 链接:https://leetcode.cn/problems/league-statistics
//测试数据 Create table If Not Exists Teams (team_id int, team_name varchar(20)); Create table If Not Exists Matches (home_team_id int, away_team_id int, home_team_goals int, away_team_goals int); insert into Teams (team_id, team_name) values ('1', 'Ajax'); insert into Teams (team_id, team_name) values ('4', 'Dortmund'); insert into Teams (team_id, team_name) values ('6', 'Arsenal'); insert into Matches (home_team_id, away_team_id, home_team_goals, away_team_goals) values ('1', '4', '0', '1'); insert into Matches (home_team_id, away_team_id, home_team_goals, away_team_goals) values ('1', '6', '3', '3'); insert into Matches (home_team_id, away_team_id, home_team_goals, away_team_goals) values ('4', '1', '5', '2'); insert into Matches (home_team_id, away_team_id, home_team_goals, away_team_goals) values ('6', '1', '0', '0');
解题思路
Matches表中保存了每场比赛的主客场球队,以及对应的得分。
而题目要求,统计每支球队的参与、得分、进球情况。也就是说,不仅要统计球队作为主场的得分情况,也要统计球队作为客场的得分情况。
那么,我们可以将Matches表中的数据做转换,一行数据转换成2行数据,分别是主场球队视角以及对手球队的得分情况,以及客场球队视角以及对手球队的得分情况。
转换后,直接与Teams表关联,使用GROUP BY+SUM汇总统计即可。
参考SQL
未特别说明的情况下,参考SQL为基于MySQL8.0实现。
select a.team_name, count(1) matches_played, sum(case when b.team_goals > b.against_team_goals then 3 when b.team_goals = b.against_team_goals then 1 else 0 end) points, sum(b.team_goals) goal_for, sum(b.against_team_goals) goal_against, sum(b.team_goals-b.against_team_goals) goal_diff from Teams a inner join ( select home_team_id team_id,home_team_goals team_goals, away_team_id against_team_id,away_team_goals against_team_goals from Matches union all select away_team_id team_id,away_team_goals team_goals, home_team_id against_team_id,home_team_goals against_team_goals from Matches ) b on a.team_id = b.team_id group by a.team_name order by 3 desc,6 desc,1;
本站所有内容均为原创,本站保留所有权利。仅允许非商业用途的转载,但必须注明来源网站、作者、来源链接!否则,由此造成的一切后果,由转载方承担!
干货分享、技术提升、面试笔试、学习交流,欢迎关注公众号:xuesql。QQ学习交流群:209942678。