UNPIVOT 子句
適用於:Databricks SQL Databricks Runtime 12.2 LTS 和更新版本。
透過將前述 table_reference 的橫列轉換,將一組欄旋轉成橫列並合併列出的欄:第一個新橫列會保留原始欄組名稱(或其別名)作為值,接下來是一組欄代表每個欄組的值。
語法
UNPIVOT [ { INCLUDE NULLS | EXCLUDE NULLS } ]
{ single_value | multi_value }
( value_column
FOR unpivot_column IN ( { column_name [ column_alias ] } [, ...] ) )
[ table_alias ]
single_value
( value_column
FOR unpivot_column IN ( { column_name [ column_alias ] } [, ...] ) )
multi_value
( ( value_column [, ...] )
FOR unpivot_column IN ( { ( column_name [, ...] ) [ column_alias ] } [, ...] ) )
參數
INCLUDE NULLS
或EXCLUDE NULLS
是否要在 中篩選出具有
NULL
的數據value_column
列。 預設值為EXCLUDE NULLS
。-
未定義的欄別名。 此欄位將存放值。 ech
value_column
的類型是對應column_name
資料行類型中最不常見的類型。 -
未定義的欄別名。 此欄將包含旋轉過的
column_name
的名稱或其column_alias
。unpivot_column
的類型是STRING
。如果是多重值
UNPIVOT
,如果沒有任何'_'
,則值會是分隔column_name
s 的column_alias
串連。 -
識別在關係中將被旋轉的列。 名稱可能限定。 所有
column_name
都必須共用最不通用的類型。 -
中
unpivot_column
所使用的選擇性名稱。 -
選擇性地指定結果數據表的標籤。 如果
table_alias
包含column_identifier
,則其數目必須符合UNPIVOT
所產生的數據行數目。
結果
以下形式的臨時表格:
-
table_reference
中的所有數據行,除了名為column_name
的數據行。 -
unpivot_column
型別的STRING
。 -
value_column
其比column_name
對之最不常見的型別的 。
範例
- A single column UNPIVOT
> CREATE OR REPLACE TEMPORARY VIEW sales(location, year, q1, q2, q3, q4) AS
VALUES ('Toronto' , 2020, 100 , 80 , 70, 150),
('San Francisco', 2020, NULL, 20 , 50, 60),
('Toronto' , 2021, 110 , 90 , 80, 170),
('San Francisco', 2021, 70 , 120, 85, 105);
> SELECT *
FROM sales UNPIVOT INCLUDE NULLS
(sales FOR quarter IN (q1 AS `Jan-Mar`,
q2 AS `Apr-Jun`,
q3 AS `Jul-Sep`,
sales.q4 AS `Oct-Dec`));
location year quarter sales
—------------ —--- —------ —-----
Toronto 2020 Jan-Mar 100
Toronto 2020 Apr-Jun 80
Toronto 2020 Jul-Sep 70
Toronto 2020 Oct-Dec 150
San Francisco 2020 Jan-Mar null
San Francisco 2020 Apr-Jun 20
San Francisco 2020 Jul-Sep 50
San Francisco 2020 Oct-Dec 60
Toronto 2021 Jan-Mar 110
Toronto 2021 Apr-Jun 90
Toronto 2021 Jul-Sep 80
Toronto 2021 Oct-Dec 170
San Francisco 2021 Jan-Mar 70
San Francisco 2021 Apr-Jun 120
San Francisco 2021 Jul-Sep 85
San Francisco 2021 Oct-Dec 105
-- This is equivalent to:
> SELECT location, year,
inline(arrays_zip(array('Jan-Mar', 'Apr-Jun', 'Jul-Sep', 'Oct-Dec'),
array(q1 , q2 , q3 , q4)))
AS (quarter, sales)
FROM sales;
- A multi column UNPIVOT
> CREATE OR REPLACE TEMPORARY VIEW oncall
(year, week, area , name1 , email1 , phone1 , name2 , email2 , phone2) AS
VALUES (2022, 1 , 'frontend', 'Freddy', 'fred@alwaysup.org' , 15551234567, 'Fanny' , 'fanny@lwaysup.org' , 15552345678),
(2022, 1 , 'backend' , 'Boris' , 'boris@alwaysup.org', 15553456789, 'Boomer', 'boomer@lwaysup.org', 15554567890),
(2022, 2 , 'frontend', 'Franky', 'frank@lwaysup.org' , 15555678901, 'Fin' , 'fin@alwaysup.org' , 15556789012),
(2022, 2 , 'backend' , 'Bonny' , 'bonny@alwaysup.org', 15557890123, 'Bea' , 'bea@alwaysup.org' , 15558901234);
> SELECT *
FROM oncall UNPIVOT ((name, email, phone) FOR precedence IN ((name1, email1, phone1) AS primary,
(name2, email2, phone2) AS secondary));
year week area precedence name email phone
---- ---- -------- ---------- ------ ------------------ -----------
2022 1 frontend primary Freddy fred@alwaysup.org 15551234567
2022 1 frontend secondary Fanny fanny@lwaysup.org 15552345678
2022 1 backend primary Boris boris@alwaysup.org 15553456789
2022 1 backend secondary Boomer boomer@lwaysup.org 15554567890
2022 2 frontend primary Franky frank@lwaysup.org 15555678901
2022 2 frontend secondary Fin fin@alwaysup.org 15556789012
2022 2 backend primary Bonny bonny@alwaysup.org 15557890123
2022 2 backend secondary Bea bea@alwaysup.org 15558901234
-- This is equivalent to:
> SELECT year, week, area,
inline(arrays_zip(array('primary', 'secondary'),
array(name1, name2),
array(email1, email2),
array(phone1, phone2)))
AS (precedence, name, email, phone)
FROM oncall;