CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE table_name [ (column_name [, ...] ) ] [ WITH ( storage_parameter [= value] [, ... ] ) | WITH OIDS | WITHOUT OIDS ] [ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ] [ TABLESPACE tablespace ] [ DISTRIBUTE BY { REPLICATION | ROUNDROBIN | { [HASH | MODULO ] ( column_name ) } } ] [ TO { GROUP groupname | NODE ( nodename [, ... ] ) } ] AS query [ WITH [ NO ] DATA ]
Note: The following description applies both to Postgres-XC and PostgreSQL if not described explicitly. You can read PostgreSQL as Postgres-XC except for version number, which is specific to each product.
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 (except that you can override the column names by giving an explicit list of new column names).
CREATE TABLE AS bears some resemblance to creating a view, but it is really quite different: it 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. In contrast, a view re-evaluates its defining SELECT statement whenever it is queried.
Note: The following description applies both to Postgres-XC and PostgreSQL if not described explicitly. You can read PostgreSQL as Postgres-XC except for version number, which is specific to each product.
Ignored for compatibility. Use of these keywords is deprecated; refer to CREATE TABLE for details.
If specified, the table is created as a temporary table. Refer to CREATE TABLE for details.
If specified, the table is created as an unlogged table. Refer to CREATE TABLE for details.
The name (optionally schema-qualified) of the table to be created.
The name of a column in the new table. If column names are not provided, they are taken from the output column names of the query.
This clause specifies optional storage parameters for the new table; see Storage Parameters for more information. The WITH clause can also include OIDS=TRUE (or just OIDS) to specify that rows of the new table should have OIDs (object identifiers) assigned to them, or OIDS=FALSE to specify that the rows should not have OIDs. See CREATE TABLE for more information.
These are obsolescent syntaxes equivalent to WITH (OIDS) and WITH (OIDS=FALSE), respectively. If you wish to give both an OIDS setting and storage parameters, you must use the WITH ( ... ) syntax; see above.
The behavior of temporary tables at the end of a transaction block can be controlled using ON COMMIT. The three options are:
No special action is taken at the ends of transactions. This is the default behavior.
All rows in the temporary table will be deleted at the end of each transaction block. Essentially, an automatic TRUNCATE is done at each commit.
The temporary table will be dropped at the end of the current transaction block.
The tablespace_name is the name of the tablespace in which the new table is to be created. If not specified, default_tablespace is consulted, or temp_tablespaces if the table is temporary.
Note: XCONLY: The following description applies only to Postgres-XC.
This clause specifies how the table is distributed or replicated among Datanodes.
Each row of the table will be replicated into all the Datanode of the Postgres-XC database cluster.
Each row of the table will be placed in one of the Datanodes by round-robin manner. The value of the row will not be needed to determine what Datanode to go.
Each row of the table will be placed based on the hash value of the specified column. Following type is allowed as distribution column: INT8, INT2, OID, INT4, BOOL, INT2VECTOR, OIDVECTOR, CHAR, NAME, TEXT, BPCHAR, BYTEA, VARCHAR, FLOAT4, FLOAT8, NUMERIC, CASH, ABSTIME, RELTIME, DATE, TIME, TIMESTAMP, TIMESTAMPTZ, INTERVAL, and TIMETZ.
Please note that floating point is not allowed as a basis of the distribution column.
Each row of the table will be placed based on the modulo of the specified column. Following type is allowed as distribution column: INT8, INT2, OID, INT4, BOOL, INT2VECTOR, OIDVECTOR, CHAR, NAME, TEXT, BPCHAR, BYTEA, VARCHAR, FLOAT4, FLOAT8, NUMERIC, CASH, ABSTIME, RELTIME, DATE, TIME, TIMESTAMP, TIMESTAMPTZ, INTERVAL, and TIMETZ.
Please note that floating point is not allowed as a basis of the distribution column.
If DISTRIBUTE BY is not specified, columns with UNIQUE constraint will be chosen as the distribution key. If no such column is specified, distribution column is the first eligible column in the definition. If no such column is found, then the table will be distributed by ROUNDROBIN.
This defines on the list of nodes on which table data exists. If this is not specified table data is present on all Datanodes.
Associated with TO NODE, it defines a Postgres-XC node of catalog pgxc_node.
Associated with TO GROUP, it defines a Postgres-XC node group in catalog pgxc_group.
A SELECT, TABLE, or VALUES command, or an EXECUTE command that runs a prepared SELECT, TABLE, or VALUES query.
This clause specifies whether or not the data produced by the query should be copied into the new table. If not, only the table structure is copied. The default is to copy the data.
Note: The following description applies both to Postgres-XC and PostgreSQL if not described explicitly. You can read PostgreSQL as Postgres-XC except for version number, which is specific to each product.
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.
Prior to PostgreSQL 8.0, CREATE TABLE AS always included OIDs in the table it created. As of PostgreSQL 8.0, the CREATE TABLE AS command allows the user to explicitly specify whether OIDs should be included. If the presence of OIDs is not explicitly specified, the default_with_oids configuration variable is used. As of PostgreSQL 8.1, this variable is false by default, so the default behavior is not identical to pre-8.0 releases. Applications that require OIDs in the table created by CREATE TABLE AS should explicitly specify WITH (OIDS) to ensure desired behavior.
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 >= '2002-01-01';
To copy a table completely, the short form using the TABLE command can also be used:
CREATE TABLE films2 AS TABLE films;
Create a new temporary table films_recent, consisting of only recent entries from the table films, using a prepared statement. The new table has OIDs and will be dropped at commit:
PREPARE recentfilms(date) AS SELECT * FROM films WHERE date_prod > $1; CREATE TEMP TABLE films_recent WITH (OIDS) ON COMMIT DROP AS EXECUTE recentfilms('2002-01-01');
Note: The following description applies both to Postgres-XC and PostgreSQL if not described explicitly. You can read PostgreSQL as Postgres-XC except for version number, which is specific to each product.
CREATE TABLE AS conforms to the SQL standard. The following are nonstandard extensions:
The standard requires parentheses around the subquery clause; in PostgreSQL, these parentheses are optional.
In the standard, the WITH [ NO ] DATA clause is required; in PostgreSQL it is optional.
PostgreSQL handles temporary tables in a way rather different from the standard; see CREATE TABLE for details.
The WITH clause is a PostgreSQL extension; neither storage parameters nor OIDs are in the standard.
The PostgreSQL concept of tablespaces is not part of the standard. Hence, the clause TABLESPACE is an extension.
Note: XCONLY: The following description applies only to Postgres-XC.
DISTRIBUTE BY is an extension of Postgres-XC.