Hive SQL50道練習題
- 2020 年 4 月 7 日
- 筆記
建表
create table student(s_id string,s_name string,s_birth string,s_sex string) row format delimited fields terminated by 't'; create table course(c_id string,c_name string,t_id string) row format delimited fields terminated by 't'; create table teacher(t_id string,t_name string) row format delimited fields terminated by 't'; create table score(s_id string,c_id string,s_score int) row format delimited fields terminated by 't';
生成數據
vi /export/data/hivedatas/student.csv
01 趙雷 1990-01-01 男 02 錢電 1990-12-21 男 03 孫風 1990-05-20 男 04 李雲 1990-08-06 男 05 周梅 1991-12-01 女 06 吳蘭 1992-03-01 女 07 鄭竹 1989-07-01 女 08 王菊 1990-01-20 女
vi /export/data/hivedatas/course.csv
01 語文 02 02 數學 01 03 英語 03
vi /export/data/hivedatas/teacher.csv
01 張三 02 李四 03 王五
vi /export/data/hivedatas/score.csv
01 01 80 01 02 90 01 03 99 02 01 70 02 02 60 02 03 80 03 01 80 03 02 80 03 03 80 04 01 50 04 02 30 04 03 20 05 01 76 05 02 87 06 01 31 06 03 34 07 02 89 07 03 98
導數據到hive
load data local inpath '/export/data/hivedatas/student.csv' into table student; load data local inpath '/export/data/hivedatas/course.csv' into table course; load data local inpath '/export/data/hivedatas/teacher.csv' into table teacher; load data local inpath '/export/data/hivedatas/score.csv' into table score;
–注:–hive查詢語法
SELECT [ALL | DISTINCT] select_expr, select_expr, ... FROM table_reference [WHERE where_condition] [GROUP BY col_list [HAVING condition]] [CLUSTER BY col_list | [DISTRIBUTE BY col_list] [SORT BY| ORDER BY col_list] ] [LIMIT number]
– 1、查詢"01"課程比"02"課程成績高的學生的資訊及課程分數:
select student.*,a.s_score as 01_score,b.s_score as 02_score from student join score a on student.s_id=a.s_id and a.c_id='01' left join score b on student.s_id=b.s_id and b.c_id='02' where a.s_score>b.s_score;
–答案2
select student.*,a.s_score as 01_score,b.s_score as 02_score from student join score a on a.c_id='01' join score b on b.c_id='02' where a.s_id=student.s_id and b.s_id=student.s_id and a.s_score>b.s_score;
– 2、查詢"01"課程比"02"課程成績低的學生的資訊及課程分數:
select student.*,a.s_score as 01_score,b.s_score as 02_score from student join score a on student.s_id=a.s_id and a.c_id='01' left join score b on student.s_id=b.s_id and b.c_id='02' where a.s_score<b.s_score;
–答案2
select student.*,a.s_score as 01_score,b.s_score as 02_score from student join score a on a.c_id='01' join score b on b.c_id='02' where a.s_id=student.s_id and b.s_id=student.s_id and a.s_score<b.s_score;
– 3、查詢平均成績大於等於60分的同學的學生編號和學生姓名和平均成績:
select student.s_id,student.s_name,tmp.平均成績 from student join ( select score.s_id,round(avg(score.s_score),1)as 平均成績 from score group by s_id)as tmp on tmp.平均成績>=60 where student.s_id = tmp.s_id
–答案2
select student.s_id,student.s_name,round(avg (score.s_score),1) as 平均成績 from student join score on student.s_id = score.s_id group by student.s_id,student.s_name having avg (score.s_score) >= 60;
– 4、查詢平均成績小於60分的同學的學生編號和學生姓名和平均成績: – (包括有成績的和無成績的)
select student.s_id,student.s_name,tmp.avgScore from student join ( select score.s_id,round(avg(score.s_score),1)as avgScore from score group by s_id)as tmp on tmp.avgScore < 60 where student.s_id=tmp.s_id union all select s2.s_id,s2.s_name,0 as avgScore from student s2 where s2.s_id not in (select distinct sc2.s_id from score sc2);
–答案2
select score.s_id,student.s_name,round(avg (score.s_score),1) as avgScore from student inner join score on student.s_id=score.s_id group by score.s_id,student.s_name having avg (score.s_score) < 60 union all select s2.s_id,s2.s_name,0 as avgScore from student s2 where s2.s_id not in (select distinct sc2.s_id from score sc2);
– 5、查詢所有同學的學生編號、學生姓名、選課總數、所有課程的總成績:
select student.s_id,student.s_name,(count(score.c_id) )as total_count,sum(score.s_score)as total_score from student left join score on student.s_id=score.s_id group by student.s_id,student.s_name ;
– 6、查詢"李"姓老師的數量:
select t_name,count(1) from teacher where t_name like '李%' group by t_name;
– 7、查詢學過"張三"老師授課的同學的資訊:
select student.* from student join score on student.s_id =score.s_id join course on course.c_id=score.c_id join teacher on course.t_id=teacher.t_id and t_name='張三';
– 8、查詢沒學過"張三"老師授課的同學的資訊:
select student.* from student left join (select s_id from score join course on course.c_id=score.c_id join teacher on course.t_id=teacher.t_id and t_name='張三')tmp on student.s_id =tmp.s_id where tmp.s_id is null;
– 9、查詢學過編號為"01"並且也學過編號為"02"的課程的同學的資訊:
select * from student join (select s_id from score where c_id =1 )tmp1 on student.s_id=tmp1.s_id join (select s_id from score where c_id =2 )tmp2 on student.s_id=tmp2.s_id;
– 10、查詢學過編號為"01"但是沒有學過編號為"02"的課程的同學的資訊:
select student.* from student join (select s_id from score where c_id =1 )tmp1 on student.s_id=tmp1.s_id left join (select s_id from score where c_id =2 )tmp2 on student.s_id =tmp2.s_id where tmp2.s_id is null;
– 11、查詢沒有學全所有課程的同學的資訊: –先查詢出課程的總數量
select count(1) from course;
–再查詢所需結果
select student.* from student left join( select s_id from score group by s_id having count(c_id)=3)tmp on student.s_id=tmp.s_id where tmp.s_id is null;
–方法二(一步到位):
select student.* from student join (select count(c_id)num1 from course)tmp1 left join( select s_id,count(c_id)num2 from score group by s_id)tmp2 on student.s_id=tmp2.s_id and tmp1.num1=tmp2.num2 where tmp2.s_id is null;
– 12、查詢至少有一門課與學號為"01"的同學所學相同的同學的資訊:
select student.* from student join (select c_id from score where score.s_id=01)tmp1 join (select s_id,c_id from score)tmp2 on tmp1.c_id =tmp2.c_id and student.s_id =tmp2.s_id where student.s_id not in('01') group by student.s_id,s_name,s_birth,s_sex;
– 13、查詢和"01"號的同學學習的課程完全相同的其他同學的資訊: –備註:hive不支援group_concat方法,可用 concat_ws(』|』, collect_set(str)) 實現
select student.*,tmp1.course_id from student join (select s_id ,concat_ws('|', collect_set(c_id)) course_id from score group by s_id having s_id not in (1))tmp1 on student.s_id = tmp1.s_id join (select concat_ws('|', collect_set(c_id)) course_id2 from score where s_id=1)tmp2 on tmp1.course_id = tmp2.course_id2;
– 14、查詢沒學過"張三"老師講授的任一門課程的學生姓名:
select student.* from student left join (select s_id from score join (select c_id from course join teacher on course.t_id=teacher.t_id and t_name='張三')tmp2 on score.c_id=tmp2.c_id )tmp on student.s_id = tmp.s_id where tmp.s_id is null;
– 15、查詢兩門及其以上不及格課程的同學的學號,姓名及其平均成績:
select student.s_id,student.s_name,tmp.avg_score from student inner join (select s_id from score where s_score<60 group by score.s_id having count(s_id)>1)tmp2 on student.s_id = tmp2.s_id left join ( select s_id,round(AVG (score.s_score)) avg_score from score group by s_id)tmp on tmp.s_id=student.s_id;
– 16、檢索"01"課程分數小於60,按分數降序排列的學生資訊:
select student.*,s_score from student,score where student.s_id=score.s_id and s_score<60 and c_id='01' order by s_score desc;
– 17、按平均成績從高到低顯示所有學生的所有課程的成績以及平均成績:
select a.s_id,tmp1.s_score as chinese,tmp2.s_score as math,tmp3.s_score as english, round(avg (a.s_score),2) as avgScore from score a left join (select s_id,s_score from score s1 where c_id='01')tmp1 on tmp1.s_id=a.s_id left join (select s_id,s_score from score s2 where c_id='02')tmp2 on tmp2.s_id=a.s_id left join (select s_id,s_score from score s3 where c_id='03')tmp3 on tmp3.s_id=a.s_id group by a.s_id,tmp1.s_score,tmp2.s_score,tmp3.s_score order by avgScore desc;
– 18.查詢各科成績最高分、最低分和平均分:以如下形式顯示:課程ID,課程name,最高分,最低分,平均分,及格率,中等率,優良率,優秀率: –及格為>=60,中等為:70-80,優良為:80-90,優秀為:>=90
select course.c_id,course.c_name,tmp.maxScore,tmp.minScore,tmp.avgScore,tmp.passRate,tmp.moderate,tmp.goodRate,tmp.excellentRates from course join(select c_id,max(s_score) as maxScore,min(s_score)as minScore, round(avg(s_score),2) avgScore, round(sum(case when s_score>=60 then 1 else 0 end)/count(c_id),2)passRate, round(sum(case when s_score>=60 and s_score<70 then 1 else 0 end)/count(c_id),2) moderate, round(sum(case when s_score>=70 and s_score<80 then 1 else 0 end)/count(c_id),2) goodRate, round(sum(case when s_score>=80 and s_score<90 then 1 else 0 end)/count(c_id),2) excellentRates from score group by c_id)tmp on tmp.c_id=course.c_id;
– 19、按各科成績進行排序,並顯示排名: – row_number() over()分組排序功能(mysql沒有該方法)
select s1.*,row_number()over(order by s1.s_score desc) Ranking from score s1 where s1.c_id='01'order by noRanking asc union all select s2.*,row_number()over(order by s2.s_score desc) Ranking from score s2 where s2.c_id='02'order by noRanking asc union all select s3.*,row_number()over(order by s3.s_score desc) Ranking from score s3 where s3.c_id='03'order by noRanking asc;
– 20、查詢學生的總成績並進行排名:
select score.s_id,s_name,sum(s_score) sumscore,row_number()over(order by sum(s_score) desc) Ranking from score ,student where score.s_id=student.s_id group by score.s_id,s_name order by sumscore desc;
– 21、查詢不同老師所教不同課程平均分從高到低顯示: – 方法1
select course.c_id,course.t_id,t_name,round(avg(s_score),2)as avgscore from course join teacher on teacher.t_id=course.t_id join score on course.c_id=score.c_id group by course.c_id,course.t_id,t_name order by avgscore desc;
– 方法2
select course.c_id,course.t_id,t_name,round(avg(s_score),2)as avgscore from course,teacher,score where teacher.t_id=course.t_id and course.c_id=score.c_id group by course.c_id,course.t_id,t_name order by avgscore desc;
– 22、查詢所有課程的成績第2名到第3名的學生資訊及該課程成績:
select tmp1.* from (select * from score where c_id='01' order by s_score desc limit 3)tmp1 order by s_score asc limit 2 union all select tmp2.* from (select * from score where c_id='02' order by s_score desc limit 3)tmp2 order by s_score asc limit 2 union all select tmp3.* from (select * from score where c_id='03' order by s_score desc limit 3)tmp3 order by s_score asc limit 2;
– 23、統計各科成績各分數段人數:課程編號,課程名稱,[100-85],[85-70],[70-60],[0-60]及所佔百分比
select c.c_id,c.c_name,tmp1.s0_60, tmp1.percentum,tmp2.s60_70, tmp2.percentum,tmp3.s70_85, tmp3.percentum,tmp4.s85_100, tmp4.percentum from course c join(select c_id,sum(case when s_score<60 then 1 else 0 end )as s0_60, round(100*sum(case when s_score<60 then 1 else 0 end )/count(c_id),2)as percentum from score group by c_id)tmp1 on tmp1.c_id =c.c_id left join(select c_id,sum(case when s_score<70 and s_score>=60 then 1 else 0 end )as s60_70, round(100*sum(case when s_score<70 and s_score>=60 then 1 else 0 end )/count(c_id),2)as percentum from score group by c_id)tmp2 on tmp2.c_id =c.c_id left join(select c_id,sum(case when s_score<85 and s_score>=70 then 1 else 0 end )as s70_85, round(100*sum(case when s_score<85 and s_score>=70 then 1 else 0 end )/count(c_id),2)as percentum from score group by c_id)tmp3 on tmp3.c_id =c.c_id left join(select c_id,sum(case when s_score>=85 then 1 else 0 end )as s85_100, round(100*sum(case when s_score>=85 then 1 else 0 end )/count(c_id),2)as percentum from score group by c_id)tmp4 on tmp4.c_id =c.c_id;
– 24、查詢學生平均成績及其名次:
select tmp.*,row_number()over(order by tmp.avgScore desc) Ranking from (select student.s_id, student.s_name, round(avg(score.s_score),2) as avgScore from student join score on student.s_id=score.s_id group by student.s_id,student.s_name)tmp order by avgScore desc;
– 25、查詢各科成績前三名的記錄
–課程id為01的前三名
select score.c_id,course.c_name,student.s_name,s_score from score join student on student.s_id=score.s_id join course on score.c_id='01' and course.c_id=score.c_id order by s_score desc limit 3;
–課程id為02的前三名
select score.c_id,course.c_name,student.s_name,s_score from score join student on student.s_id=score.s_id join course on score.c_id='02' and course.c_id=score.c_id order by s_score desc limit 3;
–課程id為03的前三名
select score.c_id,course.c_name,student.s_name,s_score from score join student on student.s_id=score.s_id join course on score.c_id='03' and course.c_id=score.c_id order by s_score desc limit 3;
– 26、查詢每門課程被選修的學生數:
select c.c_id,c.c_name,tmp.number from course c join (select c_id,count(1) as number from score where score.s_score<60 group by score.c_id)tmp on tmp.c_id=c.c_id;
– 27、查詢出只有兩門課程的全部學生的學號和姓名:
select st.s_id,st.s_name from student st join (select s_id from score group by s_id having count(c_id) =2)tmp on st.s_id=tmp.s_id;
– 28、查詢男生、女生人數:
select tmp1.man,tmp2.women from (select count(1) as man from student where s_sex='男')tmp1, (select count(1) as women from student where s_sex='女')tmp2;
– 29、查詢名字中含有"風"字的學生資訊:
select * from student where s_name like '%風%';
– 30、查詢同名同性學生名單,並統計同名人數:
select s1.s_id,s1.s_name,s1.s_sex,count(*) as sameName from student s1,student s2 where s1.s_name=s2.s_name and s1.s_id<>s2.s_id and s1.s_sex=s2.s_sex group by s1.s_id,s1.s_name,s1.s_sex;
– 31、查詢1990年出生的學生名單:
select * from student where s_birth like '1990%';
– 32、查詢每門課程的平均成績,結果按平均成績降序排列,平均成績相同時,按課程編號升序排列:
select score.c_id,c_name,round(avg(s_score),2) as avgScore from score join course on score.c_id=course.c_id group by score.c_id,c_name order by avgScore desc,score.c_id asc;
– 33、查詢平均成績大於等於85的所有學生的學號、姓名和平均成績:
select score.s_id,s_name,round(avg(s_score),2)as avgScore from score join student on student.s_id=score.s_id group by score.s_id,s_name having avg(s_score) >= 85;
– 34、查詢課程名稱為"數學",且分數低於60的學生姓名和分數:
select s_name,s_score as mathScore from student join (select s_id,s_score from score,course where score.c_id=course.c_id and c_name='數學')tmp on tmp.s_score < 60 and student.s_id=tmp.s_id;
– 35、查詢所有學生的課程及分數情況:
select a.s_name, SUM(case c.c_name when '語文' then b.s_score else 0 end ) as chainese, SUM(case c.c_name when '數學' then b.s_score else 0 end ) as math, SUM(case c.c_name when '英語' then b.s_score else 0 end ) as english, SUM(b.s_score) as sumScore from student a join score b on a.s_id=b.s_id join course c on b.c_id=c.c_id group by s_name,a.s_id;
– 36、查詢任何一門課程成績在70分以上的學生姓名、課程名稱和分數:
select student.s_id,s_name,c_name,s_score from student join (select sc.* from score sc left join(select s_id from score where s_score < 70 group by s_id)tmp on sc.s_id=tmp.s_id where tmp.s_id is null)tmp2 on student.s_id=tmp2.s_id join course on tmp2.c_id=course.c_id order by s_id; **-- 查詢全部及格的資訊** select sc.* from score sc left join(select s_id from score where s_score < 60 group by s_id)tmp on sc.s_id=tmp.s_id where tmp.s_id is null; **-- 或(效率低)** select sc.* from score sc where sc.s_id not in (select s_id from score where s_score < 60 group by s_id);
– 37、查詢課程不及格的學生:
select s_name,c_name as courseName,tmp.s_score from student join (select s_id,s_score,c_name from score,course where score.c_id=course.c_id and s_score < 60)tmp on student.s_id=tmp.s_id;
–38、查詢課程編號為01且課程成績在80分以上的學生的學號和姓名:
select student.s_id,s_name,s_score as score_01 from student join score on student.s_id=score.s_id where c_id='01' and s_score >= 80;
– 39、求每門課程的學生人數:
select course.c_id,course.c_name,count(1)as selectNum from course join score on course.c_id=score.c_id group by course.c_id,course.c_name;
– 40、查詢選修"張三"老師所授課程的學生中,成績最高的學生資訊及其成績:
select student.*,tmp3.c_name,tmp3.maxScore from (select s_id,c_name,max(s_score)as maxScore from score join (select course.c_id,c_name from course join (select t_id,t_name from teacher where t_name='張三')tmp on course.t_id=tmp.t_id)tmp2 on score.c_id=tmp2.c_id group by score.s_id,c_name order by maxScore desc limit 1)tmp3 join student on student.s_id=tmp3.s_id;
– 41、查詢不同課程成績相同的學生的學生編號、課程編號、學生成績:
select distinct a.s_id,a.c_id,a.s_score from score a,score b where a.c_id <> b.c_id and a.s_score=b.s_score;
– 42、查詢每門課程成績最好的前三名:
select tmp1.* from (select *,row_number()over(order by s_score desc) ranking from score where c_id ='01')tmp1 where tmp1.ranking <= 3 union all select tmp2.* from (select *,row_number()over(order by s_score desc) ranking from score where c_id ='02')tmp2 where tmp2.ranking <= 3 union all select tmp3.* from (select *,row_number()over(order by s_score desc) ranking from score where c_id ='03')tmp3 where tmp3.ranking <= 3;
– 43、統計每門課程的學生選修人數(超過5人的課程才統計): – 要求輸出課程號和選修人數,查詢結果按人數降序排列,若人數相同,按課程號升序排列
select distinct course.c_id,tmp.num from course join (select c_id,count(1) as num from score group by c_id)tmp where tmp.num>=5 order by tmp.num desc ,course.c_id asc;
– 44、檢索至少選修兩門課程的學生學號:
select s_id,count(c_id) as totalCourse from score group by s_id having count(c_id) >= 2;
– 45、查詢選修了全部課程的學生資訊:
select student.* from student, (select s_id,count(c_id) as totalCourse from score group by s_id)tmp where student.s_id=tmp.s_id and totalCourse=3;
–46、查詢各學生的年齡(周歲): – 按照出生日期來算,當前月日 < 出生年月的月日則,年齡減一 方法一
select s_name,s_birth, (year(CURRENT_DATE)-year(s_birth)- (case when month(CURRENT_DATE) < month(s_birth) then 1 when month(CURRENT_DATE) = month(s_birth) and day(CURRENT_DATE) < day(s_birth) then 1 else 0 end) ) as age from student;
方法二:
select s_name,s_birth, floor((datediff(current_date,s_birth) - floor((year(current_date) - year(s_birth))/4))/365) as age from student;
– 47、查詢本周過生日的學生: –方法1
select * from student where weekofyear(CURRENT_DATE)+1 =weekofyear(s_birth);
–方法2
select s_name,s_sex,s_birth from student where substring(s_birth,6,2)='10' and substring(s_birth,9,2)=14;
– 48、查詢下周過生日的學生: –方法1
select * from student where weekofyear(CURRENT_DATE)+1 =weekofyear(s_birth);
–方法2
select s_name,s_sex,s_birth from student where substring(s_birth,6,2)='10' and substring(s_birth,9,2)>=15 and substring(s_birth,9,2)<=21;
– 49、查詢本月過生日的學生: –方法1
select * from student where MONTH(CURRENT_DATE) =MONTH(s_birth);
–方法2
select s_name,s_sex,s_birth from student where substring(s_birth,6,2)='10';
– 50、查詢12月份過生日的學生:
select s_name,s_sex,s_birth from student where substring(s_birth,6,2)='12';