前往小程序,Get更优阅读体验!
立即前往
首页
学习
活动
专区
工具
TVP
发布
社区首页 >专栏 >SQL题目50道 持续更新

SQL题目50道 持续更新

作者头像
lop
发布2019-03-13 16:51:35
8490
发布2019-03-13 16:51:35
举报
文章被收录于专栏:小六

数据如下,我在答题过程中使用的是mysql数据库

代码语言:javascript
复制
create table Student
(
  S     varchar(10),
  Sname nvarchar(10),
  Sage  datetime,
  Ssex  nvarchar(10)
);
insert into Student
values ('01', N'赵雷', '1990-01-01', N'男');
insert into Student
values ('02', N'钱电', '1990-12-21', N'男');
insert into Student
values ('03', N'孙风', '1990-05-20', N'男');
insert into Student
values ('04', N'李云', '1990-08-06', N'男');
insert into Student
values ('05', N'周梅', '1991-12-01', N'女');
insert into Student
values ('06', N'吴兰', '1992-03-01', N'女');
insert into Student
values ('07', N'郑竹', '1989-07-01', N'女');
insert into Student
values ('08', N'王菊', '1990-01-20', N'女');



create table Course
(
  C     varchar(10),
  Cname nvarchar(10),
  T     varchar(10)
);
insert into Course
values ('01', N'语文', '02');
insert into Course
values ('02', N'数学', '01');
insert into Course
values ('03', N'英语', '03');


create table Teacher
(
  T     varchar(10),
  Tname nvarchar(10)
);
insert into Teacher
values ('01', N'张三');
insert into Teacher
values ('02', N'李四');
insert into Teacher
values ('03', N'王五');


create table SC
(
  S     varchar(10),
  C     varchar(10),
  score decimal(18, 1)
);
insert into SC
values ('01', '01', 80);
insert into SC
values ('01', '02', 90);
insert into SC
values ('01', '03', 99);
insert into SC
values ('02', '01', 70);
insert into SC
values ('02', '02', 60);
insert into SC
values ('02', '03', 80);
insert into SC
values ('03', '01', 80);
insert into SC
values ('03', '02', 80);
insert into SC
values ('03', '03', 80);
insert into SC
values ('04', '01', 50);
insert into SC
values ('04', '02', 30);
insert into SC
values ('04', '03', 20);
insert into SC
values ('05', '01', 76);
insert into SC
values ('05', '02', 87);
insert into SC
values ('06', '01', 31);
insert into SC
values ('06', '03', 34);
insert into SC
values ('07', '02', 89);
insert into SC
values ('07', '03', 98);

insert into SC
values ('07', '04', 98);

有些题目可能会有不对的sql,是在写题目的时候打得

代码语言:javascript
复制
# 1. 查询" 01 "课程比" 02 "课程成绩高的学生的信息及课程分数

SELECT Student.S,Sname,Sage, Ssex,C,score_01,score_02
FROM Student
       JOIN (
  SELECT *
  FROM (SELECT S,C,score score_01 FROM SC WHERE C = '01') a
         LEFT JOIN (SELECT S new_s, C new_c, score score_02 FROM SC WHERE C = '02') b ON a.S = b.new_s
  WHERE a.score_01 > b.score_02) c ON Student.S = c.new_s;


# 1.1 查询同时存在" 01 "课程和" 02 "课程的情况

SELECT *
FROM (SELECT * FROM SC WHERE C = '01') a
       JOIN (SELECT * FROM SC WHERE C = '02') b ON a.S = b.S;


# 1.2 查询存在" 01 "课程但可能不存在" 02 "课程的情况(不存在时显示为 null )

SELECT *
FROM (SELECT * FROM SC WHERE C = '01') a
       LEFT JOIN (SELECT * FROM SC WHERE C = '02') b ON a.S = b.S;


# 1.3 查询选课不存在" 01 "课程但存在" 02 "课程的情况

# 解法1
SELECT *
FROM SC
WHERE C = '02'
  AND S NOT IN (SELECT S
                FROM SC
                WHERE C = '01');

# 解法2
SELECT *
FROM SC A
WHERE A.C = '02'
  AND NOT EXISTS
  (SELECT S
   FROM SC B
   WHERE A.S = B.S
     AND C = '01');


# 解法3
SELECT *
FROM (SELECT * FROM SC WHERE C = '01') a
       LEFT JOIN (SELECT * FROM SC WHERE C = '02') b ON a.S = b.S;


# 2. 查询平均成绩大于等于 60 分的同学的学生编号和学生姓名和平均成绩

SELECT A.S,B.Sname,A.dc
FROM (SELECT S,AVG(score) dc FROM SC GROUP BY S HAVING AVG(score) > 60) A
       LEFT JOIN Student B ON A.S = B.S;


# 3. 查询在 SC 表存在成绩的学生信息

SELECT *
FROM Student
WHERE EXISTS(SELECT * FROM SC where SC.S = Student.S);


# 4. 查询所有同学的学生编号、学生姓名、选课总数、所有课程的总成绩(没成绩的显示为 null )

SELECT Student.S, Student.Sname, 选课总数, 总成绩
FROM (SELECT S, count(C) 选课总数, sum(score) 总成绩 FROM SC GROUP BY S) A
       RIGHT JOIN Student ON Student.S = A.S;


# 4.1 查有成绩的学生信息

SELECT Student.S, Student.Sname, 选课总数, 总成绩
FROM (SELECT S, count(C) 选课总数, sum(score) 总成绩 FROM SC GROUP BY S) A
       LEFT JOIN Student ON Student.S = A.S;


# 5. 查询「李」姓老师的数量 

SELECT COUNT(*)
FROM Teacher
where Tname LIKE '李%';


# 6. 查询学过「张三」老师授课的同学的信息 

SELECT *
FROM Student
WHERE EXISTS(SELECT *
             FROM SC
             WHERE Student.S = SC.S
               AND EXISTS(SELECT *
                          FROM Course
                          WHERE SC.C = Course.C
                            AND EXISTS(SELECT *
                                       FROM Teacher
                                       WHERE Teacher.Tname = '张三'
                                         AND Course.T = Teacher.T)
               ));

# 7. 查询没有学全所有课程的同学的信息 

# 解法1
SELECT *
FROM Student
WHERE S NOT IN (SELECT S FROM SC GROUP BY S HAVING COUNT(C) = (SELECT COUNT(*) FROM Course));

# 解法2
SELECT *
FROM Student
WHERE NOT EXISTS(
    SELECT S
    FROM SC
    WHERE SC.S = Student.S
    GROUP BY SC.S
    HAVING COUNT(*) = (SELECT COUNT(*) FROM Course)
  );


# 8. 查询至少有一门课与学号为" 01 "的同学所学相同的同学的信息 

# 解法1
SELECT *
FROM Student
WHERE S IN (SELECT S
            FROM SC
            WHERE C IN (
              SELECT DISTINCT C
              FROM SC
              WHERE S = '01'
            ));

# 解法2
SELECT *
FROM Student
WHERE EXISTS(
          SELECT *
          FROM SC A
          WHERE A.S = Student.S
            AND EXISTS(
              SELECT *
              FROM SC B
              WHERE A.C = B.C
                AND B.S = '01'
            ));


# 9. 查询和" 01 "号的同学学习的课程完全相同的其他同学的信息 

# 解法1 先把找出选修了其他课程的人, 将其过滤, 然后分组统计


SELECT *
FROM Student C
WHERE EXISTS(
          SELECT A.S
          FROM SC A
          WHERE C.S = A.S
            AND EXISTS(SELECT * FROM SC B WHERE A.C = B.C AND B.S = '01')
          GROUP BY A.S
          HAVING COUNT(*) = (SELECT COUNT(*) FROM SC WHERE S = '01'));


SELECT *
FROM Student a
WHERE NOT EXISTS
  (SELECT *
   FROM SC b
   WHERE S = '01'
     AND NOT EXISTS
     (SELECT * FROM SC c WHERE c.S = a.S AND c.C = b.C));


# 解法2
SELECT *
FROM Student
WHERE EXISTS(SELECT A.S
             FROM SC A
                    JOIN (SELECT C FROM SC WHERE S = '01') B ON A.C = B.C
             WHERE Student.S = A.S
             GROUP BY A.S
             HAVING COUNT(*) = (SELECT COUNT(*) FROM SC WHERE S = '01'));


# 10. 查询没学过"张三"老师讲授的任一门课程的学生姓名 

SELECT Sname
FROM Student s
WHERE NOT EXISTS(
    SELECT *
    FROM SC sc
    WHERE s.S = sc.S
      AND EXISTS(
        SELECT *
        FROM Course c
        WHERE sc.C = c.C
          AND EXISTS(
            SELECT *
            FROM Teacher t
            WHERE c.T = t.T
              AND t.Tname = '张三'
          )));


# 11. 查询两门及其以上不及格课程的同学的学号,姓名及其平均成绩 

SELECT *
FROM Student
WHERE EXISTS(SELECT S
             FROM SC
             WHERE Student.S = SC.S
             GROUP BY S
             HAVING SUM(CASE WHEN score < 60 THEN 1 ELSE 0 END) >= 2);

SELECT Student.S,Student.Sname,avg
FROM Student
       JOIN (SELECT S,avg(score) avg
             FROM SC
             GROUP BY S
             HAVING SUM(CASE WHEN score < 60 THEN 1 ELSE 0 END) >= 2) B ON Student.S = B.S;


# 12. 检索" 01 "课程分数小于 60学生信息,按分数降序排列的学生信息

SELECT *
FROM Student
       JOIN (SELECT *
             FROM SC
             WHERE SC.score < 60
) B ON Student.S = B.S
ORDER BY score DESC;


# 13. 按平均成绩从高到低显示所有学生的所有课程的成绩以及平均成绩

SELECT S,
       MAX(CASE C WHEN '01' THEN score ELSE 0 END) '01',
       MAX(CASE C WHEN '02' THEN score ELSE 0 END) '02',
       MAX(CASE C WHEN '03' THEN score ELSE 0 END) '03',
       AVG(score)                                  平均分
FROM SC
GROUP BY S
ORDER BY 平均分 DESC;

# 14. 查询各科成绩最高分、最低分和平均分:
#     以如下形式显示:课程 ID,课程 name,最高分,最低分,平均分,及格率,中等率,优良率,优秀率
#     及格为>=60,中等为:70-80,优良为:80-90,优秀为:>=90
#     要求输出课程号和选修人数,查询结果按人数降序排列,若人数相同,按课程号升序排列

SELECT ID,
       Cname,
       选修人数,
       最高分,
       最低分,
       平均分,
       及格率,
       中等率,
       优良率,
       优秀率
FROM Course
       JOIN (SELECT C                                                                            ID,
                    COUNT(*)                                                                     选修人数,
                    MAX(score)                                                                   最高分,
                    MIN(score)                                                                   最低分,
                    AVG(score)                                                                   平均分,
                    SUM(CASE WHEN score >= 60 THEN 1 ELSE 0 END) / COUNT(*) * 100                及格率,
                    SUM(CASE WHEN score >= 70 AND score < 80 THEN 1 ELSE 0 END) / COUNT(*) * 100 中等率,
                    SUM(CASE WHEN score >= 80 AND score < 90 THEN 1 ELSE 0 END) / COUNT(*) * 100 优良率,
                    SUM(CASE WHEN score >= 90 THEN 1 ELSE 0 END) / COUNT(*) * 100                优秀率
             FROM SC
             GROUP BY C) A ON Course.C = A.ID
ORDER BY 选修人数 DESC,ID ASC;

# 15. 按各科成绩进行排序,并显示排名, Score 重复时保留名次空缺

SELECT score,
       CASE
         WHEN @prevRank = score THEN ''
         WHEN @prevRank := score THEN @curRank := @curRank + 1
         END AS 排名
FROM SC,
     (SELECT @curRank := 0,@prevRank := null) B
ORDER BY score DESC;


# 15.1 按各科成绩进行排序,并显示排名, Score 重复时合并名次

SELECT score,
       CASE
         WHEN @prevRank = score THEN @curRank
         WHEN @prevRank := score THEN @curRank := @curRank + 1
         END AS 排名
FROM SC,
     (SELECT @curRank := 0,@prevRank := null) B
ORDER BY score DESC;


# 16.  查询学生的总成绩,并进行排名,总分重复时保留名次空缺

SELECT S,
       sum,
       CASE
         WHEN @prevRank = sum THEN ''
         WHEN @prevRanK := sum Then @curRank := @curRank + 1
         END AS PM
FROM (SELECT S,SUM(score) sum
      FROM SC
      GROUP BY S) A,
     (SELECT @prevRank := NULL,@curRank := 0) B
ORDER BY sum DESC;


# 16.1 查询学生的总成绩,并进行排名,总分重复时不保留名次空

SELECT S,
       sum,
       CASE
         WHEN @prevRank = sum THEN @curRank
         WHEN @prevRanK := sum THEN @curRank := @curRank + 1
         END AS PM
FROM (SELECT S,SUM(score) sum
      FROM SC
      GROUP BY S) A,
     (SELECT @prevRank := NULL,@curRank := 0) B
ORDER BY sum DESC;


# 17. 统计各科成绩各分数段人数:课程编号,课程名称,[100-85],[85-70],[70-60],[60-0] 及所占百分

SELECT *
FROM Course
       JOIN
     (SELECT C                                                                             课程编号,
             SUM(CASE WHEN score < 100 AND score >= 85 THEN 1 ELSE 0 END)                  '[100-85]人数',
             SUM(CASE WHEN score >= 70 THEN 1 ELSE 0 END)                                  '[85-70]人数',
             SUM(CASE WHEN score >= 60 THEN 1 ELSE 0 END)                                  '[70-60]人数',
             SUM(CASE WHEN score THEN 1 ELSE 0 END)                                        '[60-0]人数',
             SUM(CASE WHEN score < 100 AND score >= 85 THEN 1 ELSE 0 END) / COUNT(*) * 100 '[100-85]百分比',
             SUM(CASE WHEN score >= 70 THEN 1 ELSE 0 END) / COUNT(*) * 100                 '[85-70]百分比',
             SUM(CASE WHEN score >= 60 THEN 1 ELSE 0 END) / COUNT(*) * 100                 '[70-60]百分比',
             SUM(CASE WHEN score THEN 1 ELSE 0 END) / COUNT(*) * 100                       '[60-0]百分比'
      FROM SC
      GROUP BY C) b ON Course.C = b.课程编号;


# 18. 查询各科成绩前三名的记录

SELECT a.S,a.C,a.score
FROM SC a
       LEFT JOIN SC b ON a.C = b.C AND a.score < b.score
GROUP BY a.S,a.C,a.score
HAVING COUNT(b.S) < 3
ORDER BY a.C,a.score DESC;

SELECT *
FROM SC a
WHERE (SELECT COUNT(DISTINCT score) FROM SC WHERE C = a.C AND score >= a.score) <= 3
ORDER BY a.C,a.score DESC;

# 19. 查询每门课程被选修的学生数 

SELECT c, COUNT(*)
FROM SC
GROUP BY SC.C;


# 20. 查询出只选修两门课程的学生学号和姓名 

SELECT Student.Sname,Student.S
FROM Student
WHERE (SELECT COUNT(*)
       FROM SC
       WHERE Student.S = SC.S
       GROUP BY SC.S) = 2;


# 21. 查询男生、女生人数

SELECT Ssex,COUNT(*)
FROM Student
GROUP BY Ssex;


# 22. 查询名字中含有「风」字的学生信息

SELECT *
FROM Student
WHERE Sname LIKE '%风%';


# 23. 查询同名同性学生名单,并统计同名人数

SELECT Sname,Ssex,COUNT(*) 同名人数
FROM Student
GROUP BY Student.Sname,Ssex
HAVING COUNT(*) > 1;


# 24. 查询 1990 年出生的学生名单

SELECT *
FROM Student
WHERE YEAR(Sage) > 1990;


# 25. 查询每门课程的平均成绩,结果按平均成绩降序排列,平均成绩相同时,按课程编号升序排列

SELECT C, AVG(SC.score) AVG
FROM SC
GROUP BY SC.C
ORDER BY AVG DESC,C ASC;


# 26. 查询平均成绩大于等于 85 的所有学生的学号、姓名和平均成绩 

SELECT Student.*,B.AVG
FROM Student
       JOIN (SELECT S,AVG(score) AVG
             FROM SC
             GROUP BY SC.S
             HAVING AVG >= 85) B ON Student.S = B.S;


# 27. 查询课程名称为「数学」,且分数低于 60 的学生姓名和分数 

SELECT Student.*,B.score
FROM Student
       JOIN (SELECT *
             FROM SC
             WHERE EXISTS(SELECT *
                          FROM Course
                          WHERE SC.C = Course.C
                            AND Cname = '数学')
               AND score < 60) B ON Student.S = B.S;


# 28. 查询所有学生的课程及分数情况(存在学生没成绩,没选课的情况)

SELECT *
FROM Student
       LEFT JOIN SC ON Student.S = SC.S;


# 29. 查询任何一门课程成绩在 70 分以上的姓名、课程名称和分数

SELECT Student.Sname,Course.Cname,B.score
FROM Student
       JOIN (SELECT *
             FROM SC
             WHERE SC.score > 70) B ON Student.S = B.S
       JOIN Course ON B.C = Course.C;


# 30. 查询不及格的课程

SELECT *
FROM Course
WHERE EXISTS(SELECT *
             FROM SC
             WHERE Course.C = SC.C
               AND score < 60);


# 31. 查询课程编号为 01 且课程成绩在 80 分以上的学生的学号和姓名

SELECT *
FROM Student
WHERE EXISTS(SELECT *
             FROM SC
             WHERE Student.S = SC.S
               AND C = '01'
               AND score = 80);


# 32. 求每门课程的学生人数 

SELECT C,COUNT(*)
FROM SC
GROUP BY C;


# 33. 成绩不重复,查询选修「张三」老师所授课程的学生中,成绩最高的学生信息及其成绩

SELECT Student.*, B.score
FROM Student
       JOIN (SELECT *
             FROM SC
             WHERE EXISTS(
                       SELECT *
                       FROM Course
                       WHERE SC.C = Course.C
                         AND EXISTS(SELECT *
                                    FROM Teacher
                                    WHERE Course.T = Teacher.T
                                      AND Tname = '张三')
                     )
             ORDER BY score DESC
             LIMIT 1) B ON Student.S = B.S;


# 34. 成绩有重复的情况下,查询选修「张三」老师所授课程的学生中,成绩最高的学生信息及其成绩

SELECT *
FROM SC a
WHERE EXISTS(
    SELECT *
    FROM Course
    WHERE a.C = Course.C
      AND EXISTS(SELECT *
                 FROM Teacher
                 WHERE Course.T = Teacher.T
                   AND Tname = '李四')
  )
  AND (SELECT COUNT(DISTINCT score) FROM SC WHERE C = a.C AND score > a.score) < 1
ORDER BY a.C,a.score DESC;


# 35. 查询不同课程成绩相同的学生的学生编号、课程编号、学生成绩 

SELECT *
FROM SC A
   , SC B
WHERE A.score = B.score
  AND A.C != B.C
  AND A.S != B.S;


# 36. 查询每门功成绩最好的前两名

SELECT *
FROM SC A
WHERE (SELECT COUNT(DISTINCT B.score)
       FROM SC B
       WHERE A.C = B.C
         AND B.score > A.score) < 2;


# 37. 统计每门课程的学生选修人数(超过 5 人的课程才统计)。

SELECT C
FROM SC
GROUP BY C
HAVING COUNT(*) > 5;


# 38. 检索至少选修两门课程的学生学号 

SELECT S
FROM SC
GROUP BY S
HAVING COUNT(*) >= 2;


# 39. 查询选修了全部课程的学生信息

SELECT *
FROM Student
WHERE EXISTS(SELECT S
             FROM SC
             WHERE SC.S = Student.S
             GROUP BY S
             HAVING COUNT(*) = (SELECT COUNT(*) FROM Course));

SELECT *
FROM Student a
WHERE NOT EXISTS
  (SELECT *
   FROM SC b
   WHERE S = '01'
     AND NOT EXISTS
     (SELECT * FROM SC c WHERE c.S = a.S AND c.C = b.C));


# 40. 查询各学生的年龄,只按年份来算 

SELECT (YEAR(NOW()) - YEAR(Sage)) AGE
FROM Student;

# 41. 按照出生日期来算,当前月日 < 出生年月的月日则,年龄减一

SELECT if(DAY(NOW()) > DAY(Sage) AND MONTH(NOW()) > MONTH(Sage), (YEAR(NOW()) - YEAR(Sage)) - 1,
          (YEAR(NOW()) - YEAR(Sage)))
FROM Student,
     (SELECT @AGE := 0) B;


# 42. 查询本周过生日的学生

SELECT Student.*
FROM Student
WHERE WEEK(Sage) = WEEK(NOW());


# 43. 查询下周过生日的学生

SELECT Student.*
FROM Student
WHERE WEEK(Sage) = WEEK(NOW()) + 1;


# 44. 查询本月过生日的学生

SELECT *
FROM Student
WHERE MONTH(Student.Sage) = MONTH(NOW());


# 45. 查询下月过生日的学生

SELECT *
FROM Student
WHERE MONTH(Student.Sage) = MONTH(NOW()) + 1;
本文参与 腾讯云自媒体同步曝光计划,分享自作者个人站点/博客。
原始发表:2019年02月22日,如有侵权请联系 cloudcommunity@tencent.com 删除

本文分享自 作者个人站点/博客 前往查看

如有侵权,请联系 cloudcommunity@tencent.com 删除。

本文参与 腾讯云自媒体同步曝光计划  ,欢迎热爱写作的你一起参与!

评论
登录后参与评论
0 条评论
热度
最新
推荐阅读
领券
问题归档专栏文章快讯文章归档关键词归档开发者手册归档开发者手册 Section 归档