CREATE TABLE [ IF NOT EXISTS ] [[ { namespace. | database. } ]schema.]table
LIKE [[ { namespace. | database. } ]schema.]existing-table
[ { INCLUDING | EXCLUDING } PROJECTIONS ]
[ { INCLUDE | EXCLUDE } [SCHEMA] PRIVILEGES ]
Creating a table with LIKE replicates the source table definition and any storage policy associated with it. Table data and expressions on columns are not copied to the new table.
The user performing the operation owns the new table.
The source table cannot have out-of-date projections and cannot be a temporary table.
Copying constraints
CREATE TABLE LIKE copies all table constraints except for:
Foreign key constraints.
Sequence column constraints.
For any column that obtains its values from a sequence, including IDENTITY columns, Vertica copies the column values into the new table, but removes the original constraint. For example, the following table definition sets an IDENTITY constraint on the ID column:
The following CREATE TABLE LIKE statement uses the source table Premium_Customer to create the replica All_Customers. Vertica removes the IDENTITY constraint, changing the column to an integer column with a NOT NULL constraint:
You can qualify the LIKE clause with INCLUDING PROJECTIONS or EXCLUDING PROJECTIONS, which specify whether to copy projections from the source table:
EXCLUDING PROJECTIONS (default): Do not copy projections from the source table.
INCLUDING PROJECTIONS: Copy current projections from the source table. Vertica names the new projections according to Vertica naming conventions, to avoid name conflicts with existing objects.
Including schema privileges
You can specify default inheritance of schema privileges for the new table:
EXCLUDE [SCHEMA] PRIVILEGES (default) disables inheritance of privileges from the schema
INCLUDE [SCHEMA] PRIVILEGES grants the table the same privileges granted to its schema
When you use the CREATE TABLE LIKE statement, storage policy objects associated with the table are also copied. Data added to the new table use the same labeled storage location as the source table, unless you change the storage policy. For more information, see Working With Storage Locations.
You can qualify an AS clause with one or both of the following options:
LABEL hint that identifies a statement for profiling and debugging
AT epoch clause to specify that the query return historical data
Labeling the AS clause
You can embed a LABEL hint in an AS clause in two places:
Immediately after the keyword AS:
CREATE TABLE myTable AS /*+LABEL myLabel*/...
In the SELECT statement:
CREATE TABLE myTable AS SELECT /*+LABEL myLabel*/
If the AS clause contains a LABEL hint in both places, the first label has precedence.
Note
Labels are invalid for external tables.
Loading historical data
You can qualify a CREATE TABLE AS query with an AT epoch clause, to specify that the query return historical data, where epoch is one of the following:
EPOCH LATEST: Return data up to but not including the current epoch. The result set includes data from the latest committed DML transaction.
EPOCH integer: Return data up to and including the integer-specified epoch.
TIME 'timestamp': Return data from the timestamp-specified epoch.
Note
These options are ignored if used to query temporary or external tables.
See Epochs for additional information about how Vertica uses epochs.
If the query returns a column with zero width, Vertica automatically converts it to a VARCHAR(80) column. For example:
=> CREATE TABLE example AS SELECT '' AS X;
CREATE TABLE
=> SELECT EXPORT_TABLES ('', 'example');
EXPORT_TABLES
----------------------------------------------------------
CREATE TEMPORARY TABLE public.example
(
X varchar(80)
);
Requirements and restrictions
If you create a temporary table from a query, you must specify ON COMMIT PRESERVE ROWS in order to load the result set into the table. Otherwise, Vertica creates an empty table.
If the query output has expressions other than simple columns, such as constants or functions, you must specify an alias for that expression, or list all columns in the column name list.
You cannot use CREATE TABLE AS SELECT with a SELECT that returns values of complex types. You can, however, use CREATE TABLE LIKE.