posexplode_outer table-valued generator function

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

Returns rows by un-nesting the array with numbering of positions using OUTER semantics.

Syntax

posexplode_outer(expr)

Arguments

  • expr: An ARRAY or MAP expression.

Returns

A set of rows composed of the position and the elements of the array or the keys and values of the map. The columns produced by posexplode_outer of an array are named pos and col. The columns for a map are called pos, key and value.

If expr is NULL, a single row with NULLs for the array or map values.

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

    posexplode_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 Runtime 12.2 and later:

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

Examples

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

> SELECT posexplode_outer(array(10, 20)) AS elem, 'Spark';
 0  10 Spark
 1  20 Spark

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

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

Applies to: check marked yes Databricks Runtime 12.2 and later:

> SELECT elem, 'Spark' FROM posexplode_outer(array(10, 20)) AS t(elem);
 0  10 Spark
 1  20 Spark

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

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

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