UPDATE v11
Name
UPDATE
-- update rows of a table.
Synopsis
Description
UPDATE
changes the values of the specified columns in all rows that satisfy the condition. Only the columns to be modified need be mentioned in the SET clause; columns not explicitly modified retain their previous values.
The RETURNING INTO { record | variable [, ...] }
clause may only be specified within an SPL program. In addition the result set of the UPDATE
command must not return more than one row, otherwise an exception is thrown. If the result set is empty, then the contents of the target record or variables are set to null.
The RETURNING BULK COLLECT INTO collection [, ...]
clause may only be specified if the UPDATE
command is used within an SPL program. If more than one collection
is specified as the target of the BULK COLLECT INTO
clause, then each collection
must consist of a single, scalar field – i.e., collection
must not be a record. The result set of the UPDATE
command may contain none, one, or more rows. return_expression
evaluated for each row of the result set, becomes an element in collection
starting with the first element. Any existing rows in collection
are deleted. If the result set is empty, then collection
will be empty.
You must have the UPDATE
privilege on the table to update it, as well as the SELECT
privilege to any table whose values are read in expression
or condition
.
Parameters
optimizer_hint
Comment-embedded hints to the optimizer for selection of an execution plan.
table
The name (optionally schema-qualified) of the table to update.
dblink
Database link name identifying a remote database. See the CREATE DATABASE LINK
command for information on database links.
column
The name of a column in table.
expression
An expression to assign to the column. The expression may use the old values of this and other columns in the table.
DEFAULT
Set the column to its default value (which will be null if no specific default expression has been assigned to it).
condition
An expression that returns a value of type BOOLEAN
. Only rows for which this expression returns true will be updated.
return_expression
An expression that may include one or more columns from table. If a column name from table is specified in return_expression
, the value substituted for the column when return_expression
is evaluated is determined as follows:
If the column specified in
return_expression
is assigned a value in theUPDATE
command, then the assigned value is used in the evaluation ofreturn_expression
.If the column specified in
return_expression
is not assigned a value in theUPDATE
command, then the column’s current value in the affected row is used in the evaluation ofreturn_expression
.
record
A record whose field the evaluated return_expression
is to be assigned. The first return_expression
is assigned to the first field in record
, the second return_expression
is assigned to the second field in record
, etc. The number of fields in record
must exactly match the number of expressions and the fields must be type-compatible with their assigned expressions.
variable
A variable to which the evaluated return_expression
is to be assigned. If more than one return_expression
and variable
are specified, the first return_expression
is assigned to the first variable
, the second return_expression
is assigned to the second variable
, etc. The number of variables specified following the INTO
keyword must exactly match the number of expressions following the RETURNING
keyword and the variables must be type-compatible with their assigned expressions.
collection
A collection in which an element is created from the evaluated return_expression
. There can be either a single collection which may be a collection of a single field or a collection of a record type, or there may be more than one collection in which case each collection must consist of a single field. The number of return expressions must match in number and order the number of fields in all specified collections. Each corresponding return_expression
and collection
field must be type-compatible.
Examples
Change the location to AUSTIN
for department 20
in the dept
table:
For all employees with job = SALESMAN
in the emp
table, update the salary by 10%
and increase the commission by 500
.