Yandex.Cloud
  • Services
  • Why Yandex.Cloud
  • Pricing
  • Documentation
  • Contact us
Get started
Yandex Database
  • Getting started
    • Overview
    • Create databases
    • Examples of YQL queries
    • Examples of operations in the YDB CLI
    • Launch a test app
    • Document API
    • Developing in NodeJS through the Document API
  • Step-by-step instructions
    • Database management
    • How to connect to a database
    • Table management
    • Reading and writing data
    • Working with secondary indexes
  • Working with the SDK
  • Concepts
    • Overview
    • Data model and schema
    • Serverless and Dedicated operation modes
    • Data types
    • Transactions
    • Secondary indexes
    • Time to Live (TTL)
    • Terms and definitions
    • Quotas and limits
  • Access management
  • Pricing policy
    • Overview
    • Serverless mode
    • Dedicated mode
  • Recommendations
    • Schema design
    • Partitioning tables
    • Secondary indexes
    • Paginated output
    • Loading large data volumes
    • Using timeouts
  • YDB API and API reference
    • Database limits
    • Handling errors in the API
  • Amazon DynamoDB-compatible HTTP API
    • API reference
      • All methods
      • Actions
        • BatchGetItem
        • BatchWriteItem
        • CreateTable
        • DeleteItem
        • DeleteTable
        • DescribeTable
        • GetItem
        • ListTables
        • PutItem
        • Query
        • Scan
        • TransactGetItems
        • TransactWriteItems
        • UpdateItem
      • Common errors
  • YQL reference guide
    • Overview
    • Data types
      • Simple
      • Optional
      • Containers
      • Special
    • Syntax
      • Unsupported statements
      • For text representation of data types
      • Expressions
      • CREATE TABLE
      • DROP TABLE
      • INSERT INTO
      • UPSERT INTO
      • REPLACE INTO
      • UPDATE
      • DELETE
      • SELECT
      • GROUP BY
      • JOIN
      • FLATTEN
      • ACTION
      • DISCARD
      • PRAGMA
      • DECLARE
      • OVER, PARTITION BY, and WINDOW
    • Built-in functions
      • Basic
      • Aggregate
      • Window
      • For lists
      • For dictionaries
      • For JSON
      • For structures
      • For types
    • Preset user-defined functions
      • HyperScan
      • Pcre
      • Pire
      • Re2
      • String
      • Unicode
      • Datetime
      • Url
      • Ip
      • Digest
      • Math
      • Histogram
    • For text representation of data types
  • YQL tutorial
    • Overview
    • Creating a table
    • Adding data to a table
    • Selecting data from all columns
    • Selecting data from specific columns
    • Sorting and filtering
    • Data aggregation
    • Additional selection criteria
    • Joining tables by JOIN
    • Data insert and update by REPLACE
    • Data insert and update by UPSERT
    • Data insert by INSERT
    • Data update by UPDATE
    • Deleting data
    • Adding and deleting columns
    • Deleting a table
  • Maintenance
    • Backups
  • Diagnostics
    • System views
  • Questions and answers
    • General questions
    • Errors
    • YQL
    • All questions on the same page
  • Public materials
  1. YQL reference guide
  2. Syntax
  3. FLATTEN

FLATTEN

  • FLATTEN BY
    • Specifying the container type
    • Analogs of FLATTEN BY in other DBMS
  • FLATTEN COLUMNS

FLATTEN BY

Converts the rows in the source table using vertical unpacking of containers of variable length (lists or dictionaries).

For example:

  • Source table:
    |[a, b, c]|1|
    | --- | --- |
    |[d]|2|
    |[]|3|

  • The table after applying FLATTEN BY to the left column:
    |a|1|
    | --- | --- |
    |b|1|
    |c|1|
    |d|2|

Example

$sample = AsList(
    AsStruct(AsList('a','b','c') AS value, CAST(1 AS Uint32) AS id),
    AsStruct(AsList('d') AS value, CAST(2 AS Uint32) AS id),
    AsStruct(AsList() AS value, CAST(3 AS Uint32) AS id)
);


SELECT value, id FROM as_table($sample) FLATTEN BY (value);

This conversion can be convenient in the following cases:

  • When you need to output the statistics on cells from a container column (for example, by using GROUP BY).
  • When the cells in a container column store IDs from another table that you want to join using JOIN.

Syntax

  • FLATTEN BY is specified after FROM, but before GROUP BY, if GROUP BY is present in the query.
  • The type of the result column depends on the type of the source column:
Container type Result type Comments
List<X> X List cell type
Dict<X,Y> Tuple<X,Y> Tuple of two elements containing key-value pairs
Optional<X> X The result is almost equivalent to the clause WHERE foo IS NOT NULL, but the foo column type is changed to X
  • By default, the result column replaces the source column. Use FLATTEN BY foo AS bar to keep the source container. As a result, the source container is still available as foo and the output container is available as bar.
  • To build a Cartesian product of multiple container columns, use the clause FLATTEN BY (a, b, c). Parentheses are mandatory to avoid grammar conflicts.
  • Inside FLATTEN BY, you can only use column names from the input table. To apply FLATTEN BY to the calculation result, use a subquery.
  • If the source column had nested containers, for example, List<DictX,Y>, FLATTEN BY unpacks only the outer level. To completely unpack the nested containers, use a subquery.

Note

FLATTEN BY interprets optional data types as lists of length 0 or 1. The table rows with NULL are skipped, and the column type changes to a similar non-nullable one.

FLATTEN BY makes only one conversion at a time, so use FLATTEN LIST BY or FLATTEN OPTIONAL BY on optional containers, for example, Optional<List<String>>.

Specifying the container type

To specify the type of container to convert to, you can use:

  • FLATTEN LIST BY

    For Optional<List<T>>, FLATTEN LIST BY will unpack the list, interpreting NULL as an empty list.

  • FLATTEN DICT BY

    For Optional<Dict<T>>, FLATTEN DICT BY will unpack the dictionary, interpreting NULL as an empty dictionary.

  • FLATTEN OPTIONAL BY

    To filter the NULL values without serialization, specify the operation by using FLATTEN OPTIONAL BY.

Analogs of FLATTEN BY in other DBMS

  • PostgreSQL: unnest
  • Hive: LATERAL VIEW
  • MongoDB: unwind
  • Google BigQuery: FLATTEN
  • ClickHouse: ARRAY JOIN / arrayJoin

Examples

SELECT
  t.item.0 AS key,
  t.item.1 AS value,
  t.dict_column AS original_dict,
  t.other_column AS other
FROM my_table AS t
FLATTEN DICT BY dict_column AS item;
SELECT * FROM (
    SELECT
        AsList(1, 2, 3) AS a,
        AsList("x", "y", "z") AS b
) FLATTEN LIST BY (a, b);

FLATTEN COLUMNS

Converts a table where all columns must be structures to a table with columns corresponding to each element of each structure from the source columns.

The names of the source column structures are not used and not returned in the result. Be sure that the structure element names aren't repeated in the source columns.

Example

SELECT x, y, z
FROM (
  SELECT
    AsStruct(
        1 AS x,
        "foo" AS y),
    AsStruct(
        false AS z)
) FLATTEN COLUMNS;
In this article:
  • FLATTEN BY
  • Specifying the container type
  • Analogs of FLATTEN BY in other DBMS
  • FLATTEN COLUMNS
Language
Careers
Privacy policy
Terms of use
© 2021 Yandex.Cloud LLC