*** a/doc/src/sgml/queries.sgml --- b/doc/src/sgml/queries.sgml *************** *** 1526,1532 **** SELECT select_list FROM table_expression ! <literal>WITH</literal> Queries (Common Table Expressions) WITH --- 1526,1532 ---- ! <literal>WITH</literal> Statements (Common Table Expressions) WITH *************** *** 1539,1549 **** SELECT select_list FROM table_expression ! WITH provides a way to write subqueries for use in a larger ! query. The subqueries, which are often referred to as Common Table Expressions or CTEs, can be thought of as defining ! temporary tables that exist just for this query. One use of this feature ! is to break down complicated queries into simpler parts. An example is: WITH regional_sales AS ( --- 1539,1559 ---- ! WITH provides a way to write auxiliary statements for use in a ! larger query. These statements, which are often referred to as Common Table Expressions or CTEs, can be thought of as defining ! temporary tables that exist just for this query. ! ! ! ! SELECT Queries ! ! ! * ! ! ! One use of this feature is to break down complicated queries into simpler ! parts. An example is: WITH regional_sales AS ( *************** *** 1806,1811 **** SELECT n FROM t LIMIT 100; --- 1816,1917 ---- In each case it effectively provides temporary table(s) that can be referred to in the main command. + + + Data-Modifying Statements + + + * + + + + You can also use data-modifying statements INSERT, + UPDATE and DELETE in WITH. This allows + you to perform many different operations in the same query. An example is: + + + WITH moved_rows AS ( + DELETE FROM ONLY products + WHERE + "date" >= '2010-10-01' AND + "date" < '2010-11-01' + RETURNING * + ) + INSERT INTO products_log + SELECT * FROM moved_rows; + + + which moves rows from "products" to "products_log". In the example above, + the WITH clause is attached to the INSERT, not the + SELECT. This is important, because data-modifying statements + are not allowed in WITH clauses which are not attached to the + top level statement. However, normal WITH visibility rules + apply: it is possible to refer to a data-modifying WITH from a + subquery. + + + + Recursive self-references in data-modifying statements are not + allowed. In some cases it is possible to work around this limitation by + referring to the output of a recursive WITH: + + + WITH RECURSIVE included_parts(sub_part, part) AS ( + SELECT sub_part, part FROM parts WHERE part = 'our_product' + UNION ALL + SELECT p.sub_part, p.part + FROM included_parts pr, parts p + WHERE p.part = pr.sub_part + ) + DELETE FROM parts + WHERE part IN (SELECT part FROM included_parts); + + + The above query would remove all direct and indirect subparts of a product. + + + + The execution of data-modifying statements in WITH is + interleaved with the main plan, and the order in which the statements + are executed is arbitrary. The changes made by data-modifying statements + are not visible to the query. + + + + Trying to update the same row twice in a single command is not supported. + Only one of the modifications takes place, but it is not easy (and + sometimes not possible) to reliably predict which one. This also applies + to deleting a row that was already updated in the same command; only the + update is performed. You should generally avoid trying to modify a single + row twice in a single command. + + + + + Data-modifying statements are executed exactly once, and always to + completion. If a WITH containing a data-modifying statement + is not referred to in the query, it is possible to omit the + RETURNING clause: + + + WITH t AS ( + DELETE FROM foo + ) + DELETE FROM bar; + + + The example above would remove all rows from tables "foo" and "bar". The + number of affected rows returned to the client would only include rows + removed from "bar". + + + + Any table used as the target of a data-modifying statement in + WITH must not contain a conditional rule, an ALSO + rule or an INSTEAD rule with multiple statements. + + + *** a/doc/src/sgml/ref/delete.sgml --- b/doc/src/sgml/ref/delete.sgml *************** *** 89,95 **** DELETE FROM [ ONLY ] table [ [ AS ] The WITH clause allows you to specify one or more ! subqueries that can be referenced by name in the DELETE query. See and for details. --- 89,95 ---- The WITH clause allows you to specify one or more ! statements whose results can be referenced by name in the DELETE query. See and for details. *** a/doc/src/sgml/ref/insert.sgml --- b/doc/src/sgml/ref/insert.sgml *************** *** 90,96 **** INSERT INTO table [ ( The WITH clause allows you to specify one or more ! subqueries that can be referenced by name in the INSERT query. See and for details. --- 90,96 ---- The WITH clause allows you to specify one or more ! statements whose results can be referenced by name in the INSERT query. See and for details. *** a/doc/src/sgml/ref/select.sgml --- b/doc/src/sgml/ref/select.sgml *************** *** 58,64 **** SELECT [ ALL | DISTINCT [ ON ( expressionand with_query is: ! with_query_name [ ( column_name [, ...] ) ] AS ( select ) TABLE { [ ONLY ] table_name [ * ] | with_query_name } --- 58,64 ---- and with_query is: ! with_query_name [ ( column_name [, ...] ) ] AS ( select | insert | update | delete ) TABLE { [ ONLY ] table_name [ * ] | with_query_name } *************** *** 206,233 **** TABLE { [ ONLY ] table_name [ * ] | The WITH clause allows you to specify one or more ! subqueries that can be referenced by name in the primary query. ! The subqueries effectively act as temporary tables or views ! for the duration of the primary query. A name (without schema qualification) must be specified for each ! WITH query. Optionally, a list of column names can be specified; if this is omitted, ! the column names are inferred from the subquery. If RECURSIVE is specified, it allows a ! subquery to reference itself by name. Such a subquery must have ! the form non_recursive_term UNION [ ALL | DISTINCT ] recursive_term where the recursive self-reference must appear on the right-hand side of the UNION. Only one recursive self-reference ! is permitted per query. --- 206,241 ---- The WITH clause allows you to specify one or more ! read-only (SELECT) or data-modifying statements whose ! results can be referenced by name in the primary query. These statements ! effectively act as temporary tables or views for the duration of the ! primary query. Currently only SELECT, ! INSERT, UPDATE and ! DELETE statements are supported in ! WITH. A name (without schema qualification) must be specified for each ! WITH statement. Optionally, a list of column names can be specified; if this is omitted, ! the column names are inferred from the statement. If RECURSIVE is specified, it allows a ! SELECT subquery to reference itself by name. Such a ! subquery must have the form non_recursive_term UNION [ ALL | DISTINCT ] recursive_term where the recursive self-reference must appear on the right-hand side of the UNION. Only one recursive self-reference ! is permitted per query. Recursive data-modifying statements are not ! supported, but you can use the results of a recursive ! SELECT query in ! a data-modifying statement. See for ! an example. *************** *** 241,247 **** TABLE { [ ONLY ] table_name [ * ] | ! A useful property of WITH queries is that they are evaluated only once per execution of the primary query, even if the primary query refers to them more than once. --- 249,255 ---- ! A useful property of WITH statements is that they are evaluated only once per execution of the primary query, even if the primary query refers to them more than once. *** a/doc/src/sgml/ref/update.sgml --- b/doc/src/sgml/ref/update.sgml *************** *** 85,91 **** UPDATE [ ONLY ] table [ [ AS ] The WITH clause allows you to specify one or more ! subqueries that can be referenced by name in the UPDATE query. See and for details. --- 85,91 ---- The WITH clause allows you to specify one or more ! statements whose results can be referenced by name in the UPDATE query. See and for details.