DB2 10.5 for Linux, UNIX, and Windows

UPDATE statement

The UPDATE statement updates the values of specified columns in rows of a table, view or nickname, or the underlying tables, nicknames, or views of the specified fullselect.

Updating a row of a view updates a row of its base table, if no INSTEAD OF trigger is defined for the update operation on this view. If such a trigger is defined, the trigger will be executed instead. Updating a row using a nickname updates a row in the data source object to which the nickname refers.

The forms of this statement are:
  • The Searched UPDATE form is used to update one or more rows (optionally determined by a search condition).
  • The Positioned UPDATE form is used to update exactly one row (as determined by the current position of a cursor).

Invocation

An UPDATE 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

The privileges held by the authorization ID of the statement must include at least one of the following authorities:
  • UPDATE privilege on the target table, view, or nickname
  • UPDATE privilege on each of the columns that are to be updated, including the columns of the BUSINESS_TIME period if a period-clause is specified
  • CONTROL privilege on the target table, view, or nickname
  • DATAACCESS authority
If a row-fullselect is included in the assignment, the privileges held by the authorization ID of the statement must include at least one of the following authorities for each referenced table, view, or nickname:
  • SELECT privilege
  • CONTROL privilege
  • DATAACCESS authority
For each table, view, or nickname referenced by a subquery, the privileges held by the authorization ID of the statement must also include at least one of the following authorities:
  • SELECT privilege
  • CONTROL privilege
  • DATAACCESS authority
If the package used to process the statement is precompiled with SQL92 rules (option LANGLEVEL with a value of SQL92E or MIA), and the searched form of an UPDATE statement includes a reference to a column of the table, view, or nickname in the right side of the assignment-clause, or anywhere in the search-condition, the privileges held by the authorization ID of the statement must also include at least one of the following authorities:
  • SELECT privilege
  • CONTROL privilege
  • DATAACCESS authority

If the specified table or view is preceded by the ONLY keyword, the privileges held by the authorization ID of the statement must also include the SELECT privilege for every subtable or subview of the specified table or view.

GROUP privileges are not checked for static UPDATE statements.

If the target of the update operation is a nickname, privileges on the object at the data source are not considered until the statement is executed at the data source. At this time, the authorization ID that is used to connect to the data source must have the privileges that are required for the operation on the object at the data source. The authorization ID of the statement can be mapped to a different authorization ID at the data source.

Syntax (searched-update)

Read syntax diagramSkip visual syntax diagram
>>-UPDATE--+-+-table-name-+--+-------------------+-+------------>
           | '-view-name--'  '-| period-clause |-' |   
           +-nickname------------------------------+   
           +-ONLY--(--+-table-name-+--)------------+   
           |          '-view-name--'               |   
           '-(--fullselect--)----------------------'   

>--+------------------------+--+---------------------+---------->
   '-| correlation-clause |-'  '-| include-columns |-'   

>--SET--| assignment-clause |--+-------------------------+------>
                               '-WHERE--search-condition-'   

>--+--------------+--------------------------------------------><
   '-WITH--+-RR-+-'   
           +-RS-+     
           +-CS-+     
           '-UR-'     

period-clause

|--FOR PORTION OF BUSINESS_TIME--FROM--value1--TO--value2-------|

Syntax (positioned-update)

Read syntax diagramSkip visual syntax diagram
>>-UPDATE--+-table-name-----------------+----------------------->
           +-view-name------------------+   
           +-nickname-------------------+   
           '-ONLY--(--+-table-name-+--)-'   
                      '-view-name--'        

>--+------------------------+--SET--| assignment-clause |------->
   '-| correlation-clause |-'                               

>--WHERE CURRENT OF--cursor-name-------------------------------><

correlation-clause

   .-AS-.                                                
|--+----+--correlation-name--+-----------------------+----------|
                             |    .-,-----------.    |   
                             |    V             |    |   
                             '-(----column-name-+--)-'   

include-columns

               .-,----------------------.      
               V                        |      
|--INCLUDE--(----column-name--data-type-+--)--------------------|

assignment-clause

   .-,----------------------------------------------------------------------------------------.   
   V                                                                                          |   
|----+-column-name--+----------------------+--=--+-expression-+-----------------------------+-+--|
     |              | .------------------. |     +-NULL-------+                             |     
     |              | V                  | |     '-DEFAULT----'                             |     
     |              '---..attribute-name-+-'                                                |     
     |    .-,-------------------------------------.             .-,------------------.      |     
     |    V                                       |             V                (1) |      |     
     '-(----column-name--+----------------------+-+--)--=--(--+---+-expression-+-----+-+--)-'     
                         | .------------------. |             |   +-NULL-------+       |          
                         | V                  | |             |   '-DEFAULT----'       |          
                         '---..attribute-name-+-'             |                (2)     |          
                                                              '-row-fullselect---------'          

Notes:
  1. The number of expressions, NULLs and DEFAULTs must match the number of column names.
  2. The number of columns in the select list must match the number of column names.

Description

table-name, view-name, nickname, or (fullselect)
Identifies the object of the update operation. The name must identify one of the following objects:
  • A table, view, or nickname described in the catalog at the current server
  • A table or view at a remote server specified using a remote-object-name
The object must not be a catalog table, a view of a catalog table (unless it is one of the updatable SYSSTAT views), a system-maintained materialized query table, or a read-only view that has no INSTEAD OF trigger defined for its update operations.

If table-name is a typed table, rows of the table or any of its proper subtables may get updated by the statement. Only the columns of the specified table may be set or referenced in the WHERE clause. For a positioned UPDATE, the associated cursor must also have specified the same table, view or nickname in the FROM clause without using ONLY.

If the object of the update operation is a fullselect, the fullselect must be updatable, as defined in the "Updatable views" Notes item in the description of the CREATE VIEW statement.

If the object of the update operation is a nickname, the extended indicator variable values of DEFAULT and UNASSIGNED must not be used (SQLSTATE 22539).

For additional restrictions related to temporal tables and use of a view or fullselect as the target of the update operation, see "Considerations for a system-period temporal table" and "Considerations for an application-period temporal table" in the Notes section of this topic.

ONLY (table-name)
Applicable to typed tables, the ONLY keyword specifies that the statement should apply only to data of the specified table and rows of proper subtables cannot be updated by the statement. For a positioned UPDATE, the associated cursor must also have specified the table in the FROM clause using ONLY. If table-name is not a typed table, the ONLY keyword has no effect on the statement.
ONLY (view-name)
Applicable to typed views, the ONLY keyword specifies that the statement should apply only to data of the specified view and rows of proper subviews cannot be updated by the statement. For a positioned UPDATE, the associated cursor must also have specified the view in the FROM clause using ONLY. If view-name is not a typed view, the ONLY keyword has no effect on the statement.
period-clause
Specifies that a period clause applies to the target of the update operation. If the target of the update operation is a view, the following conditions apply to the view:
  • The FROM clause of the outer fullselect of the view definition must include a reference, directly or indirectly, to an application-period temporal table (SQLSTATE 42724M).
  • An INSTEAD OF UPDATE trigger must not be defined for the view (SQLSTATE 428HY).
FOR PORTION OF BUSINESS_TIME
Specifies that the update only applies to row values for the portion of the period in the row that is specified by the period clause. The BUSINESS_TIME period must exist in the table (SQLSTATE 4274M).
FROM value1 TO value2
Specifies that the update applies to rows for the period specified from value1 up to value2. No rows are updated if value1 is greater than or equal to value2, or if value1 or value2 is the null value (SQLSTATE 02000).
For the period specified with FROM value1 TO value2, the BUSINESS_TIME period in a row in the target of the update is in any of the following states:
  • Overlaps the beginning of the specified period if the value of the begin column is less than value1 and the value of the end column is greater than value1.
  • Overlaps the end of the specified period if the value of the end column is greater than or equal to value2 and the value of the begin column is less than value2.
  • Is fully contained within the specified period if the value for the begin column for BUSINESS_TIME is greater than or equal to value1 and the value for the corresponding end column is less than or equal to value2.
  • Is partially contained in the specified period if the row overlaps the beginning of the specified period or the end of the specified period, but not both.
  • Fully overlaps the specified period if the period in the row overlaps the beginning and end of the specified period.
  • Is not contained in the period if both columns of BUSINESS_TIME are less than or equal to value1 or greater than or equal to value2.
If the BUSINESS_TIME period in a row is not contained in the specified period, the row is not updated. Otherwise, the update is applied based on how the values in the columns of the BUSINESS_TIME period overlap the specified period as follows:
  • If the BUSINESS_TIME period in a row is fully contained within the specified period, the row is updated and the values of the begin column and end column of BUSINESS_TIME are unchanged.
  • If the BUSINESS_TIME period in a row is partially contained in the specified period and overlaps the beginning of the specified period:
    • The row is updated. In the updated row, the value of the begin column is set to value1 and the value of the end column is the original value of the end column.
    • A row is inserted using the original values from the row, except that the end column is set to value1.
  • If the BUSINESS_TIME period in a row is partially contained in the specified period and overlaps the end of the specified period:
    • The row is updated. In the updated row, the value of the begin column is the original value of the begin column and the end column is set to value2.
    • A row is inserted using the original values from the row, except that the begin column is set to value2.
  • If the BUSINESS_TIME period in a row fully overlaps the specified period:
    • The row is updated. In the updated row the value of the begin column is set to value1 and the value of the end column is set to value2.
    • A row is inserted using the original values from the row, except that the end column is set to value1.
    • An additional row is inserted using the original values from the row, except that the begin column is set to value2.
value1 and value2
Each expression must return a value that has a date data type, timestamp data type, or a valid data type for a string representation of a date or timestamp (SQLSTATE 428HY). The result of each expression must be comparable to the data type of the columns of the specified period (SQLSTATE 42884). See the comparison rules described in "Assignments and comparisons".
Each expression can contain any of the following supported operands (SQLSTATE 428HY):
  • Constant
  • Special register
  • Variable. For details, refer to References to variables.
  • Scalar function whose arguments are supported operands (though user-defined functions and non-deterministic functions cannot be used)
  • CAST specification where the cast operand is a supported operand
  • Expression using arithmetic operators and operands
correlation-clause
Can be used within search-condition or assignment-clause to designate a table, view, nickname, or fullselect. For a description of correlation-clause, see "table-reference" in the description of "Subselect".
include-columns
Specifies a set of columns that are included, along with the columns of table-name or view-name, in the intermediate result table of the UPDATE statement when it is nested in the FROM clause of a fullselect. The include-columns are appended at the end of the list of columns that are specified for table-name or view-name.
INCLUDE
Specifies a list of columns to be included in the intermediate result table of the UPDATE statement.
column-name
Specifies a column of the intermediate result table of the UPDATE statement. The name cannot be the same as the name of another include column or a column in table-name or view-name (SQLSTATE 42711).
data-type
Specifies the data type of the include column. The data type must be one that is supported by the CREATE TABLE statement.
SET
Introduces the assignment of values to column names.
assignment-clause
column-name
Identifies a column to be updated. If extended indicator variables are not enabled, the column-name must identify an updatable column of the specified table, view, or nickname, or identify an INCLUDE column. The object ID column of a typed table is not updatable (SQLSTATE 428DZ). A column must not be specified more than once, unless it is followed by ..attribute-name (SQLSTATE 42701).

If it specifies an INCLUDE column, the column name cannot be qualified.

For a Positioned UPDATE:
  • If the update-clause was specified in the select-statement of the cursor, each column name in the assignment-clause must also appear in the update-clause.
  • If the update-clause was not specified in the select-statement of the cursor and LANGLEVEL MIA or SQL92E was specified when the application was precompiled, the name of any updatable column may be specified.
  • If the update-clause was not specified in the select-statement of the cursor and LANGLEVEL SAA1 was specified either explicitly or by default when the application was precompiled, no columns may be updated.
..attribute-name
Specifies the attribute of a structured type that is set (referred to as an attribute assignment. The column-name specified must be defined with a user-defined structured type (SQLSTATE 428DP). The attribute-name must be an attribute of the structured type of column-name (SQLSTATE 42703). An assignment that does not involve the ..attribute-name clause is referred to as a conventional assignment.
expression
Indicates the new value of the column. The expression is any expression of the type described in "Expressions". The expression cannot include an aggregate function except when it occurs within a scalar fullselect (SQLSTATE 42903).

An expression may contain references to columns of the target table of the UPDATE statement. For each row that is updated, the value of such a column in an expression is the value of the column in the row before the row is updated.

An expression cannot contain references to an INCLUDE column. If expression is a single host variable, the host variable can include an indicator variable that is enabled for extended indicator variables. If extended indicator variables are enabled, the extended indicator variable values of default (-5) or unassigned (-7) must not be used (SQLSTATE 22539) if either of the following statements is true:

  • The expression is more complex than a single host variable with explicit casts
  • The target column has data type of structured type
NULL
Specifies the null value and can only be specified for nullable columns (SQLSTATE 23502). NULL cannot be the value in an attribute assignment (SQLSTATE 429B9) unless it is specifically cast to the data type of the attribute.
DEFAULT
Specifies that the default value should be used based on how the corresponding column is defined in the table. The value that is inserted depends on how the column was defined.
  • If the column was defined as a generated column based on an expression, the column value will be generated by the system, based on the expression.
  • If the column was defined using the IDENTITY clause, the value is generated by the database manager.
  • If the column was defined using the WITH DEFAULT clause, the value is set to the default defined for the column (see default-clause in "ALTER TABLE").
  • If the column was defined using the NOT NULL clause and the GENERATED clause was not used, or the WITH DEFAULT clause was not used, or DEFAULT NULL was used, the DEFAULT keyword cannot be specified for that column (SQLSTATE 23502).
  • If the column was defined using the ROW CHANGE TIMESTAMP clause, the value is generated by the database manager.

The only value that a generated column defined with the GENERATED ALWAYS clause can be set to is DEFAULT (SQLSTATE 428C9).

The DEFAULT keyword cannot be used as the value in an attribute assignment (SQLSTATE 429B9).

The DEFAULT keyword cannot be used as the value in an assignment for update on a nickname where the data source does not support DEFAULT syntax.

row-fullselect
Specifies a fullselect that returns a single row. The result column values are assigned to each corresponding column-name. If the fullselect returns no rows, the null value is assigned to each column; an error occurs if any column to be updated is not nullable. An error also occurs if there is more than one row in the result.

A row-fullselect may contain references to columns of the target table of the UPDATE statement. For each row that is updated, the value of such a column in an expression is the value of the column in the row before the row is updated. An error is returned if there is more than one row in the result (SQLSTATE 21000).

WHERE
Introduces a condition that indicates what rows are updated. You can omit the clause, give a search condition, or name a cursor. If the clause is omitted, all rows of the table, view or nickname are updated.
search-condition
Each column-name in the search condition, other than in a subquery, must name a column of the table, view or nickname. When the search condition includes a subquery in which the same table is the base object of both the UPDATE and the subquery, the subquery is completely evaluated before any rows are updated.

The search-condition is applied to each row of the table, view or nickname and the updated rows are those for which the result of the search-condition is true.

If the search condition contains a subquery, the subquery can be thought of as being executed each time the search condition is applied to a row, and the results used in applying the search condition. In actuality, a subquery with no correlated references is executed only once, whereas a subquery with a correlated reference may have to be executed once for each row.

CURRENT OF cursor-name
Identifies the cursor to be used in the update operation. The cursor-name must identify a declared cursor, explained in "DECLARE CURSOR". The DECLARE CURSOR statement must precede the UPDATE statement in the program.

The specified table, view, or nickname must also be named in the FROM clause of the SELECT statement of the cursor, and the result table of the cursor must not be read-only. (For an explanation of read-only result tables, see "DECLARE CURSOR".)

When the UPDATE statement is executed, the cursor must be positioned on a row; that row is updated.

This form of UPDATE cannot be used (SQLSTATE 42828) if the cursor references:
  • A view on which an INSTEAD OF UPDATE trigger is defined
  • A view that includes an OLAP function in the select list of the fullselect that defines the view
  • A view that is defined, either directly or indirectly, using the WITH ROW MOVEMENT clause
WITH
Specifies the isolation level at which the UPDATE statement is executed.
RR
Repeatable Read
RS
Read Stability
CS
Cursor Stability
UR
Uncommitted Read
The default isolation level of the statement is the isolation level of the package in which the statement is bound. The WITH clause has no effect on nicknames, which always use the default isolation level of the statement.

Rules

Notes

Examples