基础完成

  1. 1、查询男生、女生的人数;
  2. select gender,count(gender) as gender_num from student group by gender;
  3. 2、查询姓“张”的学生名单;
  4. select sname from student where sname regexp '^张';
  5. select sname from student where sname regexp '张{1}';
  6. select sname from student where sname like '张%';
  7. 3、课程平均分从高到低显示
  8. select course.cname,avg(score.num) as avg_num from score inner join course where score.course_id = course.cid group by cname order by avg_num desc;
  9. 4、查询有课程成绩小于60分的同学的学号、姓名;
  10. select distinct student.sid,student.sname from score inner join student on score.student_id = student.sid where score.num < 60;
  11. 5、查询至少有一门课与学号为1的同学所学课程相同的同学的学号和姓名;
  12. SELECT DISTINCT
  13. student.sid,
  14. student.sname
  15. FROM
  16. score
  17. INNER JOIN student ON score.student_id = student.sid
  18. WHERE
  19. course_id IN ( SELECT course_id FROM score WHERE student_id = 1 );
  20. 6、查询出只选修了一门课程的全部学生的学号和姓名;
  21. select sid,sname from student inner join (select student_id,course_id from score group by student_id having count(score.course_id) = 1) as s_sid on student.sid = s_sid.student_id;
  22. 7、查询各科成绩最高和最低的分:以如下形式显示:课程ID,最高分,最低分;
  23. select course_id as '课程ID',max(num) as '最高分' ,min(num) as '最低分' from score group by course_id;
  24. select course_id as '课程ID',max(num) as '最高分' ,min(num) as '最低分' from score where score.course_id in (select cid FROM course) group by course_id;
  25. select course_id as '课程ID',max(num) as '最高分' ,min(num) as '最低分' from score group by course_id having score.course_id in (select cid FROM course);
  26. select concat_ws(',',course_id,max(num),min(num)) as fp from score group by course_id having score.course_id in (select cid FROM course);
  27. select concat('课程ID: ',course_id,' 最高分:',max(num),' 最低分:',min(num)) as fp from score group by course_id having score.course_id in (select cid FROM course);
  28. 8、查询课程编号“2”的成绩比课程编号“1”课程低的所有同学的学号、姓名;
  29. SELECT
  30. sid,
  31. sname
  32. FROM
  33. student
  34. INNER JOIN (
  35. SELECT
  36. st_id1,
  37. sc1,
  38. sc2
  39. FROM
  40. ( SELECT student_id AS st_id1, num AS sc1 FROM score WHERE course_id = 1 ) AS num_1,
  41. ( SELECT student_id AS st_id2, num AS sc2 FROM score WHERE course_id = 2 ) AS num_2
  42. WHERE
  43. st_id1 = st_id2
  44. AND sc2 < sc1
  45. ) AS sr ON student.sid = sr.st_id1;
  46. 9、查询“生物”课程比“物理”课程成绩高的所有学生的学号;
  47. SELECT
  48. sid
  49. FROM
  50. student
  51. INNER JOIN (
  52. SELECT
  53. stu_swid,
  54. sw_num,
  55. wl_num
  56. FROM
  57. (
  58. SELECT
  59. student_id AS stu_swid,
  60. num AS sw_num
  61. FROM
  62. score
  63. WHERE
  64. score.course_id = ( SELECT cid AS sw_cid FROM course WHERE cname = '生物' )
  65. ) AS sw,
  66. (
  67. SELECT
  68. student_id AS stu_wlid,
  69. num AS wl_num
  70. FROM
  71. score
  72. WHERE
  73. score.course_id = ( SELECT cid AS sw_cid FROM course WHERE cname = '物理' )
  74. ) AS wl
  75. WHERE
  76. stu_swid = stu_wlid
  77. AND sw_num > wl_num
  78. ) AS super ON student.sid = super.stu_swid;
  79. 10、查询平均成绩大于60分的同学的学号和平均成绩;
  80. SELECT
  81. sid,
  82. convert(avg_me.avg_num,decimal(5,2)) as avg_num
  83. FROM
  84. student
  85. INNER JOIN ( SELECT student_id, avg( num ) AS avg_num FROM score GROUP BY student_id HAVING avg_num > 60 ) AS avg_me ON student.sid = avg_me.student_id;
  86. 11、查询所有同学的学号、姓名、选课数、总成绩;
  87. SELECT
  88. student.sid,
  89. student.sname,
  90. count( score.course_id ) AS count_course,
  91. sum( num ) AS num_score
  92. FROM
  93. student
  94. LEFT JOIN score ON student.sid = score.student_id
  95. GROUP BY
  96. student.sid
  97. 12、查询姓“李”的老师的个数;
  98. select count(tid) as count_tid from teacher where tname regexp '^李';
  99. select count(tid) as count_tid from teacher where tname regexp '李.*';
  100. select count(tid) as count_tid from teacher where tname like '李%';
  101. 13、查询没学过“张磊老师”课的同学的学号、姓名;
  102. SELECT
  103. sid,
  104. sname
  105. FROM
  106. student
  107. WHERE
  108. sid NOT IN (
  109. SELECT
  110. student_id
  111. FROM
  112. score
  113. WHERE
  114. course_id = ( SELECT cid FROM course INNER JOIN teacher ON course.teacher_id = teacher.tid WHERE tname = '张磊老师' )
  115. );
  116. 14、查询学过“1”并且也学过编号“2”课程的同学的学号、姓名;
  117. SELECT
  118. sid,
  119. sname
  120. FROM
  121. student
  122. WHERE
  123. sid IN (
  124. SELECT
  125. cor1.student_id
  126. FROM
  127. (
  128. ( SELECT student_id, course_id AS cid_1 FROM score WHERE course_id = 1 ) AS cor1,
  129. ( SELECT student_id, course_id AS cid_2 FROM score WHERE course_id = 2 ) AS cor2
  130. )
  131. WHERE
  132. cor1.student_id = cor2.student_id
  133. )
  134. 15、查询学过“李平老师”所教的所有课的同学的学号、姓名;
  135. SELECT
  136. sid,sname
  137. FROM
  138. student,
  139. (
  140. SELECT
  141. student_id,
  142. group_concat( course_id ORDER BY course_id ASC ) AS grp_co
  143. FROM
  144. score
  145. INNER JOIN ( SELECT cid FROM course INNER JOIN teacher ON course.teacher_id = teacher.tid WHERE tname = '李平老师' ) AS s1 ON course_id = cid
  146. GROUP BY
  147. student_id
  148. ) AS grp_s
  149. WHERE
  150. student.sid = grp_s.student_id
  151. AND grp_co = ( SELECT GROUP_CONCAT( cid ) FROM course INNER JOIN teacher ON course.teacher_id = teacher.tid WHERE tname = '李平老师' );

进阶完成

  1. 1、查询没有学全所有课的同学的学号、姓名;
  2. # 方法一
  3. select student_id,sname from score inner join student on score.student_id = student.sid group by student.sid having count(course_id) < (select count(cid) from course)
  4. # 方法二
  5. SELECT
  6. sid,
  7. sname
  8. FROM
  9. student
  10. WHERE
  11. sid IN (
  12. SELECT
  13. student_id
  14. FROM
  15. ( SELECT student_id, GROUP_CONCAT( course_id ) AS stu_id FROM score GROUP BY student_id ) AS stu_con,
  16. ( SELECT GROUP_CONCAT( cid ORDER BY cid ASC ) AS cor_id FROM course ) AS cor_con
  17. WHERE
  18. stu_id != cor_id
  19. );
  20. 2、查询和“002”号的同学学习的课程完全相同的其他同学学号和姓名;
  21. SELECT
  22. sid,
  23. sname
  24. FROM
  25. student
  26. WHERE
  27. sid = (
  28. SELECT
  29. stu_con.student_id
  30. FROM
  31. ( SELECT student_id, GROUP_CONCAT( course_id ORDER BY course_id ASC ) AS stu_id FROM score GROUP BY student_id ) AS stu_con,
  32. ( SELECT student_id, GROUP_CONCAT( course_id ORDER BY course_id ASC ) AS stu_id FROM score GROUP BY student_id HAVING student_id = 2 ) AS stu2_con
  33. WHERE
  34. stu_con.stu_id = stu2_con.stu_id
  35. AND stu_con.student_id != stu2_con.student_id
  36. );
  37. 3、删除学习“叶平”老师课的SC表记录;
  38. # 数据准备一下
  39. insert into teacher(tname) values('叶平老师');
  40. insert into course(cname,teacher_id) values('心理学',6);
  41. insert into score values(53,2,5,97),(54,13,5,95);
  42. # 删除数据
  43. delete from score where course_id = (select cid from course inner join teacher where course.teacher_id = teacher.tid and teacher.tname = '叶平老师');
  44. 4、向SC表中插入一些记录,这些记录要求符合以下条件:①没有上过编号“002”课程的同学学号;②插入“002”号课程的平均成绩;
  45. select sid from student where sid not in (select student_id from score where course_id = 2 );
  46. select avg(num) from score group by course_id having course_id = 2;
  47. insert into score values(82,2,2,68),(83,13,2,68),(84,14,2,68),(85,15,2,68),(86,16,2,68);
  48. 5、按平均成绩从低到高显示所有学生的“生物”、“物理”、“体育”三门的课程成绩,按如下形式显示: 学生ID,生物,物理,体育,有效课程数,有效平均分;
  49. SELECT
  50. concat_ws(
  51. ' ',
  52. '学生id:',student.sid,
  53. '生物/物理/体育:',group_concat( CASE WHEN score.num IS NOT NULL THEN score.num ELSE concat( 'null' ) END ORDER BY course.cname DESC ),
  54. '有效课程数:',count( score.course_id ),
  55. '有效平均数:',CONVERT ( avg( score.num ), DECIMAL ( 5, 2 ) )
  56. )
  57. FROM
  58. student
  59. INNER JOIN course ON cname IN ( '生物', '物理', '体育' )
  60. LEFT JOIN score ON student.sid = score.student_id
  61. AND course.cid = score.course_id
  62. GROUP BY
  63. student.sid
  64. ORDER BY
  65. avg( score.num )
  66. 6、查询各科成绩最高和最低的分:以如下形式显示:课程ID,最高分,最低分;
  67. # 方法一
  68. select concat_ws(',',course_id,max(num),min(num)) as fp from score group by course_id having score.course_id in (select cid FROM course);
  69. # 方法二
  70. select course_id as '课程ID',max(num) as '最高分' ,min(num) as '最低分' from score group by course_id having score.course_id in (select cid FROM course);
  71. # 方法三
  72. select concat('课程ID: ',course_id,' 最高分:',max(num),' 最低分:',min(num)) as fp from score group by course_id having score.course_id in (select cid FROM course);
  73. 7、按各科平均成绩从低到高和及格率的百分数从高到低顺序;
  74. # 平均成绩从低到高排序
  75. select score.course_id,course.cname,avg(num) as avg_num from score inner join course on score.course_id = course.cid group by score.course_id order by avg_num asc;
  76. # 及格率百分数从高到底排序
  77. SELECT course_id, convert(sum( CASE WHEN score.num > 60 THEN 1 ELSE 0 END ) / count(1) * 100,DECIMAL(5,2)) as percent FROM score GROUP BY course_id order by percent desc;
  78. 8、查询各科成绩前三名的记录:(不考虑成绩并列情况)
  79. # 方法一
  80. SELECT a.course_id,a.cname,SUBSTRING_INDEX(a.num, ',', 3) as score from (SELECT GROUP_CONCAT(num ORDER BY num desc) as num ,course_id,course.cname from score inner join course on score.course_id = course.cid GROUP BY score.course_id ) as a
  81. # 方法二
  82. select s1.course_id,s1.student_id,s1.num as score,count( DISTINCT s2.num) as sort_num
  83. from score as s1
  84. inner join score as s2
  85. on s1.course_id = s2.course_id and s1.num <= s2.num
  86. group by s1.course_id,s1.num having sort_num <= 3 order by s1.course_id,s1.num desc ;
  87. 9、查询每门课程被选修的学生数;
  88. select score.course_id,course.cname,count(score.student_id) as student_count from score inner join course on score.course_id = course.cid group by score.course_id
  89. 10、查询同名同姓学生名单,并统计同名人数;
  90. insert into student values(17,'女',3,'刘四');
  91. select sname,count(sname) as same_num from student group by sname having same_num > 1;
  92. 11、查询每门课程的平均成绩,结果按平均成绩升序排列,平均成绩相同时,按课程号降序排列;
  93. select course_id,CONVERT(avg(num),decimal(5,2)) as avg_num from score group by course_id order by avg_num asc,course_id desc;
  94. 12、查询平均成绩大于85的所有学生的学号、姓名和平均成绩;
  95. insert into score values(81,14,5,100);
  96. # 85分的同学原数据没有,所以手动插入一条,并且将85分条件暂时定为80
  97. SELECT
  98. sid,
  99. sname,
  100. avg_num
  101. FROM
  102. student
  103. INNER JOIN ( SELECT student_id, avg( num ) AS avg_num FROM score GROUP BY student_id HAVING avg_num > 80 ) AS avg_sid ON student.sid = avg_sid.student_id;
  104. 13、查询课程名称为“数学”,且分数低于60的学生姓名和分数;
  105. # 没有数学用物理替代
  106. # 方法一
  107. select st.sname,score.num as score from score inner join course on score.course_id = course.cid and course.cname = '物理' inner join (select sid,sname from student) as st on st.sid = score.student_id where num < 60
  108. # 方法二
  109. SELECT
  110. sname,
  111. num AS score
  112. FROM
  113. student
  114. INNER JOIN (
  115. SELECT
  116. student_id,
  117. num
  118. FROM
  119. score
  120. INNER JOIN ( SELECT cid FROM course WHERE cname = '物理' ) AS c ON course_id = c.cid
  121. WHERE
  122. num < 60
  123. ) AS cc ON student.sid = cc.student_id;
  124. 14、查询课程编号为003且课程成绩在80分以上的学生的学号和姓名;
  125. # 方法一
  126. select student.sid,student.sname from score inner join student on student_id = student.sid where course_id = 3 and num > 80;
  127. # 方法二
  128. SELECT
  129. sid,
  130. sname
  131. FROM
  132. student
  133. INNER JOIN (
  134. SELECT
  135. student_id,
  136. num
  137. FROM
  138. score
  139. INNER JOIN ( SELECT cid FROM course WHERE cid = '3' ) AS c ON course_id = c.cid
  140. WHERE
  141. num > 80
  142. ) AS score_8 ON student.sid = score_8.student_id;
  143. 15、求选了课程的学生人数
  144. SELECT
  145. count( studentd.student_id ) AS same_count_stu
  146. FROM
  147. ( SELECT student_id FROM score GROUP BY student_id HAVING count( course_id ) > 0 ) AS studentd;
  148. 16、查询选修“杨艳”老师所授课程的学生中,成绩最高的学生姓名及其成绩;
  149. SELECT
  150. st.sname,
  151. s.num
  152. FROM
  153. score s
  154. INNER JOIN course c ON c.cid = s.course_id
  155. INNER JOIN teacher t ON t.tid = c.teacher_id
  156. INNER JOIN student st ON st.sid = s.student_id
  157. WHERE
  158. t.tname = '刘海燕老师'
  159. ORDER BY
  160. s.num DESC
  161. LIMIT 1;
  162. 17、查询各个课程及相应的选修人数;
  163. SELECT
  164. cid,
  165. cname,
  166. count( student_id ) AS count_st
  167. FROM
  168. course c
  169. INNER JOIN score s ON c.cid = s.course_id
  170. GROUP BY
  171. s.course_id;
  172. 18、查询不同课程但成绩相同的学生的学号、课程号、学生成绩;
  173. SELECT
  174. score.student_id,
  175. GROUP_CONCAT( score.course_id ) cor_id,
  176. score.num
  177. FROM
  178. score
  179. INNER JOIN score c ON score.num = c.num
  180. AND score.course_id != c.course_id
  181. AND score.student_id = c.student_id
  182. GROUP BY
  183. score.student_id;
  184. 19、查询每门课程成绩最好的前两名;
  185. select SUBSTRING_INDEX(cc.st_id, ',', 2) as stid,SUBSTRING_INDEX(cc.sc, ',', 2) as sc from (select group_concat(student_id order by num desc) as st_id,group_concat(num order by num desc) as sc from score sc1 where (select count(1) from score sc2 where sc2.course_id = sc1.course_id and sc2.num > sc1.num ) <=2 group by sc1.course_id order by sc1.course_id asc,sc1.num desc) as cc;
  186. 20、检索至少选修两门课程的学生学号;
  187. select student_id from score group by student_id having count(course_id) > 1;
  188. 21、查询全部学生都选修的课程的课程号和课程名;
  189. select course.cid,course.cname from score inner join course on score.course_id = course.cid group by cid,cname having count(student_id) = (select count(sid) from student);
  190. 22、查询没学过“叶平”老师讲授的任一门课程的学生姓名;
  191. select sname from student where sid not in (select student_id from score inner join course on score.course_id = course.cid inner join teacher on tname = '李平老师' and teacher_id = tid group by student_id);
  192. 23、查询两门以上不及格课程的同学的学号及其平均成绩;
  193. # 方法一
  194. select score.student_id,avg(num) avg_num from score inner join (select student_id from score where num < 60 group by student_id having count(student_id) > 1) as sm on score.student_id = sm.student_id group by score.student_id
  195. # 方法二
  196. select student_id,avg(num) avg_num from score where student_id in (select student_id from score where num < 60 group by student_id having count(student_id) > 1) group by score.student_id ;
  197. 24、检索“004”课程分数小于60,按分数降序排列的同学学号;
  198. select student_id from score where course_id = 4 and num < 60 order by num desc;
  199. 25、删除“002”同学的“001”课程的成绩;
  200. delete from score where student_id = 2 and course_id = 1;