├── 1.sql ├── 2.sql ├── 3.sql ├── 4.sql ├── 5.sql ├── 6.sql ├── 7.sql ├── 8.sql ├── 9.sql ├── LICENSE ├── README.md └── init.sql /1.sql: -------------------------------------------------------------------------------- 1 | # 考察知识点: 2 | # 子查询,连接,联表(Join) 3 | 4 | # 1 查询" 01 "课程比" 02 "课程成绩高的学生的信息及课程分数 5 | select t1.SId SId, t1.Sage Sage, t1.Sname Sname, t1.Ssex Ssex, t1.score score1, t2.score score2 from 6 | (select student.SID,student.Sage, student.Sname, student.Ssex, score from student,sc where student.SId = sc.SId and CId='01') as t1, 7 | (select student.SID, score from student,sc where student.SId = sc.SId and CId='02') as t2 8 | where t1.SId = t2.SId and t1.score > t2.score; 9 | 10 | # 1.1 查询同时存在" 01 "课程和" 02 "课程的情况 11 | select t1.SId Sid, t1.score score1, t2.score score2 from 12 | (select SId,score from sc where CId='01') as t1, 13 | (select SId,score from sc where CId='02') as t2 14 | where t1.SId = t2.SId; 15 | 16 | # 1.2 查询存在" 01 "课程但可能不存在" 02 "课程的情况(不存在时显示为 null ) 17 | select t1.SId Sid, t1.score score1, t2.score score2 from 18 | (select SId,score from sc where CId='01') as t1 LEFT JOIN (select SId,score from sc where CId='02') as t2 19 | ON t1.SId = t2.SId; 20 | 21 | # 1.3 查询不存在" 01 "课程但存在" 02 "课程的情况 22 | select t2.SId Sid, t1.score score1, t2.score score2 from 23 | (select SId,score from sc where CId='01') as t1 RIGHT JOIN (select SId,score from sc where CId='02') as t2 24 | ON t1.SId = t2.SId 25 | WHERE t1.SId is null; -------------------------------------------------------------------------------- /2.sql: -------------------------------------------------------------------------------- 1 | # 考察点:函数,inner join 2 | # 2.查询平均成绩大于等于 60 分的同学的学生编号和学生姓名和平均成绩 3 | select * from 4 | (select SId, AVG(score) average from sc group by SId) as av INNER JOIN student ON av.SId = student.SId 5 | where av.SId = student.SId and average >= 60; -------------------------------------------------------------------------------- /3.sql: -------------------------------------------------------------------------------- 1 | # 考察点:IN 2 | # 3. 查询在 SC 表存在成绩的学生信息 3 | select * from student where SId in (select distinct SId from sc); -------------------------------------------------------------------------------- /4.sql: -------------------------------------------------------------------------------- 1 | # 考察点:函数,Join 2 | # 4. 查询所有同学的学生编号、学生姓名、选课总数、所有课程的总成绩(没成绩的显示为 null ) 3 | select s.SId, Sname, count(CId) cnt, sum(score) total from 4 | sc right join student s on sc.SId = s.SId 5 | group by Sid; 6 | 7 | # 4.1 查有成绩的学生信息 8 | select s.SId, Sname, count(CId) cnt, sum(score) total from 9 | sc inner join student s on sc.SId = s.SId 10 | group by Sid; -------------------------------------------------------------------------------- /5.sql: -------------------------------------------------------------------------------- 1 | # 考察点:like 2 | # 5. 查询「李」姓老师的数量 3 | select count(TId) from teacher where Tname like "李%"; -------------------------------------------------------------------------------- /6.sql: -------------------------------------------------------------------------------- 1 | # 考察点:子查询 2 | # 6. 查询学过「张三」老师授课的同学的信息 3 | select student.* from student inner join 4 | ( 5 | select distinct Sid from 6 | (select distinct CId from course inner join teacher on course.TId = teacher.TId where Tname="张三") as t1 7 | inner join sc on t1.CId = sc.CId 8 | ) as t on t.SId = student.SId; -------------------------------------------------------------------------------- /7.sql: -------------------------------------------------------------------------------- 1 | # 考察点:集合运算 2 | # 7. 查询没有学全所有课程的同学的信息 3 | # 思路:左表为所有可能的S-C组合,右表为存在的S-C组合,左连接,右面为null就是没出现这种选课,换言之就是这个S没有选C 4 | select distinct t1.SId, t1.Sname, t1.Sage, t1.Ssex from 5 | (select student.*,CId from student, course) as t1 left join 6 | (select SId,CId from sc) as t2 on t1.CId = t2.CId and t1.SId = t2.SId 7 | where t2.SId is null; -------------------------------------------------------------------------------- /8.sql: -------------------------------------------------------------------------------- 1 | # 8. 查询至少有一门课与学号为" 01 "的同学所学相同的同学的信息 2 | select distinct student.* from student, sc 3 | where student.SId = sc.SId and CId in (select CId from sc where SId='01') and student.SId != '01'; 4 | -------------------------------------------------------------------------------- /9.sql: -------------------------------------------------------------------------------- 1 | # 9. 查询和" 01 "号的同学学习的课程 完全相同的其他同学的信息 2 | select * from student where SId not in 3 | (select distinct at.SId from 4 | (select * from student,(select distinct CId from sc where SId = '01') as ct) as at 5 | left join sc on at.SId=sc.SId and at.CId=sc.CId 6 | where sc.score is null); 7 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2020 Ai Ranthem 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # MySQL50 2 | [题目来源](https://blog.csdn.net/flycat296/article/details/63681089) 3 | 4 | 非原创,网上偶然看到。自己做一遍,查漏补缺。 5 | 6 | 数据运行`init.sql`获取 7 | 8 | ## 练习题目 9 | 10 | 1. 查询" 01 "课程比" 02 "课程成绩高的学生的信息及课程分数 1.1 查询同时存在" 01 "课程和" 02 "课程的情况 1.2 查询存在" 01 "课程但可能不存在" 02 "课程的情况(不存在时显示为 null ) 1.3 查询不存在" 01 "课程但存在" 02 "课程的情况 11 | 2. 查询平均成绩大于等于 60 分的同学的学生编号和学生姓名和平均成绩 12 | 3. 查询在 SC 表存在成绩的学生信息 13 | 4. 查询所有同学的学生编号、学生姓名、选课总数、所有课程的总成绩(没成绩的显示为 null ) 4.1 查有成绩的学生信息 14 | 5. 查询「李」姓老师的数量 15 | 6. 查询学过「张三」老师授课的同学的信息 16 | 7. 查询没有学全所有课程的同学的信息 17 | 8. 查询至少有一门课与学号为" 01 "的同学所学相同的同学的信息 18 | 9. 查询和" 01 "号的同学学习的课程 完全相同的其他同学的信息 19 | 10. 查询没学过"张三"老师讲授的任一门课程的学生姓名 20 | 11. 查询两门及其以上不及格课程的同学的学号,姓名及其平均成绩 21 | 12. 检索" 01 "课程分数小于 60,按分数降序排列的学生信息 22 | 13. 按平均成绩从高到低显示所有学生的所有课程的成绩以及平均成绩 23 | 14. 查询各科成绩最高分、最低分和平均分: 以如下形式显示:课程 ID,课程 name,最高分,最低分,平均分,及格率,中等率,优良率,优秀率 及格为>=60,中等为:70-80,优良为:80-90,优秀为:>=90 要求输出课程号和选修人数,查询结果按人数降序排列,若人数相同,按课程号升序排列 24 | 15. 按各科成绩进行排序,并显示排名, Score 重复时保留名次空缺 15.1 按各科成绩进行排序,并显示排名, Score 重复时合并名次 25 | 16. 查询学生的总成绩,并进行排名,总分重复时保留名次空缺 16.1 查询学生的总成绩,并进行排名,总分重复时不保留名次空缺 26 | 17. 统计各科成绩各分数段人数:课程编号,课程名称,[100-85],[85-70],[70-60],[60-0] 及所占百分比 27 | 18. 查询各科成绩前三名的记录 28 | 19. 查询每门课程被选修的学生数 29 | 20. 查询出只选修两门课程的学生学号和姓名 30 | 21. 查询男生、女生人数 31 | 22. 查询名字中含有「风」字的学生信息 32 | 23. 查询同名同性学生名单,并统计同名人数 33 | 24. 查询 1990 年出生的学生名单 34 | 25. 查询每门课程的平均成绩,结果按平均成绩降序排列,平均成绩相同时,按课程编号升序排列 35 | 26. 查询平均成绩大于等于 85 的所有学生的学号、姓名和平均成绩 36 | 27. 查询课程名称为「数学」,且分数低于 60 的学生姓名和分数 37 | 28. 查询所有学生的课程及分数情况(存在学生没成绩,没选课的情况) 38 | 29. 查询任何一门课程成绩在 70 分以上的姓名、课程名称和分数 39 | 30. 查询不及格的课程 40 | 31. 查询课程编号为 01 且课程成绩在 80 分以上的学生的学号和姓名 41 | 32. 求每门课程的学生人数 42 | 33. 成绩不重复,查询选修「张三」老师所授课程的学生中,成绩最高的学生信息及其成绩 43 | 34. 成绩有重复的情况下,查询选修「张三」老师所授课程的学生中,成绩最高的学生信息及其成绩 44 | 35. 查询不同课程成绩相同的学生的学生编号、课程编号、学生成绩 45 | 36. 查询每门功成绩最好的前两名 46 | 37. 统计每门课程的学生选修人数(超过 5 人的课程才统计)。 47 | 38. 检索至少选修两门课程的学生学号 48 | 39. 查询选修了全部课程的学生信息 49 | 40. 查询各学生的年龄,只按年份来算 50 | 41. 按照出生日期来算,当前月日 < 出生年月的月日则,年龄减一 51 | 42. 查询本周过生日的学生 52 | 43. 查询下周过生日的学生 53 | 44. 查询本月过生日的学生 54 | 45. 查询下月过生日的学生 55 | 56 | ## 参考答案 57 | 58 | 1.查询" 01 "课程比" 02 "课程成绩高的学生的信息及课程分数 59 | 60 | ```sql 61 | select * 62 | from (select SId ,score from sc where sc.CId='01')as t1 , (select SId ,score from sc where sc.CId='02') as t2 63 | where t1.SId=t2.SId 64 | and t1.score>t2.score 65 | ``` 66 | 67 | 1.1 查询同时存在" 01 "课程和" 02 "课程的情况 68 | 69 | ```sql 70 | select * 71 | from (select SId ,score from sc where sc.CId='01')as t1 , (select SId ,score from sc where sc.CId='02') as t2 72 | where t1.SId=t2.SId 73 | ``` 74 | 75 | 1.2 查询存在" 01 "课程但可能不存在" 02 "课程的情况(不存在时显示为 null ) 76 | 77 | ```sql 78 | select * 79 | from (select SId ,score from sc where sc.CId='01')as t1 left join (select SId ,score from sc where sc.CId='02') as t2 80 | on t1.SId=t2.SId 81 | ``` 82 | 83 | 1.3 查询不存在" 01 "课程但存在" 02 "课程的情况 84 | 85 | ```sql 86 | select * 87 | from sc 88 | where sc.SId not in (select SId from sc where sc.CId='01') 89 | and sc.CId='02' 90 | ``` 91 | 92 | 1. 查询平均成绩大于等于 60 分的同学的学生编号和学生姓名和平均成绩 93 | 94 | ```sql 95 | select student.*,t1.avgscore 96 | from student inner JOIN( 97 | select sc.SId ,AVG(sc.score)as avgscore 98 | from sc 99 | GROUP BY sc.SId 100 | HAVING AVG(sc.score)>=60)as t1 on student.SId=t1.SId 101 | ``` 102 | 103 | 1. 查询在 SC 表存在成绩的学生信息 104 | 105 | ```sql 106 | select DISTINCT student.* 107 | from student ,sc 108 | where student.SId=sc.SId 109 | ``` 110 | 111 | 4.查询所有同学的学生编号、学生姓名、选课总数、所有课程的总成绩(没成绩的显示为null) 112 | 113 | ```sql 114 | select student.SId,student.Sname,t1.sumscore,t1.coursecount 115 | from student ,( 116 | select SC.SId,sum(sc.score)as sumscore ,count(sc.CId) as coursecount 117 | from sc 118 | GROUP BY sc.SId) as t1 119 | where student.SId =t1.SId 120 | ``` 121 | 122 | 4.1 查有成绩的学生信息 123 | 124 | ```sql 125 | select * 126 | from student 127 | where EXISTS(select * from sc where student.SId=sc.SId) 128 | ``` 129 | 130 | 1. 查询「李」姓老师的数量 131 | 132 | ```sql 133 | select count(*) 134 | from teacher 135 | where teacher.Tname like '李% 136 | ``` 137 | 138 | 1. 查询学过「张三」老师授课的同学的信息 139 | 140 | ```sql 141 | select student.* 142 | from teacher ,course ,student,sc 143 | where teacher.Tname='张三' 144 | and teacher.TId=course.TId 145 | and course.CId=sc.CId 146 | and sc.SId=student.SId 147 | ``` 148 | 149 | 1. 查询没有学全所有课程的同学的信息 150 | 151 | - 解法1 152 | 153 | ```sql 154 | select student.* 155 | from sc ,student 156 | where sc.SId=student.SId 157 | GROUP BY sc.SId 158 | Having count(*)<(select count(*) from course) 159 | ``` 160 | 161 | **但这种解法得出来的结果不包括什么课都没选的同学。** 162 | 163 | - 解法2 164 | 165 | ```sql 166 | select DISTINCT student.* 167 | from 168 | (select student.SId,course.CId 169 | from student,course ) as t1 LEFT JOIN (SELECT sc.SId,sc.CId from sc)as t2 on t1.SId=t2.SId and t1.CId=t2.CId,student 170 | where t2.SId is null 171 | and t1.SId=student.SId 172 | ``` 173 | 174 | **用笛卡尔积可以把什么课都没选的同学查询出来** 175 | 176 | 8.查询至少有一门课与学号为" 01 "的同学所学相同的同学的信息 177 | 178 | ```sql 179 | select DISTINCT student.* 180 | from sc ,student 181 | where sc.CId in (select CId from sc where sc.SId='01') 182 | and sc.SId=student.SId 183 | ``` 184 | 185 | 9.查询和" 01 "号的同学学习的课程完全相同的其他同学的信息 186 | 187 | ```sql 188 | select DISTINCT student.* 189 | from ( 190 | select student.SId,t.CId 191 | from student ,(select sc.CId from sc where sc.SId='01') as t) as t1 LEFT JOIN sc on t1.SId=sc.SId and t1.CId=sc.CId,student 192 | where sc.SId is null 193 | and t1.SId=student.SId 194 | ``` 195 | 196 | 10.查询没学过"张三"老师讲授的任一门课程的学生姓名 197 | 198 | ```sql 199 | select * 200 | from student 201 | where student.SId not in 202 | ( 203 | select student.SId 204 | from student left join sc on student.SId=sc.SId 205 | where EXISTS 206 | (select * 207 | from teacher ,course 208 | where teacher.Tname='张三' 209 | and teacher.TId=course.TId 210 | and course.CId=sc.CId)) 211 | ``` 212 | 213 | 11.查询两门及其以上不及格课程的同学的学号,姓名及其平均成绩 214 | 215 | ```sql 216 | select student.SId,student.Sname,avg(sc.score) 217 | from student ,sc 218 | where student.SId=sc.SId 219 | and sc.score<60 220 | GROUP BY sc.SId 221 | HAVING count(*)>=2 222 | ``` 223 | 224 | 1. 检索" 01 "课程分数小于 60,按分数降序排列的学生信息 225 | 226 | ```sql 227 | select student.* 228 | from student,sc 229 | where sc.CId ='01' 230 | and sc.score<60 231 | and student.SId=sc.SId 232 | ``` 233 | 234 | 1. 按平均成绩从高到低显示所有学生的所有课程的成绩以及平均成绩 235 | 236 | ```sql 237 | select 238 | sc.SId,sc.CId,sc.score,t1.avgscore 239 | from sc left join (select sc.SId,avg(sc.score) as avgscore 240 | from sc 241 | GROUP BY sc.SId) as t1 on sc.SId =t1.SId 242 | ORDER BY t1.avgscore DESC 243 | ``` 244 | 245 | 1. 查询各科成绩最高分、最低分和平均分: 以如下形式显示:课程 ID,课程 name,最高分,最低分,平均分,及格率,中等率,优良率,优秀率 及格为>=60,中等为:70-80,优良为:80-90,优秀为:>=90 要求输出课程号和选修人数,查询结果按人数降序排列,若人数相同,按课程号升序排列 246 | 247 | ```sql 248 | select sc.CId ,max(sc.score)as 最高分,min(sc.score)as 最低分,AVG(sc.score)as 平均分,count(*)as 选修人数,sum(case when sc.score>=60 then 1 else 0 end )/count(*)as 及格率,sum(case when sc.score>=70 and sc.score<80 then 1 else 0 end )/count(*)as 中等率,sum(case when sc.score>=80 and sc.score<90 and sc.score<80 then 1 else 0 end )/count(*)as 优良率,sum(case when sc.score>=90 then 1 else 0 end )/count(*)as 优秀率 249 | from sc 250 | GROUP BY sc.CId 251 | ORDER BY count(*)DESC,sc.CId asc 252 | ``` 253 | 254 | 1. 按各科成绩进行排序,并显示排名, Score 重复时保留名次空缺 255 | 256 | ```sql 257 | select sc.CId ,@curRank:=@curRank+1 as rank,sc.score 258 | from (select @curRank:=0) as t ,sc 259 | ORDER BY sc.score desc 260 | ``` 261 | 262 | 15.1 按各科成绩进行排序,并显示排名, Score 重复时合并名次 263 | 264 | ```sql 265 | select sc.CId , case when @fontscore=score then @curRank when @fontscore:=score then @curRank:=@curRank+1 end as rank,sc.score 266 | from (select @curRank:=0 ,@fontage:=null) as t ,sc 267 | ORDER BY sc.score desc 268 | ``` 269 | 270 | 1. 查询学生的总成绩,并进行排名,总分重复时保留名次空缺 271 | 272 | ```sql 273 | select t1.*,@currank:= @currank+1 as rank 274 | from (select sc.SId, sum(score) 275 | from sc 276 | GROUP BY sc.SId 277 | ORDER BY sum(score) desc) as t1,(select @currank:=0) as t 278 | ``` 279 | 280 | 16.1 查询学生的总成绩,并进行排名,总分重复时不保留名次空缺 281 | 282 | ```sql 283 | select t1.*, case when @fontscore=t1.sumscore then @currank when @fontscore:=t1.sumscore then @currank:=@currank+1 end as rank 284 | from (select sc.SId, sum(score) as sumscore 285 | from sc 286 | GROUP BY sc.SId 287 | ORDER BY sum(score) desc) as t1,(select @currank:=0,@fontscore:=null) as t 288 | ``` 289 | 290 | 1. 统计各科成绩各分数段人数:课程编号,课程名称,[100-85],[85-70],[70-60],[60-0] 及所占百分比 291 | 292 | ```sql 293 | select course.CId,course.Cname,t1.* 294 | from course LEFT JOIN ( 295 | select sc.CId,CONCAT(sum(case when sc.score>=85 and sc.score<=100 then 1 else 0 end )/count(*)*100,'%') as '[85-100]', 296 | CONCAT(sum(case when sc.score>=70 and sc.score<85 then 1 else 0 end )/count(*)*100,'%') as '[70-85)', 297 | CONCAT(sum(case when sc.score>=60 and sc.score<70 then 1 else 0 end )/count(*)*100,'%') as '[60-70)', 298 | CONCAT(sum(case when sc.score>=0 and sc.score<60 then 1 else 0 end )/count(*)*100,'%') as '[0-60)' 299 | from sc 300 | GROUP BY sc.CId) as t1 on course.CId=t1.CId 301 | ``` 302 | 303 | 1. 查询各科成绩前三名的记录 304 | 305 | 思路:前三名转化为若大于此成绩的数量少于3即为前三名。 306 | 307 | ```sql 308 | select * 309 | from sc 310 | where (select count(*) from sc as a where sc.CId =a.CId and sc.score 1 355 | ``` 356 | 357 | 24.查询 1990 年出生的学生名单 358 | 359 | ```sql 360 | select * 361 | from student 362 | where YEAR(student.Sage)=1990 363 | ``` 364 | 365 | 25.查询每门课程的平均成绩,结果按平均成绩降序排列,平均成绩相同时,按课程编号升序排列 366 | 367 | ```sql 368 | select sc.CId,AVG(sc.score) 369 | from sc 370 | GROUP BY sc.CId 371 | ORDER BY AVG(sc.score) desc ,sc.CId asc 372 | ``` 373 | 374 | 26.查询平均成绩大于等于 85 的所有学生的学号、姓名和平均成绩 375 | 376 | ```sql 377 | select student.SId,student.Sname,t1.avgscore 378 | from student INNER JOIN (select sc.SId ,AVG(sc.score) as avgscore from sc GROUP BY sc.SId HAVING AVG(sc.score)>85) as t1 on 379 | student.SId=t1.SId 380 | ``` 381 | 382 | 1. 查询课程名称为「数学」,且分数低于 60 的学生姓名和分数 383 | 384 | ```sql 385 | select student.Sname ,t1.score 386 | from student INNER JOIN (select sc.SId,sc.score 387 | from sc,course 388 | where sc.CId=course.CId 389 | and course.Cname='数学' 390 | and sc.score<60)as t1 on student.SId=t1.SId 391 | ``` 392 | 393 | 1. 查询所有学生的课程及分数情况(存在学生没成绩,没选课的情况) 394 | 395 | ```sql 396 | select student.SId,sc.CId,sc.score from Student left join sc on student.SId=sc.SId 397 | ``` 398 | 399 | 1. 查询任何一门课程成绩在 70 分以上的姓名、课程名称和分数 400 | 401 | ```sql 402 | select student.Sname,course.Cname,sc.score 403 | from student , sc ,course 404 | where sc.score>=70 405 | and student.SId=sc.SId 406 | and sc.CId=course.CId 407 | ``` 408 | 409 | 30.查询存在不及格的课程 410 | 411 | ```sql 412 | select DISTINCT sc.CId 413 | from sc 414 | where sc.score <60 415 | ``` 416 | 417 | 31.查询课程编号为 01 且课程成绩在 80 分以上的学生的学号和姓名 418 | 419 | ```sql 420 | select student.SId,student.Sname 421 | from student ,sc 422 | where sc.CId='01' 423 | and student.SId=sc.SId 424 | and sc.score>80 425 | ``` 426 | 427 | 1. 求每门课程的学生人数 428 | 429 | ```sql 430 | select sc.CId,count(*) as 学生人数 431 | from sc 432 | GROUP BY sc.CId 433 | ``` 434 | 435 | 1. 成绩不重复,查询选修「张三」老师所授课程的学生中,成绩最高的学生信息及其成绩 436 | 437 | ```sql 438 | select student.*,sc.score 439 | from student ,course ,teacher ,sc 440 | where course.CId=sc.CId 441 | and course.TId=teacher.TId 442 | and teacher.Tname='张三' 443 | and student.SId =sc.SId 444 | LIMIT 1 445 | ``` 446 | 447 | 1. 成绩有重复的情况下,查询选修「张三」老师所授课程的学生中,成绩最高的学生信息及其成绩 448 | 449 | ```sql 450 | select student.*,t1.score 451 | from student INNER JOIN (select sc.SId,sc.score, case when @fontage=sc.score then @rank when @fontage:=sc.score then @rank:=@rank+1 end as rank 452 | from course ,teacher ,sc,(select @fontage:=null,@rank:=0) as t 453 | where course.CId=sc.CId 454 | and course.TId=teacher.TId 455 | and teacher.Tname='张三' 456 | ORDER BY sc.score DESC) as t1 on student.SId=t1.SId 457 | where t1.rank=1 458 | ``` 459 | 460 | 1. 查询不同课程成绩相同的学生的学生编号、课程编号、学生成绩 461 | 462 | ```sql 463 | select * 464 | from sc as t1 465 | where exists(select * from sc as t2 where t1.SId=t2.SId and t1.CId!=t2.CId and t1.score =t2.score ) 466 | ``` 467 | 468 | 36.查询每门功成绩最好的前两名 469 | 470 | ```sql 471 | select * 472 | from sc as t1 473 | where (select count(*) from sc as t2 where t1.CId=t2.CId and t2.score >t1.score)<2 474 | ORDER BY t1.CId 475 | ``` 476 | 477 | 37.统计每门课程的学生选修人数(超过 5 人的课程才统计) 478 | 479 | ```sql 480 | select sc.CId as 课程编号,count(*) as 选修人数 481 | from sc 482 | GROUP BY sc.CId 483 | HAVING count(*)>5 484 | ``` 485 | 486 | 38.检索至少选修两门课程的学生学号 487 | 488 | ```sql 489 | select DISTINCT t1.SId 490 | from sc as t1 491 | where (select count(* )from sc where t1.SId=sc.SId)>=3 492 | ``` 493 | 494 | 1. 查询选修了全部课程的学生信息 495 | 496 | ```sql 497 | select student.* 498 | from sc ,student 499 | where sc.SId=student.SId 500 | GROUP BY sc.SId 501 | HAVING count(*) = (select DISTINCT count(*) from course ) 502 | ``` 503 | 504 | 40.查询各学生的年龄,只按年份来算 505 | 506 | ```sql 507 | select student.SId as 学生编号,student.Sname as 学生姓名,TIMESTAMPDIFF(YEAR,student.Sage,CURDATE()) as 学生年龄 508 | from student 509 | ``` 510 | 511 | 1. 按照出生日期来算,当前月日 < 出生年月的月日则,年龄减一 512 | 513 | ```sql 514 | select student.SId as 学生编号,student.Sname as 学生姓名,TIMESTAMPDIFF(YEAR,student.Sage,CURDATE()) as 学生年龄 515 | from student 516 | ``` 517 | 518 | 42.查询本周过生日的学生 519 | 520 | ```sql 521 | select * 522 | from student 523 | where YEARWEEK(student.Sage)=YEARWEEK(CURDATE()) 524 | ``` 525 | 526 | 1. 查询下周过生日的学生 527 | 528 | ```sql 529 | select * 530 | from student 531 | where YEARWEEK(student.Sage)=CONCAT(YEAR(CURDATE()),week(CURDATE())+1) 532 | ``` 533 | 534 | 44.查询本月过生日的学生 535 | 536 | ```sql 537 | select * 538 | from student 539 | where EXTRACT(YEAR_MONTH FROM student.Sage)=EXTRACT(YEAR_MONTH FROM CURDATE()) 540 | ``` 541 | 542 | 45.查询下月过生日的学生 543 | 544 | ```sql 545 | select * 546 | from student 547 | where EXTRACT(YEAR_MONTH FROM student.Sage)=EXTRACT(YEAR_MONTH FROM DATE_ADD(CURDATE(),INTERVAL 1 MON 548 | ``` -------------------------------------------------------------------------------- /init.sql: -------------------------------------------------------------------------------- 1 | create table Student(SId varchar(10),Sname varchar(10),Sage datetime,Ssex varchar(10)); 2 | insert into Student values('01' , '赵雷' , '1990-01-01' , '男'); 3 | insert into Student values('02' , '钱电' , '1990-12-21' , '男'); 4 | insert into Student values('03' , '孙风' , '1990-05-20' , '男'); 5 | insert into Student values('04' , '李云' , '1990-08-06' , '男'); 6 | insert into Student values('05' , '周梅' , '1991-12-01' , '女'); 7 | insert into Student values('06' , '吴兰' , '1992-03-01' , '女'); 8 | insert into Student values('07' , '郑竹' , '1989-07-01' , '女'); 9 | insert into Student values('09' , '张三' , '2017-12-20' , '女'); 10 | insert into Student values('10' , '李四' , '2017-12-25' , '女'); 11 | insert into Student values('11' , '李四' , '2017-12-30' , '女'); 12 | insert into Student values('12' , '赵六' , '2017-01-01' , '女'); 13 | insert into Student values('13' , '孙七' , '2018-01-01' , '女'); 14 | 15 | create table Course(CId varchar(10),Cname nvarchar(10),TId varchar(10)); 16 | insert into Course values('01' , '语文' , '02'); 17 | insert into Course values('02' , '数学' , '01'); 18 | insert into Course values('03' , '英语' , '03'); 19 | 20 | create table Teacher(TId varchar(10),Tname varchar(10)); 21 | insert into Teacher values('01' , '张三'); 22 | insert into Teacher values('02' , '李四'); 23 | insert into Teacher values('03' , '王五'); 24 | 25 | create table SC(SId varchar(10),CId varchar(10),score decimal(18,1)); 26 | insert into SC values('01' , '01' , 80); 27 | insert into SC values('01' , '02' , 90); 28 | insert into SC values('01' , '03' , 99); 29 | insert into SC values('02' , '01' , 70); 30 | insert into SC values('02' , '02' , 60); 31 | insert into SC values('02' , '03' , 80); 32 | insert into SC values('03' , '01' , 80); 33 | insert into SC values('03' , '02' , 80); 34 | insert into SC values('03' , '03' , 80); 35 | insert into SC values('04' , '01' , 50); 36 | insert into SC values('04' , '02' , 30); 37 | insert into SC values('04' , '03' , 20); 38 | insert into SC values('05' , '01' , 76); 39 | insert into SC values('05' , '02' , 87); 40 | insert into SC values('06' , '01' , 31); 41 | insert into SC values('06' , '03' , 34); 42 | insert into SC values('07' , '02' , 89); 43 | insert into SC values('07' , '03' , 98); --------------------------------------------------------------------------------