A complex data type that can represent an arbitrary number of ordered elements.
The elements can be scalars or another complex type (ARRAY,
STRUCT, or MAP).
column_name ARRAY < type >
type ::= primitive_type | complex_type
The elements of the array have no names. You refer to the value of the array item using the
ITEM pseudocolumn, or its position in the array with the POS
pseudocolumn. See for information about
these pseudocolumns.
Each row can have a different number of elements (including none) in the array for that row.
When an array contains items of scalar types, you can use aggregation functions on the array elements without using join notation. For
example, you can find the COUNT(), AVG(), SUM(), and so on of numeric array
elements, or the MAX() and MIN() of any scalar array elements by referring to
table_name.array_column in the FROM clause of the query. When
you need to cross-reference values from the array with scalar values from the same row, such as by including a GROUP
BY clause to produce a separate aggregated result for each row, then the join clause is required.
A common usage pattern with complex types is to have an array as the top-level type for the column:
an array of structs, an array of maps, or an array of arrays.
For example, you can model a denormalized table by creating a column that is an ARRAY
of STRUCT elements; each item in the array represents a row from a table that would
normally be used in a join query. This kind of data structure lets you essentially denormalize tables by
associating multiple rows from one table with the matching row in another table.
You typically do not create more than one top-level ARRAY column, because if there is
some relationship between the elements of multiple arrays, it is convenient to model the data as
an array of another complex type element (either STRUCT or MAP).
The following example shows how to construct a table with various kinds of ARRAY columns,
both at the top level and nested within other complex types.
Whenever the ARRAY consists of a scalar value, such as in the PETS
column or the CHILDREN field, you can see that future expansion is limited.
For example, you could not easily evolve the schema to record the kind of pet or the child's birthday alongside the name.
Therefore, it is more common to use an ARRAY whose elements are of STRUCT type,
to associate multiple fields with each array element.
Practice the CREATE TABLE and query notation for complex type columns
using empty tables, until you can visualize a complex data structure and construct corresponding SQL statements reliably.
,
-- An ARRAY with elements of complex type (STRUCT).
places_lived ARRAY < STRUCT <
place: STRING,
start_year: INT
>>,
-- An ARRAY as a field (CHILDREN) within a STRUCT.
-- (The STRUCT is inside another ARRAY, because it is rare
-- for a STRUCT to be a top-level column.)
marriages ARRAY < STRUCT <
spouse: STRING,
children: ARRAY
>>,
-- An ARRAY as the value part of a MAP.
-- The first MAP field (the key) would be a value such as
-- 'Parent' or 'Grandparent', and the corresponding array would
-- represent 2 parents, 4 grandparents, and so on.
ancestors MAP < STRING, ARRAY >
)
STORED AS PARQUET;
]]>
The following example shows how to examine the structure of a table containing one or more ARRAY columns by using the
DESCRIBE statement. You can visualize each ARRAY as its own two-column table, with columns
ITEM and POS.
|
| marriages | array |
| | >> |
| places_lived | array> |
| ancestors | map> |
+--------------+---------------------------+
DESCRIBE array_demo.pets;
+------+--------+
| name | type |
+------+--------+
| item | string |
| pos | bigint |
+------+--------+
DESCRIBE array_demo.marriages;
+------+--------------------------+
| name | type |
+------+--------------------------+
| item | struct< |
| | spouse:string, |
| | children:array |
| | > |
| pos | bigint |
+------+--------------------------+
DESCRIBE array_demo.places_lived;
+------+------------------+
| name | type |
+------+------------------+
| item | struct< |
| | place:string, |
| | start_year:int |
| | > |
| pos | bigint |
+------+------------------+
DESCRIBE array_demo.ancestors;
+-------+---------------+
| name | type |
+-------+---------------+
| key | string |
| value | array |
+-------+---------------+
]]>
The following example shows queries involving ARRAY columns containing elements of scalar or complex types. You
unpack
each ARRAY column by referring to it in a join query, as if it were a separate table with
ITEM and POS columns. If the array element is a scalar type, you refer to its value using the
ITEM pseudocolumn. If the array element is a STRUCT, you refer to the STRUCT fields
using dot notation and the field names. If the array element is another ARRAY or a MAP, you use
another level of join to unpack the nested collection elements.
,
,