(1 row)
</screen>
This is because a restriction placed in the <literal>ON</>
- clause is processed <emphasis>before</> the join, while
+ clause is processed <emphasis>before</> the join, while
a restriction placed in the <literal>WHERE</> clause is processed
<emphasis>after</> the join.
</para>
<para>
The naming of output columns here is different from that done in
the <literal>FROM</> clause (see <xref
- linkend="queries-table-aliases">). It is possible
+ linkend="queries-table-aliases">). It is possible
to rename the same column twice, but the name assigned in
the select list is the one that will be passed on.
</para>
<para>
<literal>WITH</> provides a way to write subqueries for use in a larger
- <literal>SELECT</> query. The subqueries can be thought of as defining
+ query. The subqueries 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:
However, the other side of this coin is that the optimizer is less able to
push restrictions from the parent query down into a <literal>WITH</> query
than an ordinary sub-query. The <literal>WITH</> query will generally be
- evaluated as stated, without suppression of rows that the parent query
+ evaluated as written, without suppression of rows that the parent query
might discard afterwards. (But, as mentioned above, evaluation might stop
early if the reference(s) to the query demand only a limited number of
rows.)
</para>
+ <para>
+ The examples above only show <literal>WITH</> being used with
+ <command>SELECT</>, but it can be attached in the same way to
+ <command>INSERT</>, <command>UPDATE</>, or <command>DELETE</>.
+ In each case it effectively provides temporary table(s) that can
+ be referred to in the main command.
+ </para>
+
</sect1>
</chapter>
<refsynopsisdiv>
<synopsis>
+[ WITH [ RECURSIVE ] <replaceable class="parameter">with_query</replaceable> [, ...] ]
DELETE FROM [ ONLY ] <replaceable class="PARAMETER">table</replaceable> [ [ AS ] <replaceable class="parameter">alias</replaceable> ]
[ USING <replaceable class="PARAMETER">using_list</replaceable> ]
[ WHERE <replaceable class="PARAMETER">condition</replaceable> | WHERE CURRENT OF <replaceable class="PARAMETER">cursor_name</replaceable> ]
<title>Parameters</title>
<variablelist>
+ <varlistentry>
+ <term><replaceable class="parameter">with_query</replaceable></term>
+ <listitem>
+ <para>
+ The <literal>WITH</literal> clause allows you to specify one or more
+ subqueries that can be referenced by name in the <command>DELETE</>
+ query. See <xref linkend="queries-with"> and <xref linkend="sql-select">
+ for details.
+ </para>
+ </listitem>
+ </varlistentry>
+
<varlistentry>
<term><literal>ONLY</></term>
<listitem>
<para>
This command conforms to the <acronym>SQL</acronym> standard, except
that the <literal>USING</literal> and <literal>RETURNING</> clauses
- are <productname>PostgreSQL</productname> extensions.
+ are <productname>PostgreSQL</productname> extensions, as is the ability
+ to use <literal>WITH</> with <command>DELETE</>.
</para>
</refsect1>
</refentry>
<refsynopsisdiv>
<synopsis>
+[ WITH [ RECURSIVE ] <replaceable class="parameter">with_query</replaceable> [, ...] ]
INSERT INTO <replaceable class="PARAMETER">table</replaceable> [ ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) ]
{ DEFAULT VALUES | VALUES ( { <replaceable class="PARAMETER">expression</replaceable> | DEFAULT } [, ...] ) [, ...] | <replaceable class="PARAMETER">query</replaceable> }
[ RETURNING * | <replaceable class="parameter">output_expression</replaceable> [ [ AS ] <replaceable class="parameter">output_name</replaceable> ] [, ...] ]
<title>Parameters</title>
<variablelist>
+ <varlistentry>
+ <term><replaceable class="parameter">with_query</replaceable></term>
+ <listitem>
+ <para>
+ The <literal>WITH</literal> clause allows you to specify one or more
+ subqueries that can be referenced by name in the <command>INSERT</>
+ query. See <xref linkend="queries-with"> and <xref linkend="sql-select">
+ for details.
+ </para>
+ <para>
+ It is possible for the <replaceable class="parameter">query</replaceable>
+ (<command>SELECT</command> statement)
+ to also contain a <literal>WITH</literal> clause. In such a case both
+ sets of <replaceable>with_query</replaceable> can be referenced within
+ the <replaceable class="parameter">query</replaceable>, but the
+ second one takes precedence since it is more closely nested.
+ </para>
+ </listitem>
+ </varlistentry>
+
<varlistentry>
<term><replaceable class="PARAMETER">table</replaceable></term>
<listitem>
<para>
<command>INSERT</command> conforms to the SQL standard, except that
the <literal>RETURNING</> clause is a
- <productname>PostgreSQL</productname> extension. Also, the case in
+ <productname>PostgreSQL</productname> extension, as is the ability
+ to use <literal>WITH</> with <command>INSERT</>.
+ Also, the case in
which a column name list is omitted, but not all the columns are
filled from the <literal>VALUES</> clause or <replaceable>query</>,
is disallowed by the standard.
<refsynopsisdiv>
<synopsis>
+[ WITH [ RECURSIVE ] <replaceable class="parameter">with_query</replaceable> [, ...] ]
UPDATE [ ONLY ] <replaceable class="PARAMETER">table</replaceable> [ [ AS ] <replaceable class="parameter">alias</replaceable> ]
SET { <replaceable class="PARAMETER">column</replaceable> = { <replaceable class="PARAMETER">expression</replaceable> | DEFAULT } |
( <replaceable class="PARAMETER">column</replaceable> [, ...] ) = ( { <replaceable class="PARAMETER">expression</replaceable> | DEFAULT } [, ...] ) } [, ...]
<title>Parameters</title>
<variablelist>
+ <varlistentry>
+ <term><replaceable class="parameter">with_query</replaceable></term>
+ <listitem>
+ <para>
+ The <literal>WITH</literal> clause allows you to specify one or more
+ subqueries that can be referenced by name in the <command>UPDATE</>
+ query. See <xref linkend="queries-with"> and <xref linkend="sql-select">
+ for details.
+ </para>
+ </listitem>
+ </varlistentry>
+
<varlistentry>
<term><replaceable class="PARAMETER">table</replaceable></term>
<listitem>
<para>
This command conforms to the <acronym>SQL</acronym> standard, except
that the <literal>FROM</literal> and <literal>RETURNING</> clauses
- are <productname>PostgreSQL</productname> extensions.
+ are <productname>PostgreSQL</productname> extensions, as is the ability
+ to use <literal>WITH</> with <command>UPDATE</>.
</para>
<para>
COPY_NODE_FIELD(cols);
COPY_NODE_FIELD(selectStmt);
COPY_NODE_FIELD(returningList);
+ COPY_NODE_FIELD(withClause);
return newnode;
}
COPY_NODE_FIELD(usingClause);
COPY_NODE_FIELD(whereClause);
COPY_NODE_FIELD(returningList);
+ COPY_NODE_FIELD(withClause);
return newnode;
}
COPY_NODE_FIELD(whereClause);
COPY_NODE_FIELD(fromClause);
COPY_NODE_FIELD(returningList);
+ COPY_NODE_FIELD(withClause);
return newnode;
}
COMPARE_NODE_FIELD(cols);
COMPARE_NODE_FIELD(selectStmt);
COMPARE_NODE_FIELD(returningList);
+ COMPARE_NODE_FIELD(withClause);
return true;
}
COMPARE_NODE_FIELD(usingClause);
COMPARE_NODE_FIELD(whereClause);
COMPARE_NODE_FIELD(returningList);
+ COMPARE_NODE_FIELD(withClause);
return true;
}
COMPARE_NODE_FIELD(whereClause);
COMPARE_NODE_FIELD(fromClause);
COMPARE_NODE_FIELD(returningList);
+ COMPARE_NODE_FIELD(withClause);
return true;
}
qry->commandType = CMD_DELETE;
+ /* process the WITH clause independently of all else */
+ if (stmt->withClause)
+ {
+ qry->hasRecursive = stmt->withClause->recursive;
+ qry->cteList = transformWithClause(pstate, stmt->withClause);
+ }
+
/* set up range table with just the result rel */
qry->resultRelation = setTargetTable(pstate, stmt->relation,
interpretInhOption(stmt->relation->inhOpt),
ListCell *attnos;
ListCell *lc;
+ /* There can't be any outer WITH to worry about */
+ Assert(pstate->p_ctenamespace == NIL);
+
qry->commandType = CMD_INSERT;
pstate->p_is_insert = true;
+ /* process the WITH clause independently of all else */
+ if (stmt->withClause)
+ {
+ qry->hasRecursive = stmt->withClause->recursive;
+ qry->cteList = transformWithClause(pstate, stmt->withClause);
+ }
+
/*
* We have three cases to deal with: DEFAULT VALUES (selectStmt == NULL),
* VALUES list, or general SELECT input. We special-case VALUES, both for
pstate->p_relnamespace = NIL;
sub_varnamespace = pstate->p_varnamespace;
pstate->p_varnamespace = NIL;
- /* There can't be any outer WITH to worry about */
- Assert(pstate->p_ctenamespace == NIL);
}
else
{
List *exprsLists = NIL;
int sublist_length = -1;
- /* process the WITH clause */
- if (selectStmt->withClause)
- {
- qry->hasRecursive = selectStmt->withClause->recursive;
- qry->cteList = transformWithClause(pstate, selectStmt->withClause);
- }
-
foreach(lc, selectStmt->valuesLists)
{
List *sublist = (List *) lfirst(lc);
Assert(list_length(valuesLists) == 1);
- /* process the WITH clause */
- if (selectStmt->withClause)
- {
- qry->hasRecursive = selectStmt->withClause->recursive;
- qry->cteList = transformWithClause(pstate, selectStmt->withClause);
- }
-
/* Do basic expression transformation (same as a ROW() expr) */
exprList = transformExpressionList(pstate,
(List *) linitial(valuesLists));
qry->commandType = CMD_UPDATE;
pstate->p_is_update = true;
+ /* process the WITH clause independently of all else */
+ if (stmt->withClause)
+ {
+ qry->hasRecursive = stmt->withClause->recursive;
+ qry->cteList = transformWithClause(pstate, stmt->withClause);
+ }
+
qry->resultRelation = setTargetTable(pstate, stmt->relation,
interpretInhOption(stmt->relation->inhOpt),
true,
%type <boolean> xml_whitespace_option
%type <node> common_table_expr
-%type <with> with_clause
+%type <with> with_clause opt_with_clause
%type <list> cte_list
%type <list> window_clause window_definition_list opt_partition_clause
*****************************************************************************/
InsertStmt:
- INSERT INTO qualified_name insert_rest returning_clause
+ opt_with_clause INSERT INTO qualified_name insert_rest returning_clause
{
- $4->relation = $3;
- $4->returningList = $5;
- $$ = (Node *) $4;
+ $5->relation = $4;
+ $5->returningList = $6;
+ $5->withClause = $1;
+ $$ = (Node *) $5;
}
;
*
*****************************************************************************/
-DeleteStmt: DELETE_P FROM relation_expr_opt_alias
+DeleteStmt: opt_with_clause DELETE_P FROM relation_expr_opt_alias
using_clause where_or_current_clause returning_clause
{
DeleteStmt *n = makeNode(DeleteStmt);
- n->relation = $3;
- n->usingClause = $4;
- n->whereClause = $5;
- n->returningList = $6;
+ n->relation = $4;
+ n->usingClause = $5;
+ n->whereClause = $6;
+ n->returningList = $7;
+ n->withClause = $1;
$$ = (Node *)n;
}
;
*
*****************************************************************************/
-UpdateStmt: UPDATE relation_expr_opt_alias
+UpdateStmt: opt_with_clause UPDATE relation_expr_opt_alias
SET set_clause_list
from_clause
where_or_current_clause
returning_clause
{
UpdateStmt *n = makeNode(UpdateStmt);
- n->relation = $2;
- n->targetList = $4;
- n->fromClause = $5;
- n->whereClause = $6;
- n->returningList = $7;
+ n->relation = $3;
+ n->targetList = $5;
+ n->fromClause = $6;
+ n->whereClause = $7;
+ n->returningList = $8;
+ n->withClause = $1;
$$ = (Node *)n;
}
;
}
;
+opt_with_clause:
+ with_clause { $$ = $1; }
+ | /*EMPTY*/ { $$ = NULL; }
+ ;
+
into_clause:
INTO OptTempTableName
{
break;
}
+ /*
+ * OLD/NEW are not allowed in WITH queries, because they would
+ * amount to outer references for the WITH, which we disallow.
+ * However, they were already in the outer rangetable when we
+ * analyzed the query, so we have to check.
+ *
+ * Note that in the INSERT...SELECT case, we need to examine
+ * the CTE lists of both top_subqry and sub_qry.
+ *
+ * Note that we aren't digging into the body of the query
+ * looking for WITHs in nested sub-SELECTs. A WITH down there
+ * can legitimately refer to OLD/NEW, because it'd be an
+ * indirect-correlated outer reference.
+ */
+ if (rangeTableEntry_used((Node *) top_subqry->cteList,
+ PRS2_OLD_VARNO, 0) ||
+ rangeTableEntry_used((Node *) sub_qry->cteList,
+ PRS2_OLD_VARNO, 0))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot refer to OLD within WITH query")));
+ if (rangeTableEntry_used((Node *) top_subqry->cteList,
+ PRS2_NEW_VARNO, 0) ||
+ rangeTableEntry_used((Node *) sub_qry->cteList,
+ PRS2_NEW_VARNO, 0))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot refer to NEW within WITH query")));
+
/*
* For efficiency's sake, add OLD to the rule action's jointree
* only if it was actually referenced in the statement or qual.
ListCell *l;
List *strippedexprs;
+ /* Insert the WITH clause if given */
+ get_with_clause(query, context);
+
/*
* If it's an INSERT ... SELECT or VALUES (...), (...), ... there will be
* a single RTE for the SELECT or VALUES.
}
else if (values_rte)
{
- /* A WITH clause is possible here */
- get_with_clause(query, context);
/* Add the multi-VALUES expression lists */
get_values_def(values_rte->values_lists, context);
}
else
{
- /* A WITH clause is possible here */
- get_with_clause(query, context);
/* Add the single-VALUES expression list */
appendContextKeyword(context, "VALUES (",
-PRETTYINDENT_STD, PRETTYINDENT_STD, 2);
RangeTblEntry *rte;
ListCell *l;
+ /* Insert the WITH clause if given */
+ get_with_clause(query, context);
+
/*
* Start the query with UPDATE relname SET
*/
StringInfo buf = context->buf;
RangeTblEntry *rte;
+ /* Insert the WITH clause if given */
+ get_with_clause(query, context);
+
/*
* Start the query with DELETE FROM relname
*/
*/
/* yyyymmddN */
-#define CATALOG_VERSION_NO 201010101
+#define CATALOG_VERSION_NO 201010151
#endif
List *cols; /* optional: names of the target columns */
Node *selectStmt; /* the source SELECT/VALUES, or NULL */
List *returningList; /* list of expressions to return */
+ WithClause *withClause; /* WITH clause */
} InsertStmt;
/* ----------------------
List *usingClause; /* optional using clause for more tables */
Node *whereClause; /* qualifications */
List *returningList; /* list of expressions to return */
+ WithClause *withClause; /* WITH clause */
} DeleteStmt;
/* ----------------------
Node *whereClause; /* qualifications */
List *fromClause; /* optional from clause for more tables */
List *returningList; /* list of expressions to return */
+ WithClause *withClause; /* WITH clause */
} UpdateStmt;
/* ----------------------
10
(54 rows)
+--
+-- Test WITH attached to a DML statement
+--
+CREATE TEMPORARY TABLE y (a INTEGER);
+INSERT INTO y SELECT generate_series(1, 10);
+WITH t AS (
+ SELECT a FROM y
+)
+INSERT INTO y
+SELECT a+20 FROM t RETURNING *;
+ a
+----
+ 21
+ 22
+ 23
+ 24
+ 25
+ 26
+ 27
+ 28
+ 29
+ 30
+(10 rows)
+
+SELECT * FROM y;
+ a
+----
+ 1
+ 2
+ 3
+ 4
+ 5
+ 6
+ 7
+ 8
+ 9
+ 10
+ 21
+ 22
+ 23
+ 24
+ 25
+ 26
+ 27
+ 28
+ 29
+ 30
+(20 rows)
+
+WITH t AS (
+ SELECT a FROM y
+)
+UPDATE y SET a = y.a-10 FROM t WHERE y.a > 20 AND t.a = y.a RETURNING y.a;
+ a
+----
+ 11
+ 12
+ 13
+ 14
+ 15
+ 16
+ 17
+ 18
+ 19
+ 20
+(10 rows)
+
+SELECT * FROM y;
+ a
+----
+ 1
+ 2
+ 3
+ 4
+ 5
+ 6
+ 7
+ 8
+ 9
+ 10
+ 11
+ 12
+ 13
+ 14
+ 15
+ 16
+ 17
+ 18
+ 19
+ 20
+(20 rows)
+
+WITH RECURSIVE t(a) AS (
+ SELECT 11
+ UNION ALL
+ SELECT a+1 FROM t WHERE a < 50
+)
+DELETE FROM y USING t WHERE t.a = y.a RETURNING y.a;
+ a
+----
+ 11
+ 12
+ 13
+ 14
+ 15
+ 16
+ 17
+ 18
+ 19
+ 20
+(10 rows)
+
+SELECT * FROM y;
+ a
+----
+ 1
+ 2
+ 3
+ 4
+ 5
+ 6
+ 7
+ 8
+ 9
+ 10
+(10 rows)
+
+DROP TABLE y;
--
-- error cases
--
LINE 2: (SELECT i::numeric(3,0) FROM (VALUES(1),(2)) t(i)
^
HINT: Cast the output of the non-recursive term to the correct type.
+-- disallow OLD/NEW reference in CTE
+CREATE TEMPORARY TABLE x (n integer);
+CREATE RULE r2 AS ON UPDATE TO x DO INSTEAD
+ WITH t AS (SELECT OLD.*) UPDATE y SET a = t.n FROM t;
+ERROR: cannot refer to OLD within WITH query
--
-- test for bug #4902
--
(SELECT * FROM y UNION ALL SELECT id+1 FROM z WHERE id < 10)
SELECT * FROM z;
+--
+-- Test WITH attached to a DML statement
+--
+
+CREATE TEMPORARY TABLE y (a INTEGER);
+INSERT INTO y SELECT generate_series(1, 10);
+
+WITH t AS (
+ SELECT a FROM y
+)
+INSERT INTO y
+SELECT a+20 FROM t RETURNING *;
+
+SELECT * FROM y;
+
+WITH t AS (
+ SELECT a FROM y
+)
+UPDATE y SET a = y.a-10 FROM t WHERE y.a > 20 AND t.a = y.a RETURNING y.a;
+
+SELECT * FROM y;
+
+WITH RECURSIVE t(a) AS (
+ SELECT 11
+ UNION ALL
+ SELECT a+1 FROM t WHERE a < 50
+)
+DELETE FROM y USING t WHERE t.a = y.a RETURNING y.a;
+
+SELECT * FROM y;
+
+DROP TABLE y;
+
--
-- error cases
--
SELECT (i+1)::numeric(10,0) FROM foo WHERE i < 10)
SELECT * FROM foo;
+-- disallow OLD/NEW reference in CTE
+CREATE TEMPORARY TABLE x (n integer);
+CREATE RULE r2 AS ON UPDATE TO x DO INSTEAD
+ WITH t AS (SELECT OLD.*) UPDATE y SET a = t.n FROM t;
+
--
-- test for bug #4902
--