Updated on 2024-05-07 GMT+08:00

UPDATE

Description

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.
  • Update...... Limit row_count supports only some scenarios of execution plan pushdown. (Table replication is not supported.) The prerequisites are that the filter criteria must contain the equivalent distribution key and the filter criteria should be relatively simple. Do not use forcible type conversion. If the command fails to be executed, simplify the filter criteria.
  • You must have the SELECT permission on all tables involved in the expressions or conditions.
  • The distribution key (or column) of a table cannot be modified.
  • For the UPDATE statement whose subquery is a stream plan, the same row cannot be concurrently updated.
  • You are not allowed to change the database encoding format to GB18030_2022 or change GB18030_2022 to another character encoding format by updating system catalogs. Otherwise, inventory data and some operations will be abnormal. If you need to change the character set encoding of a database, follow the database switching process to migrate data.

Syntax

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
13
14
15
16
17
18
[ WITH [ RECURSIVE ] with_query [, ...] ]
UPDATE [/*+ plan_hint */] [ ONLY ] table_name [ * ] [ [ AS ] alias ]
SET {column_name = { expression | DEFAULT } 
    |( column_name [, ...] ) = {( { expression | DEFAULT } [, ...] ) |sub_query }}[, ...]
    [ FROM from_list] [ WHERE condition | WHERE CURRENT OF cursor_name ]
    [ ORDER BY {expression [ [ ASC | DESC | USING operator ] [ LIMIT row_count ]
    [ RETURNING {* 
                | {output_expression [ [ AS ] output_name ]} [, ...] }];

where sub_query can be:
SELECT [ ALL | DISTINCT [ ON ( expression [, ...] ) ] ]
{ * | {expression [ [ AS ] output_name ]} [, ...] }
[ FROM from_item [, ...] ]
[ WHERE condition | WHERE CURRENT OF cursor_name ]
[ GROUP BY grouping_element [, ...] ]
[ HAVING condition [, ...] ]
[ ORDER BY {expression [ [ ASC | DESC | USING operator ] | nlssort_expression_clause ] [ NULLS { FIRST | LAST } ]} [, ...] ]
[ LIMIT { [offset,] count | ALL } ]

Parameters

  • 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. This subquery statement structure is called the common table expression (CTE) structure. When this structure is used, the execution plan contains the CTE SCAN content.

    If RECURSIVE is specified, it allows a SELECT subquery to reference itself by name.

    The detailed 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

    You can use database links to perform operations on remote tables. For details, see DATABASE LINK.

  • alias

    Specifies a substitute name for the target table.

    Value range: a string. It must comply with the naming convention.

  • 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.

    For an UPDATE statement in UPDATE t1 SET (c1,c2) = (SELECT c1, c2 FROM t2...) format, a subplan is generated for each column in the execution plan. When a large number of columns are updated, the number of subplans is large, which greatly affects the performance.

  • from_list

    Specifies a list of table expressions. You can use columns of other tables in the WHERE condition. This is similar to the list of tables that can be specified in the FROM clause of a SELECT statement.

    Note that the target table cannot appear in from_list, unless you intend a self-join (in which case it must appear with an alias in 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 advised not to use numeric types such as int for condition, because such types can be implicitly converted to Boolean values (non-zero values are implicitly converted to true and 0 is implicitly converted to false), which may cause unexpected results.

  • WHERE CURRENT OF cursor_name

    When the cursor points to a row in a table, you can use this syntax to update the row.

    cursor_name: specifies the name of a cursor.

    • This syntax is not supported by the database in the MySQL compatibility mode.
    • This syntax supports only ordinary tables and does not support partitioned tables or hash bucket tables.
    • This syntax can be used only in stored procedures.
    • This syntax cannot be used together with other WHERE conditions.
    • This syntax cannot be used together with WITH, USING, ORDER BY, or FROM.
    • The SELECT statement corresponding to the CURSOR must be declared as FOR UPDATE.
    • The SELECT statement corresponding to the CURSOR supports only a single table. It does not support LIMIT/OFFSET, subqueries, or sublinks.
    • The CURSOR declared as FOR UPDATE in a stored procedure cannot be used after being committed or rolled back.
    • If the row to which the CURSOR points does not exist, an error is reported (only when UPDATE is used instead of DELETE) in the ORA-compatible mode, indicating that the specified row does not exist. In other compatibility modes, no error is reported.
  • 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

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
-- Create the student1 table.
gaussdb=# CREATE TABLE student1
(
   stuno     int,
   classno   int 
)
DISTRIBUTE BY hash(stuno);

-- Insert data.
gaussdb=# INSERT INTO student1 VALUES(1,1);
gaussdb=# INSERT INTO student1 VALUES(2,2);
gaussdb=# INSERT INTO student1 VALUES(3,3);

-- View data.
gaussdb=# SELECT * FROM student1;

-- Update the values of all records.
gaussdb=# UPDATE student1 SET classno = classno*2;

-- View data.
gaussdb=# SELECT * FROM student1;

-- Delete the table.
gaussdb=# DROP TABLE student1;

-- Example for WHERE CURRENT OF cursor_name
gaussdb=# create table t1(c1 int, c2 varchar2); -- Create a table.
gaussdb=# insert into t1 values(generate_series(1,1000),'abcd'); -- Insert the data.

gaussdb=# declare
gaussdb-# cursor cur1 is select * from t1 where c1 = 1 for update;
gaussdb-# va t1%rowtype;
gaussdb-# begin
gaussdb$# open cur1;
gaussdb$# fetch cur1 into va;
gaussdb$# update t1 set c2 = c2 || c2  where current of cur1; -- Use WHERE CURRENT OF cursor_name to update data.
gaussdb$# close cur1;
gaussdb$# commit;
gaussdb$# end;
gaussdb$# /

gaussdb=# select * from t1 where c1 = 1; -- Query the data.