explode_outer table-valued generator function

Applies to: check marked yes Databricks SQL check marked yes Databricks Runtime

Returns a set of rows by un-nesting collection using outer semantics.

In Databricks SQL and Databricks Runtime 13.3 and above this function supports named parameter invocation.

Syntax

explode_outer(collection)

Arguments

  • collection: An ARRAY or MAP expression.

Returns

A set of rows composed of the elements of the array or the keys and values of the map. The column produced by explode_outer of an array is named col. The columns for a map are called key and value.

If collection is NULL a single row with NULLs for the array or map values is produced.

  • Applies to: check marked yes Databricks Runtime 12.1 and earlier:

    explode_outer can only be placed in the SELECT list as the root of an expression or following a LATERAL VIEW. When placing the function in the SELECT list there must be no other generator function in the same SELECT list or UNSUPPORTED_GENERATOR.MULTI_GENERATOR is raised.

  • Applies to: check marked yes Databricks SQL check marked yes Databricks Runtime 12.2 and above:

    Invocation from the LATERAL VIEW clause or the SELECT list is deprecated. Instead, invoke explode_outer as a table_reference.

Examples

Applies to: check marked yes Databricks Runtime 12.1 and earlier:

> SELECT explode_outer(array(10, 20)) AS elem, 'Spark';
 10 Spark
 20 Spark

> SELECT explode_outer(collection => array(10, 20)) AS elem, 'Spark';
 10 Spark
 20 Spark

> SELECT explode_outer(map(1, 'a', 2, 'b')) AS (num, val), 'Spark';
 1   a   Spark
 2   b   Spark

> SELECT explode_outer(cast(NULL AS array<int>)), 'Spark';
 NULL   Spark

> SELECT explode_outer(array(1, 2)), explode_outer(array(3, 4));
  Error: UNSUPPORTED_GENERATOR.MULTI_GENERATOR

Applies to: check marked yes Databricks SQL check marked yes Databricks Runtime 12.2 and above:

> SELECT elem, 'Spark' FROM explode_outer(array(10, 20)) AS t(elem);
 10 Spark
 20 Spark

> SELECT num, val, 'Spark' FROM explode_outer(map(1, 'a', 2, 'b')) AS t(num, val);
 1   a   Spark
 2   b   Spark

> SELECT * FROM explode_outer(array(1, 2)), explode_outer(array(3, 4));
 1   3
 1   4
 2   3
 2   4

> SELECT * FROM explode_outer(cast(NULL AS array<int>));
 NULL

-- Using lateral correlation in Databricks 12.2 and above
> SELECT * FROM explode_outer(array(1, 2)) AS t, LATERAL explode_outer(array(3 * t.col, 4 * t.col));
 1   3
 1   4
 2   6
 2   8