UPDATE
Function
UPDATE updates data in a table. UPDATE changes the values of the specified columns in all rows that satisfy the condition. The WHERE clause clarifies conditions. The columns to be modified need to be mentioned in the SET clause; columns not explicitly modified retain their previous values.
Precautions
- The owner of a table, users granted with the UPDATE permission on the table, or users granted with the UPDATE ANY TABLE permission can update data in the table. The system administrator has the permission to update data in the table by default.
- You must have the SELECT permission on all tables involved in the expressions or conditions.
- For column-store tables, the RETURNING clause is currently not supported.
- Column-store tables do not support non-deterministic update. If you update data in one row with multiple rows of data in a column-store table, an error will be reported.
- Memory space that records update operations in column-store tables is not recycled. You need to clean it by executing VACUUM FULL table_name.
- Currently, UPDATE cannot be used in column-store replication tables.
- The syntax for updating multiple tables takes effect only when sql_compatibility is set to B. Column-store tables, views, and tables containing RULE cannot be updated.
Syntax
Update a single table:
[ WITH [ RECURSIVE ] with_query [, ...] ]
UPDATE [/*+ plan_hint */] [ ONLY ] table_name [ partition_clause ] [ * ] [ [ AS ] alias ]
SET {column_name = { expression | DEFAULT }
|( column_name [, ...] ) = {( { expression | DEFAULT } [, ...] ) |sub_query }}[, ...]
[ FROM from_list] [ WHERE condition ]
[ ORDER BY {expression [ [ ASC | DESC | USING operator ]
[ LIMIT { count } ]
[ RETURNING {*
| {output_expression [ [ AS ] output_name ]} [, ...] }];
Update multiple tables:
[ WITH [ RECURSIVE ] with_query [, ...] ]
UPDATE [/*+ plan_hint */] table_list
SET {column_name = { expression | DEFAULT }
|( column_name [, ...] ) = {( { expression | DEFAULT } [, ...] ) |sub_query }}[, ...]
[ FROM from_list] [ WHERE condition ];
where sub_query can be:
SELECT [ ALL | DISTINCT [ ON ( expression [, ...] ) ] ]
{ * | {expression [ [ AS ] output_name ]} [, ...] }
[ FROM from_item [, ...] ]
[ WHERE condition ]
[ GROUP BY grouping_element [, ...] ]
[ HAVING condition [, ...] ]
[ ORDER BY {expression [ [ ASC | DESC | USING operator ] | nlssort_expression_clause ] [ NULLS { FIRST | LAST } ]} [, ...] ]
[ LIMIT { [offset,] count | ALL } ]
The subquery with_query is as follows:
with_query_name [ ( column_name [, ...] ) ] AS [ [ NOT ] MATERIALIZED ] ( {select | values | insert | update | delete} )
Parameter Description
WITH [ RECURSIVE ] with_query [, …]
Specifies one or more subqueries that can be referenced by name in the main query, which is equivalent to a temporary table.
If RECURSIVE is specified, it allows a SELECT subquery to reference itself by name.
The format of with_query is as follows: with_query_name [ ( column_name [, …] ) ] AS [ [ NOT ] MATERIALIZED ] ( {select | values | insert | update | delete} )
- with_query_name specifies the name of the result set generated by a subquery. Such names can be used to access the result sets of subqueries in a query.
- column_name specifies the column name displayed in the subquery result set.
- Each subquery can be a SELECT, VALUES, INSERT, UPDATE or DELETE statement.
- You can use MATERIALIZED or NOT MATERIALIZED to modify the CTE.
- If MATERIALIZED is specified, the WITH query will be materialized, and a copy of the subquery result set is generated. The copy is directly queried at the reference point. Therefore, the WITH subquery cannot be jointly optimized with the SELECT statement trunk (for example, predicate pushdown and equivalence class transfer). In this scenario, you can use NOT MATERIALIZED for modification. If the WITH query can be executed as a subquery inline, the preceding optimization can be performed.
- If the user does not explicitly declare the materialized attribute, comply with the following rules: If the CTE is referenced only once in the SELECT statement trunk to which it belongs and semantically supports inline execution, it will be rewritten as subquery inline execution. Otherwise, the materialized execution will be performed in CTE Scan mode.
plan_hint clause
Follows the UPDATE keyword in the /*+ */ format. It is used to optimize the plan of an UPDATE statement block. For details, see Hint-based Tuning. In each statement, only the first /*+ *plan*hint _*/ comment block takes effect as a hint. Multiple hints can be written.
table_name
Specifies the name (optionally schema-qualified) of the table to be updated.
Value range: an existing table name
partition_clause
Updates a specified partition.
PARTITION { ( partition_name ) | FOR ( partition_value [, …] ) } |
SUBPARTITION { ( subpartition_name ) | FOR ( subpartition_value [, …] ) }
For details about the keywords, see SELECT.
For details, see CREATE TABLE SUBPARTITION.
alias
Specifies a substitute name for the target table.
Value range: a string. It must comply with the identifier naming convention.
table_list
Specifies an expression list of a table. It is similar to from_list, but can declare both the target table and associated table. It is used only in the syntax for updating multiple tables.
column_name
Specifies the name of the column to be modified.
You can refer to this column by specifying the target table alias and the column name. Example:
UPDATE foo AS f SET f.col_name = 'namecol';
Value range: an existing column
expression
Specifies a value assigned to a column or an expression that assigns the value.
DEFAULT
Specifies the default value of a column.
The value is NULL if no specified default value has been assigned to it.
sub_query
Specifies a subquery.
This statement can be executed to update a table with information for other tables in the same database. For details about clauses in the SELECT statement, see SELECT.
When a single column is updated, the ORDER BY and LIMIT clauses can be used. When multiple columns are updated, the ORDER BY and LIMIT clauses cannot be used.
from_list
Specifies a list of table expressions, allowing columns from other tables to appear in the WHERE condition and the update expressions. This is similar to the list of tables that can be specified in the FROM clause of a SELECT statement.
NOTICE: Note that the target table must not appear in the from_list, unless you intend a self-join (in which case it must appear with an alias in the from_list).
condition
Specifies an expression that returns a value of type Boolean. Only rows for which this expression returns true are updated. You are not advised to use numeric types such as int for condition, because such types can be implicitly converted to bool values (non-zero values are implicitly converted to true and 0 is implicitly converted to false), which may cause unexpected results.
ORDER BY
For details about the keywords, see SELECT.
LIMIT
For details about the keywords, see SELECT.
output_expression
Specifies an expression to be computed and returned by the UPDATE statement after each row is updated.
Value range: The expression can use any column names of the table named by table_name or tables listed in FROM. Write * to return all columns.
output_name
Specifies a name to use for a returned column.
Examples
-- Create the student1 table.
openGauss=# CREATE TABLE student1
(
stuno int,
classno int
);
-- Insert data.
openGauss=# INSERT INTO student1 VALUES(1,1);
openGauss=# INSERT INTO student1 VALUES(2,2);
openGauss=# INSERT INTO student1 VALUES(3,3);
-- View data.
openGauss=# SELECT * FROM student1;
-- Update the values of all records.
openGauss=# UPDATE student1 SET classno = classno*2;
-- View data.
openGauss=# SELECT * FROM student1;
-- Delete the table.
openGauss=# DROP TABLE student1;