暂无图片
暂无图片
暂无图片
暂无图片
暂无图片

MySQL 将结果集转置为一行

原创 只是甲 2020-11-26
2247

备注:测试数据库版本为MySQL 8.0

如需要scott用户下建表及录入数据语句,可参考:
scott建表及录入数据sql脚本

Table of Contents

一.需求

希望将几个行组中的数据转换成几行中的列,每个原来的行组转换成一行。
例如,下面的结果集显示了每个部门中员工的数目:

deptno cnt
10 3
20 5
30 6

希望重新设置输出格式,使其结果集看起来如下:
deptno_10 deptno_20 deptno_30
3 5 6

二.解决方案

2.1 解决方案1

使用sum汇总、case进行判断

select sum(case when deptno = 10 then 1 else 0 end) as deptno_10, sum(case when deptno = 20 then 1 else 0 end) as deptno_20, sum(case when deptno = 30 then 1 else 0 end) as deptno_30 from emp order by 1;

测试记录:

mysql> select  sum(case when deptno = 10 then 1 else 0 end) as deptno_10,
    ->         sum(case when deptno = 20 then 1 else 0 end) as deptno_20,
    ->         sum(case when deptno = 30 then 1 else 0 end) as deptno_30
    ->   from emp
    ->  order by 1;
+-----------+-----------+-----------+
| deptno_10 | deptno_20 | deptno_30 |
+-----------+-----------+-----------+
|         3 |         5 |         6 |
+-----------+-----------+-----------+
1 row in set (0.00 sec)

2.2 解决方案2

使用max及case函数

select max(case when deptno = 10 then empcount else null end) as deptno_10, max(case when deptno = 20 then empcount else null end) as deptno_20, max(case when deptno = 30 then empcount else null end) as deptno_30 from ( select deptno, count(*) as empcount from emp group by deptno ) x;

测试记录

mysql> select max(case when deptno = 10 then empcount else null end) as deptno_10,
    ->        max(case when deptno = 20 then empcount else null end) as deptno_20,
    ->        max(case when deptno = 30 then empcount else null end) as deptno_30
    ->   from (
    -> select deptno, count(*) as empcount
    ->   from emp
    ->  group by deptno
    ->        ) x;
+-----------+-----------+-----------+
| deptno_10 | deptno_20 | deptno_30 |
+-----------+-----------+-----------+
|         3 |         5 |         6 |
+-----------+-----------+-----------+
1 row in set (0.00 sec)

步骤进行分解

mysql> -- 根据部门进行分组
mysql> select deptno, count(*) as empcount
    ->   from emp
    ->  group by deptno;
+--------+----------+
| deptno | empcount |
+--------+----------+
|     10 |        3 |
|     20 |        5 |
|     30 |        6 |
+--------+----------+
3 rows in set (0.00 sec)

mysql>
mysql>
mysql> -- 使用case语句进行判断
mysql> select case when deptno = 10 then empcount else null end as deptno_10,
    ->        case when deptno = 20 then empcount else null end as deptno_20,
    ->        case when deptno = 30 then empcount else null end as deptno_30
    ->   from (
    -> select deptno, count(*) as empcount
    ->   from emp
    ->  group by deptno
    ->        ) x;
+-----------+-----------+-----------+
| deptno_10 | deptno_20 | deptno_30 |
+-----------+-----------+-----------+
|         3 |      NULL |      NULL |
|      NULL |         5 |      NULL |
|      NULL |      NULL |         6 |
+-----------+-----------+-----------+
3 rows in set (0.00 sec)

mysql>
mysql> -- 使用max函数求最大值
mysql> select max(case when deptno = 10 then empcount else null end) as deptno_10,
    ->        max(case when deptno = 20 then empcount else null end) as deptno_20,
    ->        max(case when deptno = 30 then empcount else null end) as deptno_30
    ->   from (
    -> select deptno, count(*) as empcount
    ->   from emp
    ->  group by deptno
    ->        ) x;
+-----------+-----------+-----------+
| deptno_10 | deptno_20 | deptno_30 |
+-----------+-----------+-----------+
|         3 |         5 |         6 |
+-----------+-----------+-----------+
1 row in set (0.00 sec)

「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。

文章被以下合辑收录

评论