The INSERT statement inserts rows into a table or view. Inserting a row into a view also inserts the row into the table on which the view is based.
Invocation
This statement can be embedded in an application program or issued through the use of dynamic SQL statements. It is an executable statement that can be dynamically prepared.
Authorization
To execute this statement, the privileges held by the authorization ID of the statement must include at least one of the following:
In addition, for each table or view referenced in any fullselect used in the INSERT statement, the privileges held by the authorization ID of the statement must include at least one of the following:
GROUP privileges are not checked for static INSERT statements.
Syntax
>>-INSERT INTO----+-table-name-+-------------------------------->
'-view-name--'
>-----+----------------------------+---------------------------->
| .-,--------------. |
| V | |
'-(-----column-name---+---)--'
.-,------------------------------------.
V |
>-----+-VALUES------+-+-expression-+----------------+--+--------+-><
| | +-NULL-------+ | |
| | '-DEFAULT----' | |
| | .-,-----------------. | |
| | V | | |
| '-(------+-expression-+--+---)--' |
| +-NULL-------+ |
| '-DEFAULT----' |
'-+---------------------------------------+---fullselect--'
| .-,--------------------------. |
| V | |
'-WITH-----common-table-expression---+--'
| Note: | See Chapter 5. Queries for the syntax of common-table-expression and fullselect. |
Description
A value cannot be inserted into a view column that is derived from:
If the object of the insert operation is a view with such columns, a list of column names must be specified, and the list must not identify these columns.
Omission of the column list is an implicit specification of a list in which every column of the table or view is identified in left-to-right order. This list is established when the statement is prepared and therefore does not include columns that were added to a table after the statement was prepared.
The implicit column list is established at prepare time. Hence an INSERT statement embedded in an application program does not use any columns that might have been added to the table or view after prepare time.
Each host variable named must be described in the program in accordance with the rules for declaring host variables.
The number of values for each row must equal the number of names in the column list. The first value is inserted in the first column in the list, the second value in the second column, and so on.
When the base object of the INSERT and the base object of the fullselect or any subquery of the fullselect, are the same table, the fullselect is completely evaluated before any rows are inserted.
The number of columns in the result table must equal the number of names in the column list. The value of the first column of the result is inserted in the first column in the list, the second value in the second column, and so on.
Notes
This has the potential to dramatically improve INSERT performance, but is best used with clean data, due to the asynchronous nature of the error handling. See buffered insert in the Embedded SQL Programming Guide for further details.
Examples
Example 1: Insert a new department with the following specifications into the DEPARTMENT table:
INSERT INTO DEPARTMENT
VALUES ('E31', 'ARCHITECTURE', '00390', 'E01')
Example 2: Insert a new department into the DEPARTMENT table as in example 1, but do not assign a manager to the new department.
INSERT INTO DEPARTMENT (DEPTNO, DEPTNAME, ADMRDEPT )
VALUES ('E31', 'ARCHITECTURE', 'E01')
Example 3: Insert two new departments using one statement into the DEPARTMENT table as in example 2, but do not assign a manager to the new department.
INSERT INTO DEPARTMENT (DEPTNO, DEPTNAME, ADMRDEPT)
VALUES ('B11', 'PURCHASING', 'B01'), ('E41', 'DATABASE ADMINISTRATION', 'E01')
Example 4: Create a temporary table MA_EMP_ACT with the same columns as the EMP_ACT table. Load MA_EMP_ACT with the rows from the EMP_ACT table with a project number (PROJNO) starting with the letters 'MA'.
CREATE TABLEMA_EMP_ACT
( EMPNO CHAR(6) NOT NULL,
PROJNO CHAR(6) NOT NULL,
ACTNO SMALLINT NOT NULL,
EMPTIME DEC(5,2),
EMSTDATE DATE,
EMENDATE DATE )
INSERT INTOMA_EMP_ACT
SELECT * FROM EMP_ACT
WHERE SUBSTR(PROJNO, 1, 2) = 'MA'
Example 5: Use a C program statement to add a skeleton project to the PROJECT table. Obtain the project number (PROJNO), project name (PROJNAME), department number (DEPTNO), and responsible employee (RESPEMP) from host variables. Use the current date as the project start date (PRSTDATE). Assign a NULL value to the remaining columns in the table.
EXEC SQL INSERT INTO PROJECT (PROJNO, PROJNAME, DEPTNO, RESPEMP, PRSTDATE )
VALUES (:PRJNO, :PRJNM, :DPTNO, :REMP, CURRENT DATE);