From 57995544497ce7e62552ce55ecdf6eca90198788 Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Tue, 22 Nov 2016 14:02:52 -0500 Subject: [PATCH] Doc: add a section in Part II concerning RETURNING. There are assorted references to RETURNING in Part II, but nothing that would qualify as an explanation of the feature, which seems like an oversight considering how useful it is. Add something. Noted while looking for a place to point a cross-reference to ... --- doc/src/sgml/dml.sgml | 99 +++++++++++++++++++++++++++++++++++++++ doc/src/sgml/queries.sgml | 3 +- 2 files changed, 101 insertions(+), 1 deletion(-) diff --git a/doc/src/sgml/dml.sgml b/doc/src/sgml/dml.sgml index cd36a73811..0c65578b59 100644 --- a/doc/src/sgml/dml.sgml +++ b/doc/src/sgml/dml.sgml @@ -102,6 +102,18 @@ INSERT INTO products (product_no, name, price) VALUES + + It is also possible to insert the result of a query (which might be no + rows, one row, or many rows): + +INSERT INTO products (product_no, name, price) + SELECT product_no, name, price FROM new_products + WHERE release_date = 'today'; + + This provides the full power of the SQL query mechanism () for computing the rows to be inserted. + + When inserting a lot of data at the same time, considering using @@ -252,4 +264,91 @@ DELETE FROM products; then all rows in the table will be deleted! Caveat programmer. + + + Returning Data From Modified Rows + + + RETURNING + + + + INSERT + RETURNING + + + + UPDATE + RETURNING + + + + DELETE + RETURNING + + + + Sometimes it is useful to obtain data from modified rows while they are + being manipulated. The INSERT, UPDATE, + and DELETE commands all have an + optional RETURNING clause that supports this. Use + of RETURNING avoids performing an extra database query to + collect the data, and is especially valuable when it would otherwise be + difficult to identify the modified rows reliably. + + + + The allowed contents of a RETURNING clause are the same as + a SELECT command's output list + (see ). It can contain column + names of the command's target table, or value expressions using those + columns. A common shorthand is RETURNING *, which selects + all columns of the target table in order. + + + + In an INSERT, the data available to RETURNING is + the row as it was inserted. This is not so useful in trivial inserts, + since it would just repeat the data provided by the client. But it can + be very handy when relying on computed default values. For example, + when using a serial + column to provide unique identifiers, RETURNING can return + the ID assigned to a new row: + +CREATE TABLE users (firstname text, lastname text, id serial primary key); + +INSERT INTO users (firstname, lastname) VALUES ('Joe', 'Cool') RETURNING id; + + The RETURNING clause is also very useful + with INSERT ... SELECT. + + + + In an UPDATE, the data available to RETURNING is + the new content of the modified row. For example: + +UPDATE products SET price = price * 1.10 + WHERE price <= 99.99 + RETURNING name, price AS new_price; + + + + + In a DELETE, the data available to RETURNING is + the content of the deleted row. For example: + +DELETE FROM products + WHERE obsoletion_date = 'today' + RETURNING *; + + + + + If there are triggers () on the target table, + the data available to RETURNING is the row as modified by + the triggers. Thus, inspecting columns computed by triggers is another + common use-case for RETURNING. + + + diff --git a/doc/src/sgml/queries.sgml b/doc/src/sgml/queries.sgml index b8f5238c94..88e2b4132d 100644 --- a/doc/src/sgml/queries.sgml +++ b/doc/src/sgml/queries.sgml @@ -2259,7 +2259,8 @@ SELECT * FROM moved_rows; Data-modifying statements in WITH usually have - RETURNING clauses, as seen in the example above. + RETURNING clauses (see ), + as shown in the example above. It is the output of the RETURNING clause, not the target table of the data-modifying statement, that forms the temporary table that can be referred to by the rest of the query. If a