1UPDATE(7) PostgreSQL 9.2.24 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 [, ...] ) = ( { expression | DEFAULT } [, ...] ) } [, ...]
13 [ FROM from_list ]
14 [ WHERE condition | WHERE CURRENT OF cursor_name ]
15 [ RETURNING * | output_expression [ [ AS ] output_name ] [, ...] ]
16
18 UPDATE changes the values of the specified columns in all rows that
19 satisfy the condition. Only the columns to be modified need be
20 mentioned in the SET clause; columns not explicitly modified retain
21 their previous values.
22
23 There are two ways to modify a table using information contained in
24 other tables in the database: using sub-selects, or specifying
25 additional tables in the FROM clause. Which technique is more
26 appropriate depends on the specific circumstances.
27
28 The optional RETURNING clause causes UPDATE to compute and return
29 value(s) based on each row actually updated. Any expression using the
30 table's columns, and/or columns of other tables mentioned in FROM, can
31 be computed. The new (post-update) values of the table's columns are
32 used. The syntax of the RETURNING list is identical to that of the
33 output list of SELECT.
34
35 You must have the UPDATE privilege on the table, or at least on the
36 column(s) that are listed to be updated. You must also have the SELECT
37 privilege on any column whose values are read in the expressions or
38 condition.
39
41 with_query
42 The WITH clause allows you to specify one or more subqueries that
43 can be referenced by name in the UPDATE query. See Section 7.8,
44 “WITH Queries (Common Table Expressions)”, in the documentation and
45 SELECT(7) for details.
46
47 table_name
48 The name (optionally schema-qualified) of the table to update. If
49 ONLY is specified before the table name, matching rows are updated
50 in the named table only. If ONLY is not specified, matching rows
51 are also updated in any tables inheriting from the named table.
52 Optionally, * can be specified after the table name to explicitly
53 indicate that descendant tables are included.
54
55 alias
56 A substitute name for the target table. When an alias is provided,
57 it completely hides the actual name of the table. For example,
58 given UPDATE foo AS f, the remainder of the UPDATE statement must
59 refer to this table as f not foo.
60
61 column_name
62 The name of a column in the table named by table_name. The column
63 name can be qualified with a subfield name or array subscript, if
64 needed. Do not include the table's name in the specification of a
65 target column — for example, UPDATE tab SET tab.col = 1 is invalid.
66
67 expression
68 An expression to assign to the column. The expression can use the
69 old values of this and other columns in the table.
70
71 DEFAULT
72 Set the column to its default value (which will be NULL if no
73 specific default expression has been assigned to it).
74
75 from_list
76 A list of table expressions, allowing columns from other tables to
77 appear in the WHERE condition and the update expressions. This is
78 similar to the list of tables that can be specified in the FROM
79 Clause of a SELECT statement. Note that the target table must not
80 appear in the from_list, unless you intend a self-join (in which
81 case it must appear with an alias in the from_list).
82
83 condition
84 An expression that returns a value of type boolean. Only rows for
85 which this expression returns true will be updated.
86
87 cursor_name
88 The name of the cursor to use in a WHERE CURRENT OF condition. The
89 row to be updated is the one most recently fetched from this
90 cursor. The cursor must be a non-grouping query on the UPDATE's
91 target table. Note that WHERE CURRENT OF cannot be specified
92 together with a Boolean condition. See DECLARE(7) for more
93 information about using cursors with WHERE CURRENT OF.
94
95 output_expression
96 An expression to be computed and returned by the UPDATE command
97 after each row is updated. The expression can use any column names
98 of the table named by table_name or table(s) listed in FROM. Write
99 * to return all columns.
100
101 output_name
102 A name to use for a returned column.
103
105 On successful completion, an UPDATE command returns a command tag of
106 the form
107
108 UPDATE count
109
110 The count is the number of rows updated, including matched rows whose
111 values did not change. Note that the number may be less than the number
112 of rows that matched the condition when updates were suppressed by a
113 BEFORE UPDATE trigger. If count is 0, no rows were updated by the query
114 (this is not considered an error).
115
116 If the UPDATE command contains a RETURNING clause, the result will be
117 similar to that of a SELECT statement containing the columns and values
118 defined in the RETURNING list, computed over the row(s) updated by the
119 command.
120
122 When a FROM clause is present, what essentially happens is that the
123 target table is joined to the tables mentioned in the from_list, and
124 each output row of the join represents an update operation for the
125 target table. When using FROM you should ensure that the join produces
126 at most one output row for each row to be modified. In other words, a
127 target row shouldn't join to more than one row from the other table(s).
128 If it does, then only one of the join rows will be used to update the
129 target row, but which one will be used is not readily predictable.
130
131 Because of this indeterminacy, referencing other tables only within
132 sub-selects is safer, though often harder to read and slower than using
133 a join.
134
136 Change the word Drama to Dramatic in the column kind of the table
137 films:
138
139 UPDATE films SET kind = 'Dramatic' WHERE kind = 'Drama';
140
141 Adjust temperature entries and reset precipitation to its default value
142 in one row of the table weather:
143
144 UPDATE weather SET temp_lo = temp_lo+1, temp_hi = temp_lo+15, prcp = DEFAULT
145 WHERE city = 'San Francisco' AND date = '2003-07-03';
146
147 Perform the same operation and return the updated entries:
148
149 UPDATE weather SET temp_lo = temp_lo+1, temp_hi = temp_lo+15, prcp = DEFAULT
150 WHERE city = 'San Francisco' AND date = '2003-07-03'
151 RETURNING temp_lo, temp_hi, prcp;
152
153 Use the alternative column-list syntax to do the same update:
154
155 UPDATE weather SET (temp_lo, temp_hi, prcp) = (temp_lo+1, temp_lo+15, DEFAULT)
156 WHERE city = 'San Francisco' AND date = '2003-07-03';
157
158 Increment the sales count of the salesperson who manages the account
159 for Acme Corporation, using the FROM clause syntax:
160
161 UPDATE employees SET sales_count = sales_count + 1 FROM accounts
162 WHERE accounts.name = 'Acme Corporation'
163 AND employees.id = accounts.sales_person;
164
165 Perform the same operation, using a sub-select in the WHERE clause:
166
167 UPDATE employees SET sales_count = sales_count + 1 WHERE id =
168 (SELECT sales_person FROM accounts WHERE name = 'Acme Corporation');
169
170 Attempt to insert a new stock item along with the quantity of stock. If
171 the item already exists, instead update the stock count of the existing
172 item. To do this without failing the entire transaction, use
173 savepoints:
174
175 BEGIN;
176 -- other operations
177 SAVEPOINT sp1;
178 INSERT INTO wines VALUES('Chateau Lafite 2003', '24');
179 -- Assume the above fails because of a unique key violation,
180 -- so now we issue these commands:
181 ROLLBACK TO sp1;
182 UPDATE wines SET stock = stock + 24 WHERE winename = 'Chateau Lafite 2003';
183 -- continue with other operations, and eventually
184 COMMIT;
185
186 Change the kind column of the table films in the row on which the
187 cursor c_films is currently positioned:
188
189 UPDATE films SET kind = 'Dramatic' WHERE CURRENT OF c_films;
190
192 This command conforms to the SQL standard, except that the FROM and
193 RETURNING clauses are PostgreSQL extensions, as is the ability to use
194 WITH with UPDATE.
195
196 According to the standard, the column-list syntax should allow a list
197 of columns to be assigned from a single row-valued expression, such as
198 a sub-select:
199
200 UPDATE accounts SET (contact_last_name, contact_first_name) =
201 (SELECT last_name, first_name FROM salesmen
202 WHERE salesmen.id = accounts.sales_id);
203
204 This is not currently implemented — the source must be a list of
205 independent expressions.
206
207 Some other database systems offer a FROM option in which the target
208 table is supposed to be listed again within FROM. That is not how
209 PostgreSQL interprets FROM. Be careful when porting applications that
210 use this extension.
211
212
213
214PostgreSQL 9.2.24 2017-11-06 UPDATE(7)