Skip to content

SQL191 某乎问答高质量的回答中用户属于各级别的数量

Static BadgeStatic Badge

题目描述

现有某乎问答创作者信息表author_tb如下(其中author_id表示创作者编号、author_level表示创作者级别,共1-6六个级别、sex表示创作者性别):

author_idauthor_levelsex
1016m
1021f
1031m
1043m
1054f
1062f
1072m
1085f
1096f
1105m

创作者回答情况表answer_tb如下(其中answer_date表示回答日期、author_id指创作者编号、issue_id指问题编号、char_len表示回答字数):

answer_dateauthor_idissue_idchar_len
2021-11-01101E001150
2021-11-01101E002200
2021-11-01102C00350
2021-11-01103P00135
2021-11-01104C003120
2021-11-01105P001125
2021-11-01102P002105
2021-11-02101P001201
2021-11-02110C002200
2021-11-02110C001225
2021-11-02110C002220
2021-11-03101C002180
2021-11-04109E003130
2021-11-04109E001123
2021-11-05108C001160
2021-11-05108C002120
2021-11-05110P001180
2021-11-05106P00245
2021-11-05107E00356

回答字数大于等于100字的认为是高质量回答,请你统计某乎问答高质量的回答中用户属于1-2级、3-4级、5-6级的数量分别是多少,按数量降序排列,以上例子的输出结果如下:

level_cutnum
5-6级12
3-4级2
1-2级1

SQL Schema

sql
drop table if exists author_tb;
CREATE TABLE author_tb(
author_id int(10) NOT NULL, 
author_level int(10) NOT NULL,
sex char(10) NOT NULL);
INSERT INTO author_tb VALUES(101 , 6, 'm');
INSERT INTO author_tb VALUES(102 , 1, 'f');
INSERT INTO author_tb VALUES(103 , 1, 'm');
INSERT INTO author_tb VALUES(104 , 3, 'm');
INSERT INTO author_tb VALUES(105 , 4, 'f');
INSERT INTO author_tb VALUES(106 , 2, 'f');
INSERT INTO author_tb VALUES(107 , 2, 'm');
INSERT INTO author_tb VALUES(108 , 5, 'f');
INSERT INTO author_tb VALUES(109 , 6, 'f');
INSERT INTO author_tb VALUES(110 , 5, 'm');

drop table if exists answer_tb;
CREATE TABLE answer_tb(
answer_date date NOT NULL, 
author_id int(10) NOT NULL,
issue_id char(10) NOT NULL,
char_len int(10) NOT NULL);
INSERT INTO answer_tb VALUES('2021-11-1', 101, 'E001' ,150);
INSERT INTO answer_tb VALUES('2021-11-1', 101, 'E002', 200);
INSERT INTO answer_tb VALUES('2021-11-1',102, 'C003' ,50);
INSERT INTO answer_tb VALUES('2021-11-1' ,103, 'P001', 35);
INSERT INTO answer_tb VALUES('2021-11-1', 104, 'C003', 120);
INSERT INTO answer_tb VALUES('2021-11-1' ,105, 'P001', 125);
INSERT INTO answer_tb VALUES('2021-11-1' , 102, 'P002', 105);
INSERT INTO answer_tb VALUES('2021-11-2',  101, 'P001' ,201);
INSERT INTO answer_tb VALUES('2021-11-2',  110, 'C002', 200);
INSERT INTO answer_tb VALUES('2021-11-2',  110, 'C001', 225);
INSERT INTO answer_tb VALUES('2021-11-2' , 110, 'C002', 220);
INSERT INTO answer_tb VALUES('2021-11-3', 101, 'C002', 180);
INSERT INTO answer_tb VALUES('2021-11-4' ,109, 'E003', 130);
INSERT INTO answer_tb VALUES('2021-11-4', 109, 'E001',123);
INSERT INTO answer_tb VALUES('2021-11-5', 108, 'C001',160);
INSERT INTO answer_tb VALUES('2021-11-5', 108, 'C002', 120);
INSERT INTO answer_tb VALUES('2021-11-5', 110, 'P001', 180);
INSERT INTO answer_tb VALUES('2021-11-5' , 106, 'P002' , 45);
INSERT INTO answer_tb VALUES('2021-11-5' , 107, 'E003', 56);

答案

sql
SELECT IF(a2.author_level BETWEEN 1 AND 2, '1-2级',
          IF(a2.author_level BETWEEN 3 AND 4, '3-4级', '5-6级')) AS `level_cut`,
       COUNT(*)                                                  AS `num`
FROM answer_tb a1
         INNER JOIN author_tb a2 USING (author_id)
WHERE char_len >= 100
GROUP BY level_cut
ORDER BY num DESC;