SELECT INTO

Function

  • SELECT INTO new_table defines a new table based on a query result and inserts data obtained by query to the new table. Different from SELECT, data found by SELECT INTO is not returned to the client. The table columns have the same names and data types as the output columns of the SELECT.

  • SELECT INTO var_list assigns the query result to the target variable. var_list can be a user-defined variable, a parameter of a stored procedure or function, or a local variable of a stored program.

​ Note: If var_list is a parameter of a stored procedure, function, or local variable of a stored program, see the syntax in Stored Procedures. The following describes the scenarios where variables are defined by users.

Precautions

  • CREATE TABLE AS provides functions similar to SELECT INTO new_table in functions and provides a superset of functions provided by SELECT INTO new_table. You are advised to use CREATE TABLE AS, because SELECT INTO new_table cannot be used in a stored procedure.

  • In SELECT INTO var_list, only one row of the select query result can be returned. If there are multiple rows, use limit 1 to restrict the number of rows. Otherwise, an error is reported. The number of returned columns must be the same as the number of variables. Otherwise, an error is reported.

Syntax

  • SELECT INTO new_table syntax
[ WITH [ RECURSIVE ] with_query [, ...] ]
SELECT [ ALL | DISTINCT [ ON ( expression [, ...] ) ] ]
    { * | {expression [ [ AS ] output_name ]} [, ...] }
    INTO [ [ GLOBAL | LOCAL ] [ TEMPORARY | TEMP ] | UNLOGGED ] [ TABLE ] new_table
    [ FROM from_item [, ...] ]
    [ WHERE condition ]
    [ GROUP BY grouping_element [, ...] ]
    [ HAVING condition [, ...] ]
    [ WINDOW {window_name AS ( window_definition )} [, ...] ]
    [ { UNION | INTERSECT | EXCEPT | MINUS } [ ALL | DISTINCT ] select ]
    [ ORDER BY {expression [ [ ASC | DESC | USING operator ] | nlssort_expression_clause ] [ NULLS { FIRST | LAST } ]} [, ...] ]
    [ LIMIT { count | ALL } ]
    [ OFFSET start [ ROW | ROWS ] ]
    [ FETCH { FIRST | NEXT } [ count ] { ROW | ROWS } ONLY ]
    [ {FOR { UPDATE | SHARE } [ OF table_name [, ...] ] [ NOWAIT | WAIT N]} [...] ];
  • SELECT INTO var_list syntax
[ WITH [ RECURSIVE ] with_query [, ...] ]
SELECT [/*+ plan_hint */] [ ALL | DISTINCT [ ON ( expression [, ...] ) ] ]
    { * | {expression [ [ AS ] output_name ]} [, ...] }
    [into_option]
    [ FROM from_item [, ...] ]
    [ WHERE condition ]
    [ [ START WITH condition ] CONNECT BY [NOCYCLE] condition [ ORDER SIBLINGS BY expression ] ]
    [ GROUP BY grouping_element [, ...] ]
    [ HAVING condition [, ...] ]
    [ WINDOW {window_name AS ( window_definition )} [, ...] ]
    [ { UNION | INTERSECT | EXCEPT | MINUS } [ ALL | DISTINCT ] select ]
    [ ORDER BY {expression [ [ ASC | DESC | USING operator ] | nlssort_expression_clause ] [ NULLS { FIRST | LAST } ]} [, ...] ]
    [ LIMIT { [offset,] count | ALL } ]
    [ OFFSET start [ ROW | ROWS ] ]
    [ FETCH { FIRST | NEXT } [ count ] { ROW | ROWS } ONLY ]
    [into_option]
    [ {FOR { UPDATE | NO KEY UPDATE | SHARE | KEY SHARE } [ OF table_name [, ...] ] [ NOWAIT | WAIT N ]} [...] ];
    [into_option]

Parameter Description

  • new_table

    new_table specifies the name of the new table.

  • 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, they are not crash-safe: an unlogged table is automatically truncated after a crash or unclean shutdown. 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 re-create 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, openGauss creates a global temporary table. Otherwise, openGauss 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 of a session are isolated from those of another session. Each session can only view and modify the data submitted by itself. Global temporary tables have two schemas. In session-based ON COMMIT PRESERVE ROWS schema, user data is automatically cleared when a session ends. In transaction-based ON COMMIT PRESERVE ROWS schema, user data is automatically cleared when the commit or rollback operation is performed. If the ON COMMIT option is not specified during table creation, the session-based schema 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.

    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 not advised to perform operations on temporary tables in DDL statements. TEMP is equivalent to TEMPORARY.

    NOTICE:

    • Local temporary tables are visible to the current session through the schema starting with pg_temp. Users should not delete schemas starting with pg_temp or pg_toast_temp.
    • If TEMPORARY or TEMP is not specified when you create a table but 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 and indexes are being used by other sessions, do not perform ALTER or DROP.
    • 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.
  • into_option

    • The INTO statement can appear in three positions. A SELECT statement can contain only one INTO clause.
    • User-defined variables can be correctly identified only when the database is a B-compatible database and the GUC parameter enable_set_variable_b_format is set to on. into_option: { INTO var_name [, var_name] … }

NOTE: For details about other SELECT INTO parameters, see Parameter Description in SELECT.

For details about the var_name parameter, see the description of var_name.

Examples

--Add the values that are less than 5 in the r_reason_sk field in the tpcds.reason table to the new table.
openGauss=# SELECT * INTO tpcds.reason_t1 FROM tpcds.reason WHERE r_reason_sk < 5;
INSERT 0 6

--Delete the tpcds.reason_t1 table.
openGauss=# DROP TABLE tpcds.reason_t1;

--Three positions of SELECT INTO varlist
openGauss=# SELECT * INTO @my_var FROM t;
SELECT INTO
openGauss=# SELECT * FROM t INTO @my_var FOR UPDATE;
SELECT INTO
openGauss=# SELECT * FROM t FOR UPDATE INTO @my_var;
SELECT INTO

--Error scenario:
openGauss=# select * from t into @aa;
ERROR:  select result consisted of more than one row
openGauss=# select * from t limit 1 into @aa,@bb;
ERROR:  number of variables must equal the number of columns

Helpful Links

SELECT

Suggestions

  • DATABASE

    You are not advised to re-index a database in a transaction.

  • SYSTEM

    You are not advised to re-index system catalogs in transactions.

Feedback
编组 3备份
    openGauss 2024-05-07 00:46:52
    cancel