Defines a new table from the results of a query.
CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXISTS ] <table_name>
[ (<column_name> [, ...] ) ]
[ USING <access_method> ]
[ WITH ( <storage_parameter> [= <value>] [, ... ] ) | WITHOUT OIDS ]
[ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ]
[ TABLESPACE <tablespace_name> ]
AS <query>
[ WITH [ NO ] DATA ]
[ DISTRIBUTED BY ( <column> [<opclass>] [, ... ] )
| DISTRIBUTED RANDOMLY
| DISTRIBUTED REPLICATED ]
CREATE TABLE AS
creates a table and fills it with data computed by a SELECT command. The table columns have the names and data types associated with the output columns of the SELECT
, however you can override the column names by giving an explicit list of new column names.
CREATE TABLE AS
creates a new table and evaluates the query just once to fill the new table initially. The new table will not track subsequent changes to the source tables of the query.
The optional USING
clause specifies the table access method to use to store the contents for the new table you are creating; the method must be an access method of type TABLE. Set to heap
to access the table as a heap-storage table, ao_row
to access the table as an append-optimized table with row-oriented storage (AO), or ao_column
to access the table as an append-optimized table with column-oriented storage (AO/CO). The default access method is determined by the value of the default_table_access_method server configuration parameter.
Note: Although you can specify the table's access method using WITH (appendoptimized=true|false, orientation=row|column)
VMware recommends that you use USING
instead.
WITH
clause specifies optional storage parameters for the new table. Refer to the
Storage Parameters section on the
CREATE TABLE
reference page for more information.
The behavior of temporary tables at the end of a transaction block can be controlled using ON COMMIT
. The three options are:
PRESERVE ROWS — Greenplum Database takes no special action at the ends of transactions for temporary tables. This is the default behavior.
DELETE ROWS — Greenplum Database deletes all rows in the temporary table at the end of each transaction block. Essentially, an automatic TRUNCATE is done at each commit.
SELECT
,
TABLE
, or
VALUES
query.
This command is functionally similar to SELECT INTO, but it is preferred since it is less likely to be confused with other uses of the SELECT INTO
syntax. Furthermore, CREATE TABLE AS
offers a superset of the functionality offered by SELECT INTO
.
CREATE TABLE AS
can be used for fast data loading from external table data sources. See CREATE EXTERNAL TABLE.
Create a new table films_recent
consisting of only recent entries from the table films
:
CREATE TABLE films_recent AS
SELECT * FROM films WHERE date_prod >= '2020-01-01';
To copy a table completely, you can also use the short form by specifying the TABLE
command:
CREATE TABLE films2 AS
TABLE films;
Create a new temporary table films_recent
, consisting only of recent entries from the table films
, using a prepared statement. The new table will be dropped at commit:
PREPARE recentfilms(date) AS
SELECT * FROM films WHERE date_prod > $1;
CREATE TEMP TABLE films_recent ON COMMIT DROP AS
EXECUTE recentfilms('2020-01-01');
CREATE TABLE AS
conforms to the SQL standard, with the following exceptions:
WITH [NO] DATA
clause is required, in Greenplum Database it is optional.WITH
clause is a Greenplum Database extension; storage parameters are not part of the standard.TABLESPACE
clause is an extension.CREATE EXTERNAL TABLE, CREATE MATERIALIZED VIEW, CREATE TABLE, EXECUTE, SELECT, SELECT INTO, VALUES
Parent topic: SQL Commands