1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
|
<!--
doc/src/sgml/ref/update.sgml
PostgreSQL documentation
-->
<refentry id="SQL-UPDATE">
<refmeta>
<refentrytitle>UPDATE</refentrytitle>
<manvolnum>7</manvolnum>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>UPDATE</refname>
<refpurpose>update rows of a table</refpurpose>
</refnamediv>
<indexterm zone="sql-update">
<primary>UPDATE</primary>
</indexterm>
<refsynopsisdiv>
<synopsis>
[ WITH [ RECURSIVE ] <replaceable class="parameter">with_query</replaceable> [, ...] ]
UPDATE [ ONLY ] <replaceable class="PARAMETER">table</replaceable> [ [ AS ] <replaceable class="parameter">alias</replaceable> ]
SET { <replaceable class="PARAMETER">column</replaceable> = { <replaceable class="PARAMETER">expression</replaceable> | DEFAULT } |
( <replaceable class="PARAMETER">column</replaceable> [, ...] ) = ( { <replaceable class="PARAMETER">expression</replaceable> | DEFAULT } [, ...] ) } [, ...]
[ FROM <replaceable class="PARAMETER">from_list</replaceable> ]
[ WHERE <replaceable class="PARAMETER">condition</replaceable> | WHERE CURRENT OF <replaceable class="PARAMETER">cursor_name</replaceable> ]
[ RETURNING * | <replaceable class="parameter">output_expression</replaceable> [ [ AS ] <replaceable class="parameter">output_name</replaceable> ] [, ...] ]
</synopsis>
</refsynopsisdiv>
<refsect1>
<title>Description</title>
<para>
<command>UPDATE</command> 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 <literal>SET</literal> clause;
columns not explicitly modified retain their previous values.
</para>
<para>
By default, <command>UPDATE</command> will update rows in the
specified table and all its subtables. If you wish to only update
the specific table mentioned, you must use the <literal>ONLY</>
clause.
</para>
<para>
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 <literal>FROM</literal> clause. Which
technique is more appropriate depends on the specific
circumstances.
</para>
<para>
The optional <literal>RETURNING</> clause causes <command>UPDATE</>
to compute and return value(s) based on each row actually updated.
Any expression using the table's columns, and/or columns of other
tables mentioned in <literal>FROM</literal>, can be computed.
The new (post-update) values of the table's columns are used.
The syntax of the <literal>RETURNING</> list is identical to that of the
output list of <command>SELECT</>.
</para>
<para>
You must have the <literal>UPDATE</literal> privilege on the table,
or at least on the column(s) that are listed to be updated.
You must also have the <literal>SELECT</literal>
privilege on any column whose values are read in the
<replaceable class="parameter">expressions</replaceable> or
<replaceable class="parameter">condition</replaceable>.
</para>
</refsect1>
<refsect1>
<title>Parameters</title>
<variablelist>
<varlistentry>
<term><replaceable class="parameter">with_query</replaceable></term>
<listitem>
<para>
The <literal>WITH</literal> clause allows you to specify one or more
subqueries that can be referenced by name in the <command>UPDATE</>
query. See <xref linkend="queries-with"> and <xref linkend="sql-select">
for details.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">table</replaceable></term>
<listitem>
<para>
The name (optionally schema-qualified) of the table to update.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">alias</replaceable></term>
<listitem>
<para>
A substitute name for the target table. When an alias is
provided, it completely hides the actual name of the table. For
example, given <literal>UPDATE foo AS f</>, the remainder of the
<command>UPDATE</command> statement must refer to this table as
<literal>f</> not <literal>foo</>.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">column</replaceable></term>
<listitem>
<para>
The name of a column in <replaceable
class="PARAMETER">table</replaceable>.
The column name can be qualified with a subfield name or array
subscript, if needed. Do not include the table's name in the
specification of a target column — for example,
<literal>UPDATE tab SET tab.col = 1</> is invalid.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">expression</replaceable></term>
<listitem>
<para>
An expression to assign to the column. The expression can use the
old values of this and other columns in the table.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>DEFAULT</literal></term>
<listitem>
<para>
Set the column to its default value (which will be NULL if no
specific default expression has been assigned to it).
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">from_list</replaceable></term>
<listitem>
<para>
A list of table expressions, allowing columns from other tables
to appear in the <literal>WHERE</> condition and the update
expressions. This is similar to the list of tables that can be
specified in the <xref linkend="sql-from"
endterm="sql-from-title"> of a <command>SELECT</command>
statement. Note that the target table must not appear in the
<replaceable>from_list</>, unless you intend a self-join (in which
case it must appear with an alias in the <replaceable>from_list</>).
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">condition</replaceable></term>
<listitem>
<para>
An expression that returns a value of type <type>boolean</type>.
Only rows for which this expression returns <literal>true</>
will be updated.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">cursor_name</replaceable></term>
<listitem>
<para>
The name of the cursor to use in a <literal>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 <command>UPDATE</>'s target table.
Note that <literal>WHERE CURRENT OF</> cannot be
specified together with a Boolean condition. See
<xref linkend="sql-declare">
for more information about using cursors with
<literal>WHERE CURRENT OF</>.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">output_expression</replaceable></term>
<listitem>
<para>
An expression to be computed and returned by the <command>UPDATE</>
command after each row is updated. The expression can use any
column names of the <replaceable class="PARAMETER">table</replaceable>
or table(s) listed in <literal>FROM</>.
Write <literal>*</> to return all columns.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">output_name</replaceable></term>
<listitem>
<para>
A name to use for a returned column.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Outputs</title>
<para>
On successful completion, an <command>UPDATE</> command returns a command
tag of the form
<screen>
UPDATE <replaceable class="parameter">count</replaceable>
</screen>
The <replaceable class="parameter">count</replaceable> is the number
of rows updated. If <replaceable class="parameter">count</replaceable> is
0, no rows matched the <replaceable
class="parameter">condition</replaceable> (this is not considered
an error).
</para>
<para>
If the <command>UPDATE</> command contains a <literal>RETURNING</>
clause, the result will be similar to that of a <command>SELECT</>
statement containing the columns and values defined in the
<literal>RETURNING</> list, computed over the row(s) updated by the
command.
</para>
</refsect1>
<refsect1>
<title>Notes</title>
<para>
When a <literal>FROM</> clause is present, what essentially happens
is that the target table is joined to the tables mentioned in the
<replaceable>from_list</replaceable>, and each output row of the join
represents an update operation for the target table. When using
<literal>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't 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.
</para>
<para>
Because of this indeterminacy, referencing other tables only within
sub-selects is safer, though often harder to read and slower than
using a join.
</para>
</refsect1>
<refsect1>
<title>Examples</title>
<para>
Change the word <literal>Drama</> to <literal>Dramatic</> in the
column <structfield>kind</> of the table <structname>films</structname>:
<programlisting>
UPDATE films SET kind = 'Dramatic' WHERE kind = 'Drama';
</programlisting>
</para>
<para>
Adjust temperature entries and reset precipitation to its default
value in one row of the table <structname>weather</structname>:
<programlisting>
UPDATE weather SET temp_lo = temp_lo+1, temp_hi = temp_lo+15, prcp = DEFAULT
WHERE city = 'San Francisco' AND date = '2003-07-03';
</programlisting>
</para>
<para>
Perform the same operation and return the updated entries:
<programlisting>
UPDATE weather SET temp_lo = temp_lo+1, temp_hi = temp_lo+15, prcp = DEFAULT
WHERE city = 'San Francisco' AND date = '2003-07-03'
RETURNING temp_lo, temp_hi, prcp;
</programlisting>
</para>
<para>
Use the alternative column-list syntax to do the same update:
<programlisting>
UPDATE weather SET (temp_lo, temp_hi, prcp) = (temp_lo+1, temp_lo+15, DEFAULT)
WHERE city = 'San Francisco' AND date = '2003-07-03';
</programlisting>
</para>
<para>
Increment the sales count of the salesperson who manages the
account for Acme Corporation, using the <literal>FROM</literal>
clause syntax:
<programlisting>
UPDATE employees SET sales_count = sales_count + 1 FROM accounts
WHERE accounts.name = 'Acme Corporation'
AND employees.id = accounts.sales_person;
</programlisting>
</para>
<para>
Perform the same operation, using a sub-select in the
<literal>WHERE</literal> clause:
<programlisting>
UPDATE employees SET sales_count = sales_count + 1 WHERE id =
(SELECT sales_person FROM accounts WHERE name = 'Acme Corporation');
</programlisting>
</para>
<para>
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:
<programlisting>
BEGIN;
-- other operations
SAVEPOINT sp1;
INSERT INTO wines VALUES('Chateau Lafite 2003', '24');
-- 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 = 'Chateau Lafite 2003';
-- continue with other operations, and eventually
COMMIT;
</programlisting>
</para>
<para>
Change the <structfield>kind</> column of the table
<structname>films</structname> in the row on which the cursor
<literal>c_films</> is currently positioned:
<programlisting>
UPDATE films SET kind = 'Dramatic' WHERE CURRENT OF c_films;
</programlisting>
</para>
</refsect1>
<refsect1>
<title>Compatibility</title>
<para>
This command conforms to the <acronym>SQL</acronym> standard, except
that the <literal>FROM</literal> and <literal>RETURNING</> clauses
are <productname>PostgreSQL</productname> extensions, as is the ability
to use <literal>WITH</> with <command>UPDATE</>.
</para>
<para>
According to the standard, the column-list syntax should allow a list
of columns to be assigned from a single row-valued expression, such
as a sub-select:
<programlisting>
UPDATE accounts SET (contact_last_name, contact_first_name) =
(SELECT last_name, first_name FROM salesmen
WHERE salesmen.id = accounts.sales_id);
</programlisting>
This is not currently implemented — the source must be a list
of independent expressions.
</para>
<para>
Some other database systems offer a <literal>FROM</> option in which
the target table is supposed to be listed again within <literal>FROM</>.
That is not how <productname>PostgreSQL</productname> interprets
<literal>FROM</>. Be careful when porting applications that use this
extension.
</para>
</refsect1>
</refentry>
|