从网上收集整理的 SQL 笔试题。
DBMS 无特殊说明的情况下使用 PostgreSQL
# 一
# 表结构预览
-- 学生表
Student (SId,Sname,Sage,Ssex)
--SId 学生编号,Sname 学生姓名,Sage 出生年月,Ssex 学生性别
-- 课程表
Course (CId,Cname,TId)
--CId 课程编号,Cname 课程名称,TId 教师编号
-- 教师表
Teacher (TId,Tname)
--TId 教师编号,Tname 教师姓名
-- 成绩表
SC (SId,CId,score)
--SId 学生编号,CId 课程编号,score 分数
# 题目
- 查询 “01” 课程比 “02” 课程成绩高的所有学生的学号
- 查询平均成绩大于 60 分的同学的学号和平均成绩
- 查询所有同学的学号、姓名、选课数、总成绩
- 查询姓 “李” 的老师的个数
- 查询没学过 “张三” 老师课的同学的学号、姓名
- 查询学过 “01” 并且也学过编号 “02” 课程的同学的学号、姓名
- 查询学过 “张三” 老师所教的课的同学的学号、姓名
- 查询课程编号 “01” 的成绩比课程编号 “02” 课程低的所有同学的学号、姓名
- 查询所有课程成绩小于 60 分的同学的学号、姓名
- 查询没有学全所有课的同学的学号、姓名
- 查询至少有一门课与学号为 “01” 的同学所学相同的同学的学号和姓名
- 查询和 "01" 号的同学学习的课程完全相同的其他同学的学号和姓名
- 把 “SC” 表中 “张三” 老师教的课的成绩都更改为此课程的平均成绩
- 查询没学过 "张三" 老师讲授的任一门课程的学生姓名
- 查询两门及其以上不及格课程的同学的学号,姓名及其平均成绩
- 检索 "01" 课程分数小于 60,按分数降序排列的学生信息
- 按平均成绩从高到低显示所有学生的平均成绩
- 查询各科成绩最高分、最低分和平均分:以如下形式显示:课程 ID,课程 name,最高分,最低分,平均分,及格率
- 按各科平均成绩从低到高和及格率的百分数从高到低顺序
- 查询学生的总成绩并进行排名
- 查询不同老师所教不同课程平均分从高到低显示
- 查询所有课程的成绩第 2 名到第 3 名的学生信息及该课程成绩
- 统计各科成绩各分数段人数:课程编号,课程名称,[100-85],[85-70],[70-60],[0-60] 及所占百分比
- 查询学生平均成绩及其名次
- 查询各科成绩前三名的记录
- 查询每门课程被选修的学生数
- 查询出只选修了一门课程的全部学生的学号和姓名
- 查询男生、女生人数
- 查询名字中含有 "风" 字的学生信息
- 查询同名同性学生名单,并统计同名人数
- 查询 1990 年出生的学生名单 (注:Student 表中 Sage 列的类型是 datetime)
- 查询每门课程的平均成绩,结果按平均成绩升序排列,平均成绩相同时,按课程号降序排列
- 查询不及格的课程,并按课程号从大到小排列
- 查询课程编号为 "01" 且课程成绩在 60 分以上的学生的学号和姓名
- 查询选修 “张三” 老师所授课程的学生中,成绩最高的学生姓名及其成绩
- 查询每门功课成绩最好的前两名
- 统计每门课程的学生选修人数(超过 5 人的课程才统计)。要求输出课程号和选修人数,查询结果按人数降序排列,若人数相同,按课程号升序排列
- 检索至少选修两门课程的学生学号
- 查询选修了全部课程的学生信息
- 查询各学生的年龄
- 查询本周过生日的学生
- 查询下周过生日的学生
- 查询本月过生日的学生
- 查询下月过生日的学生
-- 答案分割线 --
# 附录:答案
- 查询 “01” 课程比 “02” 课程成绩高的所有学生的学号
SELECT t1.sid AS 学号 | |
FROM (SELECT * FROM sc WHERE CID = '01') AS t1 | |
LEFT JOIN (SELECT * FROM sc WHERE CID = '02') AS t2 ON t1.sid = t2.sid | |
WHERE t1.score > t2.score |
- 查询平均成绩大于 60 分的同学的学号和平均成绩
SELECT sid AS 学号, | |
AVG(score) AS 平均成绩 | |
FROM sc | |
GROUP BY sid | |
HAVING AVG(score) > 60 |
- 查询所有同学的学号、姓名、选课数、总成绩
SELECT S.sid AS 学号, | |
S.sname AS 姓名, | |
COUNT(CID) AS 选课数, | |
SUM(score) AS 总成绩 | |
FROM student AS S | |
LEFT JOIN sc ON S.sid = SC.sid | |
GROUP BY S.sid, | |
s.sname |
- 查询姓 “李” 的老师的个数
SELECT COUNT(TID) AS teacher_cnt | |
FROM teacher | |
WHERE tname LIKE '李%' |
- 查询没学过 “张三” 老师课的同学的学号、姓名
使用 LEFT JOIN(原答案):
SELECT sid, | |
sname | |
FROM student | |
WHERE sid NOT IN (SELECT sc.sid | |
FROM teacher | |
LEFT JOIN course ON teacher.TID = course.TID | |
LEFT JOIN sc ON course.CID = sc.CID | |
WHERE teacher.tname = '张三') |
或者使用 INNER JOIN:
SELECT sid AS 学号, | |
sname AS 姓名 | |
FROM student | |
WHERE sid NOT IN (SELECT SC.sid | |
FROM SC, | |
teacher AS T, | |
course AS C | |
WHERE SC.CID = C.CID | |
AND T.TID = C.TID | |
AND T.tname = '张三') |
- 查询学过 “01” 并且也学过编号 “02” 课程的同学的学号、姓名
SELECT T.sid AS 学号, | |
sname AS 姓名 | |
FROM (SELECT sid | |
FROM sc | |
GROUP BY sid | |
HAVING SUM(CASE WHEN CID = '01' THEN 1 ELSE 0 END) > 0 | |
AND SUM(CASE WHEN CID = '02' THEN 1 ELSE 0 END) > 0) T | |
LEFT JOIN student ON T.sid = student.sid |
- 查询学过 “张三” 老师所教的课的同学的学号、姓名
SELECT S.sid AS 学号, | |
S.sname AS 姓名 | |
FROM (SELECT cid | |
FROM course AS C | |
LEFT JOIN teacher AS T ON C.tid = T.tid | |
WHERE T.tname = '张三') course | |
LEFT JOIN sc ON course.cid = sc.cid | |
LEFT JOIN student AS S ON sc.sid = S.sid | |
GROUP BY S.sid, sname |
- 查询课程编号 “01” 的成绩比课程编号 “02” 课程低的所有同学的学号、姓名
SELECT S.sid AS 学号, | |
S.sname AS 姓名 | |
FROM (SELECT t1.sid AS sid | |
FROM (SELECT * FROM sc WHERE cid = '01') t1 | |
LEFT JOIN (SELECT * FROM sc WHERE cid = '02') t2 ON t1.sid = t2.sid | |
WHERE t1.score < t2.score) t1 | |
LEFT JOIN student AS S ON t1.sid = S.sid |
- 查询所有课程成绩小于 60 分的同学的学号、姓名
SELECT S.sid AS 学号, | |
S.sname AS 姓名 | |
FROM (SELECT sid | |
FROM sc | |
GROUP BY sid | |
HAVING MAX(score) < 60) t1 | |
LEFT JOIN student AS S ON t1.sid = S.sid |
- 查询没有学全所有课的同学的学号、姓名
SELECT S.sid AS 学号, | |
S.sname AS 姓名 | |
FROM (SELECT COUNT(cid), sid | |
FROM sc | |
GROUP BY sid | |
HAVING COUNT(cid) < (SELECT COUNT(cid) FROM course)) t1 | |
LEFT JOIN student AS S ON t1.sid = S.sid |
- 查询至少有一门课与学号为 “01” 的同学所学相同的同学的学号和姓名
SELECT S.sid AS 学号, | |
S.sname AS 姓名 | |
FROM (SELECT cid | |
FROM sc | |
WHERE sid = '01') t1 | |
LEFT JOIN sc ON t1.cid = sc.cid | |
LEFT JOIN student AS S ON S.sid = sc.sid | |
GROUP BY S.sid, s.sname |
- 查询和 "01" 号的同学学习的课程完全相同的其他同学的学号和姓名
#注意是和 '01' 号同学课程完全相同但非学习课程数相同的 | |
SELECT S.sid AS 学号, S.sname AS 姓名 | |
FROM (SELECT sc.sid, COUNT(sc.cid) | |
FROM (SELECT cid | |
FROM sc | |
WHERE sid = '01') t1 -- 选出 01 的同学所学的课程 | |
LEFT JOIN sc ON t1.cid = sc.cid | |
GROUP BY sc.sid | |
HAVING COUNT(sc.cid) = (SELECT COUNT(cid) FROM sc WHERE sid = '01')) t1 | |
LEFT JOIN student AS S ON t1.sid = S.sid | |
WHERE S.sid != '01' |
- 把 “SC” 表中 “张三” 老师教的课的成绩都更改为此课程的平均成绩
这道题是更新数据的题目,不进行处理
- 查询没学过 "张三" 老师讲授的任一门课程的学生姓名
SELECT sname AS 姓名 | |
FROM student | |
WHERE sid NOT IN | |
(SELECT sid | |
FROM sc | |
LEFT JOIN course AS C ON sc.cid = C.cid | |
LEFT JOIN teacher AS T ON C.tid = T.tid | |
WHERE tname = '张三') |
- 查询两门及其以上不及格课程的同学的学号,姓名及其平均成绩
SELECT S.sid AS 学号, | |
S.sname AS 姓名, | |
平均成绩 | |
FROM (SELECT sid, | |
SUM(CASE WHEN score < 60 THEN 1 ELSE 0 END), | |
AVG(score) AS 平均成绩 | |
FROM sc | |
GROUP BY sid | |
HAVING SUM(CASE WHEN score < 60 THEN 1 ELSE 0 END) >= 2) t1 | |
LEFT JOIN student AS S ON t1.sid = S.sid |
- 检索 "01" 课程分数小于 60,按分数降序排列的学生信息
SELECT sid AS 学号, (CASE WHEN cid = '01' THEN score ELSE 100 END) AS 分数 | |
FROM sc | |
WHERE (CASE WHEN cid = '01' THEN score ELSE 100 END) < 60 | |
ORDER BY 分数 DESC |
- 按平均成绩从高到低显示所有学生的平均成绩
SELECT sid AS 学号, AVG(score) AS 平均成绩 | |
FROM sc | |
GROUP BY sid | |
ORDER BY 平均成绩 DESC |
- 查询各科成绩最高分、最低分和平均分:以如下形式显示:课程 ID,课程 name,最高分,最低分,平均分,及格率
SELECT c.cid AS 课程ID, | |
c.cname AS 课程name, | |
MAX(sc.score) AS 最高分, | |
MIN(sc.score) AS 最低分, | |
AVG(sc.score) AS 平均分, | |
SUM(CASE WHEN sc.score >= 60 THEN 1 ELSE 0 END) / CAST(COUNT(sc.sid) AS DOUBLE PRECISION) AS 及格率 | |
FROM course AS C | |
LEFT JOIN sc ON c.cid = sc.cid | |
GROUP BY c.cid, c.cname |
- 按各科平均成绩从低到高和及格率的百分数从高到低顺序
#这里先按照平均成绩排序,再按照及格百分数排序, | |
SELECT c.cid AS 课程ID, | |
c.cname AS 课程name, | |
AVG(sc.score) AS 平均分, | |
SUM(CASE WHEN sc.score >= 60 THEN 1 ELSE 0 END) / CAST(COUNT(sc.sid) AS DOUBLE PRECISION) AS 及格率 | |
FROM course AS C | |
LEFT JOIN sc ON c.cid = sc.cid | |
GROUP BY c.cid, c.cname | |
ORDER BY 平均分, 及格率 DESC |
- 查询学生的总成绩并进行排名
SELECT sid AS 学号, | |
SUM(score) AS 总成绩 | |
FROM sc | |
GROUP BY sid | |
ORDER BY 总成绩 DESC |
- 查询不同老师所教不同课程平均分从高到低显示
-- 每位老师只教一门课程,所以直接按老师 id 分组计算平均分即可 | |
SELECT C.tid, AVG(sc.score) AS 平均成绩 | |
FROM course AS C | |
LEFT JOIN sc ON sc.cid = C.cid | |
GROUP BY C.tid | |
ORDER BY 平均成绩 DESC; |
- 查询所有课程的成绩第 2 名到第 3 名的学生信息及该课程成绩
SELECT sid, | |
rank_num, | |
score, | |
cid | |
FROM (SELECT RANK() OVER (PARTITION BY cid ORDER BY score DESC) AS rank_num, | |
sid, | |
score, | |
cid | |
FROM sc) t | |
WHERE rank_num IN (2, 3); |
- 统计各科成绩各分数段人数:课程编号,课程名称,[100-85],[85-70],[70-60],[0-60] 及所占百分比
(题目似乎有歧义,前边说统计各分数段人数,但是后边又说到百分比,个人认为是需要加上人数统计比较合理)
- PostgreSQL:
SELECT sc.cid, | |
cname, | |
SUM(CASE WHEN score BETWEEN 85 AND 100 THEN 1 ELSE 0 END) / CAST(COUNT(sid) AS DOUBLE PRECISION) p1, | |
SUM(CASE WHEN score BETWEEN 70 AND 85 THEN 1 ELSE 0 END) / CAST(COUNT(sid) AS DOUBLE PRECISION) p2, | |
SUM(CASE WHEN score BETWEEN 60 AND 70 THEN 1 ELSE 0 END) / CAST(COUNT(sid) AS DOUBLE PRECISION) p3, | |
SUM(CASE WHEN score BETWEEN 0 AND 60 THEN 1 ELSE 0 END) / CAST(COUNT(sid) AS DOUBLE PRECISION) p4 | |
FROM sc | |
LEFT JOIN course AS C ON sc.cid = C.cid | |
GROUP BY sc.cid, cname; |
- MySql:
select | |
sc.cid | |
,cname | |
,count(if(score between 85 and 100,sid,null))/count(sid) | |
,count(if(score between 70 and 85,sid,null))/count(sid) | |
,count(if(score between 60 and 70,sid,null))/count(sid) | |
,count(if(score between 0 and 60,sid,null))/count(sid) | |
from sc | |
left join course | |
on sc.cid=course.cid | |
group by sc.cid,cname |
- 查询学生平均成绩及其名次
SELECT sid, | |
avg_score, | |
RANK() OVER (ORDER BY avg_score DESC ) AS rank | |
FROM (SELECT sid, | |
AVG(score) avg_score | |
FROM sc | |
GROUP BY sid) t; |
- 查询各科成绩前三名的记录
SELECT cid, sid, rank, score | |
FROM (SELECT cid, | |
sid, | |
RANK() OVER (PARTITION BY cid ORDER BY score DESC ) AS rank, | |
score | |
FROM sc) t | |
WHERE t.rank <= 3; |
- 查询每门课程被选修的学生数
SELECT cid, COUNT(sid) AS cnt | |
FROM sc | |
GROUP BY cid; |
- 查询出只选修了一门课程的全部学生的学号和姓名
SELECT S.sid, S.sname | |
FROM (SELECT sid | |
FROM sc | |
GROUP BY sid | |
HAVING COUNT(cid) = 1) t1 | |
LEFT JOIN student AS S ON S.sid = t1.sid; |
- 查询男生、女生人数
SELECT ssex, COUNT(sid) AS cnt | |
FROM student | |
GROUP BY ssex; |
- 查询名字中含有 "风" 字的学生信息
SELECT sid, sname | |
FROM student | |
WHERE sname LIKE '%风%'; |
- 查询同名同性学生名单,并统计同名人数
SELECT sname, ssex, COUNT(sid) AS cnt | |
FROM student | |
GROUP BY sname, ssex | |
HAVING COUNT(sid) >= 2; |
- 查询 1990 年出生的学生名单 (注:Student 表中 Sage 列的类型是 datetime)
- PostgreSQL:
SELECT sid, sname, sage | |
FROM student | |
WHERE DATE_PART('year', sage) = 1990; |
- MySql:
SELECT sid, | |
sname, | |
sage | |
FROM student | |
WHERE YEAR(sage) = 1990; |
- 查询每门课程的平均成绩,结果按平均成绩升序排列,平均成绩相同时,按课程号降序排列
SELECT cid, AVG(score) AS avg_score | |
FROM sc | |
GROUP BY cid | |
ORDER BY avg_score, cid DESC; |
- 查询不及格的课程,并按课程号从大到小排列
(题目出得意义不是很明确)
SELECT cid, | |
sid, | |
score | |
FROM sc | |
WHERE score < 60 | |
ORDER BY cid DESC, sid; |
- 查询课程编号为 "01" 且课程成绩在 60 分以上的学生的学号和姓名
SELECT s.sid, s.sname | |
FROM sc | |
LEFT JOIN student AS S ON S.sid = sc.sid | |
WHERE sc.cid = '01' | |
AND sc.score >= 60; |
- 查询选修 “张三” 老师所授课程的学生中,成绩最高的学生姓名及其成绩
SELECT sc.sid, sc.score | |
FROM teacher AS T | |
LEFT JOIN course AS C ON T.tid = C.tid | |
LEFT JOIN sc ON sc.cid = C.cid | |
LEFT JOIN student AS S ON S.sid = sc.sid | |
WHERE T.tname = '张三' | |
ORDER BY sc.score DESC | |
LIMIT 1; |
- 查询每门功课成绩最好的前两名
SELECT cid, sid, rank, score | |
FROM (SELECT cid, | |
sid, | |
RANK() OVER (PARTITION BY cid ORDER BY score DESC) AS rank, | |
score | |
FROM sc) t | |
WHERE t.rank <= 2; |
- 统计每门课程的学生选修人数(超过 5 人的课程才统计)。要求输出课程号和选修人数,查询结果按人数降序排列,若人数相同,按课程号升序排列
SELECT cid, COUNT(sid) AS cnt | |
FROM sc | |
GROUP BY cid | |
HAVING COUNT(sid) > 5 | |
ORDER BY cnt DESC, cid; |
- 检索至少选修两门课程的学生学号
SELECT sid, count(cid) as cnt | |
FROM sc | |
GROUP BY sid | |
HAVING COUNT(cid) >= 2; |
- 查询选修了全部课程的学生信息
SELECT sid | |
FROM sc | |
GROUP BY sid | |
HAVING COUNT(cid) = (SELECT COUNT(*) FROM course); |
- 查询各学生的年龄
- PostgreSQL:
SELECT sid, sname, DATE_PART('year', CURRENT_DATE) - DATE_PART('year', sage) AS age | |
FROM student |
- MySql:
SELECT sid, | |
sname, | |
year(curdate()) - year(sage) AS sage | |
FROM student |
- 查询本周过生日的学生
- PostgreSQL:
SELECT sid, sname, sage | |
FROM student | |
WHERE DATE_PART('week', CURRENT_DATE) = DATE_PART('week', sage) |
- MySql:
select | |
sid,sname,sage | |
from student | |
where weekofyear(sage)=weekofyear(curdate()) |
- 查询下周过生日的学生
- PostgreSQL:
SELECT sid, sname, sage | |
FROM student | |
WHERE DATE_PART('week', CURRENT_DATE + INTERVAL '1 week') = DATE_PART('week', sage); |
- MySql:
select | |
sid,sname,sage | |
from student | |
where weekofyear(sage) = weekofyear(date_add(curdate(),interval 1 week)) |
- 查询本月过生日的学生
- PostgreSQL:
SELECT sid, sname, sage | |
FROM student | |
WHERE DATE_PART('month', CURRENT_DATE) = DATE_PART('month', sage); |
- MySql:
select | |
sid,sname,sage | |
from student | |
where month(sage) = month(curdate()) |
- 查询下月过生日的学生
- PostgreSQL:
SELECT sid, sname, sage | |
FROM student | |
WHERE DATE_PART('month', CURRENT_DATE + INTERVAL '1 month') = DATE_PART('month', sage); |
- MySql:
select | |
sid,sname,sage | |
from student | |
where month(date_sub(sage,interval 1 month)) = month(curdate()) |
# 附录:建表语句
- PostgreSQL
CREATE TABLE Student ( SId VARCHAR ( 10 ), Sname VARCHAR ( 10 ), Sage TIMESTAMP, Ssex VARCHAR ( 10 ) ); | |
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', '女' ); | |
CREATE TABLE Course ( CID VARCHAR ( 10 ), Cname VARCHAR ( 10 ), TID VARCHAR ( 10 ) ); | |
INSERT INTO Course | |
VALUES | |
( '01', '语文', '02' ); | |
INSERT INTO Course | |
VALUES | |
( '02', '数学', '01' ); | |
INSERT INTO Course | |
VALUES | |
( '03', '英语', '03' ); | |
CREATE TABLE Teacher ( TID VARCHAR ( 10 ), Tname VARCHAR ( 10 ) ); | |
INSERT INTO Teacher | |
VALUES | |
( '01', '张三' ); | |
INSERT INTO Teacher | |
VALUES | |
( '02', '李四' ); | |
INSERT INTO Teacher | |
VALUES | |
( '03', '王五' ); | |
CREATE TABLE SC ( SId VARCHAR ( 10 ), CID 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 ); |
- MySql:
create table Student(sid varchar(10),sname varchar(10),sage datetime,ssex nvarchar(10)); | |
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' , '女'); | |
create table Course(cid varchar(10),cname varchar(10),tid varchar(10)); | |
insert into Course values('01' , '语文' , '02'); | |
insert into Course values('02' , '数学' , '01'); | |
insert into Course values('03' , '英语' , '03'); | |
create table Teacher(tid varchar(10),tname varchar(10)); | |
insert into Teacher values('01' , '张三'); | |
insert into Teacher values('02' , '李四'); | |
insert into Teacher values('03' , '王五'); | |
create table SC(sid varchar(10),cid 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); |