'\" t .\" Title: UPDATE .\" Author: The PostgreSQL Global Development Group .\" Generator: DocBook XSL Stylesheets vsnapshot .\" Date: 2021 .\" Manual: PostgreSQL 13.4 Documentation .\" Source: PostgreSQL 13.4 .\" Language: English .\" .TH "UPDATE" "7" "2021" "PostgreSQL 13.4" "PostgreSQL 13.4 Documentation" .\" ----------------------------------------------------------------- .\" * Define some portability stuff .\" ----------------------------------------------------------------- .\" ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~ .\" http://bugs.debian.org/507673 .\" http://lists.gnu.org/archive/html/groff/2009-02/msg00013.html .\" ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~ .ie \n(.g .ds Aq \(aq .el .ds Aq ' .\" ----------------------------------------------------------------- .\" * set default formatting .\" ----------------------------------------------------------------- .\" disable hyphenation .nh .\" disable justification (adjust text to left margin only) .ad l .\" ----------------------------------------------------------------- .\" * MAIN CONTENT STARTS HERE * .\" ----------------------------------------------------------------- .SH "NAME" UPDATE \- update rows of a table .SH "SYNOPSIS" .sp .nf [ WITH [ RECURSIVE ] \fIwith_query\fR [, \&.\&.\&.] ] UPDATE [ ONLY ] \fItable_name\fR [ * ] [ [ AS ] \fIalias\fR ] SET { \fIcolumn_name\fR = { \fIexpression\fR | DEFAULT } | ( \fIcolumn_name\fR [, \&.\&.\&.] ) = [ ROW ] ( { \fIexpression\fR | DEFAULT } [, \&.\&.\&.] ) | ( \fIcolumn_name\fR [, \&.\&.\&.] ) = ( \fIsub\-SELECT\fR ) } [, \&.\&.\&.] [ FROM \fIfrom_item\fR [, \&.\&.\&.] ] [ WHERE \fIcondition\fR | WHERE CURRENT OF \fIcursor_name\fR ] [ RETURNING * | \fIoutput_expression\fR [ [ AS ] \fIoutput_name\fR ] [, \&.\&.\&.] ] .fi .SH "DESCRIPTION" .PP \fBUPDATE\fR 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\&. .PP There are two ways to modify a table using information contained in other tables in the database: using sub\-selects, or specifying additional tables in the FROM clause\&. Which technique is more appropriate depends on the specific circumstances\&. .PP The optional RETURNING clause causes \fBUPDATE\fR to compute and return value(s) based on each row actually updated\&. Any expression using the table\*(Aqs columns, and/or columns of other tables mentioned in FROM, can be computed\&. The new (post\-update) values of the table\*(Aqs columns are used\&. The syntax of the RETURNING list is identical to that of the output list of \fBSELECT\fR\&. .PP You must have the UPDATE privilege on the table, or at least on the column(s) that are listed to be updated\&. You must also have the SELECT privilege on any column whose values are read in the \fIexpressions\fR or \fIcondition\fR\&. .SH "PARAMETERS" .PP \fIwith_query\fR .RS 4 The WITH clause allows you to specify one or more subqueries that can be referenced by name in the \fBUPDATE\fR query\&. See Section\ \&7.8 and \fBSELECT\fR(7) for details\&. .RE .PP \fItable_name\fR .RS 4 The name (optionally schema\-qualified) of the table to update\&. If ONLY is specified before the table name, matching rows are updated in the named table only\&. If ONLY is not specified, matching rows are also updated in any tables inheriting from the named table\&. Optionally, * can be specified after the table name to explicitly indicate that descendant tables are included\&. .RE .PP \fIalias\fR .RS 4 A substitute name for the target table\&. When an alias is provided, it completely hides the actual name of the table\&. For example, given UPDATE foo AS f, the remainder of the \fBUPDATE\fR statement must refer to this table as f not foo\&. .RE .PP \fIcolumn_name\fR .RS 4 The name of a column in the table named by \fItable_name\fR\&. The column name can be qualified with a subfield name or array subscript, if needed\&. Do not include the table\*(Aqs name in the specification of a target column \(em for example, UPDATE table_name SET table_name\&.col = 1 is invalid\&. .RE .PP \fIexpression\fR .RS 4 An expression to assign to the column\&. The expression can use the old values of this and other columns in the table\&. .RE .PP DEFAULT .RS 4 Set the column to its default value (which will be NULL if no specific default expression has been assigned to it)\&. An identity column will be set to a new value generated by the associated sequence\&. For a generated column, specifying this is permitted but merely specifies the normal behavior of computing the column from its generation expression\&. .RE .PP \fIsub\-SELECT\fR .RS 4 A SELECT sub\-query that produces as many output columns as are listed in the parenthesized column list preceding it\&. The sub\-query must yield no more than one row when executed\&. If it yields one row, its column values are assigned to the target columns; if it yields no rows, NULL values are assigned to the target columns\&. The sub\-query can refer to old values of the current row of the table being updated\&. .RE .PP \fIfrom_item\fR .RS 4 A table expression allowing columns from other tables to appear in the WHERE condition and update expressions\&. This uses the same syntax as the FROM clause of a \fBSELECT\fR statement; for example, an alias for the table name can be specified\&. Do not repeat the target table as a \fIfrom_item\fR unless you intend a self\-join (in which case it must appear with an alias in the \fIfrom_item\fR)\&. .RE .PP \fIcondition\fR .RS 4 An expression that returns a value of type boolean\&. Only rows for which this expression returns true will be updated\&. .RE .PP \fIcursor_name\fR .RS 4 The name of the cursor to use in a WHERE CURRENT OF condition\&. The row to be updated is the one most recently fetched from this cursor\&. The cursor must be a non\-grouping query on the \fBUPDATE\fR\*(Aqs target table\&. Note that WHERE CURRENT OF cannot be specified together with a Boolean condition\&. See \fBDECLARE\fR(7) for more information about using cursors with WHERE CURRENT OF\&. .RE .PP \fIoutput_expression\fR .RS 4 An expression to be computed and returned by the \fBUPDATE\fR command after each row is updated\&. The expression can use any column names of the table named by \fItable_name\fR or table(s) listed in FROM\&. Write * to return all columns\&. .RE .PP \fIoutput_name\fR .RS 4 A name to use for a returned column\&. .RE .SH "OUTPUTS" .PP On successful completion, an \fBUPDATE\fR command returns a command tag of the form .sp .if n \{\ .RS 4 .\} .nf UPDATE \fIcount\fR .fi .if n \{\ .RE .\} .sp The \fIcount\fR is the number of rows updated, including matched rows whose values did not change\&. Note that the number may be less than the number of rows that matched the \fIcondition\fR when updates were suppressed by a BEFORE UPDATE trigger\&. If \fIcount\fR is 0, no rows were updated by the query (this is not considered an error)\&. .PP If the \fBUPDATE\fR command contains a RETURNING clause, the result will be similar to that of a \fBSELECT\fR statement containing the columns and values defined in the RETURNING list, computed over the row(s) updated by the command\&. .SH "NOTES" .PP When a FROM clause is present, what essentially happens is that the target table is joined to the tables mentioned in the \fIfrom_item\fR list, and each output row of the join represents an update operation for the target table\&. When using FROM you should ensure that the join produces at most one output row for each row to be modified\&. In other words, a target row shouldn\*(Aqt join to more than one row from the other table(s)\&. If it does, then only one of the join rows will be used to update the target row, but which one will be used is not readily predictable\&. .PP Because of this indeterminacy, referencing other tables only within sub\-selects is safer, though often harder to read and slower than using a join\&. .PP In the case of a partitioned table, updating a row might cause it to no longer satisfy the partition constraint of the containing partition\&. In that case, if there is some other partition in the partition tree for which this row satisfies its partition constraint, then the row is moved to that partition\&. If there is no such partition, an error will occur\&. Behind the scenes, the row movement is actually a \fBDELETE\fR and \fBINSERT\fR operation\&. .PP There is a possibility that a concurrent \fBUPDATE\fR or \fBDELETE\fR on the row being moved will get a serialization failure error\&. Suppose session 1 is performing an \fBUPDATE\fR on a partition key, and meanwhile a concurrent session 2 for which this row is visible performs an \fBUPDATE\fR or \fBDELETE\fR operation on this row\&. In such case, session 2\*(Aqs \fBUPDATE\fR or \fBDELETE\fR will detect the row movement and raise a serialization failure error (which always returns with an SQLSTATE code \*(Aq40001\*(Aq)\&. Applications may wish to retry the transaction if this occurs\&. In the usual case where the table is not partitioned, or where there is no row movement, session 2 would have identified the newly updated row and carried out the \fBUPDATE\fR/\fBDELETE\fR on this new row version\&. .PP Note that while rows can be moved from local partitions to a foreign\-table partition (provided the foreign data wrapper supports tuple routing), they cannot be moved from a foreign\-table partition to another partition\&. .SH "EXAMPLES" .PP Change the word Drama to Dramatic in the column kind of the table films: .sp .if n \{\ .RS 4 .\} .nf UPDATE films SET kind = \*(AqDramatic\*(Aq WHERE kind = \*(AqDrama\*(Aq; .fi .if n \{\ .RE .\} .PP Adjust temperature entries and reset precipitation to its default value in one row of the table weather: .sp .if n \{\ .RS 4 .\} .nf UPDATE weather SET temp_lo = temp_lo+1, temp_hi = temp_lo+15, prcp = DEFAULT WHERE city = \*(AqSan Francisco\*(Aq AND date = \*(Aq2003\-07\-03\*(Aq; .fi .if n \{\ .RE .\} .PP Perform the same operation and return the updated entries: .sp .if n \{\ .RS 4 .\} .nf UPDATE weather SET temp_lo = temp_lo+1, temp_hi = temp_lo+15, prcp = DEFAULT WHERE city = \*(AqSan Francisco\*(Aq AND date = \*(Aq2003\-07\-03\*(Aq RETURNING temp_lo, temp_hi, prcp; .fi .if n \{\ .RE .\} .PP Use the alternative column\-list syntax to do the same update: .sp .if n \{\ .RS 4 .\} .nf UPDATE weather SET (temp_lo, temp_hi, prcp) = (temp_lo+1, temp_lo+15, DEFAULT) WHERE city = \*(AqSan Francisco\*(Aq AND date = \*(Aq2003\-07\-03\*(Aq; .fi .if n \{\ .RE .\} .PP Increment the sales count of the salesperson who manages the account for Acme Corporation, using the FROM clause syntax: .sp .if n \{\ .RS 4 .\} .nf UPDATE employees SET sales_count = sales_count + 1 FROM accounts WHERE accounts\&.name = \*(AqAcme Corporation\*(Aq AND employees\&.id = accounts\&.sales_person; .fi .if n \{\ .RE .\} .PP Perform the same operation, using a sub\-select in the WHERE clause: .sp .if n \{\ .RS 4 .\} .nf UPDATE employees SET sales_count = sales_count + 1 WHERE id = (SELECT sales_person FROM accounts WHERE name = \*(AqAcme Corporation\*(Aq); .fi .if n \{\ .RE .\} .PP Update contact names in an accounts table to match the currently assigned salesmen: .sp .if n \{\ .RS 4 .\} .nf UPDATE accounts SET (contact_first_name, contact_last_name) = (SELECT first_name, last_name FROM salesmen WHERE salesmen\&.id = accounts\&.sales_id); .fi .if n \{\ .RE .\} .sp A similar result could be accomplished with a join: .sp .if n \{\ .RS 4 .\} .nf UPDATE accounts SET contact_first_name = first_name, contact_last_name = last_name FROM salesmen WHERE salesmen\&.id = accounts\&.sales_id; .fi .if n \{\ .RE .\} .sp However, the second query may give unexpected results if salesmen\&.id is not a unique key, whereas the first query is guaranteed to raise an error if there are multiple id matches\&. Also, if there is no match for a particular accounts\&.sales_id entry, the first query will set the corresponding name fields to NULL, whereas the second query will not update that row at all\&. .PP Update statistics in a summary table to match the current data: .sp .if n \{\ .RS 4 .\} .nf UPDATE summary s SET (sum_x, sum_y, avg_x, avg_y) = (SELECT sum(x), sum(y), avg(x), avg(y) FROM data d WHERE d\&.group_id = s\&.group_id); .fi .if n \{\ .RE .\} .PP Attempt to insert a new stock item along with the quantity of stock\&. If the item already exists, instead update the stock count of the existing item\&. To do this without failing the entire transaction, use savepoints: .sp .if n \{\ .RS 4 .\} .nf BEGIN; \-\- other operations SAVEPOINT sp1; INSERT INTO wines VALUES(\*(AqChateau Lafite 2003\*(Aq, \*(Aq24\*(Aq); \-\- Assume the above fails because of a unique key violation, \-\- so now we issue these commands: ROLLBACK TO sp1; UPDATE wines SET stock = stock + 24 WHERE winename = \*(AqChateau Lafite 2003\*(Aq; \-\- continue with other operations, and eventually COMMIT; .fi .if n \{\ .RE .\} .PP Change the kind column of the table films in the row on which the cursor c_films is currently positioned: .sp .if n \{\ .RS 4 .\} .nf UPDATE films SET kind = \*(AqDramatic\*(Aq WHERE CURRENT OF c_films; .fi .if n \{\ .RE .\} .SH "COMPATIBILITY" .PP This command conforms to the SQL standard, except that the FROM and RETURNING clauses are PostgreSQL extensions, as is the ability to use WITH with \fBUPDATE\fR\&. .PP Some other database systems offer a FROM option in which the target table is supposed to be listed again within FROM\&. That is not how PostgreSQL interprets FROM\&. Be careful when porting applications that use this extension\&. .PP According to the standard, the source value for a parenthesized sub\-list of target column names can be any row\-valued expression yielding the correct number of columns\&. PostgreSQL only allows the source value to be a row constructor or a sub\-SELECT\&. An individual column\*(Aqs updated value can be specified as DEFAULT in the row\-constructor case, but not inside a sub\-SELECT\&.