山东大学 2020级数据库系统 实验一
山东大学 2020级数据库系统 实验二
山东大学 2020级数据库系统 实验三
山东大学 2020级数据库系统 实验四
山东大学 2020级数据库系统 实验五
山东大学 2020级数据库系统 实验六
山东大学 2020级数据库系统 实验七
山东大学 2020级数据库系统 实验八、九
做数据库实验一定要静得下心来,才能发现其中的错误然后进行改正。同时,如果发现 SQL 语句总是报错,“一定是你错了,只是不知道错在哪里!”
其次,SQL 语句中较为复杂的点博主都进行了注释,希望大家一定要看懂思路后自己写一遍,而不是盲目的 Ctrl+C,Ctrl+V,切记切记!!
实验五主要考察的内容如下:
对于聚集函数 sum, max, count 的使用,同时有无 group by 的意识;
对于分部分查询的熟练程度;(可能会有其他方法,但这部分我分块查询用的比较多~~)
对于 union all 的了解及区分 union all 和 union 的区别;
create table test5_01 as select distinct substr(name, 2, length(name)) first_name, count(*) frequency from pub.student group by substr(name, 2, length(name))
5-2 在学生表pub.student中统计名字(姓名的第一位是姓氏,不作统计,名字指姓名的第二个之后的汉字)的每个字使用的频率,将统计结果放入test5_02中(特别提示:需要区别union和union all的不同),表结构如下。
letter varchar(2) frequency numeric(4)
锋 1034
红 1232
鹏 2323
………………
避坑指南:
思路:
1. 选出名字中的第二个字,记为集合 A,然后使用 union all 来连接名字中第三个字的集合,记为B;(union 和 union all 的区别在于一个去重,一个不去重)
2. 然后对 A
∪
\cup
∪ B 进行统一的计数即可;
create table test5_02 (letter varchar(2), frequency numeric(4))
insert into test5_02 select letter, count(*) frequency from ((select substr(name, 2, 1) letter from pub.student where substr(name, 2, 1) is not null) union all (select substr(name, 3, 1) letter from pub.student where substr(name, 3, 1) is not null)) group by letter
5-3 创建"学院班级学分达标情况统计表1"test5_03,依据pub.student, pub.course,pub.student_course统计形成表中各项数据,成绩>=60为及格计入学分,总学分>=10算作达标,院系为空值的数据不统计在下表中,表结构:院系名称dname、班级class、学分达标人数p_count1、学分未达标人数p_count2、总人数p_count。
Dname varchar(30) class varchar(10) P_count1 Int P_count2 int P_count int
计算机学院 2006
计算机学院 2007
软件学院 2006
………………
注意:此题较难,如果你现在静不下来,那就下下道题吧;如果能够静下来,Let’s go
避坑指南:
思路:(分块查询)
create table test5_03 (dname varchar(30), class varchar(10), p_count1 int, p_count2 int, p_count int)
-----------一张表一张表地看思路更清晰哦(一共就 t1,t2 两张表)-------------- insert into test5_03 select t1.dname, t1.class, t2.p_count1, (t1.p_count - t2.p_count1) p_count2, t1.p_count from (select distinct dname, class, count(*) p_count from pub.student where dname is not null group by dname, class) t1, --t1 表:找到 dname, class, p_count (select distinct dname, class, count(*) p_count1 from (select sid, dname, class, sum(credit) sum_credit --找到总学分 from (select sid, cid, dname, class, max(score) max_score --找到成绩的最大值 from pub.student_course natural join pub.student group by sid, cid, dname, class) natural join pub.course where max_score >= 60 --最大成绩 >= 60 才计入学分 and dname is not null group by sid, dname, class) where sum_credit >= 10 --总学分 > 10 才选出来 group by dname, class) t2, --t2 表:找到 p_count1(找 dname 和 class 是为了在后面进行连接) where t1.dname = t2.dname and t1.class = t2.class
现在给出计算 p_count2 的代码,有兴趣可以看看哈~~
select distinct dname, class, count(*) p_count2 from ((select sid, dname, class, sum(credit) sum_credit --选了课但是没有达标的学生 from (select sid, cid, dname, class, max(score) max_score from pub.student_course natural join pub.student group by sid, cid, dname, class) natural join pub.course where max_score >= 60 and dname is not null group by sid, dname, class) union (select distinct sid, dname, class, 0 as sum_credit --在 pub.student 中但是不在 pub.student_course 中的学生,这部分学生也算作不达标哦~~ from pub.student where sid not in (select sid from pub.student_course))) where sum_credit < 10 group by dname, class
create table test5_04 (dname varchar(30), class varchar(10), p_count1 int, p_count2 int, p_count int)
-----------一张表一张表地看思路更清晰哦(一共就 t1,t2 两张表)-------------- insert into test5_04 select t1.dname, t1.class, t2.p_count1, (t1.p_count - t2.p_count1) p_count2, t1.p_count from (select distinct dname, class, count(*) p_count from pub.student where dname is not null group by dname, class) t1, (select distinct dname, class, count(*) p_count1 from (select sid, dname, class, sum(credit) sum_credit from (select sid, cid, dname, class, max(score) max_score from pub.student_course natural join pub.student group by sid, cid, dname, class) natural join pub.course where max_score >= 60 and dname is not null group by sid, dname, class) where sum_credit >= --Look at here! 增加的条件在这里 —— 就是根据 class 来决定 sum_credit 的判定条件哦 case when class <= 2008 then 8 when class > 2008 then 10 end group by dname, class) t2 where t1.dname = t2.dname and t1.class = t2.class
手动算 p_count2 也是在相同的地方加上 case 即可。
create table test5_05 (dname varchar(20), avg_ds_score int, avg_os_score int);
insert into test5_05 select distinct t1.dname, t2.avg_ds_score, t3.avg_os_score from (select distinct dname from pub.student) t1, (select distinct dname, round(avg_ds_score, 0) avg_ds_score from (select distinct dname, avg(max_ds_score) avg_ds_score from (select distinct sid, dname, max(score) max_ds_score from pub.student natural join pub.student_course where cid = (select cid from pub.course where name = '数据结构') group by sid, dname) group by dname)) t2, (select distinct dname, round(avg_os_score, 0) avg_os_score from (select distinct dname, avg(max_os_score) avg_os_score from (select distinct sid, dname, max(score) max_os_score from pub.student natural join pub.student_course where cid = (select cid from pub.course where name = '操作系统') group by sid, dname) group by dname)) t3 where t1.dname = t2.dname and t2.dname = t3.dname
create table test5_06 as select t1.sid, t1.name, '计算机科学与技术学院' as dname, t2.ds_score, t3.os_score from (select sid, name from pub.student S where dname = '计算机科学与技术学院' and not exists ( (select cid from pub.course where name = '数据结构' or name = '操作系统') minus (select cid from pub.student_course T where S.sid = T.sid))) t1, (select sid, max(score) ds_score from pub.student_course where cid = (select cid from pub.course where name = '数据结构') group by sid) t2, (select sid, max(score) os_score from pub.student_course where cid = (select cid from pub.course where name = '操作系统') group by sid) t3 where t1.sid = t2.sid and t2.sid = t3.sid
create table test5_07 as select sid, name, dname, ds_score, os_score from (select distinct sid, name, dname from pub.student natural join pub.student_course where dname = '计算机科学与技术学院' and cid in (select cid from pub.course where name = '数据结构' or name = '操作系统')) natural left outer join (select distinct sid, max(score) ds_score from pub.student_course natural join pub.course where name = '数据结构' group by sid) natural left outer join (select distinct sid, max(score) os_score from pub.student_course natural join pub.course where name = '操作系统' group by sid)
create table test5_08 as select sid, name, dname, ds_score, os_score from (select distinct sid, name, dname from pub.student where dname = '计算机科学与技术学院') natural left outer join (select distinct sid, max(score) ds_score from pub.student_course natural join pub.course where name = '数据结构' group by sid) natural left outer join (select distinct sid, max(score) os_score from pub.student_course natural join pub.course where name = '操作系统' group by sid)
再次强调:一定是看懂思路之后自己实践哈~~
有问题还请斧正!