Add CREATE RECURSIVE VIEW syntax

This is specified in the SQL standard.  The CREATE RECURSIVE VIEW
specification is transformed into a normal CREATE VIEW statement with a
WITH RECURSIVE clause.

reviewed by Abhijit Menon-Sen and Stephen Frost
This commit is contained in:
Peter Eisentraut 2013-01-31 22:31:58 -05:00
parent b1980f6d03
commit 5839052693
4 changed files with 158 additions and 1 deletions

View File

@ -21,7 +21,7 @@ PostgreSQL documentation
<refsynopsisdiv>
<synopsis>
CREATE [ OR REPLACE ] [ TEMP | TEMPORARY ] VIEW <replaceable class="PARAMETER">name</replaceable> [ ( <replaceable class="PARAMETER">column_name</replaceable> [, ...] ) ]
CREATE [ OR REPLACE ] [ TEMP | TEMPORARY ] [ RECURSIVE ] VIEW <replaceable class="PARAMETER">name</replaceable> [ ( <replaceable class="PARAMETER">column_name</replaceable> [, ...] ) ]
[ WITH ( <replaceable class="PARAMETER">view_option_name</replaceable> [= <replaceable class="PARAMETER">view_option_value</replaceable>] [, ... ] ) ]
AS <replaceable class="PARAMETER">query</replaceable>
</synopsis>
@ -80,6 +80,23 @@ CREATE [ OR REPLACE ] [ TEMP | TEMPORARY ] VIEW <replaceable class="PARAMETER">n
</listitem>
</varlistentry>
<varlistentry>
<term><literal>RECURSIVE</></term>
<listitem>
<para>
Creates a recursive view. The syntax
<synopsis>
CREATE RECURSIVE VIEW <replaceable>name</> (<replaceable>columns</>) AS SELECT <replaceable>...</>;
</synopsis>
is equivalent to
<synopsis>
CREATE VIEW <replaceable>name</> AS WITH RECURSIVE <replaceable>name</> (<replaceable>columns</>) AS (SELECT <replaceable>...</>) SELECT <replaceable>columns</> FROM <replaceable>name</>;
</synopsis>
A view column list must be specified for a recursive view.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">name</replaceable></term>
<listitem>
@ -282,6 +299,16 @@ CREATE VIEW comedies AS
<literal>*</> was used to create the view, columns added later to
the table will not be part of the view.
</para>
<para>
Create a recursive view consisting of the numbers from 1 to 100:
<programlisting>
CREATE RECURSIVE VIEW nums_1_100 (n) AS
VALUES (1)
UNION ALL
SELECT n+1 FROM nums_1_100 WHERE n < 100;
</programlisting>
</para>
</refsect1>
<refsect1>

View File

@ -164,6 +164,7 @@ static void SplitColQualList(List *qualList,
static void processCASbits(int cas_bits, int location, const char *constrType,
bool *deferrable, bool *initdeferred, bool *not_valid,
bool *no_inherit, core_yyscan_t yyscanner);
static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%}
@ -7839,6 +7840,30 @@ ViewStmt: CREATE OptTemp VIEW qualified_name opt_column_list opt_reloptions
n->options = $8;
$$ = (Node *) n;
}
| CREATE OptTemp RECURSIVE VIEW qualified_name '(' columnList ')' opt_reloptions
AS SelectStmt
{
ViewStmt *n = makeNode(ViewStmt);
n->view = $5;
n->view->relpersistence = $2;
n->aliases = $7;
n->query = makeRecursiveViewSelect(n->view->relname, n->aliases, $11);
n->replace = false;
n->options = $9;
$$ = (Node *) n;
}
| CREATE OR REPLACE OptTemp RECURSIVE VIEW qualified_name '(' columnList ')' opt_reloptions
AS SelectStmt
{
ViewStmt *n = makeNode(ViewStmt);
n->view = $7;
n->view->relpersistence = $4;
n->aliases = $9;
n->query = makeRecursiveViewSelect(n->view->relname, n->aliases, $13);
n->replace = true;
n->options = $11;
$$ = (Node *) n;
}
;
opt_check_option:
@ -13570,6 +13595,66 @@ processCASbits(int cas_bits, int location, const char *constrType,
}
}
/*----------
* Recursive view transformation
*
* Convert
*
* CREATE RECURSIVE VIEW relname (aliases) AS query
*
* to
*
* CREATE VIEW relname (aliases) AS
* WITH RECURSIVE relname (aliases) AS (query)
* SELECT aliases FROM relname
*
* Actually, just the WITH ... part, which is then inserted into the original
* view definition as the query.
* ----------
*/
static Node *
makeRecursiveViewSelect(char *relname, List *aliases, Node *query)
{
SelectStmt *s = makeNode(SelectStmt);
WithClause *w = makeNode(WithClause);
CommonTableExpr *cte = makeNode(CommonTableExpr);
List *tl = NIL;
ListCell *lc;
/* create common table expression */
cte->ctename = relname;
cte->aliascolnames = aliases;
cte->ctequery = query;
cte->location = -1;
/* create WITH clause and attach CTE */
w->recursive = true;
w->ctes = list_make1(cte);
w->location = -1;
/* create target list for the new SELECT from the alias list of the
* recursive view specification */
foreach (lc, aliases)
{
ResTarget *rt = makeNode(ResTarget);
rt->name = NULL;
rt->indirection = NIL;
rt->val = makeColumnRef(strVal(lfirst(lc)), NIL, -1, 0);
rt->location = -1;
tl = lappend(tl, rt);
}
/* create new SELECT combining WITH clause, target list, and fake FROM
* clause */
s->withClause = w;
s->targetList = tl;
s->fromClause = list_make1(makeRangeVar(NULL, relname, -1));
return (Node *) s;
}
/* parser_init()
* Initialize to parse one query string
*/

View File

@ -49,6 +49,36 @@ SELECT * FROM t;
5
(5 rows)
-- recursive view
CREATE RECURSIVE VIEW nums (n) AS
VALUES (1)
UNION ALL
SELECT n+1 FROM nums WHERE n < 5;
SELECT * FROM nums;
n
---
1
2
3
4
5
(5 rows)
CREATE OR REPLACE RECURSIVE VIEW nums (n) AS
VALUES (1)
UNION ALL
SELECT n+1 FROM nums WHERE n < 6;
SELECT * FROM nums;
n
---
1
2
3
4
5
6
(6 rows)
-- This is an infinite loop with UNION ALL, but not with UNION
WITH RECURSIVE t(n) AS (
SELECT 1

View File

@ -31,6 +31,21 @@ UNION ALL
)
SELECT * FROM t;
-- recursive view
CREATE RECURSIVE VIEW nums (n) AS
VALUES (1)
UNION ALL
SELECT n+1 FROM nums WHERE n < 5;
SELECT * FROM nums;
CREATE OR REPLACE RECURSIVE VIEW nums (n) AS
VALUES (1)
UNION ALL
SELECT n+1 FROM nums WHERE n < 6;
SELECT * FROM nums;
-- This is an infinite loop with UNION ALL, but not with UNION
WITH RECURSIVE t(n) AS (
SELECT 1