INSERT
Function
INSERT inserts new rows into a table.
Precautions
You must have the INSERT permission on a table in order to insert rows into it.
Use of the RETURNING clause requires the SELECT permission on all columns mentioned in RETURNING.
If ON DUPLICATE KEY UPDATE is used, you must have the SELECT and UPDATE permissions on the table and the SELECT permission on the unique constraint (primary key or unique index).
If you use the query clause to insert rows from a query, you need to have the SELECT permission on any table or column used in the query.
When you connect to a database compatible to Teradata and td_compatible_truncation is on, a long string will be automatically truncated. If later INSERT statements (not involving foreign tables) insert long strings to columns of char- and varchar-typed columns in the target table, the system will truncate the long strings to ensure no strings exceed the maximum length defined in the target table.
NOTE: If inserting multi-byte character data (such as Chinese characters) to database with the character set byte encoding (SQL_ASCII, LATIN1), and the character data crosses the truncation position, the string is truncated based on its bytes instead of characters. Unexpected result will occur in tail after the truncation. If you want correct truncation result, you are advised to adopt encoding set such as UTF8, which has no character data crossing the truncation position.
Syntax
[ WITH [ RECURSIVE ] with_query [, ...] ]
INSERT INTO table_name [ ( column_name [, ...] ) ]
{ DEFAULT VALUES
| VALUES {( { expression | DEFAULT } [, ...] ) }[, ...]
| query }
[ ON DUPLICATE KEY UPDATE {{ column_name = { expression | DEFAULT } } [, ...] | NOTHING }]
[ RETURNING {* | {output_expression [ [ AS ] output_name ] }[, ...]} ];
Parameter Description
WITH [ RECURSIVE ] with_query [, …]
Specifies one or more subqueries that can be referenced by name in the main query, which is equivalent to a temporary table.
If RECURSIVE is specified, it allows a SELECT subquery to reference itself by name.
The detailed format of with_query is as follows: with_query_name [ (column_name [,…]) ] AS
( {select | values | insert | update | delete} )
-- with_query_name specifies the name of the result set generated by a subquery. Such names can be used to access the subquery
result set.
– column_name specifies the column name displayed in the subquery result set.
– Each subquery can be a SELECT, VALUES, INSERT, UPDATE or DELETE statement.
NOTE: The INSERT ON DUPLICATE KEY UPDATE statement does not support the WITH and WITH RECURSIVE clauses.
table_name
Specifies the name of the target table where data will be inserted.
Value range: an existing table name
column_name
Specifies the name of a column in the target table.
- The column name can be qualified with a subfield name or array subscript, if needed.
- Each column not present in the explicit or implicit column list will be filled with a default value, either its declared default value or NULL if there is none. Inserting into only some fields of a composite column leaves the other fields null.
- The target column names column_name can be listed in any order. If no list of column names is given at all, the default is all the columns of the table in their declared order.
- The target columns are the first N column names, if there are only N columns supplied by the value clause or query.
- The values provided by the value clause and query are associated with the corresponding columns from left to right in the table.
Value range: an existing column
expression
Specifies an expression or a value to assign to the corresponding column.
In the INSERT ON DUPLICATE KEY UPDATE statement, expression can be VALUES(column_name) or EXCLUDED.column_name, indicating the value of the column_name field of the referenced conflicting rows. VALUES(column_name) cannot be nested in an expression (for example, VALUES(column_name)+1), but EXCLUDED is not limited by this restriction.
If single-quotation marks are inserted in a column, the single-quotation marks need to be used for escape.
If the expression for any column is not of the correct data type, automatic type conversion will be attempted. If the attempt fails, data insertion fails, and the system returns an error message.
DEFAULT
Specifies the default value of a field. The value is NULL if no specified default value has been assigned to it.
query
Specifies a query statement (SELECT statement) that uses the query result as the inserted data.
RETURNING
Returns the inserted rows. The syntax of the RETURNING list is identical to that of the output list of SELECT. The INSERT ON DUPLICATE KEY UPDATE statement does not support the RETURNING clause.
output_expression
Specifies an expression used to calculate the output result of the INSERT statement after each row is inserted.
Value range: The expression can use any field in the table. You can use the asterisk (*) to return all fields of the inserted row.
output_name
Specifies a name to use for a returned column.
Value range: a string. It must comply with the naming convention rule.
ON DUPLICATE KEY UPDATE
For a table with a unique constraint (UNIQUE INDEX or PRIMARY KEY), if the inserted data violates the unique constraint, the UPDATE clause is executed on the conflicting row to complete the update.
Triggers are not supported.
Deferrable unique constraints or primary keys are not supported.
For a table with multiple unique constraints, if the inserted data violates multiple unique constraints, the UPDATE clause is executed to update only the first conflicting row. (The check sequence is closely related to index maintenance. Generally, the conflict check is preferentially performed on the index that is created first.)
Column-store tables and unique index columns cannot be updated.
Column-store tables is not supported.
Examples
-- Create the tpcds.reason_t2 table.
postgres=# CREATE TABLE tpcds.reason_t2
(
r_reason_sk integer,
r_reason_id character(16),
r_reason_desc character(100)
);
-- Insert a record into a table.
postgres=# INSERT INTO tpcds.reason_t2(r_reason_sk, r_reason_id, r_reason_desc) VALUES (1, 'AAAAAAAABAAAAAAA', 'reason1');
-- Insert a record into the table, which is equivalent to the previous syntax.
postgres=# INSERT INTO tpcds.reason_t2 VALUES (2, 'AAAAAAAABAAAAAAA', 'reason2');
-- Insert multiple records into the table.
postgres=# INSERT INTO tpcds.reason_t2 VALUES (3, 'AAAAAAAACAAAAAAA','reason3'),(4, 'AAAAAAAADAAAAAAA', 'reason4'),(5, 'AAAAAAAAEAAAAAAA','reason5');
-- Insert records whose r_reason_sk in the tpcds.tpcds.reason table is less than 5.
postgres=# INSERT INTO tpcds.reason_t2 SELECT * FROM tpcds.reason WHERE r_reason_sk <5;
-- Create a unique index for the table.
postgres=# CREATE UNIQUE INDEX reason_t2_u_index ON tpcds.reason_t2(r_reason_sk);
-- Insert multiple records into the table. If the records conflict, update the r_reason_id field in the conflicting row to 'BBBBBBBBCAAAAAAA'.
postgres=# INSERT INTO tpcds.reason_t2 VALUES (5, 'BBBBBBBBCAAAAAAA','reason5'),(6, 'AAAAAAAADAAAAAAA', 'reason6') ON DUPLICATE KEY UPDATE r_reason_id = 'BBBBBBBBCAAAAAAA';
-- Delete the tpcds.reason_t2.
postgres=# DROP TABLE tpcds.reason_t2;
Suggestions
VALUES
When you run the INSERT statement to insert data in batches, you are advised to combine multiple records into one statement to improve data loading performance. Example: INSERT INTO sections VALUES (30, 'Administration', 31, 1900),(40, 'Development', 35, 2000), (50, 'Development' , 60 , 2001);