INSERT

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 if no INSTEAD OF INSERT trigger is defined on this view. If such a trigger is defined, the trigger will be executed instead.

There are three forms of this statement:

Invocation

This statement can be embedded in an application program or issued interactively. It is an executable statement that can be dynamically prepared with the exception of the n ROWS form, which must be a static statement embedded in an application program. The n ROWS form is not allowed in a REXX procedure.

Authorization

The privileges held by the authorization ID of the statement must include at least one of the following:

If a select-statement is specified, the privileges held by the authorization ID of the statement must also include one of the following:

For information on the system authorities corresponding to SQL privileges, see Corresponding System Authorities When Checking Privileges to a Table or View.

Syntax

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-INSERT INTO--+-table-name-+--+-----------------------+------->
                '-view-name--'  |    .-,-----------.    |
                                |    V             |    |
                                '-(----column-name-+--)-'
 
>--+-------------------------+---------------------------------->
   +-OVERRIDING SYSTEM VALUE-+
   '-OVERRIDING USER VALUE---'
 
             .-,----------------------------.
             V                              |
>--+-VALUES----+-+-expression-+-----------+-+--+------------------+-+-><
   |           | +-DEFAULT----+           |    '-isolation-clause-' |
   |           | '-NULL-------'           |                         |
   |           |    .-,--------------.    |                         |
   |           |    V                |    |                         |
   |           '-(----+-expression-+-+--)-'                         |
   |                  +-DEFAULT----+                                |
   |                  '-NULL-------'                                |
   +-insert-multiple-rows--+------------------+---------------------+
   |                       '-isolation-clause-'                     |
   '-select-statement-----------------------------------------------'
 
insert-multiple-rows:
 
|--+-integer--+--ROWS--VALUES--(--host-structure-array--)-------|
   '-variable-'
 
isolation–clause:
 
|--WITH--+-NC-+-------------------------------------------------|
         +-UR-+
         +-CS-+
         +-RS-+
         '-RR-'
 

Description

INTO table-name or view-name
Identifies the object of the insert operation. The name must identify a table or view that exists at the current server, but it must not identify a catalog table, a view of a catalog table, or a view that is not insertable. For an explanation of insertable views, see CREATE VIEW.
(column-name,...)
Specifies the columns for which insert values are provided. Each name must be a name that identifies a column of the table or view. The same column must not be identified more than once. A view column that is not updatable must not be identified. 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 those columns. For an explanation of updatable columns in views, see CREATE VIEW.

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.

If the INSERT statement is embedded in an application and the referenced table or view exists at create program time, the statement is prepared at create program time. Otherwise, the statement is prepared at the first successful execute of the INSERT statement.

OVERRIDING SYSTEM VALUE or OVERRIDING USER VALUE
Specifies whether system generated values or user-specified values for a ROWID or identity column are used. If OVERRIDING SYSTEM VALUE is specified, the implicit or explicit list of columns for the INSERT statement must contain a column defined as GENERATED ALWAYS. If OVERRIDING USER VALUE is specified, the implicit or explicit list of columns for the INSERT statement must contain a column defined as either GENERATED ALWAYS or GENERATED BY DEFAULT.
OVERRIDING SYSTEM VALUE
Specifies that the value specified in the VALUES clause or produced by a fullselect for a column that is defined as GENERATED ALWAYS is used. A system-generated value is not inserted.
OVERRIDING USER VALUE
Specifies that the value specified in the VALUES clause or produced by a fullselect for a column that is defined as either GENERATED ALWAYS or GENERATED BY DEFAULT is ignored. Instead, a system-generated value is inserted, overriding the user-specified value.

If neither OVERRIDING SYSTEM VALUE nor OVERRIDING USER VALUE is specified:

VALUES
Specifies one or more new rows to be inserted.

Each variable in the clause must identify a host structure or variable that is declared in accordance with the rules for declaring host structures and variables. In the operational form of the statement, a reference to a host structure is replaced by a reference to each of its variables. For further information on variables and structures, see References to host variables and Host structures.

The number of values for each row in the VALUES clause 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.

expression
An expression of the type described in Expressions, that does not include an aggregate function or column name. If expression is a variable, the variable can identify a structure.
DEFAULT
Specifies that the default value is assigned to a column. The value that is inserted depends on how the column was defined, as follows:
  • If the WITH DEFAULT clause is used, the default inserted is as defined for the column (see default-clause in column-definition in CREATE TABLE).
  • If the WITH DEFAULT clause or the NOT NULL clause is not used, the value inserted is NULL.
  • If the NOT NULL clause is used and the WITH DEFAULT clause is not used or DEFAULT NULL is used, the DEFAULT keyword cannot be specified for that column.
  • If the column is a ROWID or identity column, the database manager will generate a new value.

DEFAULT must be specified for a ROWID or an identity column that was defined as GENERATED ALWAYS unless OVERRIDING USER VALUE is specified to indicate that any user-specified value will be ignored and a unique system-generated value will be inserted.

NULL
Specifies the value for a column is the null value. NULL should only be specified for nullable columns.
select-statement
Specifies a set of new rows in the form of the result table of a select-statement. The FOR READ ONLY, FOR UPDATE, and OPTIMIZE clauses are not valid for a select-statement used with insert. If an ORDER BY clause is specified on the select-statement, the rows are inserted according to the values of the columns identified in the ORDER BY clause. For an explanation of select-statement, see select-statement.

There can be one, more than one, or zero rows inserted when using the select-statement. If no rows are inserted, SQLCODE is set to +100 and SQLSTATE is set to '02000'.

When the base object of the INSERT and a base object of any subselect in the select-statement are the same table, the select statement is completely evaluated before any rows are inserted.

The number of columns in the result table must equal the number of names implicitly or explicitly specified in the column-name 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.

isolation-clause
Specifies the isolation level to be used for this statement.
WITH

Introduces the isolation level, which may be one of:

  • RR Repeatable read
  • RS Read stability
  • CS Cursor stability
  • UR Uncommitted read
  • NC No commit
If isolation-clause is not specified the default isolation is used. See isolation-clause for a description of how the default is determined.

insert-multiple-rows

integer or variable ROWS
Specifies the number of rows to be inserted. If a variable is specified, it must be numeric with zero scale and cannot include an indicator variable.
VALUES (host-structure-array)
Specifies a set of new rows in the form of an array of host structures. The host-structure-array must be declared in the program in accordance with the rules for declaring host structure arrays. A parameter marker may not be used in place of the host-structure-array name.

The number of variables in the host structure must equal the number of names in the column-list. The first host structure in the array corresponds to the first row, the second host structure in the array corresponds to the second row, and so on. In addition, the first variable in the host structure corresponds with the first column of the row, the second variable in the host structure corresponds with the second column of the row, and so on.

For an explanation of arrays of host structures see Host structure arrays.

insert-multiple-rows is not allowed if the current connection is to a non-iSeries remote server.

INSERT Rules

Default Values: The value inserted in any column that is not in the column list is the default value of the column. Columns without a default value must be included in the column list. Similarly, if you insert into a view without an INSTEAD OF INSERT trigger, the default value is inserted into any column of the base table that is not included in the view. Hence, all columns of the base table that are not in the view must have default values.

Assignment: Insert values are assigned to columns in accordance with the assignment rules described in Language elements.

Validity: If the identified table or the base table of the identified view has one or more unique indexes or unique constraints, each row inserted into the table must conform to the constraints imposed by those indexes.

The unique indexes and unique constraints are effectively checked at the end of the statement unless COMMIT(*NONE) was specified. In the case of a multiple-row INSERT, this would occur after all rows were inserted and any associated triggers were activated. If COMMIT(*NONE) is specified, checking is performed as each row is inserted.

If the identified table or the base table of the identified view has one or more check constraints, each check constraint must be true or unknown for each row inserted into the table.

The check constraints are effectively checked at the end of the statement. In the case of a multiple-row INSERT, this would occur after all rows were inserted.

If a view is identified, the inserted rows must conform to any applicable WITH CHECK OPTION. For more information, see CREATE VIEW.

Triggers: If the identified table or the base table of the identified view has an insert trigger, the trigger is activated. A trigger might cause other statements to be executed or raise error conditions based on the insert values.

Referential Integrity: Each nonnull insert value of a foreign key must equal some value of the parent key of the parent table in the relationship.

The referential constraints (other than a referential constraint with a RESTRICT delete rule) are effectively checked at the end of the statement. In the case of a multiple-row INSERT, this would occur after all rows were inserted and any associated triggers were activated.

Notes

Insert operation errors: If an insert value violates any constraints, or if any other error occurs during the execution of an INSERT statement and COMMIT(*NONE) was not specified, all changes made during the execution of the statement are backed out. However, other changes in the unit of work made prior to the error are not backed out. If COMMIT(*NONE) is specified, changes are not backed out.

Number of rows inserted: After executing an INSERT statement, the ROW_COUNT statement information item in the SQL Diagnostics Area (or SQLERRD(3) of the SQLCA) is the number of rows that the database manager inserted. The ROW_COUNT item does not include the number of rows that were inserted as a result of a trigger.

Locking: If COMMIT(*RR), COMMIT(*ALL), COMMIT(*CS), or COMMIT(*CHG) is specified, one or more exclusive locks are acquired during the execution of a successful INSERT statement. Until the locks are released by a commit or rollback operation, an inserted row can only be accessed by:

The locks can prevent other application processes from performing operations on the table. For further information about locking, see the description of the COMMIT, ROLLBACK, and LOCK TABLE statements. Also, see Isolation level and the Database Programming book.

A maximum of 500 000 000 rows can be inserted or changed in any single INSERT statement when COMMIT(*RR), COMMIT(*ALL), COMMIT(*CS), or COMMIT(*CHG) was specified. The number of rows changed includes any rows inserted, updated, or deleted under the same commitment definition as a result of a trigger.

REXX: Variables cannot be used in the INSERT statement within a REXX procedure. Instead, the INSERT must be the object of a PREPARE and EXECUTE using parameter markers.

Syntax alternatives: The following keywords are synonyms supported for compatibility to prior releases. These keywords are non-standard and should not be used:

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: Create a table MA_EMPPROJACT with the same columns as the EMPPROJACT table. Populate MA_EMPPROJACT with the rows from the EMPPROJACT table with a project number (PROJNO) starting with the letters 'MA'.

  CREATE TABLE MA_EMPPROJACT LIKE EMPPROJACT

  INSERT INTO MA_EMPPROJACT
    SELECT * FROM EMPPROJACT
      WHERE SUBSTR(PROJNO, 1, 2) = 'MA'

Example 4: Use a Java™ program statement to add a skeleton project to the PROJECT table on the connection context 'ctx'. 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.

  #sql [ctx] { INSERT INTO PROJECT (PROJNO, PROJNAME, DEPTNO, RESPEMP, PRSTDATE)
              VALUES (:PRJNO, :PRJNM, :DPTNO, :REMP, CURRENT DATE) };

Example 5: Insert two new departments using one statement into the DEPARTMENT table as in example 2, but do not assign a manager to the new departments.

  INSERT INTO DEPARTMENT (DEPTNO, DEPTNAME, ADMRDEPT)
    VALUES ('B11', 'PURCHASING', 'B01'),
           ('E41', 'DATABASE ADMINISTRATION', 'E01')

Example 6: In a PL/I program, use a multiple-row INSERT to add 10 rows to table DEPARTMENT. The host structure array DEPT contains the data to be inserted.

   DCL  1  DEPT(10),
           3  DEPT  CHAR(3),
           3  LASTNAME  CHAR(29)  VARYING,
           3  WORKDEPT  CHAR(6),
           3  JOB  CHAR(3);

   EXEC SQL INSERT INTO DEPARTMENT 10 ROWS VALUES (:DEPT);

Example 7: Insert a new project into the EMPPROJACT table using the Read Uncommitted (UR, CHG) option:

   INSERT INTO EMPPROJACT
     VALUES ('000140', 'PL2100', 30)
     WITH CHG



[ Top of Page | Previous Page | Next Page | Contents | Index ]