学生表:student(学号sno,学生姓名sname,出生年月sbirth,性别ssex)
成绩表:score(学号sno,课程号cno,成绩score)
课程表:course(课程号cno,课程名称cname,教师号ctno)
教师表:teacher(教师号tno,教师姓名tname)
注意:下面SQL的实现以MySQL为主
/*
分析思路
select 查询结果 []
from 从哪张表中查找数据 [成绩表score]
where 查询条件 [课程编号为“04”且分数小于60]
group by 分组 [没有]
having 对分组结果指定条件 []
order by 对查询结果排序[查询结果按按分数降序排列];
*/
select 学号 from score where 课程号='04' and 成绩 <60
order by 成绩 desc;
select count(教师号) from teacher where 教师姓名 like '孟%';
/*
查找1990年出生的学生名单
学生表中出生日期列的类型是datetime
*/
select 学号,姓名 from student where year(出生日期)=1990;
select sum(成绩) from score where 课程号 = '0002';
select count(distinct 学号) as 学生人数 from score;
select 课程号, count(学号) from score group by 课程号;
/*
分析思路
group by 分组 [男生、女生人数:按性别分组
having 对分组结果指定条件 [没有]
order by 对查询结果排序[没有];
*/
select 性别,count(*) from student group by 性别;
select 课程号 from score where 成绩<60 order by 课程号 desc;
学生表:student(学号sno,学生姓名sname,出生年月sbirth,性别ssex)
成绩表:score(学号sno,课程号cno,成绩score)
课程表:course(课程号cno,课程名称cname,教师号ctno)
教师表:teacher(教师号tno,教师姓名tname)
注意:下面SQL的实现以MySQL为主
/*
分析思路
select 查询结果 [课程ID:是课程号的别名,最高分:max(成绩) ,最低分:min(成绩)]
from 从哪张表中查找数据 [成绩表score]
where 查询条件 [没有]
group by 分组 [各科成绩:也就是每门课程的成绩,需要按课程号分组];
*/
select 课程号,max(成绩) as 最高分,min(成绩) as 最低分from score
group by 课程号;
/*
题目翻译成大白话:
平均成绩:展开来说就是计算每个学生的平均成绩
这里涉及到“每个”就是要分组了
平均成绩大于60分,就是对分组结果指定条件
*/
select 学号, avg(成绩)from score group by 学号having avg(成绩)>60;
/*
翻译成大白话:
第1步,需要先计算出每个学生选修的课程数据,需要按学号分组
第2步,至少选修两门课程:也就是每个学生选修课程数目>=2,对分组结果指定条件
*/
select 学号, count(课程号) as 选修课程数目from score group by 学号 having count(课程号)>=2;
/*
翻译成大白话,问题解析:
1)查找出姓名相同的学生有谁,每个姓名相同学生的人数
查询结果:姓名,人数
条件:怎么算姓名相同?按姓名分组后人数大于等于2,因为同名的人数大于等于2
*/
select 姓名,count(*) as 人数 from student group by 姓名
having count(*)>=2;
select 课程号, avg(成绩) as 平均成绩from score
group by 课程号 order by 平均成绩 asc,课程号 desc;
要求输出课程号和选修人数,查询结果按人数降序排序,若人数相同,按课程号升序排序。
select 课程号, count(学号) as '选修人数'
from score group by 课程号having count(学号)>2
order by count(学号) desc,课程号 asc;
/*第1步:得到每个学生的平均成绩,显示学号,平均成绩*/
select 学号, avg(成绩) as 平均成绩 from score group by 学号;
/* 第2步:再加上限制条件:*/
select 学号, avg(成绩) as 平均成绩from score where 成绩 <60 group by 学号 having count(课程号)>=2;
学生表:student(学号sno,学生姓名sname,出生年月sbirth,性别ssex)
成绩表:score(学号sno,课程号cno,成绩score)
课程表:course(课程号cno,课程名称cname,教师号ctno)
教师表:teacher(教师号tno,教师姓名tname)
注意:下面SQL的实现以MySQL为主
/*
第1步,写子查询(所有课程成绩 < 60 的学生)*/
select 学号 from score where 成绩 < 60;
/*第2步,查询结果:学生学号,姓名,条件是前面1步查到的学号*/
select 学号,姓名 from student where 学号 in ( select 学号
from score where 成绩 < 60);
/*
查找出学号,条件:没有学全所有课,也就是该学生选修的课程数 < 总的课程数
【考察知识点】in,子查询
*/
select 学号,姓名from student where 学号 in( select 学号 from score
group by 学号 having count(课程号) < (select count(课程号) from course));
select 学号,姓名from student where 学号 in( select 学号 from score
group by 学号having count(课程号)=2);
/*我们可以使用分组(group by)和汇总函数得到每个组里的一个值(最大值,最小值,平均值等)。
但是无法得到成绩最大值所在行的数据。*/
select 课程号,max(成绩) as 最大成绩 from score group by 课程号;
/*我们可以使用关联子查询来实现:*/
select * from score as a where 成绩 = (select max(成绩)
from score as b where b.课程号 = a.课程号);
/*上面查询结果课程号“0001”有2行数据,是因为最大成绩80有2个
分组取每组最小值:按课程号分组取成绩最小值所在行的数据*/
select * from score as a where 成绩 = (select min(成绩)
from score as b where b.课程号 = a.课程号);
/*第1步,查出有哪些组,我们可以按课程号分组,查询出有哪些组,对应这个问题里就是有哪些课程号*/
select 课程号,max(成绩) as 最大成绩from score group by 课程号;
/*第2步:先使用order by子句按成绩降序排序(desc),然后使用limt子句返回topN(对应这个问题返回的成绩前两名*/
select * from score where 课程号 = '0001' order by 成绩 desc limit 2;
/*第3步,使用union all 将每组选出的数据合并到一起.同样的,可以写出其他组的(其他课程号)取出成绩前2名的sql*/
(select * from score where 课程号 = '0001' order by 成绩 desc limit 2) union all
(select * from score where 课程号 = '0002' order by 成绩 desc limit 2) union all
(select * from score where 课程号 = '0003' order by 成绩 desc limit 2);
select a.学号,a.姓名,count(b.课程号) as 选课数,sum(b.成绩) as 总成绩
from student as a left join score as b on a.学号 = b.学号group by a.学号;
select a.学号,a.姓名, avg(b.成绩) as 平均成绩
from student as a left join score as b
on a.学号 = b.学号group by a.学号having avg(b.成绩)>85;
select a.学号, a.姓名, c.课程号,c.课程名称
from student a inner join score b on a.学号=b.学号
inner join course c on b.课程号=c.课程号;
select a.学号,a.姓名
from student as a inner join score as b on a.学号=b.学号
where b.课程号='0003' and b.成绩>80;
变成
select userId,'语文' as subjectName,chinese_score as score from tb_score1
union all
select userId,'数学' as subjectName,math_score as score from tb_score1
union all
select userId,'英语' as subjectName,english_score as score from tb_score1
union all
select userId,'政治' as subjectName,politics_score as score from tb_score1;
-- 考察case表达式
select a.课程号,b.课程名称,
sum(case when 成绩 between 85 and 100 then 1 else 0 end) as '[100-85]',
sum(case when 成绩 >=70 and 成<85 then 1 else 0 end) as '[85-70]',
sum(case when 成绩>=60 and 成绩<70 then 1 else 0 end) as '[70-60]',
sum(case when 成绩<60 then 1 else 0 end) as '[<60]'
from score as a right join course as b
on a.课程号=b.课程号 group by a.课程号,b.课程名称;
-- 考察case表达式
select 课程号,
sum(case when 成绩>=60 then 1 else 0 end) as 及格人数,
sum(case when 成绩 < 60 then 1 else 0 end) as 不及格人数
from score group by 课程号;
转化后
SELECT
userid,
SUM( CASE subjectName WHEN '语文' THEN score ELSE 0 END ) '语文',
SUM( CASE subjectName WHEN '数学' THEN score ELSE 0 END ) '数学',
SUM( CASE subjectName WHEN '英语' THEN score ELSE 0 END ) '英语',
SUM( CASE subjectName WHEN '政治' THEN score ELSE 0 END ) '政治'
FROM
tb_score
GROUP BY
userid;
SELECT
userid,
SUM( IF ( subjectName = '语文', score, 0 ) ) '语文',
SUM( IF ( subjectName = '数学', score, 0 ) ) '数学',
SUM( IF ( subjectName = '英语', score, 0 ) ) '英语',
SUM( IF ( subjectName = '政治', score, 0 ) ) '政治'
FROM
tb_score
GROUP BY
userid;
MySQL提供了 group by with rollup 函数进行group by 字段的汇总,但是与order by 互斥的不能同时用。
SELECT
IFNULL( userid, 'total' ) AS userid,
SUM( IF ( subjectName = '语文', score, 0 ) ) '语文',
SUM( IF ( subjectName = '数学', score, 0 ) ) '数学',
SUM( IF ( subjectName = '英语', score, 0 ) ) '英语',
SUM( IF ( subjectName = '政治', score, 0 ) ) '政治',
SUM( IF ( subjectName = 'total', score, 0 ) ) AS 'total'
FROM
(
SELECT
userid,
IFNULL( subjectName, 'total' ) AS subjectName,
SUM( score ) AS score
FROM
tb_score
GROUP BY userid, subjectName WITH ROLLUP
) AS a
GROUP BY userid
WITH ROLLUP;
SELECT IFNULL(userid,'total') AS userid,
SUM(IF(subjectName='语文',score,0)) AS '语文',
SUM(IF(subjectName='数学',score,0)) AS '数学',
SUM(IF(subjectName='英语',score,0)) AS '英语',
SUM(IF(subjectName='政治',score,0)) AS '政治',
SUM(score) AS total
FROM tb_score
GROUP BY userid WITH ROLLUP;
SELECT userid,
SUM(IF(subjectName='语文',score,0)) AS '语文',
SUM(IF(subjectName='数学',score,0)) AS '数学',
SUM(IF(subjectName='英语',score,0)) AS '英语',
SUM(IF(subjectName='政治',score,0)) AS '政治',
SUM(score) AS total
FROM tb_score
GROUP BY userid
UNION
SELECT 'total',SUM(IF(subjectName='语文',score,0)) AS '语文',
SUM(IF(subjectName='数学',score,0)) AS '数学',
SUM(IF(subjectName='英语',score,0)) AS '英语',
SUM(IF(subjectName='政治',score,0)) AS '政治',
SUM(score) FROM tb_score;
SELECT userid,GROUP_CONCAT(`subjectName`,":",score)AS 成绩 FROM tb_score GROUP BY userid;