1UPDATE(7) PostgreSQL 13.4 Documentation UPDATE(7)
2
3
4
6 UPDATE - update rows of a table
7
9 [ WITH [ RECURSIVE ] with_query [, ...] ]
10 UPDATE [ ONLY ] table_name [ * ] [ [ AS ] alias ]
11 SET { column_name = { expression | DEFAULT } |
12 ( column_name [, ...] ) = [ ROW ] ( { expression | DEFAULT } [, ...] ) |
13 ( column_name [, ...] ) = ( sub-SELECT )
14 } [, ...]
15 [ FROM from_item [, ...] ]
16 [ WHERE condition | WHERE CURRENT OF cursor_name ]
17 [ RETURNING * | output_expression [ [ AS ] output_name ] [, ...] ]
18
20 UPDATE changes the values of the specified columns in all rows that
21 satisfy the condition. Only the columns to be modified need be
22 mentioned in the SET clause; columns not explicitly modified retain
23 their previous values.
24
25 There are two ways to modify a table using information contained in
26 other tables in the database: using sub-selects, or specifying
27 additional tables in the FROM clause. Which technique is more
28 appropriate depends on the specific circumstances.
29
30 The optional RETURNING clause causes UPDATE to compute and return
31 value(s) based on each row actually updated. Any expression using the
32 table's columns, and/or columns of other tables mentioned in FROM, can
33 be computed. The new (post-update) values of the table's columns are
34 used. The syntax of the RETURNING list is identical to that of the
35 output list of SELECT.
36
37 You must have the UPDATE privilege on the table, or at least on the
38 column(s) that are listed to be updated. You must also have the SELECT
39 privilege on any column whose values are read in the expressions or
40 condition.
41
43 with_query
44 The WITH clause allows you to specify one or more subqueries that
45 can be referenced by name in the UPDATE query. See Section 7.8 and
46 SELECT(7) for details.
47
48 table_name
49 The name (optionally schema-qualified) of the table to update. If
50 ONLY is specified before the table name, matching rows are updated
51 in the named table only. If ONLY is not specified, matching rows
52 are also updated in any tables inheriting from the named table.
53 Optionally, * can be specified after the table name to explicitly
54 indicate that descendant tables are included.
55
56 alias
57 A substitute name for the target table. When an alias is provided,
58 it completely hides the actual name of the table. For example,
59 given UPDATE foo AS f, the remainder of the UPDATE statement must
60 refer to this table as f not foo.
61
62 column_name
63 The name of a column in the table named by table_name. The column
64 name can be qualified with a subfield name or array subscript, if
65 needed. Do not include the table's name in the specification of a
66 target column — for example, UPDATE table_name SET table_name.col =
67 1 is invalid.
68
69 expression
70 An expression to assign to the column. The expression can use the
71 old values of this and other columns in the table.
72
73 DEFAULT
74 Set the column to its default value (which will be NULL if no
75 specific default expression has been assigned to it). An identity
76 column will be set to a new value generated by the associated
77 sequence. For a generated column, specifying this is permitted but
78 merely specifies the normal behavior of computing the column from
79 its generation expression.
80
81 sub-SELECT
82 A SELECT sub-query that produces as many output columns as are
83 listed in the parenthesized column list preceding it. The sub-query
84 must yield no more than one row when executed. If it yields one
85 row, its column values are assigned to the target columns; if it
86 yields no rows, NULL values are assigned to the target columns. The
87 sub-query can refer to old values of the current row of the table
88 being updated.
89
90 from_item
91 A table expression allowing columns from other tables to appear in
92 the WHERE condition and update expressions. This uses the same
93 syntax as the FROM clause of a SELECT statement; for example, an
94 alias for the table name can be specified. Do not repeat the target
95 table as a from_item unless you intend a self-join (in which case
96 it must appear with an alias in the from_item).
97
98 condition
99 An expression that returns a value of type boolean. Only rows for
100 which this expression returns true will be updated.
101
102 cursor_name
103 The name of the cursor to use in a WHERE CURRENT OF condition. The
104 row to be updated is the one most recently fetched from this
105 cursor. The cursor must be a non-grouping query on the UPDATE's
106 target table. Note that WHERE CURRENT OF cannot be specified
107 together with a Boolean condition. See DECLARE(7) for more
108 information about using cursors with WHERE CURRENT OF.
109
110 output_expression
111 An expression to be computed and returned by the UPDATE command
112 after each row is updated. The expression can use any column names
113 of the table named by table_name or table(s) listed in FROM. Write
114 * to return all columns.
115
116 output_name
117 A name to use for a returned column.
118
120 On successful completion, an UPDATE command returns a command tag of
121 the form
122
123 UPDATE count
124
125 The count is the number of rows updated, including matched rows whose
126 values did not change. Note that the number may be less than the number
127 of rows that matched the condition when updates were suppressed by a
128 BEFORE UPDATE trigger. If count is 0, no rows were updated by the query
129 (this is not considered an error).
130
131 If the UPDATE command contains a RETURNING clause, the result will be
132 similar to that of a SELECT statement containing the columns and values
133 defined in the RETURNING list, computed over the row(s) updated by the
134 command.
135
137 When a FROM clause is present, what essentially happens is that the
138 target table is joined to the tables mentioned in the from_item list,
139 and each output row of the join represents an update operation for the
140 target table. When using FROM you should ensure that the join produces
141 at most one output row for each row to be modified. In other words, a
142 target row shouldn't join to more than one row from the other table(s).
143 If it does, then only one of the join rows will be used to update the
144 target row, but which one will be used is not readily predictable.
145
146 Because of this indeterminacy, referencing other tables only within
147 sub-selects is safer, though often harder to read and slower than using
148 a join.
149
150 In the case of a partitioned table, updating a row might cause it to no
151 longer satisfy the partition constraint of the containing partition. In
152 that case, if there is some other partition in the partition tree for
153 which this row satisfies its partition constraint, then the row is
154 moved to that partition. If there is no such partition, an error will
155 occur. Behind the scenes, the row movement is actually a DELETE and
156 INSERT operation.
157
158 There is a possibility that a concurrent UPDATE or DELETE on the row
159 being moved will get a serialization failure error. Suppose session 1
160 is performing an UPDATE on a partition key, and meanwhile a concurrent
161 session 2 for which this row is visible performs an UPDATE or DELETE
162 operation on this row. In such case, session 2's UPDATE or DELETE will
163 detect the row movement and raise a serialization failure error (which
164 always returns with an SQLSTATE code '40001'). Applications may wish to
165 retry the transaction if this occurs. In the usual case where the table
166 is not partitioned, or where there is no row movement, session 2 would
167 have identified the newly updated row and carried out the UPDATE/DELETE
168 on this new row version.
169
170 Note that while rows can be moved from local partitions to a
171 foreign-table partition (provided the foreign data wrapper supports
172 tuple routing), they cannot be moved from a foreign-table partition to
173 another partition.
174
176 Change the word Drama to Dramatic in the column kind of the table
177 films:
178
179 UPDATE films SET kind = 'Dramatic' WHERE kind = 'Drama';
180
181 Adjust temperature entries and reset precipitation to its default value
182 in one row of the table weather:
183
184 UPDATE weather SET temp_lo = temp_lo+1, temp_hi = temp_lo+15, prcp = DEFAULT
185 WHERE city = 'San Francisco' AND date = '2003-07-03';
186
187 Perform the same operation and return the updated entries:
188
189 UPDATE weather SET temp_lo = temp_lo+1, temp_hi = temp_lo+15, prcp = DEFAULT
190 WHERE city = 'San Francisco' AND date = '2003-07-03'
191 RETURNING temp_lo, temp_hi, prcp;
192
193 Use the alternative column-list syntax to do the same update:
194
195 UPDATE weather SET (temp_lo, temp_hi, prcp) = (temp_lo+1, temp_lo+15, DEFAULT)
196 WHERE city = 'San Francisco' AND date = '2003-07-03';
197
198 Increment the sales count of the salesperson who manages the account
199 for Acme Corporation, using the FROM clause syntax:
200
201 UPDATE employees SET sales_count = sales_count + 1 FROM accounts
202 WHERE accounts.name = 'Acme Corporation'
203 AND employees.id = accounts.sales_person;
204
205 Perform the same operation, using a sub-select in the WHERE clause:
206
207 UPDATE employees SET sales_count = sales_count + 1 WHERE id =
208 (SELECT sales_person FROM accounts WHERE name = 'Acme Corporation');
209
210 Update contact names in an accounts table to match the currently
211 assigned salesmen:
212
213 UPDATE accounts SET (contact_first_name, contact_last_name) =
214 (SELECT first_name, last_name FROM salesmen
215 WHERE salesmen.id = accounts.sales_id);
216
217 A similar result could be accomplished with a join:
218
219 UPDATE accounts SET contact_first_name = first_name,
220 contact_last_name = last_name
221 FROM salesmen WHERE salesmen.id = accounts.sales_id;
222
223 However, the second query may give unexpected results if salesmen.id is
224 not a unique key, whereas the first query is guaranteed to raise an
225 error if there are multiple id matches. Also, if there is no match for
226 a particular accounts.sales_id entry, the first query will set the
227 corresponding name fields to NULL, whereas the second query will not
228 update that row at all.
229
230 Update statistics in a summary table to match the current data:
231
232 UPDATE summary s SET (sum_x, sum_y, avg_x, avg_y) =
233 (SELECT sum(x), sum(y), avg(x), avg(y) FROM data d
234 WHERE d.group_id = s.group_id);
235
236 Attempt to insert a new stock item along with the quantity of stock. If
237 the item already exists, instead update the stock count of the existing
238 item. To do this without failing the entire transaction, use
239 savepoints:
240
241 BEGIN;
242 -- other operations
243 SAVEPOINT sp1;
244 INSERT INTO wines VALUES('Chateau Lafite 2003', '24');
245 -- Assume the above fails because of a unique key violation,
246 -- so now we issue these commands:
247 ROLLBACK TO sp1;
248 UPDATE wines SET stock = stock + 24 WHERE winename = 'Chateau Lafite 2003';
249 -- continue with other operations, and eventually
250 COMMIT;
251
252 Change the kind column of the table films in the row on which the
253 cursor c_films is currently positioned:
254
255 UPDATE films SET kind = 'Dramatic' WHERE CURRENT OF c_films;
256
258 This command conforms to the SQL standard, except that the FROM and
259 RETURNING clauses are PostgreSQL extensions, as is the ability to use
260 WITH with UPDATE.
261
262 Some other database systems offer a FROM option in which the target
263 table is supposed to be listed again within FROM. That is not how
264 PostgreSQL interprets FROM. Be careful when porting applications that
265 use this extension.
266
267 According to the standard, the source value for a parenthesized
268 sub-list of target column names can be any row-valued expression
269 yielding the correct number of columns. PostgreSQL only allows the
270 source value to be a row constructor or a sub-SELECT. An individual
271 column's updated value can be specified as DEFAULT in the
272 row-constructor case, but not inside a sub-SELECT.
273
274
275
276PostgreSQL 13.4 2021 UPDATE(7)