4 UPDATE — update rows of a table
8 [ WITH [ RECURSIVE ] with_query [, ...] ]
9 UPDATE [ ONLY ] table_name [ * ] [ [ AS ] alias ]
10 SET { column_name = { expression | DEFAULT } |
11 ( column_name [, ...] ) = [ ROW ] ( { expression | DEFAULT } [, ...] )
13 ( column_name [, ...] ) = ( sub-SELECT )
15 [ FROM from_item [, ...] ]
16 [ WHERE condition | WHERE CURRENT OF cursor_name ]
17 [ RETURNING [ WITH ( { OLD | NEW } AS output_alias [, ...] ) ]
18 { * | output_expression [ [ AS ] output_name ] } [, ...] ]
22 UPDATE changes the values of the specified columns in all rows that
23 satisfy the condition. Only the columns to be modified need be
24 mentioned in the SET clause; columns not explicitly modified retain
25 their previous values.
27 There are two ways to modify a table using information contained in
28 other tables in the database: using sub-selects, or specifying
29 additional tables in the FROM clause. Which technique is more
30 appropriate depends on the specific circumstances.
32 The optional RETURNING clause causes UPDATE to compute and return
33 value(s) based on each row actually updated. Any expression using the
34 table's columns, and/or columns of other tables mentioned in FROM, can
35 be computed. By default, the new (post-update) values of the table's
36 columns are used, but it is also possible to request the old
37 (pre-update) values. The syntax of the RETURNING list is identical to
38 that of the output list of SELECT.
40 You must have the UPDATE privilege on the table, or at least on the
41 column(s) that are listed to be updated. You must also have the SELECT
42 privilege on any column whose values are read in the expressions or
48 The WITH clause allows you to specify one or more subqueries
49 that can be referenced by name in the UPDATE query. See
50 Section 7.8 and SELECT for details.
53 The name (optionally schema-qualified) of the table to update.
54 If ONLY is specified before the table name, matching rows are
55 updated in the named table only. If ONLY is not specified,
56 matching rows are also updated in any tables inheriting from the
57 named table. Optionally, * can be specified after the table name
58 to explicitly indicate that descendant tables are included.
61 A substitute name for the target table. When an alias is
62 provided, it completely hides the actual name of the table. For
63 example, given UPDATE foo AS f, the remainder of the UPDATE
64 statement must refer to this table as f not foo.
67 The name of a column in the table named by table_name. The
68 column name can be qualified with a subfield name or array
69 subscript, if needed. Do not include the table's name in the
70 specification of a target column — for example, UPDATE
71 table_name SET table_name.col = 1 is invalid.
74 An expression to assign to the column. The expression can use
75 the old values of this and other columns in the table.
78 Set the column to its default value (which will be NULL if no
79 specific default expression has been assigned to it). An
80 identity column will be set to a new value generated by the
81 associated sequence. For a generated column, specifying this is
82 permitted but merely specifies the normal behavior of computing
83 the column from its generation expression.
86 A SELECT sub-query that produces as many output columns as are
87 listed in the parenthesized column list preceding it. The
88 sub-query must yield no more than one row when executed. If it
89 yields one row, its column values are assigned to the target
90 columns; if it yields no rows, NULL values are assigned to the
91 target columns. The sub-query can refer to old values of the
92 current row of the table being updated.
95 A table expression allowing columns from other tables to appear
96 in the WHERE condition and update expressions. This uses the
97 same syntax as the FROM clause of a SELECT statement; for
98 example, an alias for the table name can be specified. Do not
99 repeat the target table as a from_item unless you intend a
100 self-join (in which case it must appear with an alias in the
104 An expression that returns a value of type boolean. Only rows
105 for which this expression returns true will be updated.
108 The name of the cursor to use in a WHERE CURRENT OF condition.
109 The row to be updated is the one most recently fetched from this
110 cursor. The cursor must be a non-grouping query on the UPDATE's
111 target table. Note that WHERE CURRENT OF cannot be specified
112 together with a Boolean condition. See DECLARE for more
113 information about using cursors with WHERE CURRENT OF.
116 An optional substitute name for OLD or NEW rows in the RETURNING
119 By default, old values from the target table can be returned by
120 writing OLD.column_name or OLD.*, and new values can be returned
121 by writing NEW.column_name or NEW.*. When an alias is provided,
122 these names are hidden and the old or new rows must be referred
123 to using the alias. For example RETURNING WITH (OLD AS o, NEW AS
127 An expression to be computed and returned by the UPDATE command
128 after each row is updated. The expression can use any column
129 names of the table named by table_name or table(s) listed in
130 FROM. Write * to return all columns.
132 A column name or * may be qualified using OLD or NEW, or the
133 corresponding output_alias for OLD or NEW, to cause old or new
134 values to be returned. An unqualified column name, or *, or a
135 column name or * qualified using the target table name or alias
136 will return new values.
139 A name to use for a returned column.
143 On successful completion, an UPDATE command returns a command tag of
147 The count is the number of rows updated, including matched rows whose
148 values did not change. Note that the number may be less than the number
149 of rows that matched the condition when updates were suppressed by a
150 BEFORE UPDATE trigger. If count is 0, no rows were updated by the query
151 (this is not considered an error).
153 If the UPDATE command contains a RETURNING clause, the result will be
154 similar to that of a SELECT statement containing the columns and values
155 defined in the RETURNING list, computed over the row(s) updated by the
160 When a FROM clause is present, what essentially happens is that the
161 target table is joined to the tables mentioned in the from_item list,
162 and each output row of the join represents an update operation for the
163 target table. When using FROM you should ensure that the join produces
164 at most one output row for each row to be modified. In other words, a
165 target row shouldn't join to more than one row from the other table(s).
166 If it does, then only one of the join rows will be used to update the
167 target row, but which one will be used is not readily predictable.
169 Because of this indeterminacy, referencing other tables only within
170 sub-selects is safer, though often harder to read and slower than using
173 In the case of a partitioned table, updating a row might cause it to no
174 longer satisfy the partition constraint of the containing partition. In
175 that case, if there is some other partition in the partition tree for
176 which this row satisfies its partition constraint, then the row is
177 moved to that partition. If there is no such partition, an error will
178 occur. Behind the scenes, the row movement is actually a DELETE and
181 There is a possibility that a concurrent UPDATE or DELETE on the row
182 being moved will get a serialization failure error. Suppose session 1
183 is performing an UPDATE on a partition key, and meanwhile a concurrent
184 session 2 for which this row is visible performs an UPDATE or DELETE
185 operation on this row. In such case, session 2's UPDATE or DELETE will
186 detect the row movement and raise a serialization failure error (which
187 always returns with an SQLSTATE code '40001'). Applications may wish to
188 retry the transaction if this occurs. In the usual case where the table
189 is not partitioned, or where there is no row movement, session 2 would
190 have identified the newly updated row and carried out the UPDATE/DELETE
191 on this new row version.
193 Note that while rows can be moved from local partitions to a
194 foreign-table partition (provided the foreign data wrapper supports
195 tuple routing), they cannot be moved from a foreign-table partition to
198 An attempt of moving a row from one partition to another will fail if a
199 foreign key is found to directly reference an ancestor of the source
200 partition that is not the same as the ancestor that's mentioned in the
205 Change the word Drama to Dramatic in the column kind of the table
207 UPDATE films SET kind = 'Dramatic' WHERE kind = 'Drama';
209 Adjust temperature entries and reset precipitation to its default value
210 in one row of the table weather:
211 UPDATE weather SET temp_lo = temp_lo+1, temp_hi = temp_lo+15, prcp = DEFAULT
212 WHERE city = 'San Francisco' AND date = '2003-07-03';
214 Perform the same operation and return the updated entries, and the old
216 UPDATE weather SET temp_lo = temp_lo+1, temp_hi = temp_lo+15, prcp = DEFAULT
217 WHERE city = 'San Francisco' AND date = '2003-07-03'
218 RETURNING temp_lo, temp_hi, prcp, old.prcp AS old_prcp;
220 Use the alternative column-list syntax to do the same update:
221 UPDATE weather SET (temp_lo, temp_hi, prcp) = (temp_lo+1, temp_lo+15, DEFAULT)
222 WHERE city = 'San Francisco' AND date = '2003-07-03';
224 Increment the sales count of the salesperson who manages the account
225 for Acme Corporation, using the FROM clause syntax:
226 UPDATE employees SET sales_count = sales_count + 1 FROM accounts
227 WHERE accounts.name = 'Acme Corporation'
228 AND employees.id = accounts.sales_person;
230 Perform the same operation, using a sub-select in the WHERE clause:
231 UPDATE employees SET sales_count = sales_count + 1 WHERE id =
232 (SELECT sales_person FROM accounts WHERE name = 'Acme Corporation');
234 Update contact names in an accounts table to match the currently
235 assigned salespeople:
236 UPDATE accounts SET (contact_first_name, contact_last_name) =
237 (SELECT first_name, last_name FROM employees
238 WHERE employees.id = accounts.sales_person);
240 A similar result could be accomplished with a join:
241 UPDATE accounts SET contact_first_name = first_name,
242 contact_last_name = last_name
243 FROM employees WHERE employees.id = accounts.sales_person;
245 However, the second query may give unexpected results if employees.id
246 is not a unique key, whereas the first query is guaranteed to raise an
247 error if there are multiple id matches. Also, if there is no match for
248 a particular accounts.sales_person entry, the first query will set the
249 corresponding name fields to NULL, whereas the second query will not
250 update that row at all.
252 Update statistics in a summary table to match the current data:
253 UPDATE summary s SET (sum_x, sum_y, avg_x, avg_y) =
254 (SELECT sum(x), sum(y), avg(x), avg(y) FROM data d
255 WHERE d.group_id = s.group_id);
257 Attempt to insert a new stock item along with the quantity of stock. If
258 the item already exists, instead update the stock count of the existing
259 item. To do this without failing the entire transaction, use
264 INSERT INTO wines VALUES('Chateau Lafite 2003', '24');
265 -- Assume the above fails because of a unique key violation,
266 -- so now we issue these commands:
268 UPDATE wines SET stock = stock + 24 WHERE winename = 'Chateau Lafite 2003';
269 -- continue with other operations, and eventually
272 Change the kind column of the table films in the row on which the
273 cursor c_films is currently positioned:
274 UPDATE films SET kind = 'Dramatic' WHERE CURRENT OF c_films;
276 Updates affecting many rows can have negative effects on system
277 performance, such as table bloat, increased replica lag, and increased
278 lock contention. In such situations it can make sense to perform the
279 operation in smaller batches, possibly with a VACUUM operation on the
280 table between batches. While there is no LIMIT clause for UPDATE, it is
281 possible to get a similar effect through the use of a Common Table
282 Expression and a self-join. With the standard PostgreSQL table access
283 method, a self-join on the system column ctid is very efficient:
284 WITH exceeded_max_retries AS (
285 SELECT w.ctid FROM work_item AS w
286 WHERE w.status = 'active' AND w.num_retries > 10
287 ORDER BY w.retry_timestamp
291 UPDATE work_item SET status = 'failed'
292 FROM exceeded_max_retries AS emr
293 WHERE work_item.ctid = emr.ctid;
295 This command will need to be repeated until no rows remain to be
296 updated. Use of an ORDER BY clause allows the command to prioritize
297 which rows will be updated; it can also prevent deadlock with other
298 update operations if they use the same ordering. If lock contention is
299 a concern, then SKIP LOCKED can be added to the CTE to prevent multiple
300 commands from updating the same row. However, then a final UPDATE
301 without SKIP LOCKED or LIMIT will be needed to ensure that no matching
302 rows were overlooked.
306 This command conforms to the SQL standard, except that the FROM and
307 RETURNING clauses are PostgreSQL extensions, as is the ability to use
310 Some other database systems offer a FROM option in which the target
311 table is supposed to be listed again within FROM. That is not how
312 PostgreSQL interprets FROM. Be careful when porting applications that
315 According to the standard, the source value for a parenthesized
316 sub-list of target column names can be any row-valued expression
317 yielding the correct number of columns. PostgreSQL only allows the
318 source value to be a row constructor or a sub-SELECT. An individual
319 column's updated value can be specified as DEFAULT in the
320 row-constructor case, but not inside a sub-SELECT.