Updated on 2024-08-20 GMT+08:00

CREATE TABLE AS

Description

Creates a table from the results of a query.

It creates a table and fills it with data obtained using SELECT. The table columns have the names and data types associated with the output columns of SELECT (except that you can override the SELECT output column names by giving an explicit list of new column names).

CREATE TABLE AS queries a source table once and writes the data in a new table. This table will not change according to the source table. In contrast, the view re-computes and defines its SELECT statement at each query.

Precautions

  • This statement cannot be used to create a partitioned table.
  • If an error occurs during table creation, after it is fixed, the system may fail to delete the disk files that are created before the last automatic clearance and whose size is not 0. This problem seldom occurs and does not affect system running of the database.
  • If you add a row-level expression when adding or changing an ILM policy for a data object, note that the row-level expression supports only the functions listed in the whitelist. For details about the whitelist function list, see Row Expression Function Whitelist.

Syntax

CREATE [ [ GLOBAL | LOCAL ] [ TEMPORARY | TEMP ] | UNLOGGED ] TABLE [ IF NOT EXISTS ] table_name
    [ (column_name [, ...] ) ]
    [ { ENGINE [ = ] { InnoDB | 'InnoDB' | "InnoDB" } } [ [ , ] ... ] ]
    [ WITH ( {storage_parameter = value} [, ... ] ) ]
    [ ON COMMIT { PRESERVE ROWS | DELETE ROWS } ]
    [ ILM ADD POLICY ROW STORE { COMPRESS ADVANCED } { ROW } AFTER n { day | month | year } OF { NO MODIFICATION } [ ON ( EXPR )]]
    [ TABLESPACE tablespace_name ]
    AS query
    [ WITH [ NO ] DATA ];

Parameters

  • UNLOGGED

    Specifies that the table is created as an unlogged table. Data written to unlogged tables is not written to the WALs, which makes them considerably faster than ordinary tables. However, an unlogged table is automatically truncated after a crash or unclean shutdown. The contents of an unlogged table are also not replicated to standby servers. Any indexes created on an unlogged table are automatically unlogged as well.

    • Usage scenario: Unlogged tables do not ensure data security. Users can back up data before using unlogged tables; for example, users should back up the data before a system upgrade.
    • Troubleshooting: If data is missing in the indexes of unlogged tables due to some unexpected operations such as an unclean shutdown, users should rebuild the indexes with errors.
  • GLOBAL | LOCAL

    When creating a temporary table, you can specify the GLOBAL or LOCAL keyword before TEMP or TEMPORARY. If the keyword GLOBAL is specified, GaussDB creates a global temporary table. Otherwise, GaussDB creates a local temporary table.

  • TEMPORARY | TEMP

    If TEMP or TEMPORARY is specified, the created table is a temporary table. Temporary tables are classified into global temporary tables and local temporary tables. If the keyword GLOBAL is specified when a temporary table is created, the table is a global temporary table. Otherwise, the table is a local temporary table.

    The metadata of the global temporary table is visible to all sessions. After the sessions end, the metadata still exists. The user data, indexes, and statistics between sessions are isolated. Each session can only view and modify the data committed by itself. Global temporary tables can be created using ON COMMIT PRESERVE ROWS or ON COMMIT DELETE ROWS. The former one creates a session-level table, where user data is automatically cleared when a session ends; the latter creates a transaction-level table, where user data is automatically cleared when a COMMIT or ROLLBACK operation is performed. If the ON COMMIT option is not specified during table creation, the session level is used by default. Different from local temporary tables, you can specify a schema that does not start with pg_temp when creating a global temporary table.

    A local temporary table is automatically dropped at the end of the current session. Therefore, you can create and use temporary tables in the current session as long as the connected database node in the session is normal. Temporary tables are created only in the current session. If a DDL statement involves operations on temporary tables, a DDL error will be generated. Therefore, you are advised not to perform operations on temporary tables in DDL statements. TEMP is equivalent to TEMPORARY.

    • Local temporary tables are visible to the current session through the schema starting with pg_temp. Users should not delete schema started with pg_temp or pg_toast_temp.
    • If TEMPORARY or TEMP is not specified when you create a table and its schema is set to that starting with pg_temp in the current session, the table will be created as a temporary table.
    • If global temporary tables or indexes are being used by other sessions, do not perform ALTER or DROP on the tables or indexes.
    • The DDL of a global temporary table affects only the user data and indexes of the current session. For example, TRUNCATE, REINDEX, and ANALYZE are valid only for the current session.
  • IF NOT EXISTS

    When IF NOT EXISTS is specified, the system checks whether a relationship with the same name already exists in the current schema before creating a table. It is not created and a NOTICE is returned if a relationship with the same name already exists. When IF NOT EXISTS is not specified and a relationship with the same name exists in the schema, an ERROR is returned.

  • table_name

    Specifies the name of the table to be created.

    Value range: a string. It must comply with the naming convention.

  • column_name

    Optional. Specifies the name of a column to be created in the new table. If no column name is specified, the columns in the new table are the same as those entered in the SELECT statement.

    Value range: a string. It must comply with the naming convention.

  • ENGINE

    Supported in B-compatible mode and used only for syntax adaptation. Only InnoDB can be set and no actual effect is achieved.

  • WITH ( storage_parameter [= value] [, ... ] )

    Specifies an optional storage parameter for a table or an index. See details of parameters below.

    • FILLFACTOR

      The fill factor of a table is a percentage from 10 to 100. If the Ustore is used, the default value is 92. If the Astore is used, the default value is 100 (completely filled). When a smaller fill factor is specified, INSERT operations fill table pages only to the indicated percentage. The remaining space on each page is reserved for updating rows on that page. This gives UPDATE a chance to place the updated copy of a row on the same page, which is more efficient than placing it on a different page. For a table whose entries are never updated, setting the fill factor to 100 (complete filling) is the best choice, but in heavily updated tables a smaller fill factor would be appropriate. The parameter is only valid for row–store tables.

      Value range: 10–100

    • ORIENTATION

      Value range:

      ROW (default value): The data will be stored in rows.

    • COMPRESSION

      Specifies the compression level of table data. It determines the compression ratio and time. Generally, the higher the level of compression, the higher the ratio, the longer the time; and the lower the level of compression, the lower the ratio, the shorter the time. The actual compression ratio depends on the distribution mode of table data loaded.

      Value range:

      Row-store tables do not support compression.

  • ON COMMIT { PRESERVE ROWS | DELETE ROWS }

    ON COMMIT determines what to do when you commit a temporary table creation operation. Currently, only PRESERVE ROWS and DELETE ROWS are supported.

    • PRESERVE ROWS (default): No special action is taken at the ends of transactions. The temporary table and its table data are unchanged.
    • DELETE ROWS: All rows in the temporary table will be deleted at the end of each transaction block.
  • [ ILM ADD POLICY ROW STORE { COMPRESS ADVANCED } { ROW } AFTER n { day | month | year } OF { NO MODIFICATION } [ ON ( EXPR )]]

    When creating a table, you can call ILM ADD POLICY ROW STORE COMPRESS ADVANCED ROW to add an advanced compression policy for row store.

    • AFTER n { day | month | year } OF NO MODIFICATION: indicates the rows that are not modified in n days, months, or years.
    • ON (EXPR): indicates the row-level expression, which is used to determine whether a row is hot or cold.
  • TABLESPACE tablespace_name

    Specifies that the new table will be created in the tablespace_name tablespace. If not specified, the default tablespace is used.

  • AS query

    Specifies a SELECT or VALUES command, or an EXECUTE command that runs a prepared SELECT or VALUES query.

  • [ WITH [ NO ] DATA ]

    Specifies whether the data produced by the query should be copied to the new table. By default, the data will be copied. If the value NO is used, only the table structure will be copied.

Examples

  • If no column name is specified, the columns in the new table are the same as those queried in the SELECT statement.
    -- Create the test1 table and insert two records into the table.
    gaussdb=# CREATE TABLE test1(col1 int PRIMARY KEY,col2 varchar(10));
    gaussdb=# INSERT INTO test1 VALUES (1,'col1'),(101,'col101');
    -- Query the data whose col1 is less than 100 in the table.
    gaussdb=# SELECT * FROM test1 WHERE col1 < 100;
     col1 | col2 
    ------+------
        1 | col1
    (1 row)
    
    -- Create the test2 table and insert the queried data into the table.
    gaussdb=# CREATE TABLE test2 AS SELECT * FROM test1 WHERE col1 < 100;
    
    -- Query the structure of the test2 table.
    gaussdb=# \d test2;
     Column |         Type          | Modifiers 
    --------+-----------------------+-----------
     col1   | integer               | 
     col2   | character varying(10) |
  • Specify column names for the new table.
    -- Use test1 to copy a new table test3 and specify column names.
    gaussdb=# CREATE TABLE test3(c1,c2) AS SELECT * FROM test1;
    
    -- Query the structure of the test3 table.
    gaussdb=# \d test3
                Table "public.test3"
     Column |         Type          | Modifiers 
    --------+-----------------------+-----------
     c1     | integer               | 
     c2     | character varying(10) | 
    
    -- Delete.
    gaussdb=# DROP TABLE test1,test2,test3;
  • Specify a compression policy for the new table.
    gaussdb=# CREATE TABLE old_table (a int);
    
    -- Enable the ILM feature of the database.
    gaussdb=# ALTER DATABASE SET ILM = on;
    
    gaussdb=# CREATE TABLE ilm_table 
        ILM ADD POLICY ROW STORE COMPRESS ADVANCED 
        ROW AFTER 3 MONTHS OF NO MODIFICATION 
        AS (SELECT * FROM old_table);
    
    -- Delete.
    gaussdb=# DROP TABLE old_table,ilm_table;

Helpful Links

CREATE TABLE and SELECT