行转列
方法一:通过CASE WHEN语句
SELECT
username,
max(CASE WHEN subject = '语文' THEN score END) AS `语文`,
max(CASE WHEN subject = '数学' THEN score END) AS `数学`,
max(CASE WHEN subject = '英语' THEN score END) AS `英语`
FROM pivot
GROUP BY username
ORDER BY username;
结果:
方法二:通过map_agg函数
通过map_agg函数实现行转列需要以下两个步骤:
通过map_agg函数把两个列的多行的值,映射为map。
SELECT username, map_agg(subject, score) kv
FROM pivot
GROUP BY username
ORDER BY username;
结果:
通过map的输出,达到多列输出的目的。
最终,通过map_agg函数实现行转列的详细SQL为:
SELECT
username,
if(element_at(kv, '语文') = null, null, kv['语文']) AS `语文`,
if(element_at(kv, '数学') = null, null, kv['数学']) AS `数学`,
if(element_at(kv, '英语') = null, null, kv['英语']) AS `英语`
FROM (
SELECT username, map_agg(subject, score) kv
FROM pivot
GROUP BY username
) t
ORDER BY username;
结果:
列转行
方法一:通过UNION语句
SELECT username, subject, score
FROM (
SELECT username, '语文' AS subject, yuwen AS score FROM unpivot WHERE yuwen is not null
UNION
SELECT username, '数学' AS subject, shuxue AS score FROM unpivot WHERE shuxue is not null
UNION
SELECT username, '英语' AS subject, yingyu AS score FROM unpivot WHERE yingyu is not null
)
ORDER BY username;
结果:
方法二:通过CROSS JOIN UNNEST语句
SELECT t1.username, t2.subject, t2.score
FROM unpivot t1
CROSS JOIN UNNEST (
array['语文', '数学', '英语'],
array[yuwen, shuxue, yingyu]
) t2 (subject, score)
WHERE t2.score is not null
结果:
文档内容是否对您有帮助?