WITH ORDINALITY
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The SQL standard specifies a WITH ORDINALITY
clause that can be appended to any UNNEST function call (also known as collection derived table). PostgreSQL goes a bit further and allows for the syntax to be used also with any type of table valued function, considering that UNNEST
is just another table value function in their implementation. CockroachDB, on the other hand, allows for using WITH ORDINALITY
with almost any table expression, which makes sense for derived tables (if they're ordered) or the VALUES() table constructor. Note that JSON_TABLE and XMLTABLE have their own native FOR ORDINALITY
syntax, so WITH ORDINALITY
is redundant, there.
jOOQ supports the syntax like CockroachDB, on any org.jooq.Table
:
SELECT * FROM UNNEST(ARRAY['a', 'b']) WITH ORDINALITY
create.select() .from(unnest(array("a", "b")).withOrdinality()) .fetch();
An emulation using a ROW_NUMBER() window function is possible. The ordering stability of such a derived table is at the mercy of the optimiser implementation, and may break "unexpectedly," derived table ordering isn't required to be stable in most RDBMS. So, unless the ordinality can be assigned without any ambiguity (e.g. through native support or because the emulation is entirely implemented in jOOQ, client side), it is better not to rely on deterministic ordinalities, other than the fact that all numbers from1
toN
will be assigned uniquely.
Dialect support
This example using jOOQ:
select().from(unnest(array("a", "b")).withOrdinality().as("t", "a", "b"))
Translates to the following dialect specific expressions:
Aurora Postgres, CockroachDB, H2, HSQLDB, Postgres
SELECT t.a, t.b FROM UNNEST(ARRAY['a', 'b']) WITH ORDINALITY t (a, b)
BigQuery
SELECT t.a, t.b FROM ( SELECT null a, null b FROM UNNEST([STRUCT(1 AS dual)]) AS dual WHERE FALSE UNION ALL SELECT * FROM UNNEST(ARRAY['a', 'b']) WITH ORDINALITY t ) t
DuckDB
SELECT t.a, t.b FROM ( SELECT array_table.COLUMN_VALUE, row_number() OVER () ordinal FROM UNNEST(ARRAY['a', 'b']) array_table (COLUMN_VALUE) ) t (a, b)
ASE, Access, Aurora MySQL, ClickHouse, DB2, Derby, Exasol, Firebird, Hana, Informix, MariaDB, MemSQL, MySQL, Oracle, Redshift, SQLDataWarehouse, SQLServer, SQLite, Snowflake, Sybase, Teradata, Trino, Vertica, YugabyteDB
/* UNSUPPORTED */
Generated with jOOQ 3.20. Translate your own SQL on our website
Feedback
Do you have any feedback about this page? We'd love to hear it!