1UPDATE(7)                        SQL Commands                        UPDATE(7)
2
3
4

NAME

6       UPDATE - update rows of a table
7
8

SYNOPSIS

10       UPDATE [ ONLY ] table [ [ AS ] alias ]
11           SET { column = { expression | DEFAULT } |
12                 ( column [, ...] ) = ( { expression | DEFAULT } [, ...] ) } [, ...]
13           [ FROM fromlist ]
14           [ WHERE condition | WHERE CURRENT OF cursor_name ]
15           [ RETURNING * | output_expression [ [ AS ] output_name ] [, ...] ]
16
17

DESCRIPTION

19       UPDATE  changes  the  values  of the specified columns in all rows that
20       satisfy the condition. Only the columns to be  modified  need  be  men‐
21       tioned  in the SET clause; columns not explicitly modified retain their
22       previous values.
23
24       By default, UPDATE will update rows in the specified table and all  its
25       subtables. If you wish to only update the specific table mentioned, you
26       must use the ONLY clause.
27
28       There are two ways to modify a table  using  information  contained  in
29       other  tables  in  the database: using sub-selects, or specifying addi‐
30       tional tables in the FROM clause. Which technique is  more  appropriate
31       depends on the specific circumstances.
32
33       The  optional  RETURNING  clause  causes  UPDATE  to compute and return
34       value(s) based on each row actually updated.  Any expression using  the
35       table's  columns, and/or columns of other tables mentioned in FROM, can
36       be computed.  The new (post-update) values of the table's  columns  are
37       used.   The  syntax  of  the RETURNING list is identical to that of the
38       output list of SELECT.
39
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
43       condition.
44

PARAMETERS

46       table  The name (optionally schema-qualified) of the table to update.
47
48       alias  A  substitute  name  for the target table. When an alias is pro‐
49              vided, it completely hides the actual name  of  the  table.  For
50              example,  given  UPDATE  foo  AS  f, the remainder of the UPDATE
51              statement must refer to this table as f not foo.
52
53       column The name of a column in table.  The column name can be qualified
54              with  a  subfield  name  or  array  subscript, if needed. Do not
55              include the table's name in the specification of a target column
56              — for example, UPDATE tab SET tab.col = 1 is invalid.
57
58       expression
59              An  expression  to  assign to the column. The expression can use
60              the old values of this and other columns in the table.
61
62       DEFAULT
63              Set the column to its default value (which will be  NULL  if  no
64              specific default expression has been assigned to it).
65
66       fromlist
67              A  list of table expressions, allowing columns from other tables
68              to appear in the WHERE condition  and  the  update  expressions.
69              This  is  similar to the list of tables that can be specified in
70              the FROM Clause [select(7)] of a SELECT statement. Note that the
71              target  table must not appear in the fromlist, unless you intend
72              a self-join (in which case it must appear with an alias  in  the
73              fromlist).
74
75       condition
76              An  expression  that returns a value of type boolean.  Only rows
77              for which this expression returns true will be updated.
78
79       cursor_name
80              The name of the cursor to use in a WHERE CURRENT  OF  condition.
81              The row to be updated is the one most recently fetched from this
82              cursor. The cursor must be a non-grouping query on the  UPDATE's
83              target  table.   Note  that WHERE CURRENT OF cannot be specified
84              together with a Boolean condition. See DECLARE [declare(7)]  for
85              more information about using cursors with WHERE CURRENT OF.
86
87       output_expression
88              An  expression to be computed and returned by the UPDATE command
89              after each row is updated. The expression  can  use  any  column
90              names  of  the  table  or  table(s)  listed in FROM.  Write * to
91              return all columns.
92
93       output_name
94              A name to use for a returned column.
95

OUTPUTS

97       On successful completion, an UPDATE command returns a  command  tag  of
98       the form
99
100       UPDATE count
101
102       The count is the number of rows updated. If count is 0, no rows matched
103       the condition (this is not considered an error).
104
105       If the UPDATE command contains a RETURNING clause, the result  will  be
106       similar to that of a SELECT statement containing the columns and values
107       defined in the RETURNING list, computed over the row(s) updated by  the
108       command.
109

NOTES

111       When  a  FROM  clause  is present, what essentially happens is that the
112       target table is joined to the tables mentioned  in  the  fromlist,  and
113       each output row of the join represents an update operation for the tar‐
114       get table. When using FROM you should ensure that the join produces  at
115       most one output row for each row to be modified. In other words, a tar‐
116       get row shouldn't join to more than one row from the other table(s). If
117       it does, then only one of the join rows will be used to update the tar‐
118       get row, but which one will be used is not readily predictable.
119
120       Because of this indeterminacy, referencing  other  tables  only  within
121       sub-selects is safer, though often harder to read and slower than using
122       a join.
123

EXAMPLES

125       Change the word Drama to Dramatic in  the  column  kind  of  the  table
126       films:
127
128       UPDATE films SET kind = 'Dramatic' WHERE kind = 'Drama';
129
130
131       Adjust temperature entries and reset precipitation to its default value
132       in one row of the table weather:
133
134       UPDATE weather SET temp_lo = temp_lo+1, temp_hi = temp_lo+15, prcp = DEFAULT
135         WHERE city = 'San Francisco' AND date = '2003-07-03';
136
137
138       Perform the same operation and return the updated entries:
139
140       UPDATE weather SET temp_lo = temp_lo+1, temp_hi = temp_lo+15, prcp = DEFAULT
141         WHERE city = 'San Francisco' AND date = '2003-07-03'
142         RETURNING temp_lo, temp_hi, prcp;
143
144
145       Use the alternative column-list syntax to do the same update:
146
147       UPDATE weather SET (temp_lo, temp_hi, prcp) = (temp_lo+1, temp_lo+15, DEFAULT)
148         WHERE city = 'San Francisco' AND date = '2003-07-03';
149
150
151       Increment the sales count of the salesperson who  manages  the  account
152       for Acme Corporation, using the FROM clause syntax:
153
154       UPDATE employees SET sales_count = sales_count + 1 FROM accounts
155         WHERE accounts.name = 'Acme Corporation'
156         AND employees.id = accounts.sales_person;
157
158
159       Perform the same operation, using a sub-select in the WHERE clause:
160
161       UPDATE employees SET sales_count = sales_count + 1 WHERE id =
162         (SELECT sales_person FROM accounts WHERE name = 'Acme Corporation');
163
164
165       Attempt to insert a new stock item along with the quantity of stock. If
166       the item already exists, instead update the stock count of the existing
167       item.  To  do  this  without  failing the entire transaction, use save‐
168       points:
169
170       BEGIN;
171       -- other operations
172       SAVEPOINT sp1;
173       INSERT INTO wines VALUES('Chateau Lafite 2003', '24');
174       -- Assume the above fails because of a unique key violation,
175       -- so now we issue these commands:
176       ROLLBACK TO sp1;
177       UPDATE wines SET stock = stock + 24 WHERE winename = 'Chateau Lafite 2003';
178       -- continue with other operations, and eventually
179       COMMIT;
180
181
182       Change the kind column of the table films in the row on which the  cur‐
183       sor c_films is currently positioned:
184
185       UPDATE films SET kind = 'Dramatic' WHERE CURRENT OF c_films;
186
187

COMPATIBILITY

189       This  command  conforms  to  the SQL standard, except that the FROM and
190       RETURNING clauses are PostgreSQL extensions.
191
192       According to the standard, the column-list syntax should allow  a  list
193       of  columns to be assigned from a single row-valued expression, such as
194       a sub-select:
195
196       UPDATE accounts SET (contact_last_name, contact_first_name) =
197           (SELECT last_name, first_name FROM salesmen
198            WHERE salesmen.id = accounts.sales_id);
199
200       This is not currently implemented — the source must be a list of  inde‐
201       pendent expressions.
202
203       Some other database systems offer a FROM option in which the target ta‐
204       ble is supposed to be listed again within FROM.  That is not how  Post‐
205       greSQL  interprets  FROM. Be careful when porting applications that use
206       this extension.
207
208
209
210SQL - Language Statements         2011-09-22                         UPDATE(7)
Impressum