aboutsummaryrefslogtreecommitdiff
path: root/doc/src/sgml/ref/update.sgml
blob: f642b3c8e6d2b7115baa7a0f1d8c76bffd895246 (plain)
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
<!--
$PostgreSQL: pgsql/doc/src/sgml/ref/update.sgml,v 1.33.2.2 2006/03/08 22:59:17 tgl Exp $
PostgreSQL documentation
-->

<refentry id="SQL-UPDATE">
 <refmeta>
  <refentrytitle id="SQL-UPDATE-TITLE">UPDATE</refentrytitle>
  <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>
UPDATE [ ONLY ] <replaceable class="PARAMETER">table</replaceable> SET <replaceable class="PARAMETER">column</replaceable> = { <replaceable class="PARAMETER">expression</replaceable> | DEFAULT } [, ...]
    [ FROM <replaceable class="PARAMETER">fromlist</replaceable> ]
    [ WHERE <replaceable class="PARAMETER">condition</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>
   You must have the <literal>UPDATE</literal> privilege on the table
   to update it, as well as the <literal>SELECT</literal>
   privilege to any table whose values are read in the
   <replaceable class="parameter">expression</replaceable>s or
   <replaceable class="parameter">condition</replaceable>.
  </para>
 </refsect1>

 <refsect1>
  <title>Parameters</title>

  <variablelist>
   <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">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.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="PARAMETER">expression</replaceable></term>
    <listitem>
     <para>
      An expression to assign to the column.  The expression may 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">fromlist</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>fromlist</>, unless you intend a self-join (in which
      case it must appear with an alias in the <replaceable>fromlist</>).
     </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>
  </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>
 </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>fromlist</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>
   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>
 </refsect1>

 <refsect1>
  <title>Compatibility</title>

  <para>
   This command conforms to the <acronym>SQL</acronym> standard, except
   that the <literal>FROM</literal> clause is a
   <productname>PostgreSQL</productname> extension.
  </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>

<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"../reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
-->