LATERAL VIEW 子句
适用于: Databricks SQL Databricks Runtime
与生成器函数(例如 EXPLODE
)结合使用,将生成包含一个或多个行的虚拟表。 LATERAL VIEW
将行应用于每个原始输出行。
在 Databricks SQL 中,以及从 Databricks Runtime 12.2 开始,此子句已弃用。 应以 table_reference 的形式调用表值生成器函数。
语法
LATERAL VIEW [ OUTER ] generator_function ( expression [, ...] ) [ table_identifier ] AS column_identifier [, ...]
参数
OUTER
如果指定了
OUTER
,则输入数组/映射为空或为 Null 时返回 Null。-
生成器函数(EXPLODE、INLINE 等)。
-
generator_function
的别名,它是可选项。 -
列出列别名
generator_function
,它可用于输出行。 列标识符的数目必须与 generator 函数返回的列数匹配。
示例
> 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
LATERAL VIEW EXPLODE(ARRAY(30, 60)) tableName AS c_age
LATERAL VIEW EXPLODE(ARRAY(40, 80)) AS d_age;
id name age class address c_age d_age
------ ------- ------- -------- ----------- -------- --------
100 John 30 1 Street 1 30 40
100 John 30 1 Street 1 30 80
100 John 30 1 Street 1 60 40
100 John 30 1 Street 1 60 80
200 Mary NULL 1 Street 2 30 40
200 Mary NULL 1 Street 2 30 80
200 Mary NULL 1 Street 2 60 40
200 Mary NULL 1 Street 2 60 80
300 Mike 80 3 Street 3 30 40
300 Mike 80 3 Street 3 30 80
300 Mike 80 3 Street 3 60 40
300 Mike 80 3 Street 3 60 80
400 Dan 50 4 Street 4 30 40
400 Dan 50 4 Street 4 30 80
400 Dan 50 4 Street 4 60 40
400 Dan 50 4 Street 4 60 80
> SELECT c_age, COUNT(1) FROM person
LATERAL VIEW EXPLODE(ARRAY(30, 60)) AS c_age
LATERAL VIEW EXPLODE(ARRAY(40, 80)) AS d_age
GROUP BY c_age;
c_age count(1)
-------- -----------
60 8
30 8
SELECT * FROM person
LATERAL VIEW EXPLODE(ARRAY()) tableName AS c_age;
id name age class address c_age
----- ------- ------ -------- ---------- --------
> SELECT * FROM person
LATERAL VIEW OUTER EXPLODE(ARRAY()) tableName AS c_age;
id name age class address c_age
------ ------- ------- -------- ----------- --------
100 John 30 1 Street 1 NULL
200 Mary NULL 1 Street 2 NULL
300 Mike 80 3 Street 3 NULL
400 Dan 50 4 Street 4 NULL