Enhanced cycle mark values

Per SQL:202x draft, in the CYCLE clause of a recursive query, the
cycle mark values can be of type boolean and can be omitted, in which
case they default to TRUE and FALSE.

Reviewed-by: Vik Fearing <vik@postgresfriends.org>
Discussion: https://www.postgresql.org/message-id/flat/db80ceee-6f97-9b4a-8ee8-3ba0c58e5be2@2ndquadrant.com
This commit is contained in:
Peter Eisentraut 2021-02-27 08:11:14 +01:00
parent 4e90052c46
commit f4adc41c4f
7 changed files with 144 additions and 47 deletions

View File

@ -2349,14 +2349,13 @@ WITH RECURSIVE search_graph(id, link, data, depth) AS (
SELECT g.id, g.link, g.data, sg.depth + 1
FROM graph g, search_graph sg
WHERE g.id = sg.link
) <emphasis>CYCLE id SET is_cycle TO true DEFAULT false USING path</emphasis>
) <emphasis>CYCLE id SET is_cycle USING path</emphasis>
SELECT * FROM search_graph;
</programlisting>
and it will be internally rewritten to the above form. The
<literal>CYCLE</literal> clause specifies first the list of columns to
track for cycle detection, then a column name that will show whether a
cycle has been detected, then two values to use in that column for the yes
and no cases, and finally the name of another column that will track the
cycle has been detected, and finally the name of another column that will track the
path. The cycle and path columns will implicitly be added to the output
rows of the CTE.
</para>

View File

@ -74,7 +74,7 @@ SELECT [ ALL | DISTINCT [ ON ( <replaceable class="parameter">expression</replac
<replaceable class="parameter">with_query_name</replaceable> [ ( <replaceable class="parameter">column_name</replaceable> [, ...] ) ] AS [ [ NOT ] MATERIALIZED ] ( <replaceable class="parameter">select</replaceable> | <replaceable class="parameter">values</replaceable> | <replaceable class="parameter">insert</replaceable> | <replaceable class="parameter">update</replaceable> | <replaceable class="parameter">delete</replaceable> )
[ SEARCH { BREADTH | DEPTH } FIRST BY <replaceable>column_name</replaceable> [, ...] SET <replaceable>search_seq_col_name</replaceable> ]
[ CYCLE <replaceable>column_name</replaceable> [, ...] SET <replaceable>cycle_mark_col_name</replaceable> TO <replaceable>cycle_mark_value</replaceable> DEFAULT <replaceable>cycle_mark_default</replaceable> USING <replaceable>cycle_path_col_name</replaceable> ]
[ CYCLE <replaceable>column_name</replaceable> [, ...] SET <replaceable>cycle_mark_col_name</replaceable> [ TO <replaceable>cycle_mark_value</replaceable> DEFAULT <replaceable>cycle_mark_default</replaceable> ] USING <replaceable>cycle_path_col_name</replaceable> ]
TABLE [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ]
</synopsis>
@ -302,8 +302,10 @@ TABLE [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ]
been detected. <replaceable>cycle_mark_value</replaceable> and
<replaceable>cycle_mark_default</replaceable> must be constants and they
must be coercible to a common data type, and the data type must have an
inequality operator. (The SQL standard requires that they be character
strings, but PostgreSQL does not require that.) Furthermore, a column
inequality operator. (The SQL standard requires that they be Boolean
constants or character strings, but PostgreSQL does not require that.) By
default, <literal>TRUE</literal> and <literal>FALSE</literal> (of type
<type>boolean</type>) are used. Furthermore, a column
named <replaceable>cycle_path_col_name</replaceable> will be added to the
result column list of the <literal>WITH</literal> query. This column is
used internally for tracking visited rows. See <xref

View File

@ -425,6 +425,7 @@ T121 WITH (excluding RECURSIVE) in query expression YES
T122 WITH (excluding RECURSIVE) in subquery YES
T131 Recursive query YES
T132 Recursive query in subquery YES
T133 Enhanced cycle mark values YES SQL:202x draft
T141 SIMILAR predicate YES
T151 DISTINCT predicate YES
T152 DISTINCT predicate with negation YES

View File

@ -11442,6 +11442,17 @@ opt_cycle_clause:
n->location = @1;
$$ = (Node *) n;
}
| CYCLE columnList SET ColId USING ColId
{
CTECycleClause *n = makeNode(CTECycleClause);
n->cycle_col_list = $2;
n->cycle_mark_column = $4;
n->cycle_mark_value = makeBoolAConst(true, -1);
n->cycle_mark_default = makeBoolAConst(false, -1);
n->cycle_path_column = $6;
n->location = @1;
$$ = (Node *) n;
}
| /*EMPTY*/
{
$$ = NULL;

View File

@ -5208,10 +5208,21 @@ get_with_clause(Query *query, deparse_context *context)
}
appendStringInfo(buf, " SET %s", quote_identifier(cte->cycle_clause->cycle_mark_column));
appendStringInfoString(buf, " TO ");
get_rule_expr(cte->cycle_clause->cycle_mark_value, context, false);
appendStringInfoString(buf, " DEFAULT ");
get_rule_expr(cte->cycle_clause->cycle_mark_default, context, false);
{
Const *cmv = castNode(Const, cte->cycle_clause->cycle_mark_value);
Const *cmd = castNode(Const, cte->cycle_clause->cycle_mark_default);
if (!(cmv->consttype == BOOLOID && !cmv->constisnull && DatumGetBool(cmv->constvalue) == true &&
cmd->consttype == BOOLOID && !cmd->constisnull && DatumGetBool(cmd->constvalue) == false))
{
appendStringInfoString(buf, " TO ");
get_rule_expr(cte->cycle_clause->cycle_mark_value, context, false);
appendStringInfoString(buf, " DEFAULT ");
get_rule_expr(cte->cycle_clause->cycle_mark_default, context, false);
}
}
appendStringInfo(buf, " USING %s", quote_identifier(cte->cycle_clause->cycle_path_column));
}

View File

@ -951,7 +951,7 @@ with recursive search_graph(f, t, label) as (
select g.*
from graph g, search_graph sg
where g.f = sg.t
) cycle f, t set is_cycle to true default false using path
) cycle f, t set is_cycle using path
select * from search_graph;
f | t | label | is_cycle | path
---+---+------------+----------+-------------------------------------------
@ -1071,7 +1071,7 @@ with recursive a as (
select 1 as b
union all
select * from a
) cycle b set c to true default false using p
) cycle b set c using p
select * from a;
b | c | p
---+---+-----------
@ -1087,7 +1087,7 @@ with recursive search_graph(f, t, label) as (
from graph g, search_graph sg
where g.f = sg.t
) search depth first by f, t set seq
cycle f, t set is_cycle to true default false using path
cycle f, t set is_cycle using path
select * from search_graph;
f | t | label | seq | is_cycle | path
---+---+------------+-------------------------------------------+----------+-------------------------------------------
@ -1125,7 +1125,7 @@ with recursive search_graph(f, t, label) as (
from graph g, search_graph sg
where g.f = sg.t
) search breadth first by f, t set seq
cycle f, t set is_cycle to true default false using path
cycle f, t set is_cycle using path
select * from search_graph;
f | t | label | seq | is_cycle | path
---+---+------------+---------+----------+-------------------------------------------
@ -1163,10 +1163,10 @@ with recursive search_graph(f, t, label) as (
select g.*
from graph g, search_graph sg
where g.f = sg.t
) cycle foo, tar set is_cycle to true default false using path
) cycle foo, tar set is_cycle using path
select * from search_graph;
ERROR: cycle column "foo" not in WITH query column list
LINE 7: ) cycle foo, tar set is_cycle to true default false using pa...
LINE 7: ) cycle foo, tar set is_cycle using path
^
with recursive search_graph(f, t, label) as (
select * from graph g
@ -1257,38 +1257,99 @@ ERROR: search_sequence column name and cycle path column name are the same
LINE 7: ) search depth first by f, t set foo
^
-- test ruleutils and view expansion
create temp view v_cycle as
create temp view v_cycle1 as
with recursive search_graph(f, t, label) as (
select * from graph g
union all
select g.*
from graph g, search_graph sg
where g.f = sg.t
) cycle f, t set is_cycle to true default false using path
) cycle f, t set is_cycle using path
select f, t, label from search_graph;
select pg_get_viewdef('v_cycle');
pg_get_viewdef
--------------------------------------------------------------------
WITH RECURSIVE search_graph(f, t, label) AS ( +
SELECT g.f, +
g.t, +
g.label +
FROM graph g +
UNION ALL +
SELECT g.f, +
g.t, +
g.label +
FROM graph g, +
search_graph sg +
WHERE (g.f = sg.t) +
) CYCLE f, t SET is_cycle TO true DEFAULT false USING path+
SELECT search_graph.f, +
search_graph.t, +
search_graph.label +
create temp view v_cycle2 as
with recursive search_graph(f, t, label) as (
select * from graph g
union all
select g.*
from graph g, search_graph sg
where g.f = sg.t
) cycle f, t set is_cycle to 'Y' default 'N' using path
select f, t, label from search_graph;
select pg_get_viewdef('v_cycle1');
pg_get_viewdef
------------------------------------------------
WITH RECURSIVE search_graph(f, t, label) AS (+
SELECT g.f, +
g.t, +
g.label +
FROM graph g +
UNION ALL +
SELECT g.f, +
g.t, +
g.label +
FROM graph g, +
search_graph sg +
WHERE (g.f = sg.t) +
) CYCLE f, t SET is_cycle USING path +
SELECT search_graph.f, +
search_graph.t, +
search_graph.label +
FROM search_graph;
(1 row)
select * from v_cycle;
select pg_get_viewdef('v_cycle2');
pg_get_viewdef
-----------------------------------------------------------------------------
WITH RECURSIVE search_graph(f, t, label) AS ( +
SELECT g.f, +
g.t, +
g.label +
FROM graph g +
UNION ALL +
SELECT g.f, +
g.t, +
g.label +
FROM graph g, +
search_graph sg +
WHERE (g.f = sg.t) +
) CYCLE f, t SET is_cycle TO 'Y'::text DEFAULT 'N'::text USING path+
SELECT search_graph.f, +
search_graph.t, +
search_graph.label +
FROM search_graph;
(1 row)
select * from v_cycle1;
f | t | label
---+---+------------
1 | 2 | arc 1 -> 2
1 | 3 | arc 1 -> 3
2 | 3 | arc 2 -> 3
1 | 4 | arc 1 -> 4
4 | 5 | arc 4 -> 5
5 | 1 | arc 5 -> 1
1 | 2 | arc 1 -> 2
1 | 3 | arc 1 -> 3
1 | 4 | arc 1 -> 4
2 | 3 | arc 2 -> 3
4 | 5 | arc 4 -> 5
5 | 1 | arc 5 -> 1
1 | 2 | arc 1 -> 2
1 | 3 | arc 1 -> 3
1 | 4 | arc 1 -> 4
2 | 3 | arc 2 -> 3
4 | 5 | arc 4 -> 5
5 | 1 | arc 5 -> 1
1 | 2 | arc 1 -> 2
1 | 3 | arc 1 -> 3
1 | 4 | arc 1 -> 4
2 | 3 | arc 2 -> 3
4 | 5 | arc 4 -> 5
5 | 1 | arc 5 -> 1
2 | 3 | arc 2 -> 3
(25 rows)
select * from v_cycle2;
f | t | label
---+---+------------
1 | 2 | arc 1 -> 2

View File

@ -509,7 +509,7 @@ with recursive search_graph(f, t, label) as (
select g.*
from graph g, search_graph sg
where g.f = sg.t
) cycle f, t set is_cycle to true default false using path
) cycle f, t set is_cycle using path
select * from search_graph;
with recursive search_graph(f, t, label) as (
@ -545,7 +545,7 @@ with recursive a as (
select 1 as b
union all
select * from a
) cycle b set c to true default false using p
) cycle b set c using p
select * from a;
-- search+cycle
@ -556,7 +556,7 @@ with recursive search_graph(f, t, label) as (
from graph g, search_graph sg
where g.f = sg.t
) search depth first by f, t set seq
cycle f, t set is_cycle to true default false using path
cycle f, t set is_cycle using path
select * from search_graph;
with recursive search_graph(f, t, label) as (
@ -566,7 +566,7 @@ with recursive search_graph(f, t, label) as (
from graph g, search_graph sg
where g.f = sg.t
) search breadth first by f, t set seq
cycle f, t set is_cycle to true default false using path
cycle f, t set is_cycle using path
select * from search_graph;
-- various syntax errors
@ -576,7 +576,7 @@ with recursive search_graph(f, t, label) as (
select g.*
from graph g, search_graph sg
where g.f = sg.t
) cycle foo, tar set is_cycle to true default false using path
) cycle foo, tar set is_cycle using path
select * from search_graph;
with recursive search_graph(f, t, label) as (
@ -654,19 +654,31 @@ with recursive search_graph(f, t, label) as (
select * from search_graph;
-- test ruleutils and view expansion
create temp view v_cycle as
create temp view v_cycle1 as
with recursive search_graph(f, t, label) as (
select * from graph g
union all
select g.*
from graph g, search_graph sg
where g.f = sg.t
) cycle f, t set is_cycle to true default false using path
) cycle f, t set is_cycle using path
select f, t, label from search_graph;
select pg_get_viewdef('v_cycle');
create temp view v_cycle2 as
with recursive search_graph(f, t, label) as (
select * from graph g
union all
select g.*
from graph g, search_graph sg
where g.f = sg.t
) cycle f, t set is_cycle to 'Y' default 'N' using path
select f, t, label from search_graph;
select * from v_cycle;
select pg_get_viewdef('v_cycle1');
select pg_get_viewdef('v_cycle2');
select * from v_cycle1;
select * from v_cycle2;
--
-- test multiple WITH queries