From 55c9050b4ec413e9b1b9eb9296196fc9c1957c8c Mon Sep 17 00:00:00 2001 From: Peter Eisentraut Date: Mon, 22 Feb 2021 09:36:49 +0100 Subject: [PATCH] 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. --- doc/src/sgml/queries.sgml | 5 +- doc/src/sgml/ref/select.sgml | 8 +- src/backend/parser/gram.y | 11 +++ src/backend/utils/adt/ruleutils.c | 19 ++++- src/test/regress/expected/with.out | 117 ++++++++++++++++++++++------- src/test/regress/sql/with.sql | 30 +++++--- 6 files changed, 143 insertions(+), 47 deletions(-) diff --git a/doc/src/sgml/queries.sgml b/doc/src/sgml/queries.sgml index 4741506eb5..bc0b3cc9fe 100644 --- a/doc/src/sgml/queries.sgml +++ b/doc/src/sgml/queries.sgml @@ -2349,14 +2349,13 @@ Cycle Detection SELECT g.id, g.link, g.data, sg.depth + 1 FROM graph g, search_graph sg WHERE g.id = sg.link -) CYCLE id SET is_cycle TO true DEFAULT false USING path +) CYCLE id SET is_cycle USING path SELECT * FROM search_graph; and it will be internally rewritten to the above form. The CYCLE 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. diff --git a/doc/src/sgml/ref/select.sgml b/doc/src/sgml/ref/select.sgml index eb8b524951..ab91105599 100644 --- a/doc/src/sgml/ref/select.sgml +++ b/doc/src/sgml/ref/select.sgml @@ -74,7 +74,7 @@ with_query_name [ ( column_name [, ...] ) ] AS [ [ NOT ] MATERIALIZED ] ( select | values | insert | update | delete ) [ SEARCH { BREADTH | DEPTH } FIRST BY column_name [, ...] SET search_seq_col_name ] - [ CYCLE column_name [, ...] SET cycle_mark_col_name TO cycle_mark_value DEFAULT cycle_mark_default USING cycle_path_col_name ] + [ CYCLE column_name [, ...] SET cycle_mark_col_name [ TO cycle_mark_value DEFAULT cycle_mark_default ] USING cycle_path_col_name ] TABLE [ ONLY ] table_name [ * ] @@ -302,8 +302,10 @@ <literal>WITH</literal> Clause been detected. cycle_mark_value and cycle_mark_default 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, TRUE and FALSE (of type + boolean) are used. Furthermore, a column named cycle_path_col_name will be added to the result column list of the WITH query. This column is used internally for tracking visited rows. See 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; diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c index 4a9244f4f6..879288c139 100644 --- a/src/backend/utils/adt/ruleutils.c +++ b/src/backend/utils/adt/ruleutils.c @@ -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)); } diff --git a/src/test/regress/expected/with.out b/src/test/regress/expected/with.out index c519a61c4f..1394302f3b 100644 --- a/src/test/regress/expected/with.out +++ b/src/test/regress/expected/with.out @@ -892,7 +892,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 ---+---+------------+----------+------------------------------------------- @@ -1012,7 +1012,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 ---+---+----------- @@ -1028,7 +1028,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 ---+---+------------+-------------------------------------------+----------+------------------------------------------- @@ -1066,7 +1066,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 ---+---+------------+---------+----------+------------------------------------------- @@ -1104,10 +1104,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 @@ -1198,38 +1198,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 diff --git a/src/test/regress/sql/with.sql b/src/test/regress/sql/with.sql index f4ba0d8e39..359bfd456f 100644 --- a/src/test/regress/sql/with.sql +++ b/src/test/regress/sql/with.sql @@ -465,7 +465,7 @@ CREATE TEMPORARY TABLE tree( 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 ( @@ -501,7 +501,7 @@ CREATE TEMPORARY TABLE tree( 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 @@ -512,7 +512,7 @@ CREATE TEMPORARY TABLE tree( 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 ( @@ -522,7 +522,7 @@ CREATE TEMPORARY TABLE tree( 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 @@ -532,7 +532,7 @@ CREATE TEMPORARY TABLE tree( 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 ( @@ -610,19 +610,31 @@ CREATE TEMPORARY TABLE tree( 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; + +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_cycle'); +select pg_get_viewdef('v_cycle1'); +select pg_get_viewdef('v_cycle2'); -select * from v_cycle; +select * from v_cycle1; +select * from v_cycle2; -- -- test multiple WITH queries -- 2.30.1