| --- |
| layout: global |
| title: LATERAL VIEW Clause |
| displayTitle: LATERAL VIEW Clause |
| license: | |
| Licensed to the Apache Software Foundation (ASF) under one or more |
| contributor license agreements. See the NOTICE file distributed with |
| this work for additional information regarding copyright ownership. |
| The ASF licenses this file to You under the Apache License, Version 2.0 |
| (the "License"); you may not use this file except in compliance with |
| the License. You may obtain a copy of the License at |
| |
| http://www.apache.org/licenses/LICENSE-2.0 |
| |
| Unless required by applicable law or agreed to in writing, software |
| distributed under the License is distributed on an "AS IS" BASIS, |
| WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. |
| See the License for the specific language governing permissions and |
| limitations under the License. |
| --- |
| |
| ### Description |
| |
| The `LATERAL VIEW` clause is used in conjunction with generator functions such as `EXPLODE`, which will generate a virtual table containing one or more rows. `LATERAL VIEW` will apply the rows to each original output row. |
| |
| ### Syntax |
| |
| ```sql |
| LATERAL VIEW [ OUTER ] generator_function ( expression [ , ... ] ) [ table_alias ] AS column_alias [ , ... ] |
| ``` |
| |
| ### Parameters |
| |
| * **OUTER** |
| |
| If `OUTER` specified, returns null if an input array/map is empty or null. |
| |
| * **generator_function** |
| |
| Specifies a generator function (EXPLODE, INLINE, etc.). |
| |
| * **table_alias** |
| |
| The alias for `generator_function`, which is optional. |
| |
| * **column_alias** |
| |
| Lists the column aliases of `generator_function`, which may be used in output rows. We may have multiple aliases if `generator_function` have multiple output columns. |
| |
| ### Examples |
| |
| ```sql |
| 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 | |
| +------+-------+-------+--------+-----------+--------+ |
| ``` |
| |
| ### Related Statements |
| |
| * [SELECT Main](sql-ref-syntax-qry-select.html) |
| * [WHERE Clause](sql-ref-syntax-qry-select-where.html) |
| * [GROUP BY Clause](sql-ref-syntax-qry-select-groupby.html) |
| * [HAVING Clause](sql-ref-syntax-qry-select-having.html) |
| * [ORDER BY Clause](sql-ref-syntax-qry-select-orderby.html) |
| * [SORT BY Clause](sql-ref-syntax-qry-select-sortby.html) |
| * [DISTRIBUTE BY Clause](sql-ref-syntax-qry-select-distribute-by.html) |
| * [LIMIT Clause](sql-ref-syntax-qry-select-limit.html) |
| * [OFFSET Clause](sql-ref-syntax-qry-select-offset.html) |
| * [CASE Clause](sql-ref-syntax-qry-select-case.html) |
| * [PIVOT Clause](sql-ref-syntax-qry-select-pivot.html) |
| * [UNPIVOT Clause](sql-ref-syntax-qry-select-unpivot.html) |