--創(chuàng)建測(cè)試數(shù)據(jù)
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'孫風(fēng)' , '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'數(shù)學(xué)' , '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)
go
--1、查詢"01"課程比"02"課程成績(jī)高的學(xué)生的信息及課程分?jǐn)?shù)
--1.1、查詢同時(shí)存在"01"課程和"02"課程的情況
select a.* , b.score [課程'01'的分?jǐn)?shù)],c.score [課程'02'的分?jǐn)?shù)] from Student a , SC b , SC c
where a.S# = b.S# and a.S# = c.S# and b.C# = '01' and c.C# = '02' and b.score > c.score
--1.2、查詢同時(shí)存在"01"課程和"02"課程的情況和存在"01"課程但可能不存在"02"課程的情況(不存在時(shí)顯示為null)(以下存在相同內(nèi)容時(shí)不再解釋)
select a.* , b.score [課程"01"的分?jǐn)?shù)],c.score [課程"02"的分?jǐn)?shù)] from Student a
left join SC b on a.S# = b.S# and b.C# = '01'
left join SC c on a.S# = c.S# and c.C# = '02'
where b.score > isnull(c.score,0)
--2、查詢"01"課程比"02"課程成績(jī)低的學(xué)生的信息及課程分?jǐn)?shù)
--2.1、查詢同時(shí)存在"01"課程和"02"課程的情況
select a.* , b.score [課程'01'的分?jǐn)?shù)],c.score [課程'02'的分?jǐn)?shù)] from Student a , SC b , SC c
where a.S# = b.S# and a.S# = c.S# and b.C# = '01' and c.C# = '02' and b.score < c.score
--2.2、查詢同時(shí)存在"01"課程和"02"課程的情況和不存在"01"課程但存在"02"課程的情況
select a.* , b.score [課程"01"的分?jǐn)?shù)],c.score [課程"02"的分?jǐn)?shù)] from Student a
left join SC b on a.S# = b.S# and b.C# = '01'
left join SC c on a.S# = c.S# and c.C# = '02'
where isnull(b.score,0) < c.score
--3、查詢平均成績(jī)大于等于60分的同學(xué)的學(xué)生編號(hào)和學(xué)生姓名和平均成績(jī)
select a.S# , a.Sname , cast(avg(b.score) as decimal(18,2)) avg_score
from Student a , sc b
where a.S# = b.S#
group by a.S# , a.Sname
having cast(avg(b.score) as decimal(18,2)) >= 60
order by a.S#
--4、查詢平均成績(jī)小于60分的同學(xué)的學(xué)生編號(hào)和學(xué)生姓名和平均成績(jī)
--4.1、查詢?cè)趕c表存在成績(jī)的學(xué)生信息的SQL語句。
select a.S# , a.Sname , cast(avg(b.score) as decimal(18,2)) avg_score
from Student a , sc b
where a.S# = b.S#
group by a.S# , a.Sname
having cast(avg(b.score) as decimal(18,2)) < 60
order by a.S#
--4.2、查詢?cè)趕c表中不存在成績(jī)的學(xué)生信息的SQL語句。
select a.S# , a.Sname , isnull(cast(avg(b.score) as decimal(18,2)),0) avg_score
from Student a left join sc b
on a.S# = b.S#
group by a.S# , a.Sname
having isnull(cast(avg(b.score) as decimal(18,2)),0) < 60
order by a.S#
--5、查詢所有同學(xué)的學(xué)生編號(hào)、學(xué)生姓名、選課總數(shù)、所有課程的總成績(jī)
--5.1、查詢所有有成績(jī)的SQL。
select a.S# [學(xué)生編號(hào)], a.Sname [學(xué)生姓名], count(b.C#) 選課總數(shù), sum(score) [所有課程的總成績(jī)]
from Student a , SC b
where a.S# = b.S#
group by a.S#,a.Sname
order by a.S#
--5.2、查詢所有(包括有成績(jī)和無成績(jī))的SQL。
select a.S# [學(xué)生編號(hào)], a.Sname [學(xué)生姓名], count(b.C#) 選課總數(shù), sum(score) [所有課程的總成績(jī)]
from Student a left join SC b
on a.S# = b.S#
group by a.S#,a.Sname
order by a.S#
--6、查詢"李"姓老師的數(shù)量
--方法1
select count(Tname) ["李"姓老師的數(shù)量] from Teacher where Tname like N'李%'
--方法2
select count(Tname) ["李"姓老師的數(shù)量] from Teacher where left(Tname,1) = N'李'
/*
"李"姓老師的數(shù)量
-----------
1
*/
--7、查詢學(xué)過"張三"老師授課的同學(xué)的信息
select distinct Student.* from Student , SC , Course , Teacher
where Student.S# = SC.S# and SC.C# = Course.C# and Course.T# = Teacher.T# and Teacher.Tname = N'張三'
order by Student.S#
--8、查詢沒學(xué)過"張三"老師授課的同學(xué)的信息
select m.* from Student m where S# not in (select distinct SC.S# from SC , Course , Teacher where SC.C# = Course.C# and Course.T# = Teacher.T# and Teacher.Tname = N'張三') order by m.S#
--9、查詢學(xué)過編號(hào)為"01"并且也學(xué)過編號(hào)為"02"的課程的同學(xué)的信息
--方法1
select Student.* from Student , SC where Student.S# = SC.S# and SC.C# = '01' and exists (Select 1 from SC SC_2 where SC_2.S# = SC.S# and SC_2.C# = '02') order by Student.S#
--方法2
select Student.* from Student , SC where Student.S# = SC.S# and SC.C# = '02' and exists (Select 1 from SC SC_2 where SC_2.S# = SC.S# and SC_2.C# = '01') order by Student.S#
--方法3
select m.* from Student m where S# in
(
select S# from
(
select distinct S# from SC where C# = '01'
union all
select distinct S# from SC where C# = '02'
) t group by S# having count(1) = 2
)
order by m.S#
--10、查詢學(xué)過編號(hào)為"01"但是沒有學(xué)過編號(hào)為"02"的課程的同學(xué)的信息
--方法1
select Student.* from Student , SC where Student.S# = SC.S# and SC.C# = '01' and not exists (Select 1 from SC SC_2 where SC_2.S# = SC.S# and SC_2.C# = '02') order by Student.S#
--方法2
select Student.* from Student , SC where Student.S# = SC.S# and SC.C# = '01' and Student.S# not in (Select SC_2.S# from SC SC_2 where SC_2.S# = SC.S# and SC_2.C# = '02') order by Student.S#
--11、查詢沒有學(xué)全所有課程的同學(xué)的信息
--11.1、
select Student.*
from Student , SC
where Student.S# = SC.S#
group by Student.S# , Student.Sname , Student.Sage , Student.Ssex having count(C#) < (select count(C#) from Course)
--11.2
select Student.*
from Student left join SC
on Student.S# = SC.S#
group by Student.S# , Student.Sname , Student.Sage , Student.Ssex having count(C#) < (select count(C#) from Course)
11.3
select c.*
from student c
where exists
(
select *
from course b
where not exists( select *
from sc a
where a.c#=b.c# and c.s#=a.s#
)
)
--12、查詢至少有一門課與學(xué)號(hào)為"01"的同學(xué)所學(xué)相同的同學(xué)的信息
select distinct Student.* from Student , SC where Student.S# = SC.S# and SC.C# in (select C# from SC where S# = '01') and Student.S# <> '01'
--13、查詢和"01"號(hào)的同學(xué)學(xué)習(xí)的課程完全相同的其他同學(xué)的信息
select Student.* from Student where S# in
(select distinct SC.S# from SC where S# <> '01' and SC.C# in (select distinct C# from SC where S# = '01')
group by SC.S# having count(1) = (select count(1) from SC where S#='01'))
--14、查詢沒學(xué)過"張三"老師講授的任一門課程的學(xué)生姓名
select student.* from student where student.S# not in
(select distinct sc.S# from sc , course , teacher where sc.C# = course.C# and course.T# = teacher.T# and teacher.tname = N'張三')
order by student.S#
--15、查詢兩門及其以上不及格課程的同學(xué)的學(xué)號(hào),姓名及其平均成績(jī)
select student.S# , student.sname , cast(avg(score) as decimal(18,2)) avg_score from student , sc
where student.S# = SC.S# and student.S# in (select S# from SC where score < 60 group by S# having count(1) >= 2)
group by student.S# , student.sname
--16、檢索"01"課程分?jǐn)?shù)小于60,按分?jǐn)?shù)降序排列的學(xué)生信息
select student.* , sc.C# , sc.score from student , sc
where student.S# = SC.S# and sc.score < 60 and sc.C# = '01'
order by sc.score desc
--17、按平均成績(jī)從高到低顯示所有學(xué)生的所有課程的成績(jī)以及平均成績(jī)
--17.1 SQL 2000 靜態(tài)
select a.S# 學(xué)生編號(hào) , a.Sname 學(xué)生姓名 ,
max(case c.Cname when N'語文' then b.score else null end) [語文],
max(case c.Cname when N'數(shù)學(xué)' then b.score else null end) [數(shù)學(xué)],
max(case c.Cname when N'英語' then b.score else null end) [英語],
cast(avg(b.score) as decimal(18,2)) 平均分
from Student a
left join SC b on a.S# = b.S#
left join Course c on b.C# = c.C#
group by a.S# , a.Sname
order by 平均分 desc
--17.2 SQL 2000 動(dòng)態(tài)
declare @sql nvarchar(4000)
set @sql = 'select a.S# ' + N'學(xué)生編號(hào)' + ' , a.Sname ' + N'學(xué)生姓名'
select @sql = @sql + ',max(case c.Cname when N'''+Cname+''' then b.score else null end) ['+Cname+']'
from (select distinct Cname from Course) as t
set @sql = @sql + ' , cast(avg(b.score) as decimal(18,2)) ' + N'平均分' + ' from Student a left join SC b on a.S# = b.S# left join Course c on b.C# = c.C#
group by a.S# , a.Sname order by ' + N'平均分' + ' desc'
exec(@sql)
--17.3 有關(guān)sql 2005的動(dòng)靜態(tài)寫法參見我的文章《普通行列轉(zhuǎn)換(version 2.0)》或《普通行列轉(zhuǎn)換(version 3.0)》。
--18、查詢各科成績(jī)最高分、最低分和平均分:以如下形式顯示:課程ID,課程name,最高分,最低分,平均分,及格率,中等率,優(yōu)良率,優(yōu)秀率
--及格為>=60,中等為:70-80,優(yōu)良為:80-90,優(yōu)秀為:>=90
--方法1
select m.C# [課程編號(hào)], m.Cname [課程名稱],
max(n.score) [最高分],
min(n.score) [最低分],
cast(avg(n.score) as decimal(18,2)) [平均分],
cast((select count(1) from SC where C# = m.C# and score >= 60)*100.0 / (select count(1) from SC where C# = m.C#) as decimal(18,2)) [及格率(%)],
cast((select count(1) from SC where C# = m.C# and score >= 70 and score < 80 )*100.0 / (select count(1) from SC where C# = m.C#) as decimal(18,2)) [中等率(%)],
cast((select count(1) from SC where C# = m.C# and score >= 80 and score < 90 )*100.0 / (select count(1) from SC where C# = m.C#) as decimal(18,2)) [優(yōu)良率(%)],
cast((select count(1) from SC where C# = m.C# and score >= 90)*100.0 / (select count(1) from SC where C# = m.C#) as decimal(18,2)) [優(yōu)秀率(%)]
from Course m , SC n
where m.C# = n.C#
group by m.C# , m.Cname
order by m.C#
--方法2
select m.C# [課程編號(hào)], m.Cname [課程名稱],
(select max(score) from SC where C# = m.C#) [最高分],
(select min(score) from SC where C# = m.C#) [最低分],
(select cast(avg(score) as decimal(18,2)) from SC where C# = m.C#) [平均分],
cast((select count(1) from SC where C# = m.C# and score >= 60)*100.0 / (select count(1) from SC where C# = m.C#) as decimal(18,2)) [及格率(%)],
cast((select count(1) from SC where C# = m.C# and score >= 70 and score < 80 )*100.0 / (select count(1) from SC where C# = m.C#) as decimal(18,2)) [中等率(%)],
cast((select count(1) from SC where C# = m.C# and score >= 80 and score < 90 )*100.0 / (select count(1) from SC where C# = m.C#) as decimal(18,2)) [優(yōu)良率(%)],
cast((select count(1) from SC where C# = m.C# and score >= 90)*100.0 / (select count(1) from SC where C# = m.C#) as decimal(18,2)) [優(yōu)秀率(%)]
from Course m
order by m.C#
--19、按各科成績(jī)進(jìn)行排序,并顯示排名
--19.1 sql 2000用子查詢完成
--Score重復(fù)時(shí)保留名次空缺
select t.* , px = (select count(1) from SC where C# = t.C# and score > t.score) + 1 from sc t order by t.c# , px
--Score重復(fù)時(shí)合并名次
select t.* , px = (select count(distinct score) from SC where C# = t.C# and score >= t.score) from sc t order by t.c# , px
--19.2 sql 2005用rank,DENSE_RANK完成
--Score重復(fù)時(shí)保留名次空缺(rank完成)
select t.* , px = rank() over(partition by c# order by score desc) from sc t order by t.C# , px
--Score重復(fù)時(shí)合并名次(DENSE_RANK完成)
select t.* , px = DENSE_RANK() over(partition by c# order by score desc) from sc t order by t.C# , px
--20、查詢學(xué)生的總成績(jī)并進(jìn)行排名
--20.1 查詢學(xué)生的總成績(jī)
select m.S# [學(xué)生編號(hào)] ,
m.Sname [學(xué)生姓名] ,
isnull(sum(score),0) [總成績(jī)]
from Student m left join SC n on m.S# = n.S#
group by m.S# , m.Sname
order by [總成績(jī)] desc
--20.2 查詢學(xué)生的總成績(jī)并進(jìn)行排名,sql 2000用子查詢完成,分總分重復(fù)時(shí)保留名次空缺和不保留名次空缺兩種。
select t1.* , px = (select count(1) from
(
select m.S# [學(xué)生編號(hào)] ,
m.Sname [學(xué)生姓名] ,
isnull(sum(score),0) [總成績(jī)]
from Student m left join SC n on m.S# = n.S#
group by m.S# , m.Sname
) t2 where 總成績(jī) > t1.總成績(jī)) + 1 from
(
select m.S# [學(xué)生編號(hào)] ,
m.Sname [學(xué)生姓名] ,
isnull(sum(score),0) [總成績(jī)]
from Student m left join SC n on m.S# = n.S#
group by m.S# , m.Sname
) t1
order by px
select t1.* , px = (select count(distinct 總成績(jī)) from
(
select m.S# [學(xué)生編號(hào)] ,
m.Sname [學(xué)生姓名] ,
isnull(sum(score),0) [總成績(jī)]
from Student m left join SC n on m.S# = n.S#
group by m.S# , m.Sname
) t2 where 總成績(jī) >= t1.總成績(jī)) from
(
select m.S# [學(xué)生編號(hào)] ,
m.Sname [學(xué)生姓名] ,
isnull(sum(score),0) [總成績(jī)]
from Student m left join SC n on m.S# = n.S#
group by m.S# , m.Sname
) t1
order by px
--20.3 查詢學(xué)生的總成績(jī)并進(jìn)行排名,sql 2005用rank,DENSE_RANK完成,分總分重復(fù)時(shí)保留名次空缺和不保留名次空缺兩種。
select t.* , px = rank() over(order by [總成績(jī)] desc) from
(
select m.S# [學(xué)生編號(hào)] ,
m.Sname [學(xué)生姓名] ,
isnull(sum(score),0) [總成績(jī)]
from Student m left join SC n on m.S# = n.S#
group by m.S# , m.Sname
) t
order by px
select t.* , px = DENSE_RANK() over(order by [總成績(jī)] desc) from
(
select m.S# [學(xué)生編號(hào)] ,
m.Sname [學(xué)生姓名] ,
isnull(sum(score),0) [總成績(jī)]
from Student m left join SC n on m.S# = n.S#
group by m.S# , m.Sname
) t
order by px
--21、查詢不同老師所教不同課程平均分從高到低顯示
select m.T# , m.Tname , cast(avg(o.score) as decimal(18,2)) avg_score
from Teacher m , Course n , SC o
where m.T# = n.T# and n.C# = o.C#
group by m.T# , m.Tname
order by avg_score desc
--22、查詢所有課程的成績(jī)第2名到第3名的學(xué)生信息及該課程成績(jī)
--22.1 sql 2000用子查詢完成
--Score重復(fù)時(shí)保留名次空缺
select * from (select t.* , px = (select count(1) from SC where C# = t.C# and score > t.score) + 1 from sc t) m where px between 2 and 3 order by m.c# , m.px
--Score重復(fù)時(shí)合并名次
select * from (select t.* , px = (select count(distinct score) from SC where C# = t.C# and score >= t.score) from sc t) m where px between 2 and 3 order by m.c# , m.px
--22.2 sql 2005用rank,DENSE_RANK完成
--Score重復(fù)時(shí)保留名次空缺(rank完成)
select * from (select t.* , px = rank() over(partition by c# order by score desc) from sc t) m where px between 2 and 3 order by m.C# , m.px
--Score重復(fù)時(shí)合并名次(DENSE_RANK完成)
select * from (select t.* , px = DENSE_RANK() over(partition by c# order by score desc) from sc t) m where px between 2 and 3 order by m.C# , m.px
--23、統(tǒng)計(jì)各科成績(jī)各分?jǐn)?shù)段人數(shù):課程編號(hào),課程名稱,[100-85],[85-70],[70-60],[0-60]及所占百分比
--23.1 統(tǒng)計(jì)各科成績(jī)各分?jǐn)?shù)段人數(shù):課程編號(hào),課程名稱,[100-85],[85-70],[70-60],[0-60]
--橫向顯示
select Course.C# [課程編號(hào)] , Cname as [課程名稱] ,
sum(case when score >= 85 then 1 else 0 end) [85-100],
sum(case when score >= 70 and score < 85 then 1 else 0 end) [70-85],
sum(case when score >= 60 and score < 70 then 1 else 0 end) [60-70],
sum(case when score < 60 then 1 else 0 end) [0-60]
from sc , Course
where SC.C# = Course.C#
group by Course.C# , Course.Cname
order by Course.C#
--縱向顯示1(顯示存在的分?jǐn)?shù)段)
select m.C# [課程編號(hào)] , m.Cname [課程名稱] , 分?jǐn)?shù)段 = (
case when n.score >= 85 then '85-100'
when n.score >= 70 and n.score < 85 then '70-85'
when n.score >= 60 and n.score < 70 then '60-70'
else '0-60'
end) ,
count(1) 數(shù)量
from Course m , sc n
where m.C# = n.C#
group by m.C# , m.Cname , (
case when n.score >= 85 then '85-100'
when n.score >= 70 and n.score < 85 then '70-85'
when n.score >= 60 and n.score < 70 then '60-70'
else '0-60'
end)
order by m.C# , m.Cname , 分?jǐn)?shù)段
--縱向顯示2(顯示存在的分?jǐn)?shù)段,不存在的分?jǐn)?shù)段用0顯示)
select m.C# [課程編號(hào)] , m.Cname [課程名稱] , 分?jǐn)?shù)段 = (
case when n.score >= 85 then '85-100'
when n.score >= 70 and n.score < 85 then '70-85'
when n.score >= 60 and n.score < 70 then '60-70'
else '0-60'
end) ,
count(1) 數(shù)量
from Course m , sc n
where m.C# = n.C#
group by all m.C# , m.Cname , (
case when n.score >= 85 then '85-100'
when n.score >= 70 and n.score < 85 then '70-85'
when n.score >= 60 and n.score < 70 then '60-70'
else '0-60'
end)
order by m.C# , m.Cname , 分?jǐn)?shù)段
--23.2 統(tǒng)計(jì)各科成績(jī)各分?jǐn)?shù)段人數(shù):課程編號(hào),課程名稱,[100-85],[85-70],[70-60],[<60]及所占百分比
--橫向顯示
select m.C# 課程編號(hào), m.Cname 課程名稱,
(select count(1) from SC where C# = m.C# and score < 60) [0-60],
cast((select count(1) from SC where C# = m.C# and score < 60)*100.0 / (select count(1) from SC where C# = m.C#) as decimal(18,2)) [百分比(%)],
(select count(1) from SC where C# = m.C# and score >= 60 and score < 70) [60-70],
cast((select count(1) from SC where C# = m.C# and score >= 60 and score < 70)*100.0 / (select count(1) from SC where C# = m.C#) as decimal(18,2)) [百分比(%)],
(select count(1) from SC where C# = m.C# and score >= 70 and score < 85) [70-85],
cast((select count(1) from SC where C# = m.C# and score >= 70 and score < 85)*100.0 / (select count(1) from SC where C# = m.C#) as decimal(18,2)) [百分比(%)],
(select count(1) from SC where C# = m.C# and score >= 85) [85-100],
cast((select count(1) from SC where C# = m.C# and score >= 85)*100.0 / (select count(1) from SC where C# = m.C#) as decimal(18,2)) [百分比(%)]
from Course m
order by m.C#
--縱向顯示1(顯示存在的分?jǐn)?shù)段)
select m.C# [課程編號(hào)] , m.Cname [課程名稱] , 分?jǐn)?shù)段 = (
case when n.score >= 85 then '85-100'
when n.score >= 70 and n.score < 85 then '70-85'
when n.score >= 60 and n.score < 70 then '60-70'
else '0-60'
end) ,
count(1) 數(shù)量 ,
cast(count(1) * 100.0 / (select count(1) from sc where C# = m.C#) as decimal(18,2)) [百分比(%)]
from Course m , sc n
where m.C# = n.C#
group by m.C# , m.Cname , (
case when n.score >= 85 then '85-100'
when n.score >= 70 and n.score < 85 then '70-85'
when n.score >= 60 and n.score < 70 then '60-70'
else '0-60'
end)
order by m.C# , m.Cname , 分?jǐn)?shù)段
--縱向顯示2(顯示存在的分?jǐn)?shù)段,不存在的分?jǐn)?shù)段用0顯示)
select m.C# [課程編號(hào)] , m.Cname [課程名稱] , 分?jǐn)?shù)段 = (
case when n.score >= 85 then '85-100'
when n.score >= 70 and n.score < 85 then '70-85'
when n.score >= 60 and n.score < 70 then '60-70'
else '0-60'
end) ,
count(1) 數(shù)量 ,
cast(count(1) * 100.0 / (select count(1) from sc where C# = m.C#) as decimal(18,2)) [百分比(%)]
from Course m , sc n
where m.C# = n.C#
group by all m.C# , m.Cname , (//包含所有的分組結(jié)果
case when n.score >= 85 then '85-100'
when n.score >= 70 and n.score < 85 then '70-85'
when n.score >= 60 and n.score < 70 then '60-70'
else '0-60'
end)
order by m.C# , m.Cname , 分?jǐn)?shù)段
--24、查詢學(xué)生平均成績(jī)及其名次
--24.1 查詢學(xué)生的平均成績(jī)并進(jìn)行排名,sql 2000用子查詢完成,分平均成績(jī)重復(fù)時(shí)保留名次空缺和不保留名次空缺兩種。
select t1.* , px = (select count(1) from
(
select m.S# [學(xué)生編號(hào)] ,
m.Sname [學(xué)生姓名] ,
isnull(cast(avg(score) as decimal(18,2)),0) [平均成績(jī)]
from Student m left join SC n on m.S# = n.S#
group by m.S# , m.Sname
) t2 where 平均成績(jī) > t1.平均成績(jī)) + 1 from
(
select m.S# [學(xué)生編號(hào)] ,
m.Sname [學(xué)生姓名] ,
isnull(cast(avg(score) as decimal(18,2)),0) [平均成績(jī)]
from Student m left join SC n on m.S# = n.S#
group by m.S# , m.Sname
) t1
order by px
select t1.* , px = (select count(distinct 平均成績(jī)) from
(
select m.S# [學(xué)生編號(hào)] ,
m.Sname [學(xué)生姓名] ,
isnull(cast(avg(score) as decimal(18,2)),0) [平均成績(jī)]
from Student m left join SC n on m.S# = n.S#
group by m.S# , m.Sname
) t2 where 平均成績(jī) >= t1.平均成績(jī)) from
(
select m.S# [學(xué)生編號(hào)] ,
m.Sname [學(xué)生姓名] ,
isnull(cast(avg(score) as decimal(18,2)),0) [平均成績(jī)]
from Student m left join SC n on m.S# = n.S#
group by m.S# , m.Sname
) t1
order by px
--24.2 查詢學(xué)生的平均成績(jī)并進(jìn)行排名,sql 2005用rank,DENSE_RANK完成,分平均成績(jī)重復(fù)時(shí)保留名次空缺和不保留名次空缺兩種。
select t.* , px = rank() over(order by [平均成績(jī)] desc) from
(
select m.S# [學(xué)生編號(hào)] ,
m.Sname [學(xué)生姓名] ,
isnull(cast(avg(score) as decimal(18,2)),0) [平均成績(jī)]
from Student m left join SC n on m.S# = n.S#
group by m.S# , m.Sname
) t
order by px
select t.* , px = DENSE_RANK() over(order by [平均成績(jī)] desc) from
(
select m.S# [學(xué)生編號(hào)] ,
m.Sname [學(xué)生姓名] ,
isnull(cast(avg(score) as decimal(18,2)),0) [平均成績(jī)]
from Student m left join SC n on m.S# = n.S#
group by m.S# , m.Sname
) t
order by px
--25、查詢各科成績(jī)前三名的記錄
--25.1 分?jǐn)?shù)重復(fù)時(shí)保留名次空缺
select m.* , n.C# , n.score from Student m, SC n where m.S# = n.S# and n.score in
(select top 3 score from sc where C# = n.C# order by score desc) order by n.C# , n.score desc
--25.2 分?jǐn)?shù)重復(fù)時(shí)不保留名次空缺,合并名次
--sql 2000用子查詢實(shí)現(xiàn)
select * from (select t.* , px = (select count(distinct score) from SC where C# = t.C# and score >= t.score) from sc t) m where px between 1 and 3 order by m.c# , m.px
--sql 2005用DENSE_RANK實(shí)現(xiàn)
select * from (select t.* , px = DENSE_RANK() over(partition by c# order by score desc) from sc t) m where px between 1 and 3 order by m.C# , m.px
--26、查詢每門課程被選修的學(xué)生數(shù)
select c# , count(S#)[學(xué)生數(shù)] from sc group by C#
--27、查詢出只有兩門課程的全部學(xué)生的學(xué)號(hào)和姓名
select Student.S# , Student.Sname
from Student , SC
where Student.S# = SC.S#
group by Student.S# , Student.Sname
having count(SC.C#) = 2
order by Student.S#
--28、查詢男生、女生人數(shù)
select count(Ssex) as 男生人數(shù) from Student where Ssex = N'男'
select count(Ssex) as 女生人數(shù) from Student where Ssex = N'女'
select sum(case when Ssex = N'男' then 1 else 0 end) [男生人數(shù)],sum(case when Ssex = N'女' then 1 else 0 end) [女生人數(shù)] from student
select case when Ssex = N'男' then N'男生人數(shù)' else N'女生人數(shù)' end [男女情況] , count(1) [人數(shù)] from student group by case when Ssex = N'男' then N'男生人數(shù)' else N'女生人數(shù)' end
--29、查詢名字中含有"風(fēng)"字的學(xué)生信息
select * from student where sname like N'%風(fēng)%'
select * from student where charindex(N'風(fēng)' , sname) > 0
--30、查詢同名同性學(xué)生名單,并統(tǒng)計(jì)同名人數(shù)
select Sname [學(xué)生姓名], count(*) [人數(shù)] from Student group by Sname having count(*) > 1
--31、查詢1990年出生的學(xué)生名單(注:Student表中Sage列的類型是datetime)
select * from Student where year(sage) = 1990
select * from Student where datediff(yy,sage,'1990-01-01') = 0
select * from Student where datepart(yy,sage) = 1990
select * from Student where convert(varchar(4),sage,120) = '1990'
--32、查詢每門課程的平均成績(jī),結(jié)果按平均成績(jī)降序排列,平均成績(jī)相同時(shí),按課程編號(hào)升序排列
select m.C# , m.Cname , cast(avg(n.score) as decimal(18,2)) avg_score
from Course m, SC n
where m.C# = n.C#
group by m.C# , m.Cname
order by avg_score desc, m.C# asc
--33、查詢平均成績(jī)大于等于85的所有學(xué)生的學(xué)號(hào)、姓名和平均成績(jī)
select a.S# , a.Sname , cast(avg(b.score) as decimal(18,2)) avg_score
from Student a , sc b
where a.S# = b.S#
group by a.S# , a.Sname
having cast(avg(b.score) as decimal(18,2)) >= 85
order by a.S#
--34、查詢課程名稱為"數(shù)學(xué)",且分?jǐn)?shù)低于60的學(xué)生姓名和分?jǐn)?shù)
select sname , score
from Student , SC , Course
where SC.S# = Student.S# and SC.C# = Course.C# and Course.Cname = N'數(shù)學(xué)' and score < 60
--35、查詢所有學(xué)生的課程及分?jǐn)?shù)情況;
select Student.* , Course.Cname , SC.C# , SC.score
from Student, SC , Course
where Student.S# = SC.S# and SC.C# = Course.C#
order by Student.S# , SC.C#
--36、查詢?nèi)魏我婚T課程成績(jī)?cè)?0分以上的姓名、課程名稱和分?jǐn)?shù);
select Student.* , Course.Cname , SC.C# , SC.score
from Student, SC , Course
where Student.S# = SC.S# and SC.C# = Course.C# and SC.score >= 70
order by Student.S# , SC.C#
--37、查詢不及格的課程
select Student.* , Course.Cname , SC.C# , SC.score
from Student, SC , Course
where Student.S# = SC.S# and SC.C# = Course.C# and SC.score < 60
order by Student.S# , SC.C#
--38、查詢課程編號(hào)為01且課程成績(jī)?cè)?0分以上的學(xué)生的學(xué)號(hào)和姓名;
select Student.* , Course.Cname , SC.C# , SC.score
from Student, SC , Course
where Student.S# = SC.S# and SC.C# = Course.C# and SC.C# = '01' and SC.score >= 80
order by Student.S# , SC.C#
--39、求每門課程的學(xué)生人數(shù)
select Course.C# , Course.Cname , count(*) [學(xué)生人數(shù)]
from Course , SC
where Course.C# = SC.C#
group by Course.C# , Course.Cname
order by Course.C# , Course.Cname
--40、查詢選修"張三"老師所授課程的學(xué)生中,成績(jī)最高的學(xué)生信息及其成績(jī)
--40.1 當(dāng)最高分只有一個(gè)時(shí)
select top 1 Student.* , Course.Cname , SC.C# , SC.score
from Student, SC , Course , Teacher
where Student.S# = SC.S# and SC.C# = Course.C# and Course.T# = Teacher.T# and Teacher.Tname = N'張三'
order by SC.score desc
--40.2 當(dāng)最高分出現(xiàn)多個(gè)時(shí)
select Student.* , Course.Cname , SC.C# , SC.score
from Student, SC , Course , Teacher
where Student.S# = SC.S# and SC.C# = Course.C# and Course.T# = Teacher.T# and Teacher.Tname = N'張三' and
SC.score = (select max(SC.score) from SC , Course , Teacher where SC.C# = Course.C# and Course.T# = Teacher.T# and Teacher.Tname = N'張三')
--41、查詢不同課程成績(jī)相同的學(xué)生的學(xué)生編號(hào)、課程編號(hào)、學(xué)生成績(jī)
--方法1
select m.* from SC m ,(select C# , score from SC group by C# , score having count(1) > 1) n
where m.C#= n.C# and m.score = n.score order by m.C# , m.score , m.S#
--方法2
select m.* from SC m where exists (select 1 from (select C# , score from SC group by C# , score having count(1) > 1) n
where m.C#= n.C# and m.score = n.score) order by m.C# , m.score , m.S#
--42、查詢每門功成績(jī)最好的前兩名
select t.* from sc t where score in (select top 2 score from sc where C# = T.C# order by score desc) order by t.C# , t.score desc
--43、統(tǒng)計(jì)每門課程的學(xué)生選修人數(shù)(超過5人的課程才統(tǒng)計(jì))。要求輸出課程號(hào)和選修人數(shù),查詢結(jié)果按人數(shù)降序排列,若人數(shù)相同,按課程號(hào)升序排列
select Course.C# , Course.Cname , count(*) [學(xué)生人數(shù)]
from Course , SC
where Course.C# = SC.C#
group by Course.C# , Course.Cname
having count(*) >= 5
order by [學(xué)生人數(shù)] desc , Course.C#
--44、檢索至少選修兩門課程的學(xué)生學(xué)號(hào)
select student.S# , student.Sname
from student , SC
where student.S# = SC.S#
group by student.S# , student.Sname
having count(1) >= 2
order by student.S#
--45、查詢選修了全部課程的學(xué)生信息
--方法1 根據(jù)數(shù)量來完成
select student.* from student where S# in
(select S# from sc group by S# having count(1) = (select count(1) from course))
--方法2 使用雙重否定來完成
select t.* from student t where t.S# not in
(
select distinct m.S# from
(
select S# , C# from student , course
) m where not exists (select 1 from sc n where n.S# = m.S# and n.C# = m.C#)
)
--方法3 使用雙重否定來完成
select t.* from student t where not exists(select 1 from
(
select distinct m.S# from
(
select S# , C# from student , course
) m where not exists (select 1 from sc n where n.S# = m.S# and n.C# = m.C#)
) k where k.S# = t.S#
)
--46、查詢各學(xué)生的年齡
--46.1 只按照年份來算
select * , datediff(yy , sage , getdate()) [年齡] from student
--46.2 按照出生日期來算,當(dāng)前月日 < 出生年月的月日則,年齡減一
select * , case when right(convert(varchar(10),getdate(),120),5) < right(convert(varchar(10),sage,120),5) then datediff(yy , sage , getdate()) - 1 else datediff(yy , sage , getdate()) end [年齡] from student
--47、查詢本周過生日的學(xué)生
select * from student where datediff(week,datename(yy,getdate()) + right(convert(varchar(10),sage,120),6),getdate()) = 0
--48、查詢下周過生日的學(xué)生
select * from student where datediff(week,datename(yy,getdate()) + right(convert(varchar(10),sage,120),6),getdate()) = -1
--49、查詢本月過生日的學(xué)生
select * from student where datediff(mm,datename(yy,getdate()) + right(convert(varchar(10),sage,120),6),getdate()) = 0
--50、查詢下月過生日的學(xué)生
select * from student where datediff(mm,datename(yy,getdate()) + right(convert(varchar(10),sage,120),6),getdate()) = -1
drop table Student,Course,Teacher,SC
</script>