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

From a SELECT

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Occasionally, creating a table from a SELECT statement is very useful, copying the source table's data types and data.

// Create a new table from a source SELECT statement
create.createTable("book_archive")
      .as(select(BOOK.ID, BOOK.TITLE).from(BOOK))
      .execute();

// Create a new table from a source SELECT statement and specify that data should be included, explicitly
create.createTable("book_archive")
      .as(select(BOOK.ID, BOOK.TITLE).from(BOOK))
      .withData()
      .execute();

// Create a new table from a source SELECT statement and specify that data should be excluded, explicitly
create.createTable("book_archive")
      .as(select(BOOK.ID, BOOK.TITLE).from(BOOK))
      .withNoData()
      .execute();

Dialect support

This example using jOOQ:

createTable("book_archive")
      .as(select(BOOK.ID, BOOK.TITLE).from(BOOK))
      .withNoData()

Translates to the following dialect specific expressions:

-- ACCESS, ASE, SQLDATAWAREHOUSE, SQLSERVER
SELECT BOOK.ID, BOOK.TITLE
INTO book_archive
FROM BOOK
WHERE 1 = 0

-- AURORA_MYSQL, MEMSQL, ORACLE, REDSHIFT, SQLITE, VERTICA
CREATE TABLE book_archive
AS
SELECT BOOK.ID, BOOK.TITLE
FROM BOOK
WHERE 1 = 0

-- AURORA_POSTGRES, DERBY, EXASOL, POSTGRES, YUGABYTEDB
CREATE TABLE book_archive
AS
SELECT BOOK.ID, BOOK.TITLE
FROM BOOK
WITH NO DATA

-- COCKROACHDB, DUCKDB, H2, MARIADB, MYSQL, SNOWFLAKE
CREATE TABLE book_archive
AS
SELECT BOOK.ID, BOOK.TITLE
FROM BOOK
WHERE FALSE

-- DB2
CREATE TABLE book_archive
AS (
  SELECT BOOK.ID, BOOK.TITLE
  FROM BOOK
) WITH NO DATA

-- HANA, HSQLDB
CREATE TABLE book_archive
AS (
  SELECT BOOK.ID, BOOK.TITLE
  FROM BOOK
)
WITH NO DATA

-- TERADATA
CREATE TABLE book_archive
AS (
  SELECT BOOK.ID, BOOK.TITLE
  FROM BOOK
  WHERE 1 = 0
)
WITH DATA

-- BIGQUERY, FIREBIRD, INFORMIX, SYBASE, TRINO
/* UNSUPPORTED */

(These are currently generated with jOOQ 3.19, see #10141), or translate your own on our website

References to this page

Feedback

Do you have any feedback about this page? We'd love to hear it!

The jOOQ Logo