UPDATE statement

An UPDATE statement sets the value in a column.

You can update the current row of an open, updatable cursor. If there is no current row, or if the current row no longer satisfies the cursor's query, an exception is raised.

Syntax

{
    UPDATE table-Name
        SET column-Name = Value
        [ , column-Name = Value} ]*
        [WHERE clause] |
    UPDATE table-Name
        SET column-Name = Value
        [ , column-Name = Value ]*
        WHERE CURRENT OF
}

The first syntactical form is called a searched update. The second syntactical form is called a positioned update.

For searched updates, you update all rows of the table for which the WHERE clause evaluates to TRUE.

For positioned updates, you can update only columns that were included in the FOR UPDATE clause of the SELECT statement that created the cursor. If the SELECT statement did not include a FOR UPDATE clause, the cursor is read-only and cannot be used to update.

Specifying DEFAULT for the update value sets the value of the column to the default defined for that table.

-- All the employees except the manager of department (WORKDEPT) 'E21' have 
been temporarily reassigned. 
-- Indicate this by changing their job (JOB) to NULL and their pay
-- (SALARY, BONUS, COMM) values to zero in the EMPLOYEE table. 
UPDATE EMPLOYEE
  SET JOB=NULL, SALARY=0, BONUS=0, COMM=0
  WHERE WORKDEPT = 'E21' AND JOB <> 'MANAGER'

-- PROMOTE the job (JOB) of certain employees to MANAGER
UPDATE EMPLOYEE
	SET JOB = 'MANAGER'
	WHERE CURRENT OF CURS1;
-- Increase the project staffing (PRSTAFF) by 1.5 for all projects
stmt.executeUpdate("UPDATE PROJECT SET PRSTAFF = "
"PRSTAFF + 1.5" +
"WHERE CURRENT OF" + ResultSet.getCursorName());

-- Change the job (JOB) of employee number (EMPNO) '000290' in the EMPLOYEE table 
-- to its DEFAULT value which is NULL
UPDATE EMPLOYEE
  SET JOB = DEFAULT
  WHERE EMPNO = '000290';

Statement dependency system

A searched update statement depends on the table being updated, all of its conglomerates (units of storage such as heaps or indexes), all of its constraints, and any other table named in the WHERE clause or SET expressions. A CREATE or DROP INDEX statement or an ALTER TABLE statement for the target table of a prepared searched update statement invalidates the prepared searched update statement.

The positioned update statement depends on the cursor and any tables the cursor references. You can compile a positioned update even if the cursor has not been opened yet. However, removing the open cursor with the JDBC close method invalidates the positioned update.

A CREATE or DROP INDEX statement or an ALTER TABLE statement for the target table of a prepared positioned update invalidates the prepared positioned update statement.

Dropping an alias invalidates a prepared update statement if the latter statement uses the alias.

Dropping or adding triggers on the target table of the update invalidates the update statement.

Related concepts
Interaction with the dependency system
CREATE statements
DROP Statements
RENAME statements
SET statements
Related reference
ALTER TABLE statement
CALL (PROCEDURE)
CONSTRAINT clause
DECLARE GLOBAL TEMPORARY TABLE statement
DELETE statement
FOR UPDATE clause
FROM clause
GROUP BY clause
HAVING clause
INNER JOIN
INSERT statement
JOIN operation
LEFT OUTER JOIN
LOCK TABLE statement
ORDER BY clause
Query
RIGHT OUTER JOIN
ScalarSubquery
SelectExpression
SELECT statement
TableExpression
TableSubquery
VALUES expression
WHERE clause
WHERE CURRENT OF clause