1UPDATE() SQL Commands UPDATE()
2
3
4
6 UPDATE - update rows of a table
7
8
10 UPDATE [ ONLY ] table [ [ AS ] alias ]
11 SET { column = { expression | DEFAULT } |
12 ( column [, ...] ) = ( { expression | DEFAULT } [, ...] ) } [, ...]
13 [ FROM fromlist ]
14 [ WHERE condition ]
15 [ RETURNING * | output_expression [ AS output_name ] [, ...] ]
16
17
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 to update it, as well
41 as the SELECT privilege to any table whose values are read in the
42 expressions or condition.
43
45 table The name (optionally schema-qualified) of the table to update.
46
47 alias A substitute name for the target table. When an alias is pro‐
48 vided, it completely hides the actual name of the table. For
49 example, given UPDATE foo AS f, the remainder of the UPDATE
50 statement must refer to this table as f not foo.
51
52 column The name of a column in table. The column name can be qualified
53 with a subfield name or array subscript, if needed. Do not
54 include the table's name in the specification of a target column
55 — for example, UPDATE tab SET tab.col = 1 is invalid.
56
57 expression
58 An expression to assign to the column. The expression may use
59 the old values of this and other columns in the table.
60
61 DEFAULT
62 Set the column to its default value (which will be NULL if no
63 specific default expression has been assigned to it).
64
65 fromlist
66 A list of table expressions, allowing columns from other tables
67 to appear in the WHERE condition and the update expressions.
68 This is similar to the list of tables that can be specified in
69 the FROM Clause [select(7)] of a SELECT statement. Note that the
70 target table must not appear in the fromlist, unless you intend
71 a self-join (in which case it must appear with an alias in the
72 fromlist).
73
74 condition
75 An expression that returns a value of type boolean. Only rows
76 for which this expression returns true will be updated.
77
78 output_expression
79 An expression to be computed and returned by the UPDATE command
80 after each row is updated. The expression may use any column
81 names of the table or table(s) listed in FROM. Write * to
82 return all columns.
83
84 output_name
85 A name to use for a returned column.
86
88 On successful completion, an UPDATE command returns a command tag of
89 the form
90
91 UPDATE count
92
93 The count is the number of rows updated. If count is 0, no rows matched
94 the condition (this is not considered an error).
95
96 If the UPDATE command contains a RETURNING clause, the result will be
97 similar to that of a SELECT statement containing the columns and values
98 defined in the RETURNING list, computed over the row(s) updated by the
99 command.
100
102 When a FROM clause is present, what essentially happens is that the
103 target table is joined to the tables mentioned in the fromlist, and
104 each output row of the join represents an update operation for the tar‐
105 get table. When using FROM you should ensure that the join produces at
106 most one output row for each row to be modified. In other words, a tar‐
107 get row shouldn't join to more than one row from the other table(s). If
108 it does, then only one of the join rows will be used to update the tar‐
109 get row, but which one will be used is not readily predictable.
110
111 Because of this indeterminacy, referencing other tables only within
112 sub-selects is safer, though often harder to read and slower than using
113 a join.
114
116 Change the word Drama to Dramatic in the column kind of the table
117 films:
118
119 UPDATE films SET kind = 'Dramatic' WHERE kind = 'Drama';
120
121
122 Adjust temperature entries and reset precipitation to its default value
123 in one row of the table weather:
124
125 UPDATE weather SET temp_lo = temp_lo+1, temp_hi = temp_lo+15, prcp = DEFAULT
126 WHERE city = 'San Francisco' AND date = '2003-07-03';
127
128
129 Perform the same operation and return the updated entries:
130
131 UPDATE weather SET temp_lo = temp_lo+1, temp_hi = temp_lo+15, prcp = DEFAULT
132 WHERE city = 'San Francisco' AND date = '2003-07-03'
133 RETURNING temp_lo, temp_hi, prcp;
134
135
136 Use the alternative column-list syntax to do the same update:
137
138 UPDATE weather SET (temp_lo, temp_hi, prcp) = (temp_lo+1, temp_lo+15, DEFAULT)
139 WHERE city = 'San Francisco' AND date = '2003-07-03';
140
141
142 Increment the sales count of the salesperson who manages the account
143 for Acme Corporation, using the FROM clause syntax:
144
145 UPDATE employees SET sales_count = sales_count + 1 FROM accounts
146 WHERE accounts.name = 'Acme Corporation'
147 AND employees.id = accounts.sales_person;
148
149
150 Perform the same operation, using a sub-select in the WHERE clause:
151
152 UPDATE employees SET sales_count = sales_count + 1 WHERE id =
153 (SELECT sales_person FROM accounts WHERE name = 'Acme Corporation');
154
155
156 Attempt to insert a new stock item along with the quantity of stock. If
157 the item already exists, instead update the stock count of the existing
158 item. To do this without failing the entire transaction, use save‐
159 points.
160
161 BEGIN;
162 -- other operations
163 SAVEPOINT sp1;
164 INSERT INTO wines VALUES('Chateau Lafite 2003', '24');
165 -- Assume the above fails because of a unique key violation,
166 -- so now we issue these commands:
167 ROLLBACK TO sp1;
168 UPDATE wines SET stock = stock + 24 WHERE winename = 'Chateau Lafite 2003';
169 -- continue with other operations, and eventually
170 COMMIT;
171
172
174 This command conforms to the SQL standard, except that the FROM and
175 RETURNING clauses are PostgreSQL extensions.
176
177 According to the standard, the column-list syntax should allow a list
178 of columns to be assigned from a single row-valued expression, such as
179 a sub-select:
180
181 UPDATE accounts SET (contact_last_name, contact_first_name) =
182 (SELECT last_name, first_name FROM salesmen
183 WHERE salesmen.id = accounts.sales_id);
184
185 This is not currently implemented — the source must be a list of inde‐
186 pendent expressions.
187
188 Some other database systems offer a FROM option in which the target ta‐
189 ble is supposed to be listed again within FROM. That is not how Post‐
190 greSQL interprets FROM. Be careful when porting applications that use
191 this extension.
192
193
194
195SQL - Language Statements 2008-06-08 UPDATE()