INSERT statement
Use the INSERT
statement to create records in a database table. You can specify either:
-
A list of values to be inserted as a new record
-
A
SELECT
statement that copies data from another table to be inserted as a set of new records
The format of the INSERT
statement is:
INSERT INTO table_name [(column_name, ...)] VALUES (expr, ...)
column_name
is an optional list of column names that provides the name and order of the columns whose values are specified in the VALUES
clause. If you omit column_name
, the value expressions (expr
) must provide values for all columns defined in the table and must be in the same order that the columns are defined for the table. column_name
may also specify a field repetition, for example lastDates[4]
.
expr
is the list of expressions giving the values for the columns of the new record. Usually the expressions are constant values for the columns (but they can also be a subquery). You must enclose character string values in pairs of single quotation marks ('). To include a single quotation mark in a character string value enclosed by single quotation marks, use two single quotation marks together (for example, 'Don''t'
).
Subqueries must be enclosed in parentheses.
Insert a list of expressions.
INSERT INTO emp (last_name, first_name, emp_id, salary, hire_date)
VALUES ('Smith', 'John', 'E22345', 27500, DATE '2028-06-05')
Each INSERT
statement adds one record to the database table. In this case a record has been added to the employee database table, emp
. Values are specified for five columns. The remaining columns in the table are assigned a blank value, meaning Null.
In container fields, you can INSERT
text only, unless you prepare a parameterized statement and stream the data from your application. To use binary data, you may simply assign the filename by enclosing it in single quotation marks or use the PutAs()
function. When specifying the filename, the file type is deduced from the file extension:
INSERT INTO table_name (container_name) VALUES(? AS 'filename.file extension')
Unsupported file types will be inserted as type FILE.
When using the PutAs()
function, specify the type: PutAs(col, 'type')
, where the type value is a supported file type as described in Retrieving the contents of a container field: CAST() function and GetAs() function.
The SELECT
statement is a query that returns values for each column_name
value specified in the column name list. Using a SELECT
statement instead of a list of value expressions lets you select a set of rows from one table and insert it into another table using a single INSERT
statement.
Insert using a SELECT
statement.
INSERT INTO emp1 (first_name, last_name, emp_id, dept, salary)
SELECT first_name, last_name, emp_id, dept, salary from emp
WHERE dept = 'D050'
In this type of INSERT
statement, the number of columns to be inserted must match the number of columns in the SELECT
statement. The list of columns to be inserted must correspond to the columns in the SELECT
statement just as it would to a list of value expressions in the other type of INSERT
statement. For example, the first column inserted corresponds to the first column selected; the second inserted to the second, and so on.
The size and data type of these corresponding columns must be compatible. Each column in the SELECT
list should have a data type that the ODBC or JDBC client driver accepts on a regular INSERT
/UPDATE
of the corresponding column in the INSERT
list. Values are truncated when the size of the value in the SELECT
list column is greater than the size of the corresponding INSERT
list column.
The SELECT
statement is evaluated before any values are inserted.