1 <!-- doc/src/sgml/dml.sgml -->
4 <title>Data Manipulation
</title>
7 The previous chapter discussed how to create tables and other
8 structures to hold your data. Now it is time to fill the tables
9 with data. This chapter covers how to insert, update, and delete
10 table data. The chapter
11 after this will finally explain how to extract your long-lost data
15 <sect1 id=
"dml-insert">
16 <title>Inserting Data
</title>
18 <indexterm zone=
"dml-insert">
19 <primary>inserting
</primary>
22 <indexterm zone=
"dml-insert">
23 <primary>INSERT
</primary>
27 When a table is created, it contains no data. The first thing to
28 do before a database can be of much use is to insert data. Data is
29 inserted one row at a time. You can also insert more than one row
30 in a single command, but it is not possible to insert something that
31 is not a complete row. Even if you know only some column values, a
32 complete row must be created.
36 To create a new row, use the
<xref linkend=
"sql-insert"/>
37 command. The command requires the
38 table name and column values. For
39 example, consider the products table from
<xref linkend=
"ddl"/>:
41 CREATE TABLE products (
47 An example command to insert a row would be:
49 INSERT INTO products VALUES (
1, 'Cheese',
9.99);
51 The data values are listed in the order in which the columns appear
52 in the table, separated by commas. Usually, the data values will
53 be literals (constants), but scalar expressions are also allowed.
57 The above syntax has the drawback that you need to know the order
58 of the columns in the table. To avoid this you can also list the
59 columns explicitly. For example, both of the following commands
60 have the same effect as the one above:
62 INSERT INTO products (product_no, name, price) VALUES (
1, 'Cheese',
9.99);
63 INSERT INTO products (name, price, product_no) VALUES ('Cheese',
9.99,
1);
65 Many users consider it good practice to always list the column
70 If you don't have values for all the columns, you can omit some of
71 them. In that case, the columns will be filled with their default
74 INSERT INTO products (product_no, name) VALUES (
1, 'Cheese');
75 INSERT INTO products VALUES (
1, 'Cheese');
77 The second form is a
<productname>PostgreSQL
</productname>
78 extension. It fills the columns from the left with as many values
79 as are given, and the rest will be defaulted.
83 For clarity, you can also request default values explicitly, for
84 individual columns or for the entire row:
86 INSERT INTO products (product_no, name, price) VALUES (
1, 'Cheese', DEFAULT);
87 INSERT INTO products DEFAULT VALUES;
92 You can insert multiple rows in a single command:
94 INSERT INTO products (product_no, name, price) VALUES
102 It is also possible to insert the result of a query (which might be no
103 rows, one row, or many rows):
105 INSERT INTO products (product_no, name, price)
106 SELECT product_no, name, price FROM new_products
107 WHERE release_date = 'today';
109 This provides the full power of the SQL query mechanism (
<xref
110 linkend=
"queries"/>) for computing the rows to be inserted.
115 When inserting a lot of data at the same time, consider using
116 the
<xref linkend=
"sql-copy"/> command.
117 It is not as flexible as the
<xref linkend=
"sql-insert"/>
118 command, but is more efficient. Refer
119 to
<xref linkend=
"populate"/> for more information on improving
120 bulk loading performance.
125 <sect1 id=
"dml-update">
126 <title>Updating Data
</title>
128 <indexterm zone=
"dml-update">
129 <primary>updating
</primary>
132 <indexterm zone=
"dml-update">
133 <primary>UPDATE
</primary>
137 The modification of data that is already in the database is
138 referred to as updating. You can update individual rows, all the
139 rows in a table, or a subset of all rows. Each column can be
140 updated separately; the other columns are not affected.
144 To update existing rows, use the
<xref linkend=
"sql-update"/>
145 command. This requires
146 three pieces of information:
147 <orderedlist spacing=
"compact">
149 <para>The name of the table and column to update
</para>
153 <para>The new value of the column
</para>
157 <para>Which row(s) to update
</para>
163 Recall from
<xref linkend=
"ddl"/> that SQL does not, in general,
164 provide a unique identifier for rows. Therefore it is not
165 always possible to directly specify which row to update.
166 Instead, you specify which conditions a row must meet in order to
167 be updated. Only if you have a primary key in the table (independent of
168 whether you declared it or not) can you reliably address individual rows
169 by choosing a condition that matches the primary key.
170 Graphical database access tools rely on this fact to allow you to
171 update rows individually.
175 For example, this command updates all products that have a price of
176 5 to have a price of
10:
178 UPDATE products SET price =
10 WHERE price =
5;
180 This might cause zero, one, or many rows to be updated. It is not
181 an error to attempt an update that does not match any rows.
185 Let's look at that command in detail. First is the key word
186 <literal>UPDATE
</literal> followed by the table name. As usual,
187 the table name can be schema-qualified, otherwise it is looked up
188 in the path. Next is the key word
<literal>SET
</literal> followed
189 by the column name, an equal sign, and the new column value. The
190 new column value can be any scalar expression, not just a constant.
191 For example, if you want to raise the price of all products by
10%
194 UPDATE products SET price = price *
1.10;
196 As you see, the expression for the new value can refer to the existing
197 value(s) in the row. We also left out the
<literal>WHERE
</literal> clause.
198 If it is omitted, it means that all rows in the table are updated.
199 If it is present, only those rows that match the
200 <literal>WHERE
</literal> condition are updated. Note that the equals
201 sign in the
<literal>SET
</literal> clause is an assignment while
202 the one in the
<literal>WHERE
</literal> clause is a comparison, but
203 this does not create any ambiguity. Of course, the
204 <literal>WHERE
</literal> condition does
205 not have to be an equality test. Many other operators are
206 available (see
<xref linkend=
"functions"/>). But the expression
207 needs to evaluate to a Boolean result.
211 You can update more than one column in an
212 <command>UPDATE
</command> command by listing more than one
213 assignment in the
<literal>SET
</literal> clause. For example:
215 UPDATE mytable SET a =
5, b =
3, c =
1 WHERE a
> 0;
220 <sect1 id=
"dml-delete">
221 <title>Deleting Data
</title>
223 <indexterm zone=
"dml-delete">
224 <primary>deleting
</primary>
227 <indexterm zone=
"dml-delete">
228 <primary>DELETE
</primary>
232 So far we have explained how to add data to tables and how to
233 change data. What remains is to discuss how to remove data that is
234 no longer needed. Just as adding data is only possible in whole
235 rows, you can only remove entire rows from a table. In the
236 previous section we explained that SQL does not provide a way to
237 directly address individual rows. Therefore, removing rows can
238 only be done by specifying conditions that the rows to be removed
239 have to match. If you have a primary key in the table then you can
240 specify the exact row. But you can also remove groups of rows
241 matching a condition, or you can remove all rows in the table at
246 You use the
<xref linkend=
"sql-delete"/>
247 command to remove rows; the syntax is very similar to the
248 <xref linkend=
"sql-update"/> command. For instance, to remove all
249 rows from the products table that have a price of
10, use:
251 DELETE FROM products WHERE price =
10;
258 DELETE FROM products;
260 then all rows in the table will be deleted! Caveat programmer.
264 <sect1 id=
"dml-returning">
265 <title>Returning Data from Modified Rows
</title>
267 <indexterm zone=
"dml-returning">
268 <primary>RETURNING
</primary>
271 <indexterm zone=
"dml-returning">
272 <primary>INSERT
</primary>
273 <secondary>RETURNING
</secondary>
276 <indexterm zone=
"dml-returning">
277 <primary>UPDATE
</primary>
278 <secondary>RETURNING
</secondary>
281 <indexterm zone=
"dml-returning">
282 <primary>DELETE
</primary>
283 <secondary>RETURNING
</secondary>
286 <indexterm zone=
"dml-returning">
287 <primary>MERGE
</primary>
288 <secondary>RETURNING
</secondary>
292 Sometimes it is useful to obtain data from modified rows while they are
293 being manipulated. The
<command>INSERT
</command>,
<command>UPDATE
</command>,
294 <command>DELETE
</command>, and
<command>MERGE
</command> commands all have an
295 optional
<literal>RETURNING
</literal> clause that supports this. Use
296 of
<literal>RETURNING
</literal> avoids performing an extra database query to
297 collect the data, and is especially valuable when it would otherwise be
298 difficult to identify the modified rows reliably.
302 The allowed contents of a
<literal>RETURNING
</literal> clause are the same as
303 a
<command>SELECT
</command> command's output list
304 (see
<xref linkend=
"queries-select-lists"/>). It can contain column
305 names of the command's target table, or value expressions using those
306 columns. A common shorthand is
<literal>RETURNING *
</literal>, which selects
307 all columns of the target table in order.
311 In an
<command>INSERT
</command>, the default data available to
312 <literal>RETURNING
</literal> is
313 the row as it was inserted. This is not so useful in trivial inserts,
314 since it would just repeat the data provided by the client. But it can
315 be very handy when relying on computed default values. For example,
316 when using a
<link linkend=
"datatype-serial"><type>serial
</type></link>
317 column to provide unique identifiers,
<literal>RETURNING
</literal> can return
318 the ID assigned to a new row:
320 CREATE TABLE users (firstname text, lastname text, id serial primary key);
322 INSERT INTO users (firstname, lastname) VALUES ('Joe', 'Cool') RETURNING id;
324 The
<literal>RETURNING
</literal> clause is also very useful
325 with
<literal>INSERT ... SELECT
</literal>.
329 In an
<command>UPDATE
</command>, the default data available to
330 <literal>RETURNING
</literal> is
331 the new content of the modified row. For example:
333 UPDATE products SET price = price *
1.10
334 WHERE price
<=
99.99
335 RETURNING name, price AS new_price;
340 In a
<command>DELETE
</command>, the default data available to
341 <literal>RETURNING
</literal> is
342 the content of the deleted row. For example:
345 WHERE obsoletion_date = 'today'
351 In a
<command>MERGE
</command>, the default data available to
352 <literal>RETURNING
</literal> is
353 the content of the source row plus the content of the inserted, updated, or
354 deleted target row. Since it is quite common for the source and target to
355 have many of the same columns, specifying
<literal>RETURNING *
</literal>
356 can lead to a lot of duplicated columns, so it is often more useful to
357 qualify it so as to return just the source or target row. For example:
359 MERGE INTO products p USING new_products n ON p.product_no = n.product_no
360 WHEN NOT MATCHED THEN INSERT VALUES (n.product_no, n.name, n.price)
361 WHEN MATCHED THEN UPDATE SET name = n.name, price = n.price
367 In each of these commands, it is also possible to explicitly return the
368 old and new content of the modified row. For example:
370 UPDATE products SET price = price *
1.10
371 WHERE price
<=
99.99
372 RETURNING name, old.price AS old_price, new.price AS new_price,
373 new.price - old.price AS price_change;
375 In this example, writing
<literal>new.price
</literal> is the same as
376 just writing
<literal>price
</literal>, but it makes the meaning clearer.
380 This syntax for returning old and new values is available in
381 <command>INSERT
</command>,
<command>UPDATE
</command>,
382 <command>DELETE
</command>, and
<command>MERGE
</command> commands, but
383 typically old values will be
<literal>NULL
</literal> for an
384 <command>INSERT
</command>, and new values will be
<literal>NULL
</literal>
385 for a
<command>DELETE
</command>. However, there are situations where it
386 can still be useful for those commands. For example, in an
387 <command>INSERT
</command> with an
388 <link linkend=
"sql-on-conflict"><literal>ON CONFLICT DO UPDATE
</literal></link>
389 clause, the old values will be non-
<literal>NULL
</literal> for conflicting
390 rows. Similarly, if a
<command>DELETE
</command> is turned into an
391 <command>UPDATE
</command> by a
<link linkend=
"sql-createrule">rewrite rule
</link>,
392 the new values may be non-
<literal>NULL
</literal>.
396 If there are triggers (
<xref linkend=
"triggers"/>) on the target table,
397 the data available to
<literal>RETURNING
</literal> is the row as modified by
398 the triggers. Thus, inspecting columns computed by triggers is another
399 common use-case for
<literal>RETURNING
</literal>.