题目的数据已经上传,可以自行下载
准备工作
create table Student(
SId varchar(10),
Sname varchar(10),
Sage datetime,
Ssex varchar(10)
);
create table Course(
CId varchar(10),
Cname nvarchar(10),
TId varchar(10)
);
create table Teacher(
TId varchar(10),
Tname varchar(10)
);
create table SC(
SId varchar(10),
CId varchar(10),
score decimal(18,1)
);
insert into Student values('01' , '赵雷' , '1990-01-01' , '男');
insert into Student values('02' , '钱电' , '1990-12-21' , '男');
insert into Student values('03' , '孙⻛' , '1990-12-20' , '男');
insert into Student values('04' , '李云' , '1990-12-06' , '男');
insert into Student values('05' , '周梅' , '1991-12-01' , '⼥');
insert into Student values('06' , '吴兰' , '1992-01-01' , '⼥');
insert into Student values('07' , '郑⽵' , '1989-01-01' , '⼥');
insert into Student values('09' , '张三' , '2017-12-20' , '⼥');
insert into Student values('10' , '李四' , '2017-12-25' , '⼥');
insert into Student values('11' , '李四' , '2012-06-06' , '⼥');
insert into Student values('12' , '赵六' , '2013-06-13' , '⼥');
insert into Student values('13' , '孙七' , '2014-06-01' , '⼥');
insert into Course values('01' , '语⽂' , '02');
insert into Course values('02' , '数学' , '01');
insert into Course values('03' , '英语' , '03');
insert into Teacher values('01' , '张三');
insert into Teacher values('02' , '李四');
insert into Teacher values('03' , '王五');
insert into SC values('01' , '01' , 80);
insert into SC values('01' , '02' , 90);
insert into SC values('01' , '03' , 99);
insert into SC values('02' , '01' , 70);
insert into SC values('02' , '02' , 60);
insert into SC values('02' , '03' , 80);
insert into SC values('03' , '01' , 80);
insert into SC values('03' , '02' , 80);
insert into SC values('03' , '03' , 80);
insert into SC values('04' , '01' , 50);
insert into SC values('04' , '02' , 30);
insert into SC values('04' , '03' , 20);
insert into SC values('05' , '01' , 76);
insert into SC values('05' , '02' , 87);
insert into SC values('06' , '01' , 31);
insert into SC values('06' , '03' , 34);
insert into SC values('07' , '02' , 89);
insert into SC values('07' , '03' , 98);
1. 查询 “01” 课程比 “02” 课程成绩高的学生的信息及课程分数
SELECT s.*,
sc1.score AS score_01,
sc2.score AS score_02
FROM Student s
-- 连接学生选“01”课程的成绩记录
JOIN SC sc1 ON s.SId = sc1.SId AND sc1.CId = '01'
-- 连接学生选“02”课程的成绩记录
JOIN SC sc2 ON s.SId = sc2.SId AND sc2.CId = '02'
WHERE sc1.score > sc2.score;
2. 查询同时存在 “01” 课程和 “02” 课程的情况
SELECT DISTINCT sc1.SId
FROM SC sc1
JOIN SC sc2 ON sc1.SId = sc2.SId
WHERE sc1.CId = '01' AND sc2.CId = '02';
3. 查询存在 “01” 课程但可能不存在 “02” 课程的情况(不存在时显示为 null )
SELECT s.SId,
s.Sname,
sc1.score AS score_01,
sc2.score AS score_02
FROM Student s
JOIN SC sc1 ON s.SId = sc1.SId AND sc1.CId = '01'
-- 左连接保证即使没有“02”课程成绩也能显示
LEFT JOIN SC sc2 ON s.SId = sc2.SId AND sc2.CId = '02';
4. 查询不存在 “01” 课程但存在 “02” 课程的情况
SELECT s.*,
sc2.score AS score_02
FROM Student s
JOIN SC sc2 ON s.SId = sc2.SId AND sc2.CId = '02'
WHERE NOT EXISTS (
SELECT 1 FROM SC sc1 WHERE sc1.SId = s.SId AND sc1.CId = '01'
);
5. 查询平均成绩大于等于 60 分的同学的学生编号和学生姓名和平均成绩
SELECT s.SId,
s.Sname,
AVG(sc.score) AS avg_score
FROM Student s
JOIN SC sc ON s.SId = sc.SId
GROUP BY s.SId, s.Sname
HAVING AVG(sc.score) >= 60;
6. 查询在 SC 表存在成绩的学生信息
SELECT DISTINCT s.*
FROM Student s
JOIN SC sc ON s.SId = sc.SId;
7. 查询所有同学的学生编号、学生姓名、选课总数、所有课程的总成绩(没成绩的显示为 null )
SELECT s.SId,
s.Sname,
COUNT(sc.CId) AS course_count,
COALESCE(SUM(sc.score), 0) AS total_score
FROM Student s
-- 左连接保证所有学生都能显示,包括没选课的
LEFT JOIN SC sc ON s.SId = sc.SId
GROUP BY s.SId, s.Sname;
8. 查询 [李] 姓老师的数量
SELECT COUNT(*) AS teacher_count
FROM Teacher
WHERE Tname LIKE '李%';
9. 查询学过 [张三] 老师授课的同学的信息
SELECT DISTINCT s.*
FROM Student s
JOIN SC sc ON s.SId = sc.SId
JOIN Course c ON sc.CId = c.CId
JOIN Teacher t ON c.TId = t.TId
WHERE t.Tname = '张三';
10. 查询没有学全所有课程的同学的信息
-- 先查询出学全所有课程的学生,再取反
SELECT s.*
FROM Student s
WHERE s.SId NOT IN (
SELECT sc.SId
FROM SC sc
GROUP BY sc.SId
HAVING COUNT(DISTINCT sc.CId) = (SELECT COUNT(*) FROM Course)
);
11. 查询至少有一门课与学号为 “01” 的同学所学相同的同学的信息
SELECT DISTINCT s.*
FROM Student s
JOIN SC sc ON s.SId = sc.SId
WHERE sc.CId IN (
SELECT CId FROM SC WHERE SId = '01'
) AND s.SId != '01';
12. 查询和 “01” 号的同学学习的课程完全相同的其他同学的信息
-- 先找出 01 同学学的课程集合,再找学的课程集合与之完全匹配的其他同学
SELECT s.*
FROM Student s
WHERE s.SId != '01'
AND (SELECT GROUP_CONCAT(CId ORDER BY CId) FROM SC WHERE SId = s.SId) =
(SELECT GROUP_CONCAT(CId ORDER BY CId) FROM SC WHERE SId = '01');
13. 查询没学过 “张三” 老师讲授的任一门课程的学生姓名
SELECT Sname
FROM Student
WHERE SId NOT IN (
SELECT DISTINCT SC.SId
FROM SC
JOIN Course ON SC.CId = Course.CId
JOIN Teacher ON Course.TId = Teacher.TId
WHERE Teacher.Tname = '张三'
);
14. 查询两门及其以上不及格课程的同学的学号,姓名及其平均成绩
SELECT s.SId, s.Sname, AVG(sc.score) AS avg_score
FROM Student s
JOIN SC sc ON s.SId = sc.SId
WHERE sc.score < 60
GROUP BY s.SId, s.Sname
HAVING COUNT(sc.CId) >= 2;
15. 检索 “01” 课程分数小于 60,按分数降序排列的学生信息
SELECT s.*, sc.score
FROM Student s
JOIN SC sc ON s.SId = sc.SId
WHERE sc.CId = '01' AND sc.score < 60
ORDER BY sc.score DESC;
16. 按平均成绩从高到低显示所有学生的所有课程的成绩以及平均成绩
SELECT s.SId,
s.Sname,
GROUP_CONCAT(
CONCAT_WS(':', sc.CId, sc.score)
ORDER BY sc.CId
SEPARATOR '; '
) AS course_scores,
AVG(sc.score) AS avg_score
FROM Student s
LEFT JOIN SC sc ON s.SId = sc.SId
GROUP BY s.SId, s.Sname
ORDER BY avg_score DESC;
17. 查询各科成绩最高分、最低分和平均分:以如下形式显示:课程 ID,课程 name,最高分,最低分,平均分,及格率,中等率,优良率,优秀率及格为 >=60,中等为:70 - 80,优良为:80 - 90,优秀为:>=90,要求输出课程号和选修人数,查询结果按人数降序排列,若人数相同,按课程号升序排列
SELECT c.CId,
c.Cname,
COUNT(sc.SId) AS student_count,
MAX(sc.score) AS max_score,
MIN(sc.score) AS min_score,
AVG(sc.score) AS avg_score,
-- 及格率
CONCAT(ROUND(SUM(CASE WHEN sc.score >= 60 THEN 1 ELSE 0 END) / COUNT(sc.SId) * 100, 2), '%') AS pass_rate,
-- 中等率
CONCAT(ROUND(SUM(CASE WHEN sc.score >= 70 AND sc.score < 80 THEN 1 ELSE 0 END) / COUNT(sc.SId) * 100, 2), '%') AS medium_rate,
-- 优良率
CONCAT(ROUND(SUM(CASE WHEN sc.score >= 80 AND sc.score < 90 THEN 1 ELSE 0 END) / COUNT(sc.SId) * 100, 2), '%') AS good_rate,
-- 优秀率
CONCAT(ROUND(SUM(CASE WHEN sc.score >= 90 THEN 1 ELSE 0 END) / COUNT(sc.SId) * 100, 2), '%') AS excellent_rate
FROM Course c
LEFT JOIN SC sc ON c.CId = sc.CId
GROUP BY c.CId, c.Cname
ORDER BY student_count DESC, c.CId ASC;
18. 按各科平均成绩进行排序,并显示排名,Score 重复时保留名次空缺
-- 使用变量实现排名(MySQL 8.0 以下版本方式,8.0+ 可用窗口函数更简洁)
SET @rank := 0;
SET @prev_avg := NULL;
SELECT sub.CId,
sub.avg_score,
CASE
WHEN @prev_avg = sub.avg_score THEN @rank
ELSE @rank := @rank + 1
END AS ranking,
@prev_avg := sub.avg_score
FROM (
SELECT c.CId, AVG(sc.score) AS avg_score
FROM Course c
LEFT JOIN SC sc ON c.CId = sc.CId
GROUP BY c.CId
ORDER BY avg_score DESC
) AS sub;
19. 按各科平均成绩进行排序,并显示排名,Score 重复时不保留名次空缺
-- MySQL 8.0+ 可用窗口函数 RANK()
SELECT c.CId,
AVG(sc.score) AS avg_score,
RANK() OVER (ORDER BY AVG(sc.score) DESC) AS ranking
FROM Course c
LEFT JOIN SC sc ON c.CId = sc.CId
GROUP BY c.CId;
20. 查询学生的总成绩,并进行排名,总分重复时保留名次空缺
-- MySQL 8.0 以下用变量,8.0+ 用窗口函数
SET @rank_total := 0;
SET @prev_total := NULL;
SELECT sub.SId,
sub.Sname,
sub.total_score,
CASE
WHEN @prev_total = sub.total_score THEN @rank_total
ELSE @rank_total := @rank_total + 1
END AS ranking,
@prev_total := sub.total_score
FROM (
SELECT s.SId,
s.Sname,
SUM(sc.score) AS total_score
FROM Student s
LEFT JOIN SC sc ON s.SId = sc.SId
GROUP BY s.SId, s.Sname
ORDER BY total_score DESC
) AS sub;
21. 查询学生的总成绩,并进行排名,总分重复时不保留名次空缺
SELECT
s.SId,
s.Sname,
SUM(sc.score) AS total_score,
DENSE_RANK() OVER (ORDER BY SUM(sc.score) DESC) AS ranking
FROM
Student s
LEFT JOIN
SC sc ON s.SId = sc.SId
GROUP BY
s.SId, s.Sname
ORDER BY
total_score DESC;
22. 统计各科成绩各分数段人数:课程编号,课程名称,[100-85],[85-70],[70-60],[60-0] 及所占百分比
SELECT
c.CId,
c.Cname,
-- 统计[100-85]分数段人数
SUM(CASE WHEN sc.score BETWEEN 85 AND 100 THEN 1 ELSE 0 END) AS '100-85',
-- 计算[100-85]分数段人数占比
CONCAT(ROUND(SUM(CASE WHEN sc.score BETWEEN 85 AND 100 THEN 1 ELSE 0 END) / COUNT(sc.SId) * 100, 2), '%') AS '100-85%',
-- 统计[85-70]分数段人数
SUM(CASE WHEN sc.score BETWEEN 70 AND 84 THEN 1 ELSE 0 END) AS '85-70',
-- 计算[85-70]分数段人数占比
CONCAT(ROUND(SUM(CASE WHEN sc.score BETWEEN 70 AND 84 THEN 1 ELSE 0 END) / COUNT(sc.SId) * 100, 2), '%') AS '85-70%',
-- 统计[70-60]分数段人数
SUM(CASE WHEN sc.score BETWEEN 60 AND 69 THEN 1 ELSE 0 END) AS '70-60',
-- 计算[70-60]分数段人数占比
CONCAT(ROUND(SUM(CASE WHEN sc.score BETWEEN 60 AND 69 THEN 1 ELSE 0 END) / COUNT(sc.SId) * 100, 2), '%') AS '70-60%',
-- 统计[60-0]分数段人数
SUM(CASE WHEN sc.score < 60 THEN 1 ELSE 0 END) AS '60-0',
-- 计算[60-0]分数段人数占比
CONCAT(ROUND(SUM(CASE WHEN sc.score < 60 THEN 1 ELSE 0 END) / COUNT(sc.SId) * 100, 2), '%') AS '60-0%'
FROM
Course c
LEFT JOIN
SC sc ON c.CId = sc.CId
GROUP BY
c.CId, c.Cname;
23. 查询各科成绩前三名的记录
-- 利用窗口函数 ROW_NUMBER 按课程分组并排序取前三名
WITH RankedScores AS (
SELECT
sc.CId,
sc.SId,
sc.score,
ROW_NUMBER() OVER (PARTITION BY sc.CId ORDER BY sc.score DESC) AS rank_num
FROM
SC sc
)
SELECT
rs.CId,
c.Cname,
s.Sname,
rs.score
FROM
RankedScores rs
JOIN
Course c ON rs.CId = c.CId
JOIN
Student s ON rs.SId = s.SId
WHERE
rs.rank_num <= 3
ORDER BY
rs.CId, rs.rank_num;
24. 查询每门课程被选修的学生数
SELECT
c.CId,
c.Cname,
COUNT(DISTINCT sc.SId) AS student_count
FROM
Course c
LEFT JOIN
SC sc ON c.CId = sc.CId
GROUP BY
c.CId, c.Cname;
25. 查询出只选修两门课程的学生学号和姓名
SELECT
s.SId,
s.Sname
FROM
Student s
JOIN
SC sc ON s.SId = sc.SId
GROUP BY
s.SId, s.Sname
HAVING
COUNT(DISTINCT sc.CId) = 2;
26. 查询男生、女生人数
SELECT
Ssex,
COUNT(SId) AS student_count
FROM
Student
GROUP BY
Ssex;
27. 查询名字中含有「风」字的学生信息
SELECT
*
FROM
Student
WHERE
Sname LIKE '%风%';
28. 查询同名同性学生名单,并统计同名人数
SELECT
Sname,
Ssex,
COUNT(SId) AS name_count
FROM
Student
GROUP BY
Sname, Ssex
HAVING
COUNT(SId) > 1;
29. 查询 1990 年出生的学生名单
SELECT
*
FROM
Student
WHERE
YEAR(Sage) = 1990;
30. 查询每门课程的平均成绩,结果按平均成绩降序排列,平均成绩相同时,按课程编号升序排列
SELECT
c.CId,
c.Cname,
AVG(sc.score) AS avg_score
FROM
Course c
LEFT JOIN
SC sc ON c.CId = sc.CId
GROUP BY
c.CId, c.Cname
ORDER BY
avg_score DESC, c.CId ASC;
31. 查询平均成绩大于等于 85 的所有学生的学号、姓名和平均成绩
SELECT s.SId,
s.Sname,
AVG(sc.score) AS avg_score
FROM Student s
JOIN SC sc ON s.SId = sc.SId
GROUP BY s.SId, s.Sname
HAVING AVG(sc.score) >= 85;
32. 查询课程名称为「数学」,且分数低于 60 的学生姓名和分数
SELECT s.Sname,
sc.score
FROM Student s
JOIN SC sc ON s.SId = sc.SId
JOIN Course c ON sc.CId = c.CId
WHERE c.Cname = '数学' AND sc.score < 60;
33. 查询所有学生的课程及分数情况(存在学生没成绩,没选课的情况)
SELECT s.SId,
s.Sname,
c.Cname,
sc.score
FROM Student s
-- 左连接课程表,保证所有学生都显示,不管是否选课
LEFT JOIN SC sc ON s.SId = sc.SId
-- 左连接课程表,保证即使没选课也能关联到课程信息(没选课时课程名称等为 null )
LEFT JOIN Course c ON sc.CId = c.CId;
34. 查询任何一门课程成绩在 70 分以上的姓名、课程名称和分数
SELECT s.Sname,
c.Cname,
sc.score
FROM Student s
JOIN SC sc ON s.SId = sc.SId
JOIN Course c ON sc.CId = c.CId
WHERE sc.score > 70;
35. 查询不及格的课程
SELECT c.CId,
c.Cname,
sc.SId,
sc.score
FROM Course c
JOIN SC sc ON c.CId = sc.CId
WHERE sc.score < 60;
36. 查询课程编号为 01 且课程成绩在 80 分以上的学生的学号和姓名
SELECT s.SId,
s.Sname
FROM Student s
JOIN SC sc ON s.SId = sc.SId
WHERE sc.CId = '01' AND sc.score > 80;
37. 求每门课程的学生人数
SELECT c.CId,
c.Cname,
COUNT(DISTINCT sc.SId) AS student_count
FROM Course c
LEFT JOIN SC sc ON c.CId = sc.CId
GROUP BY c.CId, c.Cname;
38. 成绩不重复,查询选修「张三」老师所授课程的学生中,成绩最高的学生信息及其成绩
-- 先找到张三老师授课的课程编号,再关联 SC 表找到对应课程成绩最高的学生
SELECT s.*,
sc.score
FROM Student s
JOIN SC sc ON s.SId = sc.SId
JOIN Course c ON sc.CId = c.CId
JOIN Teacher t ON c.TId = t.TId
WHERE t.Tname = '张三'
AND sc.score = (
SELECT MAX(score)
FROM SC
WHERE CId IN (SELECT CId FROM Course WHERE TId = (SELECT TId FROM Teacher WHERE Tname = '张三'))
);
39. 成绩有重复的情况下,查询选修「张三」老师所授课程的学生中,成绩最高的学生信息及其成绩
-- 使用窗口函数 RANK() ,成绩相同排名相同,取排名第一的(包含重复成绩情况)
WITH RankedScores AS (
SELECT s.*,
sc.score,
RANK() OVER (ORDER BY sc.score DESC) AS rnk
FROM Student s
JOIN SC sc ON s.SId = sc.SId
JOIN Course c ON sc.CId = c.CId
JOIN Teacher t ON c.TId = t.TId
WHERE t.Tname = '张三'
)
SELECT *
FROM RankedScores
WHERE rnk = 1;
40. 查询不同课程成绩相同的学生的学生编号、课程编号、学生成绩
SELECT sc1.SId,
sc1.CId,
sc1.score
FROM SC sc1
JOIN SC sc2 ON sc1.score = sc2.score AND sc1.CId != sc2.CId AND sc1.SId = sc2.SId;
41. 查询每门课程成绩最好的前两名
WITH RankedScores AS (
SELECT
sc.CId,
sc.SId,
sc.score,
-- 按课程分组,对成绩降序排名
ROW_NUMBER() OVER (PARTITION BY sc.CId ORDER BY sc.score DESC) AS rank_num
FROM
SC sc
)
SELECT
rs.CId,
c.Cname,
s.Sname,
rs.score
FROM
RankedScores rs
JOIN
Course c ON rs.CId = c.CId
JOIN
Student s ON rs.SId = s.SId
WHERE
rs.rank_num <= 2
ORDER BY
rs.CId, rs.rank_num;
42. 统计每门课程的学生选修人数(超过 5 人的课程才统计)
SELECT
c.CId,
c.Cname,
COUNT(DISTINCT sc.SId) AS student_count
FROM
Course c
LEFT JOIN
SC sc ON c.CId = sc.CId
GROUP BY
c.CId, c.Cname
HAVING
COUNT(DISTINCT sc.SId) > 5;
43. 检索至少选修两门课程的学生学号
SELECT
SId
FROM
SC
GROUP BY
SId
HAVING
COUNT(DISTINCT CId) >= 2;
44. 查询选修了全部课程的学生信息
SELECT
s.*
FROM
Student s
WHERE
(SELECT COUNT(DISTINCT CId) FROM SC WHERE SId = s.SId) = (SELECT COUNT(CId) FROM Course);
45. 查询各学生的年龄,只按年份来算
SELECT
SId,
Sname,
-- 用当前年份减去出生年份得到年龄
YEAR(NOW()) - YEAR(Sage) AS age
FROM
Student;
46. 按照出生日期来算,当前月日 < 出生年月的月日则,年龄减一
SELECT
SId,
Sname,
-- 判断当前月日和出生月日,决定年龄计算方式
CASE
WHEN DATE_FORMAT(NOW(), '%m%d') < DATE_FORMAT(Sage, '%m%d')
THEN YEAR(NOW()) - YEAR(Sage) - 1
ELSE YEAR(NOW()) - YEAR(Sage)
END AS age
FROM
Student;
47. 查询本周过生日的学生
SELECT
*
FROM
Student
WHERE
WEEKOFYEAR(Sage) = WEEKOFYEAR(NOW());
48. 查询下周过生日的学生
SELECT
*
FROM
Student
WHERE
WEEKOFYEAR(Sage) = WEEKOFYEAR(NOW()) + 1;
49. 查询本月过生日的学生
SELECT
*
FROM
Student
WHERE
MONTH(Sage) = MONTH(NOW());
50. 查询下月过生日的学生
SELECT
*
FROM
Student
WHERE
MONTH(Sage) = MONTH(NOW()) + 1;