MySQL 系列教程之(十四)50 道 SQL 练习题精讲丨【绽放吧!数据库】
数据表介绍
--1.学生表
Student(SId,Sname,Sage,Ssex)
--SId 学生编号,Sname 学生姓名,Sage 出生年月,Ssex 学生性别
--2.课程表
Course(CId,Cname,TId)
--CId 课程编号,Cname 课程名称,TId 教师编号
--3.教师表
Teacher(TId,Tname)
--TId 教师编号,Tname 教师姓名
--4.成绩表
SC(SId,CId,score)
--SId 学生编号,CId 课程编号,score 分数
练习题目
1.查询" 01 “课程比” 02 "课程成绩高的学生的信息及课程分数
-- 此处可以先考虑分别查询 01和02课程的学员id和分数
select SId,score from SC where CId = '01';
select SId,score from SC where CId = '02';
-- 对比结果可以清楚的知道,两个表中有些SId不对应,不对应就没有可比性
-- 因此可以对两个结果做join,条件就是SId要相等,
-- 并且01的成绩要比02大
select s1.SId,s1.score
from
(select SId,score from SC where CId = '01') s1
join
(select SId,score from SC where CId = '02') s2
on s1.SId = s2.SId
where s1.score > s2.score
-- 通过以上的sql得到了符合条件的学员id和分数,再到学员表中获取学员信息
select stu.SId,stu.Sname,s.score
from student as stu
right join (
select s1.SId,s1.score
from
(select SId,score from SC where CId = '01') s1
join
(select SId,score from SC where CId = '02') s2
on s1.SId = s2.SId
where s1.score > s2.score
) as s
on stu.SId = s.SId;
2.查询同时存在" 01 “课程和” 02 "课程的情况
-- 本题和上一题内容相似,我们只需要把01和02的学员的SID作为连接条件就可以
select s1.*
from
(select SId,score from SC where CId = '01') s1
join
(select SId,score from SC where CId = '02') s2
on s1.SId = s2.SId
3.查询存在" 01 “课程但可能不存在” 02 "课程的情况(不存在时显示为 null )
select s1.SId,s2.score
from
(select SId,score from SC where CId = '01') s1
left join
(select SId,score from SC where CId = '02') s2
on s1.SId = s2.SId
4.查询不存在" 01 “课程但存在” 02 "课程的情况
select * from SC
where SId not in(select SId from SC where CId = '01')
and CId = '02'
5.查询平均成绩大于等于 60 分的同学的学生编号和学生姓名和平均成绩
-- 此题主要考核 分组后的条件过滤
select SC.SId,Sname,round(avg(score),2) as avg_score
from SC,Student
where SC.SId = Student.SId
group by SC.SId,Sname having avg_score >= 60;
6.查询在 SC 表存在成绩的学生信息
-- 此题主要考核 数据去重 distinct
select distinct stu.* from Student stu join SC on SC.SId = stu.SId;
7.查询所有同学的学生编号、学生姓名、选课总数、所有课程的总成绩(没成绩的显示为 null )
select stu.SId,stu.Sname,count(SC.CId) as total ,sum(SC.score) as sum_score
from Student as stu left join SC on stu.SId = SC.SId
group by stu.SId,stu.Sname;
8.查询「李」姓老师的数量
select count(*) from teacher where Tname like '李%';
9.查询学过「张三」老师授课的同学的信息
select stu.*
from Student as stu
join SC on stu.SId = SC.SId
join course as C on SC.CId = C.CId
join Teacher as T on C.TId = T.TId
where T.Tname = '张三';
10.查询没有学全所有课程的同学的信息
-- 排除法,找到所有学过全部课程的学生,
select * from Student where SId not in(
select SId from SC group by SId having count(CId) = (select count(*) from course)
)
11.查询至少有一门课与学号为" 01 "的同学所学相同的同学的信息
select distinct stu.*
from student as stu
left join sc on sc.SId = stu.SId
where sc.CId in (select CId from sc where SId = '01');
12.查询和" 01 "号的同学学习的课程 完全相同的其他同学的信息
-- 注意要对比的是课程ID号,在对比课程数
select s2.SId
from SC as s1 join SC as s2
on s1.CId = s2.CId and s1.SId = '01' and s2.SId != '01'
group by s2.SId
having count(s1.SId) = (select count(*) from SC where SId = '01');
select stu.*
from student as stu
left join sc on sc.SId = stu.SId
join ( select CId from sc where SId = '01') as t on t.CId = sc.CId
group by stu.SId having count(sc.SId) = 5;
13.查询没学过"张三"老师讲授的任一门课程的学生姓名
select SId,Sname from Student where SId not in
(select SId from SC
where CId = (
select Course.Cid from Course
join Teacher on Teacher.TId = Course.TId
where Teacher.Tname = '张三'
))
14.查询两门及其以上不及格课程的同学的学号,姓名及其平均成绩
select SC.SId,Student.Sname,round(avg(SC.score),2) as avg_sc
from SC join Student on Student.SId = SC.SId
where SC.score < 60 group by SC.SId,Student.Sname
having count(SC.CId) >=2;
15.检索" 01 "课程分数小于 60,按分数降序排列的学生信息
select SC.SId,Student.Sname,SC.score
from SC join Student on SC.SId = Student.SId
where SC.CId = '01' and SC.score < 60
order by SC.score desc;
16.按平均成绩从高到低显示所有学生的所有课程的成绩以及平均成绩
select SC.*,s2.avg_sc from SC
join (select SId, avg(score) as avg_sc from SC group by SId) as s2
on SC.SId = s2.SId
order by avg_sc desc, SC.SId;
--最佳解决方案 王宇鹏
select a.sname,b.score 语文,c.score 数学,d.score 英语,avg(e.score)
from student a
left join sc b on a.sid=b.sid and b.cid='01'
left join sc c on a.sid=c.sid and c.cid='02'
left join sc d on a.sid=d.sid and d.cid='03'
left join sc e on a.sid=e.sid
group by a.sname,语文,数学,英语
order by avg(e.score) desc;
17.查询各科成绩最高分、最低分和平均分:
以如下形式显示:课程 ID,课程 name,最高分,最低分,平均分,及格率,中等率,优良率,优秀率 及格为>=60,中等为:70-80,优良为:80-90,优秀为:>=90
要求输出课程号和选修人数,查询结果按人数降序排列,若人数相同,按课程号升序排列
select SC.CId,C.Cname,
max(SC.score) as '最高分',
min(SC.score) as '最低分',
avg(SC.score) as '平均分',
count(SC.CId) as '选修人数',
SUM(CASE WHEN SC.score >= 60 THEN 1 ELSE 0 END) / count(SC.CId) as '及格率',
SUM(CASE WHEN SC.score >= 70 and SC.score < 80 THEN 1 ELSE 0 END) / count(SC.CId) as '中等率',
SUM(CASE WHEN SC.score >= 80 and SC.score < 90 THEN 1 ELSE 0 END) / count(SC.CId) as '优良率',
SUM(CASE WHEN SC.score >= 90 THEN 1 ELSE 0 END) / count(SC.CId) as '优秀率'
from SC,Course as C
where SC.CId = C.CId
group by SC.CId,C.Cname
order by '选修人数' desc,SC.CId;
18.按各科平均成绩进行排序,并显示排名, Score 重复时保留名次空缺
select s1.*,s2.*
from
(select cid,round(avg(score),2) as avg_sc from sc group by cid) as s1
join
(select cid,round(avg(score),2) as avg_sc from sc group by cid) as s2
on s1.avg_sc >= s2.avg_sc
-- 数据不重复
+------+--------+------+--------+
| cid | avg_sc | cid | avg_sc |
+------+--------+------+--------+
| 01 | 67.86 | 01 | 67.86 |
| 02 | 72.50 | 01 | 67.86 |
| 02 | 72.50 | 02 | 72.50 |
| 01 | 67.86 | 03 | 66.83 |
| 02 | 72.50 | 03 | 66.83 |
| 03 | 66.83 | 03 | 66.83 |
+------+--------+------+--------+
-- 数据重复 按照s2中cid分组,去重s1中重复的平均分,在统计
+------+--------+------+--------+
| cid | avg_sc | cid | avg_sc |
+------+--------+------+--------+
| 01 | 67.86 | 01 | 67.86 |
| 02 | 72.50 | 01 | 67.86 |
-- | 04 | 67.86 | 01 | 67.86 |
| 02 | 72.50 | 02 | 72.50 |
| 01 | 67.86 | 03 | 66.83 |
| 02 | 72.50 | 03 | 66.83 |
| 03 | 66.83 | 03 | 66.83 |
-- | 04 | 67.86 | 03 | 66.83 |
| 01 | 67.86 | 04 | 67.86 |
| 02 | 72.50 | 04 | 67.86 |
-- | 04 | 67.86 | 04 | 67.86 |
+------+--------+------+--------+
-- 最终方案
select s1.*,s2.*,count(distinct s1.avg_sc) as rank
from
(select cid,round(avg(score),2) as avg_sc from sc group by cid) as s1
join
(select cid,round(avg(score),2) as avg_sc from sc group by cid) as s2
on s1.avg_sc >= s2.avg_sc
group by s2.cid
order by rank;
--有争议的名次空缺问题
select
@rownum := @rownum+1 as rownum,
IF(@total = A.avg_sc,@rank,@rank := @rownum) as rank,
@total := A.avg_sc,
A.*
from
(
select s2.cid,s2.avg_sc,count(distinct s1.avg_sc) as ranks
from
(select cid,round(avg(score),2) as avg_sc from sc group by cid) as s1
join
(select cid,round(avg(score),2) as avg_sc from sc group by cid) as s2
on s1.avg_sc >= s2.avg_sc
group by s2.cid
order by ranks
) as A,
(select @rank:=0,@rownum:=0) as B
19.按各科平均成绩进行排序,并显示排名, Score 重复时不保留名次空缺
select b.CId,b.avg_sc,@i := @i+1 as Rank
from (select @i := 0) a,
(select CId,round(avg(Score),2) as avg_sc from SC group by CId order by avg_sc desc) b;
20.查询学生的总成绩,并进行排名,总分重复时保留名次空缺
select s2.SId,s2.avg_sc,count(distinct s1.avg_sc) as Rank
from
(select sum(score) as avg_sc from SC group by SId) as s1
join
(select SId,sum(score) as avg_sc from SC group by SId) as s2
on s1.avg_sc >= s2.avg_sc
group by s2.SId order by Rank;
21.查询学生的总成绩,并进行排名,总分重复时不保留名次空缺
select b.SId,b.avg_sc,@i := @i+1 as Rank
from (select @i := 0) a,
(select SId,sum(Score) as avg_sc from SC group by sId order by avg_sc desc) b;
22.统计各科成绩各分数段人数:课程编号,课程名称,[100-85],[85-70],[70-60],[60-0]及所占百分比
select Course.CId,Course.Cname,
sum(CASE WHEN SC.score >= 85 and SC.score <= 100 THEN 1 ELSE 0 END) '[100-85]',
concat(round(sum(CASE WHEN SC.score >= 85 and SC.score <= 100 THEN 1 ELSE 0 END)/count(SC.SId),2)*100,'%') as '百分比',
sum(CASE WHEN SC.score >= 70 and SC.score < 85 THEN 1 ELSE 0 END) '[85-70]',
concat(round(sum(CASE WHEN SC.score >= 70 and SC.score < 85 THEN 1 ELSE 0 END)/count(SC.SId),2)*100,'%') as '百分比',
sum(CASE WHEN SC.score >= 60 and SC.score < 70 THEN 1 ELSE 0 END) '[70-60]',
concat(round(sum(CASE WHEN SC.score >= 60 and SC.score < 70 THEN 1 ELSE 0 END)/count(SC.SId),2)*100,'%') as '百分比',
sum(CASE WHEN SC.score >= 0 and SC.score < 60 THEN 1 ELSE 0 END) '[60-0]',
concat(round(sum(CASE WHEN SC.score >= 0 and SC.score < 60 THEN 1 ELSE 0 END)/count(SC.SId),2)*100,'%') as '百分比'
from SC,Course
where SC.CId = Course.CId
group by Course.CId,Course.Cname;
23.查询各科成绩前三名的记录
(select CId,score from SC where CId = '01' order by score desc limit 3)
union all
(select CId,score from SC where CId = '02' order by score desc limit 3)
union all
(select CId,score from SC where CId = '03' order by score desc limit 3)
24.查询每门课程被选修的学生数
select CId,count(SId) from SC group by CId;
25.查询出只选修两门课程的学生学号和姓名
select SC.SId,Student.Sname
from SC join Student on SC.SId = Student.SId
group by SC.SId,Student.Sname having count(SC.CId) = 2;
26.查询男生、女生人数
select Ssex,count(*) from Student group by Ssex;
27.查询名字中含有「风」字的学生信息
select * from Student where Sname like '%风%';
28.查询同名同性学生名单,并统计同名人数
select s1.Sname,count(s1.Sname)
from Student s1 join Student s2
on s1.Sname = s2.Sname and s1.Ssex = s2.Ssex and s1.SId != s2.SId
group by s1.Sname;
29.查询 1990 年出生的学生名单
select * from Student where year(Sage) = 1990;
30.查询每门课程的平均成绩,结果按平均成绩降序排列,平均成绩相同时,按课程编号升序排列
select CId,avg(score) as avg_sc
from SC group by CId order by avg_sc desc,CId;
31.查询平均成绩大于等于 85 的所有学生的学号、姓名和平均成绩
select SC.SId,Stu.Sname,round(avg(SC.score),2) as avg_sc
from SC join Student as Stu on SC.SId = Stu.SId
group by SC.SId,Stu.Sname having avg_sc >= 85;
32.查询课程名称为「数学」,且分数低于 60 的学生姓名和分数
select C.Cname,Stu.Sname,SC.score
from Course as C join SC on C.CId = SC.CId
join Student as Stu on SC.SId = Stu.SId
where C.Cname = '数学' and SC.score < 60;
33.查询所有学生的课程及分数情况(存在学生没成绩,没选课的情况)
select Student.Sname,Course.Cname,SC.score
from Student left join SC on Student.SId = SC.SId
left join Course on SC.CId = Course.CId
order by Student.Sname;
-- 张波
select a.SId,a.sname,b.score 语文,c.score 数学,d.score 英语
from student a
left join sc b on a.sid=b.sid and b.cid='01'
left join sc c on a.sid=c.sid and c.cid='02'
left join sc d on a.sid=d.sid and d.cid='03'
group by a.SId,a.sname,语文,数学,英语
order by a.Sid;
34.查询任何一门课程成绩在 70 分以上的姓名、课程名称和分数
select Student.Sname,Course.Cname,SC.score
from Student,Course,SC
where Student.SId = SC.SId and SC.CId = Course.CId
and SC.score > 70;
35.查询不及格的课程
select Student.Sname,Course.Cname,SC.score
from Student,Course,SC
where Student.SId = SC.SId and SC.CId = Course.CId
and SC.score < 60;
36.查询课程编号为 01 且课程成绩在 80 分以上的学生的学号和姓名
select SC.SId,Student.Sname
from SC join Student on SC.SId = Student.SId
where SC.Score > 80 and SC.CId = '01';
37.求每门课程的学生人数
select CId,count(SId) from SC group by CId;
38.成绩不重复,查询选修「张三」老师所授课程的学生中,成绩最高的学生信息及其成绩
select Student.SId,Student.Sname,SC.score
from Student join SC on Student.SId = SC.SId
join Course on SC.CId = Course.CId
join Teacher on Teacher.TId = Course.TId
where Teacher.Tname = '张三';
order by SC.score desc limit 1;
39.成绩有重复的情况下,查询选修「张三」老师所授课程的学生中,成绩最高的学生信息及其成绩
-- 查询张三老师授课的学生中最高分数,查询所有等于最高分的
-- -- 先查询最高分数
-- select max(SC.score)
-- from SC join Course on SC.CId = Course.CId
-- join Teacher on Teacher.TId = Course.TId
-- where Teacher.Tname = '张三'
-- 追加 分数条件
select Student.SId,Student.Sname,SC.score
from Student join SC on Student.SId = SC.SId
join Course on SC.CId = Course.CId
join Teacher on Teacher.TId = Course.TId
where Teacher.Tname = '张三'
and SC.score = (select max(SC.score)
from SC join Course on SC.CId = Course.CId
join Teacher on Teacher.TId = Course.TId
where Teacher.Tname = '张三');
-- 王宇鹏
select a.sname,b.score
from student a join sc b on a.sid=b.sid
and b.cid in (select cid from course where tid in (select tid from teacher where tname='张三'))
join (select cid,max(score) m from sc group by cid) c on b.cid=c.cid and b.score=c.m;
40.查询不同课程成绩相同的学生的学生编号、课程编号、学生成绩
select distinct s1.SId,s1.CId,s1.Score
from SC s1 join SC s2
on s1.CId != s2.CId and s1.score = s2.score
group by s1.SId,s1.CId,s1.Score
41.查询每门课程成绩最好的前两名
(select CId,score from SC where CId = '01' order by score desc limit 2)
union all
(select CId,score from SC where CId = '02' order by score desc limit 2)
union all
(select CId,score from SC where CId = '03' order by score desc limit 2)
42.统计每门课程的学生选修人数(超过 5 人的课程才统计)。
select CId,count(SId) from SC group by CId having count(SId) > 5;
43.检索至少选修两门课程的学生学号
select SId,count(CId) as num from SC group by SId having num >=2;
44.查询选修了全部课程的学生信息
select SId from SC group by SId
having count(CId) = (select count(*) from Course);
45.查询各学生的年龄,只按年份来算
select Stu.SId,Stu.Sname,(year(now()) - year(Stu.Sage)) as '年龄'
from Student as stu;
46.按照出生日期来算,当前月日 < 出生年月的月日则,年龄减一
TIMESTAMPDIFF() 从日期时间表达式中减去间隔
https://dev.mysql.com/doc/refman/5.7/en/date-and-time-functions.html
select student.SId,student.Sname,
TIMESTAMPDIFF(YEAR,student.Sage,CURDATE()) from student
47.查询本周过生日的学生
返回日期从范围内的数字日历星期1到53
select *from student
where WEEKOFYEAR(student.Sage)=WEEKOFYEAR(CURDATE());
48.查询下周过生日的学生
select *
from student
where WEEKOFYEAR(student.Sage)=WEEKOFYEAR(CURDATE())+1;
49.查询本月过生日的学生
select *
from student
where MONTH(student.Sage)=MONTH(CURDATE());
50.查询下月过生日的学生
select *
from student
where MONTH(student.Sage)=MONTH(CURDATE())+1;
数据Data
--学生表 Student
create table Student(SId varchar(10),Sname varchar(10),Sage datetime,Ssex varchar(10));
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' , '女');
-- 科目表 Course
create table Course(CId varchar(10),Cname nvarchar(10),TId varchar(10));
insert into Course values('01' , '语文' , '02');
insert into Course values('02' , '数学' , '01');
insert into Course values('03' , '英语' , '03');
-- 教师表 Teacher
create table Teacher(TId varchar(10),Tname varchar(10));
insert into Teacher values('01' , '张三');
insert into Teacher values('02' , '李四');
insert into Teacher values('03' , '王五');
-- 成绩表 SC
create table SC(SId varchar(10),CId varchar(10),score decimal(18,1));
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);
【绽放吧!数据库】有奖征文火热进行中:https://bbs.huaweicloud.com/blogs/285617
- 点赞
- 收藏
- 关注作者
评论(0)