SELECT INTO
Description
Defines a new table based on a query result and inserts data obtained by query to the new table. Different from common SELECT, SELECT INTO does not return data to the client. The columns of the new table have the same names and data types as the output columns of SELECT.
Precautions
CREATE TABLE AS provides functions similar to SELECT INTO in functions and provides a superset of functions provided by SELECT INTO. You are advised to use CREATE TABLE AS, because SELECT INTO cannot be used in a stored procedure.
Syntax
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 |
[ WITH [ RECURSIVE ] with_query [, ...] ] SELECT [ ALL | DISTINCT [ ON ( expression [, ...] ) ] ] { * | {expression [ [ AS ] output_name ]} [, ...] } INTO [ UNLOGGED ] [ TABLE ] new_table [ FROM from_item [, ...] ] [ WHERE condition ] [ GROUP BY expression [, ...] ] [ 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]} [...] ]; |
Parameters
- 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, 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.
For details about other SELECT INTO parameters, see Parameters in "SELECT."
Examples
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 |
-- Create a table and insert data into the table. gaussdb=# CREATE TABLE tbl_person ( id integer, name varchar(20), sex varchar(5) CHECK(sex ='Male' or sex = 'Female') ); gaussdb=# INSERT INTO tbl_person VALUES (1, 'Bob', 'Male'),(2, 'Anne', 'Female'),(3, 'Jack', 'Male'),(4, 'Danny', 'Male'),(5, 'Alice', 'Female'),(6, 'Susan', 'Female'); -- Add information about all persons whose sex is male in the person table to the new table. gaussdb=# SELECT * INTO tbl_man FROM tbl_person WHERE sex = 'Male'; -- Query data in the tbl_man table. gaussdb=# SELECT * FROM tbl_man; id | name | sex ----+-------+----- 1 | Bob | Male 3 | Jack | Male 4 | Danny | Male (3 rows) -- Delete the table. gaussdb=# DROP TABLE tbl_person, tbl_man; |
Helpful Links
Feedback
Was this page helpful?
Provide feedbackThank you very much for your feedback. We will continue working to improve the documentation.See the reply and handling status in My Cloud VOC.
For any further questions, feel free to contact us through the chatbot.
Chatbot