1UPDATE(7) PostgreSQL 11.3 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_list ]
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).
76
77 sub-SELECT
78 A SELECT sub-query that produces as many output columns as are
79 listed in the parenthesized column list preceding it. The sub-query
80 must yield no more than one row when executed. If it yields one
81 row, its column values are assigned to the target columns; if it
82 yields no rows, NULL values are assigned to the target columns. The
83 sub-query can refer to old values of the current row of the table
84 being updated.
85
86 from_list
87 A list of table expressions, allowing columns from other tables to
88 appear in the WHERE condition and the update expressions. This is
89 similar to the list of tables that can be specified in the FROM
90 Clause of a SELECT statement. Note that the target table must not
91 appear in the from_list, unless you intend a self-join (in which
92 case it must appear with an alias in the from_list).
93
94 condition
95 An expression that returns a value of type boolean. Only rows for
96 which this expression returns true will be updated.
97
98 cursor_name
99 The name of the cursor to use in a WHERE CURRENT OF condition. The
100 row to be updated is the one most recently fetched from this
101 cursor. The cursor must be a non-grouping query on the UPDATE's
102 target table. Note that WHERE CURRENT OF cannot be specified
103 together with a Boolean condition. See DECLARE(7) for more
104 information about using cursors with WHERE CURRENT OF.
105
106 output_expression
107 An expression to be computed and returned by the UPDATE command
108 after each row is updated. The expression can use any column names
109 of the table named by table_name or table(s) listed in FROM. Write
110 * to return all columns.
111
112 output_name
113 A name to use for a returned column.
114
116 On successful completion, an UPDATE command returns a command tag of
117 the form
118
119 UPDATE count
120
121 The count is the number of rows updated, including matched rows whose
122 values did not change. Note that the number may be less than the number
123 of rows that matched the condition when updates were suppressed by a
124 BEFORE UPDATE trigger. If count is 0, no rows were updated by the query
125 (this is not considered an error).
126
127 If the UPDATE command contains a RETURNING clause, the result will be
128 similar to that of a SELECT statement containing the columns and values
129 defined in the RETURNING list, computed over the row(s) updated by the
130 command.
131
133 When a FROM clause is present, what essentially happens is that the
134 target table is joined to the tables mentioned in the from_list, and
135 each output row of the join represents an update operation for the
136 target table. When using FROM you should ensure that the join produces
137 at most one output row for each row to be modified. In other words, a
138 target row shouldn't join to more than one row from the other table(s).
139 If it does, then only one of the join rows will be used to update the
140 target row, but which one will be used is not readily predictable.
141
142 Because of this indeterminacy, referencing other tables only within
143 sub-selects is safer, though often harder to read and slower than using
144 a join.
145
146 In the case of a partitioned table, updating a row might cause it to no
147 longer satisfy the partition constraint of the containing partition. In
148 that case, if there is some other partition in the partition tree for
149 which this row satisfies its partition constraint, then the row is
150 moved to that partition. If there is no such partition, an error will
151 occur. Behind the scenes, the row movement is actually a DELETE and
152 INSERT operation.
153
154 There is a possibility that a concurrent UPDATE or DELETE on the row
155 being moved will get a serialization failure error. Suppose session 1
156 is performing an UPDATE on a partition key, and meanwhile a concurrent
157 session 2 for which this row is visible performs an UPDATE or DELETE
158 operation on this row. In such case, session 2's UPDATE or DELETE will
159 detect the row movement and raise a serialization failure error (which
160 always returns with an SQLSTATE code '40001'). Applications may wish to
161 retry the transaction if this occurs. In the usual case where the table
162 is not partitioned, or where there is no row movement, session 2 would
163 have identified the newly updated row and carried out the UPDATE/DELETE
164 on this new row version.
165
166 Note that while rows can be moved from local partitions to a
167 foreign-table partition (provided the foreign data wrapper supports
168 tuple routing), they cannot be moved from a foreign-table partition to
169 another partition.
170
172 Change the word Drama to Dramatic in the column kind of the table
173 films:
174
175 UPDATE films SET kind = 'Dramatic' WHERE kind = 'Drama';
176
177 Adjust temperature entries and reset precipitation to its default value
178 in one row of the table weather:
179
180 UPDATE weather SET temp_lo = temp_lo+1, temp_hi = temp_lo+15, prcp = DEFAULT
181 WHERE city = 'San Francisco' AND date = '2003-07-03';
182
183 Perform the same operation and return the updated entries:
184
185 UPDATE weather SET temp_lo = temp_lo+1, temp_hi = temp_lo+15, prcp = DEFAULT
186 WHERE city = 'San Francisco' AND date = '2003-07-03'
187 RETURNING temp_lo, temp_hi, prcp;
188
189 Use the alternative column-list syntax to do the same update:
190
191 UPDATE weather SET (temp_lo, temp_hi, prcp) = (temp_lo+1, temp_lo+15, DEFAULT)
192 WHERE city = 'San Francisco' AND date = '2003-07-03';
193
194 Increment the sales count of the salesperson who manages the account
195 for Acme Corporation, using the FROM clause syntax:
196
197 UPDATE employees SET sales_count = sales_count + 1 FROM accounts
198 WHERE accounts.name = 'Acme Corporation'
199 AND employees.id = accounts.sales_person;
200
201 Perform the same operation, using a sub-select in the WHERE clause:
202
203 UPDATE employees SET sales_count = sales_count + 1 WHERE id =
204 (SELECT sales_person FROM accounts WHERE name = 'Acme Corporation');
205
206 Update contact names in an accounts table to match the currently
207 assigned salesmen:
208
209 UPDATE accounts SET (contact_first_name, contact_last_name) =
210 (SELECT first_name, last_name FROM salesmen
211 WHERE salesmen.id = accounts.sales_id);
212
213 A similar result could be accomplished with a join:
214
215 UPDATE accounts SET contact_first_name = first_name,
216 contact_last_name = last_name
217 FROM salesmen WHERE salesmen.id = accounts.sales_id;
218
219 However, the second query may give unexpected results if salesmen.id is
220 not a unique key, whereas the first query is guaranteed to raise an
221 error if there are multiple id matches. Also, if there is no match for
222 a particular accounts.sales_id entry, the first query will set the
223 corresponding name fields to NULL, whereas the second query will not
224 update that row at all.
225
226 Update statistics in a summary table to match the current data:
227
228 UPDATE summary s SET (sum_x, sum_y, avg_x, avg_y) =
229 (SELECT sum(x), sum(y), avg(x), avg(y) FROM data d
230 WHERE d.group_id = s.group_id);
231
232 Attempt to insert a new stock item along with the quantity of stock. If
233 the item already exists, instead update the stock count of the existing
234 item. To do this without failing the entire transaction, use
235 savepoints:
236
237 BEGIN;
238 -- other operations
239 SAVEPOINT sp1;
240 INSERT INTO wines VALUES('Chateau Lafite 2003', '24');
241 -- Assume the above fails because of a unique key violation,
242 -- so now we issue these commands:
243 ROLLBACK TO sp1;
244 UPDATE wines SET stock = stock + 24 WHERE winename = 'Chateau Lafite 2003';
245 -- continue with other operations, and eventually
246 COMMIT;
247
248 Change the kind column of the table films in the row on which the
249 cursor c_films is currently positioned:
250
251 UPDATE films SET kind = 'Dramatic' WHERE CURRENT OF c_films;
252
254 This command conforms to the SQL standard, except that the FROM and
255 RETURNING clauses are PostgreSQL extensions, as is the ability to use
256 WITH with UPDATE.
257
258 Some other database systems offer a FROM option in which the target
259 table is supposed to be listed again within FROM. That is not how
260 PostgreSQL interprets FROM. Be careful when porting applications that
261 use this extension.
262
263 According to the standard, the source value for a parenthesized
264 sub-list of target column names can be any row-valued expression
265 yielding the correct number of columns. PostgreSQL only allows the
266 source value to be a row constructor or a sub-SELECT. An individual
267 column's updated value can be specified as DEFAULT in the
268 row-constructor case, but not inside a sub-SELECT.
269
270
271
272PostgreSQL 11.3 2019 UPDATE(7)