1. create database yhd character set utf8;
  2. use yhd;
  3. -- 建表
  4. -- 学生表
  5. CREATE TABLE `Student`(
  6. `s_id` VARCHAR(20),
  7. `s_name` VARCHAR(20) NOT NULL DEFAULT '',
  8. `s_birth` VARCHAR(20) NOT NULL DEFAULT '',
  9. `s_sex` VARCHAR(10) NOT NULL DEFAULT '',
  10. PRIMARY KEY(`s_id`)
  11. );
  12. -- 课程表
  13. CREATE TABLE `Course`(
  14. `c_id` VARCHAR(20),
  15. `c_name` VARCHAR(20) NOT NULL DEFAULT '',
  16. `t_id` VARCHAR(20) NOT NULL,
  17. PRIMARY KEY(`c_id`)
  18. );
  19. -- 教师表
  20. CREATE TABLE `Teacher`(
  21. `t_id` VARCHAR(20),
  22. `t_name` VARCHAR(20) NOT NULL DEFAULT '',
  23. PRIMARY KEY(`t_id`)
  24. );
  25. -- 成绩表
  26. CREATE TABLE `Score`(
  27. `s_id` VARCHAR(20),
  28. `c_id` VARCHAR(20),
  29. `s_score` INT(3),
  30. PRIMARY KEY(`s_id`,`c_id`)
  31. );
  32. -- 插入学生表测试数据
  33. insert into Student values('01' , '赵雷' , '1990-01-01' , '男');
  34. insert into Student values('02' , '钱电' , '1990-12-21' , '男');
  35. insert into Student values('03' , '孙风' , '1990-05-20' , '男');
  36. insert into Student values('04' , '李云' , '1990-08-06' , '男');
  37. insert into Student values('05' , '周梅' , '1991-12-01' , '女');
  38. insert into Student values('06' , '吴兰' , '1992-03-01' , '女');
  39. insert into Student values('07' , '郑竹' , '1989-07-01' , '女');
  40. insert into Student values('08' , '王菊' , '1990-01-20' , '女');
  41. -- 课程表测试数据
  42. insert into Course values('01' , '语文' , '02');
  43. insert into Course values('02' , '数学' , '01');
  44. insert into Course values('03' , '英语' , '03');
  45. -- 教师表测试数据
  46. insert into Teacher values('01' , '张三');
  47. insert into Teacher values('02' , '李四');
  48. insert into Teacher values('03' , '王五');
  49. -- 成绩表测试数据
  50. insert into Score values('01' , '01' , 80);
  51. insert into Score values('01' , '02' , 90);
  52. insert into Score values('01' , '03' , 99);
  53. insert into Score values('02' , '01' , 70);
  54. insert into Score values('02' , '02' , 60);
  55. insert into Score values('02' , '03' , 80);
  56. insert into Score values('03' , '01' , 80);
  57. insert into Score values('03' , '02' , 80);
  58. insert into Score values('03' , '03' , 80);
  59. insert into Score values('04' , '01' , 50);
  60. insert into Score values('04' , '02' , 30);
  61. insert into Score values('04' , '03' , 20);
  62. insert into Score values('05' , '01' , 76);
  63. insert into Score values('05' , '02' , 87);
  64. insert into Score values('06' , '01' , 31);
  65. insert into Score values('06' , '03' , 34);
  66. insert into Score values('07' , '02' , 89);
  67. insert into Score values('07' , '03' , 98);

1.学生表
# Student(s_id,s_name,s_birth,s_sex) —学生编号,学生姓名, 出生年月,学生性别
# 2.课程表
# Course(c_id,c_name,t_id) – —课程编号, 课程名称, 教师编号
# 3.教师表
# Teacher(t_id,t_name) —教师编号,教师姓名
# 4.成绩表
# Score(s_id,c_id,s_score) —学生编号,课程编号,分数

  1. -- 1、查询"01"课程比"02"课程成绩高的学生的信息及课程分数
  2. select a.* ,b.s_score as 01_score,c.s_score as 02_score from
  3. student a
  4. join score b on a.s_id=b.s_id and b.c_id='01'
  5. left join score c on a.s_id=c.s_id and c.c_id='02' or c.c_id = NULL where b.s_score>c.s_score
  6. --也可以这样写
  7. select a.*,b.s_score as 01_score,c.s_score as 02_score from student a,score b,score c
  8. where a.s_id=b.s_id
  9. and a.s_id=c.s_id
  10. and b.c_id='01'
  11. and c.c_id='02'
  12. and b.s_score>c.s_score
  13. -- 2、查询"01"课程比"02"课程成绩低的学生的信息及课程分数
  14. select a.* ,b.s_score as 01_score,c.s_score as 02_score from
  15. student a left join score b on a.s_id=b.s_id and b.c_id='01' or b.c_id=NULL
  16. join score c on a.s_id=c.s_id and c.c_id='02' where b.s_score<c.s_score
  17. -- 3、查询平均成绩大于等于60分的同学的学生编号和学生姓名和平均成绩
  18. select b.s_id,b.s_name,ROUND(AVG(a.s_score),2) as avg_score from
  19. student b
  20. join score a on b.s_id = a.s_id
  21. GROUP BY b.s_id,b.s_name HAVING avg_score >=60;
  22. -- 4、查询平均成绩小于60分的同学的学生编号和学生姓名和平均成绩
  23. -- (包括有成绩的和无成绩的)
  24. select b.s_id,b.s_name,ROUND(AVG(a.s_score),2) as avg_score from
  25. student b
  26. left join score a on b.s_id = a.s_id
  27. GROUP BY b.s_id,b.s_name HAVING avg_score <60
  28. union
  29. select a.s_id,a.s_name,0 as avg_score from
  30. student a
  31. where a.s_id not in (
  32. select distinct s_id from score);
  33. -- 5、查询所有同学的学生编号、学生姓名、选课总数、所有课程的总成绩
  34. select a.s_id,a.s_name,count(b.c_id) as sum_course,sum(b.s_score) as sum_score from
  35. student a
  36. left join score b on a.s_id=b.s_id
  37. GROUP BY a.s_id,a.s_name;
  38. -- 6、查询"李"姓老师的数量
  39. select count(t_id) from teacher where t_name like '李%';
  40. -- 7、查询学过"张三"老师授课的同学的信息
  41. select a.* from
  42. student a
  43. join score b on a.s_id=b.s_id where b.c_id in(
  44. select c_id from course where t_id =(
  45. select t_id from teacher where t_name = '张三'));
  46. -- 8、查询没学过"张三"老师授课的同学的信息
  47. select * from
  48. student c
  49. where c.s_id not in(
  50. select a.s_id from student a join score b on a.s_id=b.s_id where b.c_id in(
  51. select a.c_id from course a join teacher b on a.t_id = b.t_id where t_name ='张三'));
  52. -- 9、查询学过编号为"01"并且也学过编号为"02"的课程的同学的信息
  53. select a.* from
  54. student a,score b,score c
  55. where a.s_id = b.s_id and a.s_id = c.s_id and b.c_id='01' and c.c_id='02';
  56. -- 10、查询学过编号为"01"但是没有学过编号为"02"的课程的同学的信息
  57. select a.* from
  58. student a
  59. 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')
  60. -- 11、查询没有学全所有课程的同学的信息
  61. --@wendiepei的写法
  62. select s.* from student s
  63. left join Score s1 on s1.s_id=s.s_id
  64. group by s.s_id having count(s1.c_id)<(select count(*) from course)
  65. --@k1051785839的写法
  66. select *
  67. from student
  68. where s_id not in(
  69. select s_id from score t1
  70. group by s_id having count(*) =(select count(distinct c_id) from course))
  71. -- 12、查询至少有一门课与学号为"01"的同学所学相同的同学的信息
  72. select * from student where s_id in(
  73. select distinct a.s_id from score a where a.c_id in(select a.c_id from score a where a.s_id='01')
  74. );
  75. -- 13、查询和"01"号的同学学习的课程完全相同的其他同学的信息
  76. --@ouyang_1993的写法
  77. SELECT
  78. Student.*
  79. FROM
  80. Student
  81. WHERE
  82. s_id IN (SELECT s_id FROM Score GROUP BY s_id HAVING COUNT(s_id) = (
  83. #下面的语句是找到'01'同学学习的课程数
  84. SELECT COUNT(c_id) FROM Score WHERE s_id = '01'
  85. )
  86. )
  87. AND s_id NOT IN (
  88. #下面的语句是找到学过‘01’同学没学过的课程,有哪些同学。并排除他们
  89. SELECT s_id FROM Score
  90. WHERE c_id IN(
  91. #下面的语句是找到‘01’同学没学过的课程
  92. SELECT DISTINCT c_id FROM Score
  93. WHERE c_id NOT IN (
  94. #下面的语句是找出‘01’同学学习的课程
  95. SELECT c_id FROM Score WHERE s_id = '01'
  96. )
  97. ) GROUP BY s_id
  98. ) #下面的条件是排除01同学
  99. AND s_id NOT IN ('01')
  100. --@k1051785839的写法
  101. SELECT
  102. t3.*
  103. FROM
  104. (
  105. SELECT
  106. s_id,
  107. group_concat(c_id ORDER BY c_id) group1
  108. FROM
  109. score
  110. WHERE
  111. s_id &lt;> '01'
  112. GROUP BY
  113. s_id
  114. ) t1
  115. INNER JOIN (
  116. SELECT
  117. group_concat(c_id ORDER BY c_id) group2
  118. FROM
  119. score
  120. WHERE
  121. s_id = '01'
  122. GROUP BY
  123. s_id
  124. ) t2 ON t1.group1 = t2.group2
  125. INNER JOIN student t3 ON t1.s_id = t3.s_id
  126. -- 14、查询没学过"张三"老师讲授的任一门课程的学生姓名
  127. select a.s_name from student a where a.s_id not in (
  128. select s_id from score where c_id =
  129. (select c_id from course where t_id =(
  130. select t_id from teacher where t_name = '张三')));
  131. -- 15、查询两门及其以上不及格课程的同学的学号,姓名及其平均成绩
  132. select a.s_id,a.s_name,ROUND(AVG(b.s_score)) from
  133. student a
  134. left join score b on a.s_id = b.s_id
  135. where a.s_id in(
  136. select s_id from score where s_score<60 GROUP BY s_id having count(1)>=2)
  137. GROUP BY a.s_id,a.s_name
  138. -- 16、检索"01"课程分数小于60,按分数降序排列的学生信息
  139. select a.*,b.c_id,b.s_score from
  140. student a,score b
  141. where a.s_id = b.s_id and b.c_id='01' and b.s_score<60 ORDER BY b.s_score DESC;
  142. -- 17、按平均成绩从高到低显示所有学生的所有课程的成绩以及平均成绩
  143. select a.s_id,(select s_score from score where s_id=a.s_id and c_id='01') as 语文,
  144. (select s_score from score where s_id=a.s_id and c_id='02') as 数学,
  145. (select s_score from score where s_id=a.s_id and c_id='03') as 英语,
  146. round(avg(s_score),2) as 平均分 from score a GROUP BY a.s_id ORDER BY 平均分 DESC;
  147. --@喝完这杯还有一箱的写法
  148. SELECT a.s_id,MAX(CASE a.c_id WHEN '01' THEN a.s_score END ) 语文,
  149. MAX(CASE a.c_id WHEN '02' THEN a.s_score END ) 数学,
  150. MAX(CASE a.c_id WHEN '03' THEN a.s_score END ) 英语,
  151. 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
  152. -- 18.查询各科成绩最高分、最低分和平均分:以如下形式显示:课程ID,课程name,最高分,最低分,平均分,及格率,中等率,优良率,优秀率
  153. --及格为>=60,中等为:70-80,优良为:80-90,优秀为:>=90
  154. select a.c_id,b.c_name,MAX(s_score),MIN(s_score),ROUND(AVG(s_score),2),
  155. ROUND(100*(SUM(case when a.s_score>=60 then 1 else 0 end)/SUM(case when a.s_score then 1 else 0 end)),2) as 及格率,
  156. ROUND(100*(SUM(case when a.s_score>=70 and a.s_score<=80 then 1 else 0 end)/SUM(case when a.s_score then 1 else 0 end)),2) as 中等率,
  157. ROUND(100*(SUM(case when a.s_score>=80 and a.s_score<=90 then 1 else 0 end)/SUM(case when a.s_score then 1 else 0 end)),2) as 优良率,
  158. ROUND(100*(SUM(case when a.s_score>=90 then 1 else 0 end)/SUM(case when a.s_score then 1 else 0 end)),2) as 优秀率
  159. from score a left join course b on a.c_id = b.c_id GROUP BY a.c_id,b.c_name
  160. -- 19、按各科成绩进行排序,并显示排名
  161. -- mysql没有rank函数
  162. select a.s_id,a.c_id,
  163. @i:=@i +1 as i保留排名,
  164. @k:=(case when @score=a.s_score then @k else @i end) as rank不保留排名,
  165. @score:=a.s_score as score
  166. from (
  167. select s_id,c_id,s_score from score GROUP BY s_id,c_id,s_score ORDER BY s_score DESC
  168. )a,(select @k:=0,@i:=0,@score:=0)s
  169. --@k1051785839的写法
  170. (select * from (select
  171. t1.c_id,
  172. t1.s_score,
  173. (select count(distinct t2.s_score) from score t2 where t2.s_score>=t1.s_score and t2.c_id='01') rank
  174. FROM score t1 where t1.c_id='01'
  175. order by t1.s_score desc) t1)
  176. union
  177. (select * from (select
  178. t1.c_id,
  179. t1.s_score,
  180. (select count(distinct t2.s_score) from score t2 where t2.s_score>=t1.s_score and t2.c_id='02') rank
  181. FROM score t1 where t1.c_id='02'
  182. order by t1.s_score desc) t2)
  183. union
  184. (select * from (select
  185. t1.c_id,
  186. t1.s_score,
  187. (select count(distinct t2.s_score) from score t2 where t2.s_score>=t1.s_score and t2.c_id='03') rank
  188. FROM score t1 where t1.c_id='03'
  189. order by t1.s_score desc) t3)
  190. -- 20、查询学生的总成绩并进行排名
  191. select a.s_id,
  192. @i:=@i+1 as i,
  193. @k:=(case when @score=a.sum_score then @k else @i end) as rank,
  194. @score:=a.sum_score as score
  195. from (select s_id,SUM(s_score) as sum_score from score GROUP BY s_id ORDER BY sum_score DESC)a,
  196. (select @k:=0,@i:=0,@score:=0)s
  197. -- 21、查询不同老师所教不同课程平均分从高到低显示
  198. select a.t_id,c.t_name,a.c_id,ROUND(avg(s_score),2) as avg_score from course a
  199. left join score b on a.c_id=b.c_id
  200. left join teacher c on a.t_id=c.t_id
  201. GROUP BY a.c_id,a.t_id,c.t_name ORDER BY avg_score DESC;
  202. -- 22、查询所有课程的成绩第2名到第3名的学生信息及该课程成绩
  203. select d.*,c.排名,c.s_score,c.c_id from (
  204. 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'
  205. ORDER BY a.s_score DESC
  206. )c
  207. left join student d on c.s_id=d.s_id
  208. where 排名 BETWEEN 2 AND 3
  209. UNION
  210. select d.*,c.排名,c.s_score,c.c_id from (
  211. 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'
  212. ORDER BY a.s_score DESC
  213. )c
  214. left join student d on c.s_id=d.s_id
  215. where 排名 BETWEEN 2 AND 3
  216. UNION
  217. select d.*,c.排名,c.s_score,c.c_id from (
  218. 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'
  219. ORDER BY a.s_score DESC
  220. )c
  221. left join student d on c.s_id=d.s_id
  222. where 排名 BETWEEN 2 AND 3;
  223. -- 23、统计各科成绩各分数段人数:课程编号,课程名称,[100-85],[85-70],[70-60],[0-60]及所占百分比
  224. 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
  225. left join (select c_id,SUM(case when s_score >85 and s_score <=100 then 1 else 0 end) as `85-100`,
  226. ROUND(100*(SUM(case when s_score >85 and s_score <=100 then 1 else 0 end)/count(*)),2) as 百分比
  227. from score GROUP BY c_id)b on a.c_id=b.c_id
  228. left join (select c_id,SUM(case when s_score >70 and s_score <=85 then 1 else 0 end) as `70-85`,
  229. ROUND(100*(SUM(case when s_score >70 and s_score <=85 then 1 else 0 end)/count(*)),2) as 百分比
  230. from score GROUP BY c_id)c on a.c_id=c.c_id
  231. left join (select c_id,SUM(case when s_score >60 and s_score <=70 then 1 else 0 end) as `60-70`,
  232. ROUND(100*(SUM(case when s_score >60 and s_score <=70 then 1 else 0 end)/count(*)),2) as 百分比
  233. from score GROUP BY c_id)d on a.c_id=d.c_id
  234. left join (select c_id,SUM(case when s_score >=0 and s_score <=60 then 1 else 0 end) as `0-60`,
  235. ROUND(100*(SUM(case when s_score >=0 and s_score <=60 then 1 else 0 end)/count(*)),2) as 百分比
  236. from score GROUP BY c_id)e on a.c_id=e.c_id
  237. left join course f on a.c_id = f.c_id
  238. -- 24、查询学生平均成绩及其名次
  239. select a.s_id,
  240. @i:=@i+1 as '不保留空缺排名',
  241. @k:=(case when @avg_score=a.avg_s then @k else @i end) as '保留空缺排名',
  242. @avg_score:=avg_s as '平均分'
  243. 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;
  244. -- 25、查询各科成绩前三名的记录
  245. -- 1.选出b表比a表成绩大的所有组
  246. -- 2.选出比当前id成绩大的 小于三个的
  247. select a.s_id,a.c_id,a.s_score from score a
  248. left join score b on a.c_id = b.c_id and a.s_score<b.s_score
  249. group by a.s_id,a.c_id,a.s_score HAVING COUNT(b.s_id)<3
  250. ORDER BY a.c_id,a.s_score DESC
  251. -- 26、查询每门课程被选修的学生数
  252. select c_id,count(s_id) from score a GROUP BY c_id
  253. -- 27、查询出只有两门课程的全部学生的学号和姓名
  254. select s_id,s_name from student where s_id in(
  255. select s_id from score GROUP BY s_id HAVING COUNT(c_id)=2);
  256. -- 28、查询男生、女生人数
  257. select s_sex,COUNT(s_sex) as 人数 from student GROUP BY s_sex
  258. -- 29、查询名字中含有"风"字的学生信息
  259. select * from student where s_name like '%风%';
  260. -- 30、查询同名同性学生名单,并统计同名人数
  261. select a.s_name,a.s_sex,count(*) from student a JOIN
  262. student b on a.s_id !=b.s_id and a.s_name = b.s_name and a.s_sex = b.s_sex
  263. GROUP BY a.s_name,a.s_sex
  264. -- 31、查询1990年出生的学生名单
  265. select s_name from student where s_birth like '1990%'
  266. -- 32、查询每门课程的平均成绩,结果按平均成绩降序排列,平均成绩相同时,按课程编号升序排列
  267. 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
  268. -- 33、查询平均成绩大于等于85的所有学生的学号、姓名和平均成绩
  269. select a.s_id,b.s_name,ROUND(avg(a.s_score),2) as avg_score from score a
  270. left join student b on a.s_id=b.s_id GROUP BY s_id HAVING avg_score>=85
  271. -- 34、查询课程名称为"数学",且分数低于60的学生姓名和分数
  272. select a.s_name,b.s_score from score b join student a on a.s_id=b.s_id where b.c_id=(
  273. select c_id from course where c_name ='数学') and b.s_score<60
  274. -- 35、查询所有学生的课程及分数情况;
  275. select a.s_id,a.s_name,
  276. SUM(case c.c_name when '语文' then b.s_score else 0 end) as '语文',
  277. SUM(case c.c_name when '数学' then b.s_score else 0 end) as '数学',
  278. SUM(case c.c_name when '英语' then b.s_score else 0 end) as '英语',
  279. SUM(b.s_score) as '总分'
  280. from student a left join score b on a.s_id = b.s_id
  281. left join course c on b.c_id = c.c_id
  282. GROUP BY a.s_id,a.s_name
  283. -- 36、查询任何一门课程成绩在70分以上的姓名、课程名称和分数;
  284. select a.s_name,b.c_name,c.s_score from course b left join score c on b.c_id = c.c_id
  285. left join student a on a.s_id=c.s_id where c.s_score>=70
  286. -- 37、查询不及格的课程
  287. 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
  288. where a.s_score<60
  289. --38、查询课程编号为01且课程成绩在80分以上的学生的学号和姓名;
  290. select a.s_id,b.s_name from score a LEFT JOIN student b on a.s_id = b.s_id
  291. where a.c_id = '01' and a.s_score>80
  292. -- 39、求每门课程的学生人数
  293. select count(*) from score GROUP BY c_id;
  294. -- 40、查询选修"张三"老师所授课程的学生中,成绩最高的学生信息及其成绩
  295. -- 查询老师id
  296. select c_id from course c,teacher d where c.t_id=d.t_id and d.t_name='张三'
  297. -- 查询最高分(可能有相同分数)
  298. select MAX(s_score) from score where c_id='02'
  299. -- 查询信息
  300. select a.*,b.s_score,b.c_id,c.c_name from student a
  301. LEFT JOIN score b on a.s_id = b.s_id
  302. LEFT JOIN course c on b.c_id=c.c_id
  303. where b.c_id =(select c_id from course c,teacher d where c.t_id=d.t_id and d.t_name='张三')
  304. and b.s_score in (select MAX(s_score) from score where c_id='02')
  305. -- 41、查询不同课程成绩相同的学生的学生编号、课程编号、学生成绩
  306. 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
  307. -- 42、查询每门功成绩最好的前两名
  308. -- 牛逼的写法
  309. select a.s_id,a.c_id,a.s_score from score a
  310. 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
  311. -- 43、统计每门课程的学生选修人数(超过5人的课程才统计)。要求输出课程号和选修人数,查询结果按人数降序排列,若人数相同,按课程号升序排列
  312. select c_id,count(*) as total from score GROUP BY c_id HAVING total>5 ORDER BY total,c_id ASC
  313. -- 44、检索至少选修两门课程的学生学号
  314. select s_id,count(*) as sel from score GROUP BY s_id HAVING sel>=2
  315. -- 45、查询选修了全部课程的学生信息
  316. select * from student where s_id in(
  317. select s_id from score GROUP BY s_id HAVING count(*)=(select count(*) from course))
  318. --46、查询各学生的年龄
  319. -- 按照出生日期来算,当前月日 < 出生年月的月日则,年龄减一
  320. select s_birth,(DATE_FORMAT(NOW(),'%Y')-DATE_FORMAT(s_birth,'%Y') -
  321. (case when DATE_FORMAT(NOW(),'%m%d')>DATE_FORMAT(s_birth,'%m%d') then 0 else 1 end)) as age
  322. from student;
  323. -- 47、查询本周过生日的学生
  324. select * from student where WEEK(DATE_FORMAT(NOW(),'%Y%m%d'))=WEEK(s_birth)
  325. select * from student where YEARWEEK(s_birth)=YEARWEEK(DATE_FORMAT(NOW(),'%Y%m%d'))
  326. select WEEK(DATE_FORMAT(NOW(),'%Y%m%d'))
  327. -- 48、查询下周过生日的学生
  328. select * from student where WEEK(DATE_FORMAT(NOW(),'%Y%m%d'))+1 =WEEK(s_birth)
  329. -- 49、查询本月过生日的学生
  330. select * from student where MONTH(DATE_FORMAT(NOW(),'%Y%m%d')) =MONTH(s_birth)
  331. -- 50、查询下月过生日的学生
  332. select * from student where MONTH(DATE_FORMAT(NOW(),'%Y%m%d'))+1 =MONTH(s_birth)