PIVOT 子句
說明
PIVOT
子句用於資料觀點。我們可以根據特定欄位值取得彙總值,這些值將轉換為 SELECT
子句中使用的多個欄位。PIVOT
子句可以在資料表名稱或子查詢後指定。
語法
PIVOT ( { aggregate_expression [ AS aggregate_expression_alias ] } [ , ... ]
FOR column_list IN ( expression_list ) )
參數
-
aggregate_expression
指定彙總運算式 (SUM(a)、COUNT(DISTINCT b) 等)。
-
aggregate_expression_alias
指定彙總運算式的別名。
-
column_list
包含
FROM
子句中的欄位,指定我們想要以新欄位取代的欄位。我們可以使用括號將欄位括起來,例如(c1, c2)
。 -
expression_list
指定新欄位,用於比對
column_list
中的值作為彙總條件。我們也可以為它們新增別名。
範例
CREATE TABLE person (id INT, name STRING, age INT, class INT, address STRING);
INSERT INTO person VALUES
(100, 'John', 30, 1, 'Street 1'),
(200, 'Mary', NULL, 1, 'Street 2'),
(300, 'Mike', 80, 3, 'Street 3'),
(400, 'Dan', 50, 4, 'Street 4');
SELECT * FROM person
PIVOT (
SUM(age) AS a, AVG(class) AS c
FOR name IN ('John' AS john, 'Mike' AS mike)
);
+------+-----------+---------+---------+---------+---------+
| id | address | john_a | john_c | mike_a | mike_c |
+------+-----------+---------+---------+---------+---------+
| 200 | Street 2 | NULL | NULL | NULL | NULL |
| 100 | Street 1 | 30 | 1.0 | NULL | NULL |
| 300 | Street 3 | NULL | NULL | 80 | 3.0 |
| 400 | Street 4 | NULL | NULL | NULL | NULL |
+------+-----------+---------+---------+---------+---------+
SELECT * FROM person
PIVOT (
SUM(age) AS a, AVG(class) AS c
FOR (name, age) IN (('John', 30) AS c1, ('Mike', 40) AS c2)
);
+------+-----------+-------+-------+-------+-------+
| id | address | c1_a | c1_c | c2_a | c2_c |
+------+-----------+-------+-------+-------+-------+
| 200 | Street 2 | NULL | NULL | NULL | NULL |
| 100 | Street 1 | 30 | 1.0 | NULL | NULL |
| 300 | Street 3 | NULL | NULL | NULL | NULL |
| 400 | Street 4 | NULL | NULL | NULL | NULL |
+------+-----------+-------+-------+-------+-------+