Available in versions: Dev (3.21) | Latest (3.20) | 3.19 | 3.18 | 3.17 | 3.16 | 3.15 | 3.14 | 3.13 | 3.12 | 3.11
Derived column lists
Supported by ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The SQL standard specifies how a table can be renamed / aliased in one go along with its columns. It references the term "derived column list" for the following syntax:
SELECT t.a, t.b FROM ( SELECT 1, 2 ) t(a, b)
This feature is useful in various use-cases where column names are not known in advance (but the table's degree is!). An example for this are unnested tables, or the VALUES() table constructor:
-- Unnested tables SELECT t.a, t.b FROM unnest(my_table_function()) t(a, b) -- VALUES() constructor SELECT t.a, t.b FROM VALUES(1, 2),(3, 4) t(a, b)
Only few databases really support such a syntax, but fortunately, jOOQ can emulate it easily using UNION ALL and an empty dummy record specifying the new column names. The two statements are equivalent:
-- Using derived column lists SELECT t.a, t.b FROM ( SELECT 1, 2 ) t(a, b) -- Using UNION ALL and a dummy record SELECT t.a, t.b FROM ( SELECT null a, null b FROM DUAL WHERE 1 = 0 UNION ALL SELECT 1, 2 FROM DUAL ) t
In jOOQ, you would simply specify a varargs list of column aliases as such:
// Unnested tables
create.select().from(unnest(myTableFunction()).as("t", "a", "b")).fetch();
// VALUES() constructor
create.select().from(values(
row(1, 2),
row(3, 4)
).as("t", "a", "b"))
.fetch();
Dialect support
This example using jOOQ:
selectFrom(values(row(1, 2)).as("t", "a", "b"))
Translates to the following dialect specific expressions:
Access
SELECT t.a, t.b
FROM (
SELECT
1 a,
2 b
FROM (
SELECT count(*) dual
FROM MSysResources
) AS dual
) t
ASE, Redshift, SQLDataWarehouse, Vertica
SELECT t.a, t.b FROM ( SELECT 1, 2 ) t (a, b)
Aurora MySQL, MemSQL
SELECT t.a, t.b
FROM (
SELECT
1 a,
2 b
FROM DUAL
) t
Aurora Postgres, CockroachDB, DB2, Databricks, DuckDB, Exasol, H2, HSQLDB, Oracle, Postgres, SQLServer, Snowflake, Trino, YugabyteDB
SELECT t.a, t.b FROM ( VALUES (1, 2) ) 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 ([ STRUCT (1, 2)]) t
) t
ClickHouse, MariaDB, Spanner
SELECT t.a, t.b
FROM (
SELECT
1 a,
2 b
) t
Firebird
SELECT t.a, t.b FROM ( SELECT 1, 2 FROM RDB$DATABASE ) t (a, b)
Hana
SELECT t.a, t.b
FROM (
SELECT
1 a,
2 b
FROM SYS.DUMMY
) t
Informix
SELECT t.a, t.b
FROM (
TABLE (MULTISET { ROW (1, 2)})
) t (a, b)
MySQL
SELECT t.a, t.b FROM ( VALUES ROW (1, 2) ) t (a, b)
SQLite
SELECT t.a, t.b
FROM (
SELECT
null a,
null b
WHERE 1 = 0
UNION ALL
SELECT *
FROM (
VALUES (1, 2)
) t
) t
Sybase
SELECT t.a, t.b FROM ( SELECT 1, 2 FROM SYS.DUMMY ) t (a, b)
Teradata
SELECT t.a, t.b
FROM (
SELECT 1, 2
FROM (
SELECT 1 AS "dual"
) AS "dual"
) t (a, b)
Generated with jOOQ 3.21. Support in older jOOQ versions may differ. Translate your own SQL on our website
Feedback
Do you have any feedback about this page? We'd love to hear it!