mysql 练习
2022年9月29日大约 15 分钟
mysql 练习
数据表
SET NAMES utf8mb4;
SET FOREIGN_KEY_CHECKS = 0;
-- ----------------------------
-- Table structure for course
-- ----------------------------
DROP TABLE IF EXISTS `course`;
CREATE TABLE `course` (
`c_id` varchar(20) NOT NULL DEFAULT '',
`c_name` varchar(20) NOT NULL DEFAULT '',
`t_id` varchar(20) NOT NULL,
PRIMARY KEY (`c_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
-- ----------------------------
-- Records of course
-- ----------------------------
BEGIN;
INSERT INTO `course` VALUES ('01', '语文', '02');
INSERT INTO `course` VALUES ('02', '数学', '01');
INSERT INTO `course` VALUES ('03', '英语', '03');
COMMIT;
-- ----------------------------
-- Table structure for score
-- ----------------------------
DROP TABLE IF EXISTS `score`;
CREATE TABLE `score` (
`s_id` varchar(20) NOT NULL DEFAULT '',
`c_id` varchar(20) NOT NULL DEFAULT '',
`s_score` int(3) DEFAULT NULL,
PRIMARY KEY (`s_id`,`c_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
-- ----------------------------
-- Records of score
-- ----------------------------
BEGIN;
INSERT INTO `score` VALUES ('01', '01', 80);
INSERT INTO `score` VALUES ('01', '02', 90);
INSERT INTO `score` VALUES ('01', '03', 99);
INSERT INTO `score` VALUES ('02', '01', 70);
INSERT INTO `score` VALUES ('02', '02', 60);
INSERT INTO `score` VALUES ('02', '03', 80);
INSERT INTO `score` VALUES ('03', '01', 80);
INSERT INTO `score` VALUES ('03', '02', 80);
INSERT INTO `score` VALUES ('03', '03', 80);
INSERT INTO `score` VALUES ('04', '01', 50);
INSERT INTO `score` VALUES ('04', '02', 30);
INSERT INTO `score` VALUES ('04', '03', 20);
INSERT INTO `score` VALUES ('05', '01', 76);
INSERT INTO `score` VALUES ('05', '02', 87);
INSERT INTO `score` VALUES ('06', '01', 31);
INSERT INTO `score` VALUES ('06', '03', 34);
INSERT INTO `score` VALUES ('07', '02', 89);
INSERT INTO `score` VALUES ('07', '03', 98);
COMMIT;
-- ----------------------------
-- Table structure for student
-- ----------------------------
DROP TABLE IF EXISTS `student`;
CREATE TABLE `student` (
`s_id` varchar(20) NOT NULL DEFAULT '',
`s_name` varchar(20) NOT NULL DEFAULT '',
`s_birth` varchar(20) NOT NULL DEFAULT '',
`s_sex` varchar(10) NOT NULL DEFAULT '',
PRIMARY KEY (`s_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
-- ----------------------------
-- Records of student
-- ----------------------------
BEGIN;
INSERT INTO `student` VALUES ('01', '赵雷', '1990-01-01', '男');
INSERT INTO `student` VALUES ('02', '钱电', '1990-12-21', '男');
INSERT INTO `student` VALUES ('03', '孙风', '1990-05-20', '男');
INSERT INTO `student` VALUES ('04', '李云', '1990-08-06', '男');
INSERT INTO `student` VALUES ('05', '周梅', '1991-12-01', '女');
INSERT INTO `student` VALUES ('06', '吴兰', '1992-03-01', '女');
INSERT INTO `student` VALUES ('07', '郑竹', '1989-07-01', '女');
INSERT INTO `student` VALUES ('08', '王菊', '1990-01-20', '女');
COMMIT;
-- ----------------------------
-- Table structure for teacher
-- ----------------------------
DROP TABLE IF EXISTS `teacher`;
CREATE TABLE `teacher` (
`t_id` varchar(20) NOT NULL DEFAULT '',
`t_name` varchar(20) NOT NULL DEFAULT '',
PRIMARY KEY (`t_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
-- ----------------------------
-- Records of teacher
-- ----------------------------
BEGIN;
INSERT INTO `teacher` VALUES ('01', '张三');
INSERT INTO `teacher` VALUES ('02', '李四');
INSERT INTO `teacher` VALUES ('03', '王五');
COMMIT;
SET FOREIGN_KEY_CHECKS = 1;
练习题
1、查询"01"课程比"02"课程成绩高的学生的信息及课程分数
SELECT
s.*,
b.s_score AS scose_01,
c.s_score AS scose_02
FROM
student AS s
JOIN score AS b ON s.s_id = b.s_id
AND b.c_id = '01'
LEFT JOIN score AS c ON s.s_id = c.s_id
AND c.c_id = '02' or c.c_id = NULL
WHERE
b.s_score > c.s_score
--也可以这样写
SELECT
a.*,
b.s_score AS 01_score,
c.s_score AS 02_score
FROM
student a,
score b,
score c
WHERE
a.s_id = b.s_id
AND a.s_id = c.s_id
AND b.c_id = '01'
AND c.c_id = '02'
AND b.s_score > c.s_score
2、查询"01"课程比"02"课程成绩低的学生的信息及课程分数
SELECT
s.*,
b.s_score AS scose_01,
c.s_score AS scose_02
FROM
student AS s
JOIN score b ON s.s_id = b.s_id
AND b.c_id = '01'
LEFT JOIN score c ON s.s_id = c.s_id
AND c.c_id = '02' or c.c_id = NULL
WHERE
b.s_score < c.s_score
----另一种
SELECT
s.*,
b.s_score AS scose_01,
c.s_score AS scose_02
FROM
student AS s,
score AS b,
score AS c
WHERE
s.s_id = b.s_id
AND s.s_id = c.s_id
AND b.c_id = '01'
AND c.c_id = '02'
AND b.s_score < c.s_score
3、查询平均成绩大于等于60分的同学的学生编号和学生姓名和平均成绩
SELECT
s.*,
round( avg( b.s_score ), 2 ) AS avg_score
FROM
student AS s
JOIN score b ON s.s_id = b.s_id
GROUP BY
s.s_id,
s.s_name
HAVING
avg_score > 60
4、查询平均成绩小于60分的同学的学生编号和学生姓名和平均成绩-- (包括有成绩的和无成绩的)
SELECT
b.s_id,
b.s_name,
ROUND( AVG( a.s_score ), 2 ) AS avg_score
FROM
student b
LEFT JOIN score a ON b.s_id = a.s_id
GROUP BY
b.s_id,
b.s_name
HAVING
avg_score < 60 UNION
SELECT
a.s_id,
a.s_name,
0 AS avg_score
FROM
student a
WHERE
a.s_id NOT IN ( SELECT DISTINCT s_id FROM score );
5、查询所有同学的学生编号、学生姓名、选课总数、所有课程的总成绩
SELECT
s.s_id,
s.s_name,
count( b.c_id ) AS course_num,
sum( b.s_score ) AS course_score
FROM
student AS s
LEFT JOIN score b ON s.s_id = b.s_id
GROUP BY
s.s_id,
s.s_name
ORDER BY course_score desc
6、查询"李"姓老师的数量
select count(t_id) as num from teacher where t_name like '李%';
7、查询学过"张三"老师授课的同学的信息
SELECT
a.*
FROM
student a
JOIN score b ON a.s_id = b.s_id
WHERE
b.c_id IN (
SELECT
c_id
FROM
course
WHERE
t_id = (
SELECT
t_id
FROM
teacher
WHERE
t_name = '张三'
));
8、查询没学过"张三"老师授课的同学的信息
--先查询张三老师所教的所有课程
--再查询课程中有成绩的学生id
--最后查询不包含这些学生的id
SELECT
*
FROM
student c
WHERE
c.s_id NOT IN (
SELECT
a.s_id
FROM
student a
JOIN score b ON a.s_id = b.s_id
WHERE
b.c_id IN ( SELECT a.c_id FROM course a JOIN teacher b ON a.t_id = b.t_id WHERE t_name = '张三' ));
9、查询学过编号为"01"并且也学过编号为"02"的课程的同学的信息
SELECT
a.*
FROM
student a,
score b,
score c
WHERE
a.s_id = b.s_id
AND a.s_id = c.s_id
AND b.c_id = '01'
AND c.c_id = '02'
10、查询学过编号为"01"但是没有学过编号为"02"的课程的同学的信息
select a.* from
student a
where a.s_id in (select s_id from score where c_id='01' )
and a.s_id not in(select s_id from score where c_id='02')
11、查询没有学全所有课程的同学的信息
SELECT
a.*
FROM
student a
LEFT JOIN score b ON a.s_id = b.s_id
GROUP BY
a.s_id
HAVING
COUNT( b.c_id ) < (SELECT COUNT( * ) FROM course)
--其他写法
select *
from student
where s_id not in(
select s_id from score t1
group by s_id having count(*) =(select count(distinct c_id) from course))
12、查询至少有一门课与学号为"01"的同学所学相同的同学的信息
--先从 课程表中查询 01同学选的课程
--再查询选该课程的所有学生
SELECT
*
FROM
student
WHERE
s_id IN (
SELECT DISTINCT
b.s_id
FROM
score b
WHERE
c_id IN ( SELECT s.c_id FROM score s WHERE s_id = '01' ))
13、查询和"01"号的同学学习的课程完全相同的其他同学的信息
---找到'01'同学学习的课程数
---找到学过‘01’同学没学过的课程,有哪些同学。并排除他们
---找到‘01’同学没学过的课程
---找出‘01’同学学习的课程
---排除01同学
SELECT
student.*
FROM
student
WHERE
s_id IN (SELECT s_id FROM score GROUP BY s_id HAVING COUNT(s_id) = (
SELECT COUNT(c_id) FROM score WHERE s_id = '01'
)
)
AND s_id NOT IN (
SELECT s_id FROM score
WHERE c_id IN(
SELECT DISTINCT c_id FROM score
WHERE c_id NOT IN (
SELECT c_id FROM score WHERE s_id = '01'
)
) GROUP BY s_id
)
AND s_id NOT IN ('01')
--第二种
SELECT
t3.*
FROM
( SELECT s_id, group_concat( c_id ORDER BY c_id ) group1 FROM score WHERE s_id > '01' GROUP BY s_id ) t1
INNER JOIN ( SELECT group_concat( c_id ORDER BY c_id ) group2 FROM score WHERE s_id = '01' GROUP BY s_id ) t2 ON t1.group1 = t2.group2
INNER JOIN student t3 ON t1.s_id = t3.s_id
14、查询没学过"张三"老师讲授的任一门课程的学生姓名
-- 找出张三老师的id
-- 找出张三老师的所有课程id
-- 找出所有上过张三老师的学生id
-- 找出没学过的学生
SELECT
s.s_name
FROM
student s
WHERE
s_id NOT IN (
SELECT
s_id
FROM
score
WHERE
c_id IN (
SELECT
c_id
FROM
course
WHERE
t_id = ( SELECT t_id FROM teacher WHERE t_name = '张三' ))
)
15、查询两门及其以上不及格课程的同学的学号,姓名及其平均成绩
---查询2门不及格以上的学生id
---查询这些学生的信息及平均成绩
SELECT
s.*,
ROUND( avg( a.s_score ), 2 ) AS score
FROM
student s
LEFT JOIN score a ON s.s_id = a.s_id
WHERE
s.s_id IN ( SELECT s_id FROM score WHERE s_score < 60 GROUP BY s_id HAVING COUNT( 1 ) >= 2 )
GROUP BY
s.s_id,
s.s_name
16、检索"01"课程分数小于60,按分数降序排列的学生信息
SELECT
s.*,
c.c_id,
c.s_score AS score
FROM
student s,
score c
WHERE
s.s_id = c.s_id
AND c.c_id = '01'
AND c.s_score < 60
ORDER BY
score DESC
17、按平均成绩从高到低显示所有学生的所有课程的成绩以及平均成绩
--只查询学生每一科的成绩
SELECT s.s_id,
(SELECT s_score from score where s_id = s.s_id and c_id = '01') as 语文,
(SELECT s_score from score where s_id = s.s_id and c_id = '02') as 数学,
(SELECT s_score from score where s_id = s.s_id and c_id = '03') as 英语,
ROUND(avg(s.s_score),2) as 平均分
from score s GROUP BY s.s_id ORDER BY 平均分 desc
--其他写法
SELECT a.s_id,MAX(CASE a.c_id WHEN '01' THEN a.s_score END ) 语文,
MAX(CASE a.c_id WHEN '02' THEN a.s_score END ) 数学,
MAX(CASE a.c_id WHEN '03' THEN a.s_score END ) 英语,
avg(a.s_score),b.s_name FROM score a JOIN student b ON a.s_id=b.s_id GROUP BY a.s_id ORDER BY 5 DESC
18.查询各科成绩最高分、最低分和平均分:
--以如下形式显示:课程ID,课程name,最高分,最低分,平均分,及格率,中等率,优良率,优秀率
--及格为>=60,中等为:70-80,优良为:80-90,优秀为:>=90
---case when 条件 then 结果1 else 结果2 end 满足条件为结果1 否则为结果2
select a.c_id,a.c_name,max(s_score) as 最高分,min(s_score) as 最低分,ROUND(avg(s_score),2) as 平均分,
ROUND(100*(SUM(case when s.s_score >= 60 then 1 else 0 end)/SUM(case when s.s_score then 1 else 0 end)),2) as 及格率,
ROUND(100*(SUM(case when s.s_score >= 70 and s.s_score <= 80 then 1 else 0 end)/SUM(case when s.s_score then 1 else 0 end)),2) as 中等率,
ROUND(100*(SUM(case when s.s_score >= 80 and s.s_score <= 90 then 1 else 0 end)/SUM(case when s.s_score then 1 else 0 end)),2) as 优良率,
ROUND(100*(SUM(case when s.s_score >= 90 then 1 else 0 end)/SUM(case when s.s_score then 1 else 0 end)),2) as 优秀率
from score s left join course a on s.c_id = a.c_id group by a.c_id,a.c_name
19、按各科成绩进行排序,并显示排名
-- mysql没有rank函数
SELECT
@i :=(case when @o != a.c_id then 1 else @i+1 end) as rank,
@o :=a.c_id as c_id,
a.s_id as s_id,
a.s_score as score
FROM
(
SELECT
s.s_id,
s.c_id,
s.s_score
FROM
score s
GROUP BY
s.c_id,
s.s_score
ORDER BY
s.c_id,
s.s_score DESC
) a,
( SELECT @i := 0, @o := 0 ) s
--其他写法
(select * from (select
t1.c_id,
t1.s_score,
(select count(distinct t2.s_score) from score t2 where t2.s_score>=t1.s_score and t2.c_id='01') rank
FROM score t1 where t1.c_id='01'
order by t1.s_score desc) t1)
union
(select * from (select
t1.c_id,
t1.s_score,
(select count(distinct t2.s_score) from score t2 where t2.s_score>=t1.s_score and t2.c_id='02') rank
FROM score t1 where t1.c_id='02'
order by t1.s_score desc) t2)
union
(select * from (select
t1.c_id,
t1.s_score,
(select count(distinct t2.s_score) from score t2 where t2.s_score>=t1.s_score and t2.c_id='03') rank
FROM score t1 where t1.c_id='03'
order by t1.s_score desc) t3)
20、查询学生的总成绩并进行排名
select a.s_id,
@i:=@i+1 as i,
@k:=(case when @score=a.sum_score then @k else @i end) as rank,
@score:=a.sum_score as score
from (select s_id,SUM(s_score) as sum_score from score GROUP BY s_id ORDER BY sum_score DESC)a,
(select @k:=0,@i:=0,@score:=0)s
21、查询不同老师所教不同课程平均分从高到低显示
SELECT
t.*,
round(avg( s.s_score ),2) AS score
FROM
teacher t,
course c,
score s
WHERE
t.t_id = c.t_id
AND s.c_id = c.c_id
GROUP BY
t.t_id,
t.t_name
ORDER BY
score DESC
---其他写法
select a.t_id,c.t_name,a.c_id,ROUND(avg(s_score),2) as avg_score from course a
left join score b on a.c_id=b.c_id
left join teacher c on a.t_id=c.t_id
GROUP BY a.c_id,a.t_id,c.t_name ORDER BY avg_score DESC;
22、查询所有课程的成绩第2名到第3名的学生信息及该课程成绩
--UNION 查询 最后才能加排序
SELECT s.s_id, s2.s_name, s.s_score, s.c_id FROM score s, student s2 WHERE s.s_id = s2.s_id AND s.s_score IN (
SELECT * FROM ( SELECT s.s_score FROM score s WHERE s.c_id = '01' GROUP BY s.c_id,s.s_score ORDER BY s.c_id,s.s_score DESC
LIMIT 1,2) AS a ) AND s.c_id = '01'
UNION
SELECT s.s_id, s2.s_name, s.s_score, s.c_id FROM score s, student s2 WHERE s.s_id = s2.s_id AND s.s_score IN (
SELECT * FROM ( SELECT s.s_score FROM score s WHERE s.c_id = '02' GROUP BY s.c_id,s.s_score ORDER BY s.c_id,s.s_score DESC
LIMIT 1,2) AS a ) AND s.c_id = '02'
UNION
SELECT s.s_id, s2.s_name, s.s_score, s.c_id FROM score s, student s2 WHERE s.s_id = s2.s_id AND s.s_score IN (
SELECT * FROM ( SELECT s.s_score FROM score s WHERE s.c_id = '03' GROUP BY s.c_id,s.s_score ORDER BY s.c_id,s.s_score DESC
LIMIT 1,2) AS a ) AND s.c_id = '03' ORDER BY c_id ASC,s_score DESC
---其他写法
select d.*,c.排名,c.s_score,c.c_id from (
select a.s_id,a.s_score,a.c_id,@i:=@i+1 as 排名 from score a,(select @i:=0)s where a.c_id='01'
ORDER BY a.s_score DESC
)c
left join student d on c.s_id=d.s_id
where 排名 BETWEEN 2 AND 3
UNION
select d.*,c.排名,c.s_score,c.c_id from (
select a.s_id,a.s_score,a.c_id,@j:=@j+1 as 排名 from score a,(select @j:=0)s where a.c_id='02'
ORDER BY a.s_score DESC
)c
left join student d on c.s_id=d.s_id
where 排名 BETWEEN 2 AND 3
UNION
select d.*,c.排名,c.s_score,c.c_id from (
select a.s_id,a.s_score,a.c_id,@k:=@k+1 as 排名 from score a,(select @k:=0)s where a.c_id='03'
ORDER BY a.s_score DESC
)c
left join student d on c.s_id=d.s_id
where 排名 BETWEEN 2 AND 3;
23、统计各科成绩各分数段人数:课程编号,课程名称,[100-85],[85-70],[70-60],[0-60]及所占百分比
---先查询每个分数段人数 百分比
---在使用left join 链接 a b c d e f
select distinct f.c_name,a.c_id,b.`85-100`,b.百分比,c.`70-85`,c.百分比,d.`60-70`,d.百分比,e.`0-60`,e.百分比 from score a
left join (select c_id,SUM(case when s_score >85 and s_score <=100 then 1 else 0 end) as `85-100`,
ROUND(100*(SUM(case when s_score >85 and s_score <=100 then 1 else 0 end)/count(*)),2) as 百分比
from score GROUP BY c_id)b on a.c_id=b.c_id
left join (select c_id,SUM(case when s_score >70 and s_score <=85 then 1 else 0 end) as `70-85`,
ROUND(100*(SUM(case when s_score >70 and s_score <=85 then 1 else 0 end)/count(*)),2) as 百分比
from score GROUP BY c_id)c on a.c_id=c.c_id
left join (select c_id,SUM(case when s_score >60 and s_score <=70 then 1 else 0 end) as `60-70`,
ROUND(100*(SUM(case when s_score >60 and s_score <=70 then 1 else 0 end)/count(*)),2) as 百分比
from score GROUP BY c_id)d on a.c_id=d.c_id
left join (select c_id,SUM(case when s_score >=0 and s_score <=60 then 1 else 0 end) as `0-60`,
ROUND(100*(SUM(case when s_score >=0 and s_score <=60 then 1 else 0 end)/count(*)),2) as 百分比
from score GROUP BY c_id)e on a.c_id=e.c_id
left join course f on a.c_id = f.c_id
24、查询学生平均成绩及其名次
--查询平均成绩
select a.s_id,
@i:=@i+1 as '不保留空缺排名',
@k:=(case when @avg_score=a.avg_s then @k else @i end) as '保留空缺排名',
@avg_score:=avg_s as '平均分'
from (select s_id,ROUND(AVG(s_score),2) as avg_s from score GROUP BY s_id ORDER BY avg_s DESC)a,(select @avg_score:=0,@i:=0,@k:=0)b;
25、查询各科成绩前三名的记录
-- 1.选出b表比a表成绩大的所有组
-- 2.选出比当前id成绩大的 小于三个的
select a.s_id,a.c_id,a.s_score from score a
left join score b on a.c_id = b.c_id and a.s_score<b.s_score
group by a.s_id,a.c_id,a.s_score HAVING COUNT(b.s_id)<3
ORDER BY a.c_id,a.s_score DESC
26、查询每门课程被选修的学生数
select c_id,count(s_id) as number from score GROUP BY c_id
27、查询出只有两门课程的全部学生的学号和姓名
select s_id,s_name from student where s_id in(select s_id from score GROUP BY s_id HAVING COUNT(c_id)=2);
28、查询男生、女生人数
select s_sex,COUNT(s_sex) as 人数 from student GROUP BY s_sex
29、查询名字中含有"风"字的学生信息
select * from student where s_name like '%风%';
30、查询同名同性学生名单,并统计同名人数
select a.s_name,a.s_sex,count(*) from student a JOIN
student b on a.s_id !=b.s_id and a.s_name = b.s_name and a.s_sex = b.s_sex
GROUP BY a.s_name,a.s_sex
31、查询1990年出生的学生名单
select s_name from student where s_birth like '1990%'
32、查询每门课程的平均成绩,结果按平均成绩降序排列,平均成绩相同时,按课程编号升序排列
select c_id,ROUND(AVG(s_score),2) as avg_score from score GROUP BY c_id ORDER BY avg_score DESC,c_id ASC
33、查询平均成绩大于等于85的所有学生的学号、姓名和平均成绩
select a.s_id,b.s_name,ROUND(avg(a.s_score),2) as avg_score from score a
left join student b on a.s_id=b.s_id GROUP BY s_id HAVING avg_score>=85
34、查询课程名称为"数学",且分数低于60的学生姓名和分数
select a.s_name,b.s_score from score b join student a on a.s_id=b.s_id where b.c_id=(
select c_id from course where c_name ='数学') and b.s_score<60
35、查询所有学生的课程及分数情况;
SELECT a.s_id,a.s_name,
SUM(case c.c_name when '语文' then b.s_score else 0 end) as '语文',
SUM(case c.c_name when '数学' then b.s_score else 0 end) as '数学',
SUM(case c.c_name when '英语' then b.s_score else 0 end) as '英语',
SUM(case b.s_score when b.s_score then b.s_score else 0 end) as '总分'
FROM student a left join score b on a.s_id = b.s_id
left join course c on c.c_id = b.c_id
GROUP BY a.s_id,a.s_name
36、查询任何一门课程成绩在70分以上的姓名、课程名称和分数;
select a.s_name,b.c_name,c.s_score from course b left join score c on b.c_id = c.c_id
left join student a on a.s_id=c.s_id where c.s_score>=70
---另一种
SELECT s.s_id,s.s_name,c.c_name,b.s_score from student s,score b,course c where s.s_id = b.s_id
and b.c_id = c.c_id and b.s_score >= 70
37、查询不及格的课程
select a.s_id,a.c_id,b.c_name,a.s_score from score a left join course b on a.c_id = b.c_id
where a.s_score<60
---另一种
SELECT s.s_id,s.s_name,c.c_name,b.s_score from student s,score b,course c where s.s_id = b.s_id
and b.c_id = c.c_id and b.s_score < 60
##38、查询课程编号为01且课程成绩在80分以上的学生的学号和姓名;
select a.s_id,b.s_name from score a LEFT JOIN student b on a.s_id = b.s_id
where a.c_id = '01' and a.s_score>80
---另一种
SELECT s.s_id,s.s_name,c.c_name,b.s_score from student s,score b,course c where s.s_id = b.s_id
and b.c_id = c.c_id and c.c_id = '01' and b.s_score > 80
39、求每门课程的学生人数
select count(*) from score GROUP BY c_id;
40、查询选修"张三"老师所授课程的学生中,成绩最高的学生信息及其成绩
-- 查询老师id
select c_id from course c,teacher d where c.t_id=d.t_id and d.t_name='张三'
-- 查询最高分(可能有相同分数)
select MAX(s_score) from score where c_id='02'
-- 查询信息
select a.*,b.s_score,b.c_id,c.c_name from student a
LEFT JOIN score b on a.s_id = b.s_id
LEFT JOIN course c on b.c_id=c.c_id
where b.c_id =(select c_id from course c,teacher d where c.t_id=d.t_id and d.t_name='张三')
and b.s_score in (select MAX(s_score) from score where c_id='02')
41、查询不同课程成绩相同的学生的学生编号、课程编号、学生成绩
select DISTINCT b.s_id,b.c_id,b.s_score from score a,score b where a.c_id != b.c_id and a.s_score = b.s_score
42、查询每门功成绩最好的前两名
-- 牛逼的写法
select a.s_id,a.c_id,a.s_score from score a
where (select COUNT(1) from score b where b.c_id=a.c_id and b.s_score>=a.s_score)<=2 ORDER BY a.c_id
43、统计每门课程的学生选修人数(超过5人的课程才统计)。要求输出课程号和选修人数,查询结果按人数降序排列,若人数相同,按课程号升序排列
select c_id,count(*) as total from score GROUP BY c_id HAVING total>5 ORDER BY total,c_id ASC
44、检索至少选修两门课程的学生学号
select s_id,count(*) as sel from score GROUP BY s_id HAVING sel>=2
45、查询选修了全部课程的学生信息
select * from student where s_id in(
select s_id from score GROUP BY s_id HAVING count(*)=(select count(*) from course))
46、查询各学生的年龄
-- 按照出生日期来算,当前月日 < 出生年月的月日则,年龄减一
select s_birth,(DATE_FORMAT(NOW(),'%Y')-DATE_FORMAT(s_birth,'%Y') -
(case when DATE_FORMAT(NOW(),'%m%d')>DATE_FORMAT(s_birth,'%m%d') then 0 else 1 end)) as age
from student;
47、查询本周过生日的学生
select * from student where WEEK(DATE_FORMAT(NOW(),'%Y%m%d'))=WEEK(s_birth)
48、查询下周过生日的学生
select * from student where WEEK(DATE_FORMAT(NOW(),'%Y%m%d'))+1 =WEEK(s_birth)
49、查询本月过生日的学生
select * from student where MONTH(DATE_FORMAT(NOW(),'%Y%m%d')) =MONTH(s_birth)
50、查询下月过生日的学生
select * from student where MONTH(DATE_FORMAT(NOW(),'%Y%m%d'))+1 =MONTH(s_birth)