Updated on 2024-08-20 GMT+08:00

UPDATE

Description

Updates specified columns in all rows that meet the specified conditions. You can use WHERE to declare conditions. All columns specified by the SET clause will be updated. Other columns retain their original 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. When the separation of duties is disabled, system administrators have this permission 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 keys can be updated only when enable_update_distkey is set to on and constraints are met. Otherwise, distribution keys do not support the UPDATE operation.

    The constraints on updating distribution keys are as follows:

    • Distribution columns can be updated only when enable_update_distkey is set to on.
    • The UPDATE statement cannot be pushed down to DNs for execution. The PGXC plan is directly generated and is not changed based on the values before and after the distribution key is updated.
    • Tables with row-level UPDATE TRIGGER are not supported. Otherwise, the execution fails and an error message is displayed. The row-level INSERT/DELETE TRIGGER does not take effect, and the update-statement-level TRIGGER is executed normally.
    • Concurrent update of the same row is not supported. You need to obtain a lock first. The result (returning 0 or reporting an error) of obtaining a lock on DNs depends on the setting of the GUC parameter concurrent_dml_mode. An error will be reported in the following cases: (1) The error message "update distribute column conflict" is displayed. (2) When the time spent for obtaining a lock exceeds the threshold, an error message is displayed, indicating that the lock times out.
    • Tables with global secondary indexes (GSIs) are not supported. Otherwise, an error is reported.
    • Only Hash distribution is supported. LIST/RANGE distribution tables are not supported. Otherwise, an error is reported.
    • MERGE INTO and UPSERT cannot be used to update distribution keys. Otherwise, an error is reported.
    • GTM_FREE is not supported. Otherwise, an error is reported.
    • UPDATE RETURNING is not supported. Otherwise, an error is reported.
    • Statements with joined tables are not supported. Otherwise, an error is reported.
    • UPDATE+LIMIT is not supported. Otherwise, an error is reported.
  • For the UPDATE statement whose subquery is a stream plan, the same row cannot be concurrently updated.
  • You cannot modify the database character encoding by updating a system catalog. Such operation will cause exceptions in existing data or other operations. If you need to change the character 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
19
[ WITH [ RECURSIVE ] with_query [, ...] ]
UPDATE [/*+ plan_hint */] [ ONLY ] {table_name [ partition_clause ] | subquery | view_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.

    Format of with_query:

    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

    Follows the UPDATE keyword in the /*+ */ format. It is used to optimize the plan of an UPDATE statement block. For details, see Hint-based Optimization. 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. If ONLY is specified before the table name, only matched rows in the table are updated. If it is not specified, any matching rows inherited from the table are also updated.

    Value range: an existing table name

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

  • subquery

    Specifies the subquery to be updated. When a subquery is updated, the subquery is regarded as a temporary view. The CHECK OPTION option can be added to the end of the subquery.

    [ WITH [ RECURSIVE ] with_query [, ...] ]
    SELECT [/*+ plan_hint */] [ ALL ]
    { * | {expression [ [ AS ] output_name ]} [, ...] }
    [ into_option ]
    [ FROM from_item [, ...] ]
    [ WHERE condition ]
    [ [ START WITH condition ] CONNECT BY [NOCYCLE] condition [ ORDER SIBLINGS BY expression ] ]
    [ ORDER BY {expression [ [ ASC | DESC | USING operator ] | nlssort_expression_clause ] [ NULLS { FIRST | LAST } ]} [, ...] ]
    [ FETCH { FIRST | NEXT } [ count ] { ROW | ROWS } ONLY ]
    [ into_option ];
    The specified subquery source from_item is as follows:
    {[ ONLY ] {table_name | view_name} [ * ] [ partition_clause ] [ [ AS ] alias [ ( column_alias [, ...] ) ] ]
    |( select ) [ AS ] alias [ ( column_alias [, ...] ) ]
    |with_query_name [ [ AS ] alias [ ( column_alias [, ...] ) ] ]
    |from_item [ NATURAL ] join_type from_item [ ON join_condition | USING ( join_column [, ...] ) ]}

    If a subquery contains only one table, data is updated into the table. If a subquery contains multiple tables or has nested relationships, check whether a key-preserved table exists to determine whether data can be updated. For details about key-preserved tables and WITH CHECK OPTION, see CREATE VIEW.

  • view_name

    Specifies the target view to be updated.

    The restrictions on updating views and subqueries are as follows:

    • The UPDATE operation can be performed only on columns that directly reference user columns in the base table.
    • A subquery or view must contain at least one updatable column. For details about updatable columns, see CREATE VIEW.
    • Views and subqueries that contain the DISTINCT, GROUP BY, HAVING, LIMIT, or OFFSET clause at the top layer are not supported.
    • Views and subqueries that contain set operations (UNION, INTERSECT, EXCEPT, and MINUS) at the top layer are not supported.
    • Views and subqueries whose target lists contain aggregate functions, window functions, or return set functions (such as array_agg, json_agg, and generate_series) are not supported.
    • Views with BEFORE or AFTER triggers but without INSTEAD OF triggers or INSTEAD rules are not supported.
    • Table types supported in views and subqueries include ordinary tables, temporary tables, global temporary tables, partitioned tables, level-2 partitioned tables, Ustore tables, and Astore tables.
    • Only one base table can be updated at a time in a multi-table join view or join subquery.
    • Join views or subqueries can update only key-preserved tables. If CHECK OPTION is specified, join columns cannot be updated. For details about the key-preserved table, see CREATE VIEW.
    • System views cannot be updated.
  • partition_clause

    Updates a specified partition.

    PARTITION { ( partition_name [, ...] ) | FOR ( partition_value [, ...] ) }

    If PARTITION specifies multiple partition names, the partition names can be the same. The union set of the partition ranges is used.

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

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

    Note that the target table cannot 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 the Boolean type. 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.

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

  • Modify all data in the table.
    -- Create the tbl_test1 table and insert data into the table.
    gaussdb=# CREATE TABLE tbl_test1(id int, info varchar(10));
    gaussdb=# INSERT INTO tbl_test1 VALUES (1, 'A'), (2, 'B');
    
    -- Query.
    gaussdb=# SELECT * FROM tbl_test1;
     id | info 
    ----+------
      1 | A
      2 | B
    (2 rows)
    
    -- Modify the info column of all data in the tbl_test1 table.
    gaussdb=# UPDATE tbl_test1 SET info = 'aa';
    
    -- Query the tbl_test1 table.
    gaussdb=# SELECT * FROM tbl_test1;
     id | info 
    ----+------
      1 | aa
      2 | aa
    (2 rows)
  • Modify some data in the table.
    -- Modify the data whose ID is 2 in the tbl_test1 table.
    gaussdb=# UPDATE tbl_test1 SET info = 'bb' WHERE id = 2;
    
    -- Query the tbl_test1 table.
    gaussdb=# SELECT * FROM tbl_test1;
     id | info 
    ----+------
      1 | aa
      2 | bb
    (2 rows)
  • Modify the data and return the modified data.
    -- Modify the data whose ID is 1 in the tbl_test1 table and specify the info column to be returned.
    gaussdb=# UPDATE tbl_test1 SET info = 'ABC' WHERE id = 1 RETURNING info;
     info 
    ------
     ABC
    (1 row)
    
    UPDATE 1
    
    -- Delete the tbl_test1 table.
    gaussdb=# DROP TABLE tbl_test1;
  • Use a subquery to insert new data based on the existing data when modifying data.
    -- Create a table.
    gaussdb=# CREATE TABLE test_grade (
        sid int,                -- Student ID
        name varchar(50),       -- Name
        score char,             -- Score
        examtime date,          -- Exam time
        last_exam boolean       -- The last exam or not
    );
    
    -- Insert data.
    gaussdb=# INSERT INTO test_grade VALUES (1,'Scott','A','2008-07-08',1),(2,'Ben','D','2008-07-08',1),(3,'Jack','D','2008-07-08',1);
    
    -- Query.
    gaussdb=# SELECT * FROM test_grade;
     sid | name  | score |  examtime  | last_exam 
    -----+-------+-------+------------+-----------
       3 | Jack  | D     | 2008-07-08 | t
       1 | Scott | A     | 2008-07-08 | t
       2 | Ben   | D     | 2008-07-08 | t
    (3 rows)
    
    -- On August 25, 2008, Ben took a make-up exam and the score is B. You need to change the value of last_exam to No, and then insert the score of August 25, 2008.
    gaussdb=# WITH old_exa AS ( UPDATE test_grade SET last_exam = 0 WHERE sid = 2 AND examtime = '2008-07-08' RETURNING sid, name ) 
            INSERT INTO test_grade VALUES ( ( SELECT sid FROM old_exa ), (SELECT name FROM old_exa), 'B', '2008-08-25', 1 );
    
    -- Query.
    gaussdb=# SELECT * FROM test_grade;
     sid | name  | score |  examtime  | last_exam 
    -----+-------+-------+------------+-----------
       3 | Jack  | D     | 2008-07-08 | t
       1 | Scott | A     | 2008-07-08 | t
       2 | Ben   | D     | 2008-07-08 | f
       2 | Ben   | B     | 2008-08-25 | t
    (4 rows)
    
    -- Delete.
    gaussdb=# DROP TABLE test_grade;
  • Updating a view or subquery

    Example 1: Update a subquery.

    -- Create a schema.
    gaussdb=# CREATE SCHEMA upd_subqry;
    CREATE SCHEMA
    gaussdb=# SET CURRENT_SCHEMA = 'upd_subqry';
    SET
    
    -- Create tables and insert data into the tables.
    gaussdb=# CREATE TABLE t1 (x1 int, y1 int);
    NOTICE:  The 'DISTRIBUTE BY' clause is not specified. Using 'x1' as the distribution column by default.
    HINT:  Please use 'DISTRIBUTE BY' clause to specify suitable data distribution column.
    CREATE TABLE
    gaussdb=# CREATE TABLE t2 (x2 int PRIMARY KEY, y2 int);
    NOTICE:  CREATE TABLE / PRIMARY KEY will create implicit index "t2_pkey" for table "t2"
    CREATE TABLE
    gaussdb=# INSERT INTO t1 VALUES (1, 1), (2, 2), (3, 3), (5, 5);
    INSERT 0 4
    gaussdb=# INSERT INTO t2 VALUES (1, 1), (2, 2), (3, 3), (5, 5);
    INSERT 0 4
    
    -- Update t1 through a subquery.
    gaussdb=# UPDATE (SELECT * FROM t1) SET y1 = 13 where y1 = 3;
    UPDATE 1
    gaussdb=# UPDATE (SELECT * FROM t1 WHERE y1 < 2) SET y1 = 12 WHERE y1 = 2;
    UPDATE 0
    
    -- Insert a subquery with READ ONLY specified.
    gaussdb=# UPDATE (SELECT * FROM t1 WITH READ ONLY) SET y1 = 1 WHERE y1 = 11;
    ERROR:  cannot perform a DML operation on a read-only subquery.
    
    -- Insert a multi-table join subquery.
    gaussdb=# UPDATE (SELECT * FROM t1, t2 WHERE x1 = x2) SET y1 = 11 WHERE y2 = 1;
    UPDATE 1
    
    -- Insert a multi-table join subquery with CHECK OPTION specified. The join columns x1 and x2 cannot be updated.
    gaussdb=# UPDATE (SELECT * FROM t1, t2 WHERE x1 = x2 WITH CHECK OPTION) SET y1 = 1 WHERE y2 = 1;
    UPDATE 1
    gaussdb=# UPDATE (SELECT * FROM t1, t2 WHERE x1 = x2 WITH CHECK OPTION) SET x1 = 6 WHERE y2 = 5;
    ERROR:  virtual column not allowed here
    
    -- Delete a schema.
    gaussdb=# RESET CURRENT_SCHEMA;
    RESET
    gaussdb=# DROP SCHEMA upd_subqry CASCADE;
    NOTICE:  drop cascades to 2 other objects
    DETAIL:  drop cascades to table upd_subqry.t1
    drop cascades to table upd_subqry.t2
    DROP SCHEMA

    Example 2: Update a view.

    -- Create a schema.
    gaussdb=# CREATE SCHEMA upd_view;
    CREATE SCHEMA
    gaussdb=# SET CURRENT_SCHEMA = 'upd_view';
    SET
    
    -- Create tables and insert data into the tables.
    gaussdb=# CREATE TABLE t1 (x1 int, y1 int);
    NOTICE:  The 'DISTRIBUTE BY' clause is not specified. Using 'x1' as the distribution column by default.
    HINT:  Please use 'DISTRIBUTE BY' clause to specify suitable data distribution column.
    CREATE TABLE
    gaussdb=# CREATE TABLE t2 (x2 int PRIMARY KEY, y2 int);
    NOTICE:  CREATE TABLE / PRIMARY KEY will create implicit index "t2_pkey" for table "t2"
    CREATE TABLE
    gaussdb=# INSERT INTO t1 VALUES (1, 1), (2, 2), (3, 3), (5, 5);
    INSERT 0 4
    gaussdb=# INSERT INTO t2 VALUES (1, 1), (2, 2), (3, 3), (5, 5);
    INSERT 0 4
    
    -- Create a single table view.
    gaussdb=# CREATE VIEW v_upd1 AS SELECT * FROM t1;
    CREATE VIEW
    gaussdb=# CREATE VIEW v_upd_read AS SELECT * FROM t1 WITH READ ONLY;
    CREATE VIEW
    
    -- Update t1 through a view.
    gaussdb=# UPDATE v_upd1 SET y1 = 13 where y1 = 3;
    UPDATE 1
    gaussdb=# UPDATE v_upd_read SET y1 = 1 WHERE y1 = 11;
    ERROR:  cannot perform a DML operation on a read-only subquery.
    
    -- Create a multi-table view.
    gaussdb=# CREATE VIEW vv_upd AS SELECT * FROM t1, t2 WHERE x1 = x2;
    CREATE VIEW
    gaussdb=# CREATE VIEW vv_upd_wco AS SELECT * FROM t1, t2 WHERE x1 = x2 WITH CHECK OPTION;
    CREATE VIEW
    
    -- Update t1 through the join view.
    gaussdb=# UPDATE vv_upd SET y1 = 1 WHERE y2 = 1;
    UPDATE 1
    gaussdb=# UPDATE vv_upd_wco SET x1 = 6 WHERE y2 = 5;
    ERROR:  virtual column not allowed here
    
    -- Delete a schema.
    gaussdb=# RESET CURRENT_SCHEMA;
    RESET
    gaussdb=# DROP SCHEMA upd_view CASCADE;
    NOTICE:  drop cascades to 6 other objects
    DETAIL:  drop cascades to table upd_view.t1
    drop cascades to table upd_view.t2
    drop cascades to view upd_view.v_upd1
    drop cascades to view upd_view.v_upd_read
    drop cascades to view upd_view.vv_upd
    drop cascades to view upd_view.vv_upd_wco
    DROP SCHEMA
    ERROR:  virtual column not allowed here