CREATE TEMPORARY TABLE
Creates a table whose data persists only during the current session. Temporary table data is not visible to other sessions.
Syntax
CREATE [ scope ] TEMP[ORARY] TABLE [ IF NOT EXISTS ] [[database.]schema.]table-name ( column‑definition[,…] ) [ table-constraint ] [ ON COMMIT { DELETE | PRESERVE } ROWS ] [ NO PROJECTION ] [ ORDER BY table-column[,…] ] [ segmentation‑spec ] [ KSAFE [k‑num] ] [ {INCLUDE | EXCLUDE} [SCHEMA] PRIVILEGES ]
CREATE TEMP[ORARY] TABLE [ IF NOT EXISTS ] [[database.]schema.]table-name [ ( column-name-list ) ] [ ON COMMIT { DELETE | PRESERVE } ROWS ] AS [ /*+ hint[, hint] */ ] [ AT epoch ] query [ ENCODED BY column‑ref‑list ]
Parameters
scope |
Specifies visibility of the table definition:
If no scope is specified, Vertica uses the default that is set by configuration parameter DefaultTempTableLocal. Regardless of this setting, retention of temporary table data is set by the keywords For more information, see Creating Temporary Tables. |
IF NOT EXISTS
|
Specifies to generate an informational message if an object already exists under the specified name. If you omit this option and the object exists, Vertica generates a The For related information, see |
[database.]schema
|
Specifies a schema, by default myschema.thisDbObject If you specify a database, it must be the current database. If you do not specify a schema, the table is created in the default schema. |
table-name
|
Identifies the table to create, where table-name conforms to conventions described in Identifiers. It must also be unique among all names of sequences, tables, projections, views, and models within the same schema. |
column-definition
|
Defines a table column. A table can have up to 1600 columns. |
table‑constraint
|
Adds a constraint to table metadata. |
ON COMMIT
|
Specifies whether data is transaction- or session-scoped: ON COMMIT {PRESERVE | DELETE} ROWS
|
NO PROJECTION
|
Prevents Vertica from creating auto-projections for this table. A superprojection is created only when data is explicitly loaded into this table.
|
{INCLUDE | EXCLUDE} [SCHEMA] PRIVILEGES
|
Specifies default inheritance of schema privileges for this table:
For details, see Inherited Privileges in the Administrator's Guide. |
ORDER BY table‑column[,…]
|
Invalid for external tables, specifies columns from the If you omit the |
segmentation‑spec |
Invalid for external tables, specifies how to distribute data for auto-projections of this table. Supply one of the following clauses:
If this clause is omitted, Vertica generates auto-projections with default hash segmentation. |
KSAFE [k‑num]
|
Invalid for external tables, specifies K-safety of auto-projections created for this table, where k‑num must be equal to or greater than system K‑safety. If you omit this option, the projection uses the system K-safety level. For general information, see K-Safety in an Enterprise Mode Database in Vertica Concepts. Eon Mode: K‑safety of temporary tables is always set to 0, regardless of system K‑safety. If a |
column‑name‑list
|
Valid only when creating a table from a query ( For example: CREATE TABLE customer_occupations (name, profession) AS SELECT customer_name, occupation FROM customer_dimension; This clause and the |
AS query
|
Creates and loads a table from the results of a query, specified as follows: You cannot use SELECT AS to query tables containing complex types, even if you do not select the columns with those types. Complex types are supported only in external tables. See Complex Types. For details, see Creating a Table from a Query in the Administrator's Guide. |
ENCODED BY column‑ref‑list |
A comma-delimited list of columns from the source table, where each column is qualified by one or both of the following encoding options:
This option and column-name-list are mutually exclusive. This option is invalid for external tables |
Privileges
The following privileges are required:
CREATE
privileges on the table schema-
If creating a temporary table that includes a named sequence:
SELECT
privilege on sequence objectUSAGE
privilege on sequence schema
Restrictions
- Queries on temporary tables are subject to the same restrictions on SQL support as persistent tables.
- You cannot add projections to non-empty, global temporary tables (
ON COMMIT PRESERVE ROWS
). Make sure that projections exist before you load data. See Auto-Projections in the Administrator's Guide. - While you can add projections for temporary tables that are defined with
ON COMMIT DELETE ROWS
specified, be aware that you might lose all data. - Mergeout operations cannot be used on session-scoped temporary data.
- In general, session-scoped temporary table data is not visible using system (virtual) tables.
- Temporary tables do not recover. If a node fails, queries that use the temporary table also fail. Restart the session and populate the temporary table.