Replicating a Table

You can create a table from an existing one using CREATE TABLE with the LIKE clause:

CREATE TABLE [schema.]table-name LIKE [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. It does not copy table data or expressions on columns.

Copying Constraints

CREATE TABLE…LIKE copies all table constraints, with the following exceptions:

  • Foreign key constraints.
  • Any column that obtains its values from a sequence, including IDENTITY and AUTO_INCREMENT 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 column ID:
    CREATE TABLE public.Premium_Customer
    (
        ID IDENTITY ,
        lname varchar(25),
        fname varchar(25),
        store_membership_card int
    );
    

    The following CREATE TABLE…LIKE statement replicates this table as All_Customers. Vertica removes the IDENTITY constraint from All_Customers.ID, changing it to an integer column with a NOT NULL constraint:

    => CREATE TABLE All_Customers like Premium_Customer;
    CREATE TABLE
    => select export_tables('','All_Customers');
                       export_tables                                                               
    ---------------------------------------------------
    CREATE TABLE public.All_Customers
    (
        ID int NOT NULL,
        lname varchar(25),
        fname varchar(25),
        store_membership_card int
    );
    
    (1 row)
    

Including Projections

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

For more information see Setting Privilege Inheritance on Tables and Views.

Restrictions

The following restrictions apply to the source table:

  • It cannot have out-of-date projections.
  • It cannot be a temporary table.

Example

  1. Create the table states:
    => CREATE TABLE states (
         state char(2) NOT NULL, bird varchar(20), tree varchar (20), tax float, stateDate char (20)) 
         PARTITION BY state;
  2. Populate the table with data:
    INSERT INTO states VALUES ('MA', 'chickadee', 'american_elm', 5.675, '07-04-1620');
    INSERT INTO states VALUES ('VT', 'Hermit_Thrasher', 'Sugar_Maple', 6.0, '07-04-1610');
    INSERT INTO states VALUES ('NH', 'Purple_Finch', 'White_Birch', 0, '07-04-1615');
    INSERT INTO states VALUES ('ME', 'Black_Cap_Chickadee', 'Pine_Tree', 5, '07-04-1615');
    INSERT INTO states VALUES ('CT', 'American_Robin', 'White_Oak', 6.35, '07-04-1618');
    INSERT INTO states VALUES ('RI', 'Rhode_Island_Red', 'Red_Maple', 5, '07-04-1619');
  3. View the table contents:
    => SELECT * FROM states;
    
    
     state |        bird         |     tree     |  tax  |      stateDate
    -------+---------------------+--------------+-------+----------------------
     VT    | Hermit_Thrasher     | Sugar_Maple  |     6 | 07-04-1610
     CT    | American_Robin      | White_Oak    |  6.35 | 07-04-1618
     RI    | Rhode_Island_Red    | Red_Maple    |     5 | 07-04-1619
     MA    | chickadee           | american_elm | 5.675 | 07-04-1620
     NH    | Purple_Finch        | White_Birch  |     0 | 07-04-1615
     ME    | Black_Cap_Chickadee | Pine_Tree    |     5 | 07-04-1615
    (6 rows
  4. Create a sample projection and refresh:

    => CREATE PROJECTION states_p AS SELECT state FROM states;
    
    => SELECT START_REFRESH();
    
  5. Create a table like the states table and include its projections:

    => CREATE TABLE newstates LIKE states INCLUDING PROJECTIONS;
  6. View projections for the two tables. Vertica has copied projections from states to newstates:
    => \dj
                                                          List of projections
                Schema             |                   Name                    |  Owner  |       Node       | Comment
    -------------------------------+-------------------------------------------+---------+------------------+---------
     public                        | newstates_b0                              | dbadmin |                  |
     public                        | newstates_b1                              | dbadmin |                  |
     public                        | newstates_p_b0                            | dbadmin |                  |
     public                        | newstates_p_b1                            | dbadmin |                  |
     public                        | states_b0                                 | dbadmin |                  |
     public                        | states_b1                                 | dbadmin |                  |
     public                        | states_p_b0                               | dbadmin |                  |
     public                        | states_p_b1                               | dbadmin |                  |        
  7. View the table newstates, which shows columns copied from states:
    => SELECT * FROM newstates;
    
    
     state | bird | tree | tax | stateDate
    -------+------+------+-----+-----------
    (0 rows)
    

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.