Available in versions: Dev (3.19) | Latest (3.18) | 3.17 | 3.16 | 3.15 | 3.14 | 3.13 | 3.12 | 3.11 | 3.10 | 3.9
Derived column lists
Applies to ✅ 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, DERBY, DUCKDB, EXASOL, H2, HSQLDB, ORACLE, POSTGRES, SNOWFLAKE, SQLSERVER, 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 -- 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) -- MARIADB SELECT t.a, t.b FROM ( SELECT 1 a, 2 b ) t -- 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)
(These are currently generated with jOOQ 3.19, see #10141), or translate your own on our website
Feedback
Do you have any feedback about this page? We'd love to hear it!