Adjust cycle detection examples and tests

Adjust the existing cycle detection example and test queries to put
the cycle column before the path column.  This is mainly because the
SQL-standard CYCLE clause puts them in that order, and so if we added
that feature that would make the sequence of examples more consistent
and easier to follow.

Discussion: https://www.postgresql.org/message-id/c5603982-0088-7f14-0caa-fdcd0c837b57@2ndquadrant.com
This commit is contained in:
Peter Eisentraut 2020-10-12 07:46:20 +02:00
parent 88ea7a1188
commit 3fb676504d
3 changed files with 83 additions and 83 deletions

View File

@ -2144,20 +2144,20 @@ SELECT * FROM search_graph;
<literal>UNION ALL</literal> to <literal>UNION</literal> would not eliminate the looping.
Instead we need to recognize whether we have reached the same row again
while following a particular path of links. We add two columns
<structfield>path</structfield> and <structfield>cycle</structfield> to the loop-prone query:
<structfield>is_cycle</structfield> and <structfield>path</structfield> to the loop-prone query:
<programlisting>
WITH RECURSIVE search_graph(id, link, data, depth, path, cycle) AS (
WITH RECURSIVE search_graph(id, link, data, depth, is_cycle, path) AS (
SELECT g.id, g.link, g.data, 1,
ARRAY[g.id],
false
false,
ARRAY[g.id]
FROM graph g
UNION ALL
SELECT g.id, g.link, g.data, sg.depth + 1,
path || g.id,
g.id = ANY(path)
g.id = ANY(path),
path || g.id
FROM graph g, search_graph sg
WHERE g.id = sg.link AND NOT cycle
WHERE g.id = sg.link AND NOT is_cycle
)
SELECT * FROM search_graph;
</programlisting>
@ -2172,17 +2172,17 @@ SELECT * FROM search_graph;
compare fields <structfield>f1</structfield> and <structfield>f2</structfield>:
<programlisting>
WITH RECURSIVE search_graph(id, link, data, depth, path, cycle) AS (
WITH RECURSIVE search_graph(id, link, data, depth, is_cycle, path) AS (
SELECT g.id, g.link, g.data, 1,
ARRAY[ROW(g.f1, g.f2)],
false
false,
ARRAY[ROW(g.f1, g.f2)]
FROM graph g
UNION ALL
SELECT g.id, g.link, g.data, sg.depth + 1,
path || ROW(g.f1, g.f2),
ROW(g.f1, g.f2) = ANY(path)
ROW(g.f1, g.f2) = ANY(path),
path || ROW(g.f1, g.f2)
FROM graph g, search_graph sg
WHERE g.id = sg.link AND NOT cycle
WHERE g.id = sg.link AND NOT is_cycle
)
SELECT * FROM search_graph;
</programlisting>

View File

@ -579,79 +579,79 @@ insert into graph values
(1, 4, 'arc 1 -> 4'),
(4, 5, 'arc 4 -> 5'),
(5, 1, 'arc 5 -> 1');
with recursive search_graph(f, t, label, path, cycle) as (
select *, array[row(g.f, g.t)], false from graph g
with recursive search_graph(f, t, label, is_cycle, path) as (
select *, false, array[row(g.f, g.t)] from graph g
union all
select g.*, path || row(g.f, g.t), row(g.f, g.t) = any(path)
select g.*, row(g.f, g.t) = any(path), path || row(g.f, g.t)
from graph g, search_graph sg
where g.f = sg.t and not cycle
where g.f = sg.t and not is_cycle
)
select * from search_graph;
f | t | label | path | cycle
---+---+------------+-------------------------------------------+-------
1 | 2 | arc 1 -> 2 | {"(1,2)"} | f
1 | 3 | arc 1 -> 3 | {"(1,3)"} | f
2 | 3 | arc 2 -> 3 | {"(2,3)"} | f
1 | 4 | arc 1 -> 4 | {"(1,4)"} | f
4 | 5 | arc 4 -> 5 | {"(4,5)"} | f
5 | 1 | arc 5 -> 1 | {"(5,1)"} | f
1 | 2 | arc 1 -> 2 | {"(5,1)","(1,2)"} | f
1 | 3 | arc 1 -> 3 | {"(5,1)","(1,3)"} | f
1 | 4 | arc 1 -> 4 | {"(5,1)","(1,4)"} | f
2 | 3 | arc 2 -> 3 | {"(1,2)","(2,3)"} | f
4 | 5 | arc 4 -> 5 | {"(1,4)","(4,5)"} | f
5 | 1 | arc 5 -> 1 | {"(4,5)","(5,1)"} | f
1 | 2 | arc 1 -> 2 | {"(4,5)","(5,1)","(1,2)"} | f
1 | 3 | arc 1 -> 3 | {"(4,5)","(5,1)","(1,3)"} | f
1 | 4 | arc 1 -> 4 | {"(4,5)","(5,1)","(1,4)"} | f
2 | 3 | arc 2 -> 3 | {"(5,1)","(1,2)","(2,3)"} | f
4 | 5 | arc 4 -> 5 | {"(5,1)","(1,4)","(4,5)"} | f
5 | 1 | arc 5 -> 1 | {"(1,4)","(4,5)","(5,1)"} | f
1 | 2 | arc 1 -> 2 | {"(1,4)","(4,5)","(5,1)","(1,2)"} | f
1 | 3 | arc 1 -> 3 | {"(1,4)","(4,5)","(5,1)","(1,3)"} | f
1 | 4 | arc 1 -> 4 | {"(1,4)","(4,5)","(5,1)","(1,4)"} | t
2 | 3 | arc 2 -> 3 | {"(4,5)","(5,1)","(1,2)","(2,3)"} | f
4 | 5 | arc 4 -> 5 | {"(4,5)","(5,1)","(1,4)","(4,5)"} | t
5 | 1 | arc 5 -> 1 | {"(5,1)","(1,4)","(4,5)","(5,1)"} | t
2 | 3 | arc 2 -> 3 | {"(1,4)","(4,5)","(5,1)","(1,2)","(2,3)"} | f
f | t | label | is_cycle | path
---+---+------------+----------+-------------------------------------------
1 | 2 | arc 1 -> 2 | f | {"(1,2)"}
1 | 3 | arc 1 -> 3 | f | {"(1,3)"}
2 | 3 | arc 2 -> 3 | f | {"(2,3)"}
1 | 4 | arc 1 -> 4 | f | {"(1,4)"}
4 | 5 | arc 4 -> 5 | f | {"(4,5)"}
5 | 1 | arc 5 -> 1 | f | {"(5,1)"}
1 | 2 | arc 1 -> 2 | f | {"(5,1)","(1,2)"}
1 | 3 | arc 1 -> 3 | f | {"(5,1)","(1,3)"}
1 | 4 | arc 1 -> 4 | f | {"(5,1)","(1,4)"}
2 | 3 | arc 2 -> 3 | f | {"(1,2)","(2,3)"}
4 | 5 | arc 4 -> 5 | f | {"(1,4)","(4,5)"}
5 | 1 | arc 5 -> 1 | f | {"(4,5)","(5,1)"}
1 | 2 | arc 1 -> 2 | f | {"(4,5)","(5,1)","(1,2)"}
1 | 3 | arc 1 -> 3 | f | {"(4,5)","(5,1)","(1,3)"}
1 | 4 | arc 1 -> 4 | f | {"(4,5)","(5,1)","(1,4)"}
2 | 3 | arc 2 -> 3 | f | {"(5,1)","(1,2)","(2,3)"}
4 | 5 | arc 4 -> 5 | f | {"(5,1)","(1,4)","(4,5)"}
5 | 1 | arc 5 -> 1 | f | {"(1,4)","(4,5)","(5,1)"}
1 | 2 | arc 1 -> 2 | f | {"(1,4)","(4,5)","(5,1)","(1,2)"}
1 | 3 | arc 1 -> 3 | f | {"(1,4)","(4,5)","(5,1)","(1,3)"}
1 | 4 | arc 1 -> 4 | t | {"(1,4)","(4,5)","(5,1)","(1,4)"}
2 | 3 | arc 2 -> 3 | f | {"(4,5)","(5,1)","(1,2)","(2,3)"}
4 | 5 | arc 4 -> 5 | t | {"(4,5)","(5,1)","(1,4)","(4,5)"}
5 | 1 | arc 5 -> 1 | t | {"(5,1)","(1,4)","(4,5)","(5,1)"}
2 | 3 | arc 2 -> 3 | f | {"(1,4)","(4,5)","(5,1)","(1,2)","(2,3)"}
(25 rows)
-- ordering by the path column has same effect as SEARCH DEPTH FIRST
with recursive search_graph(f, t, label, path, cycle) as (
select *, array[row(g.f, g.t)], false from graph g
with recursive search_graph(f, t, label, is_cycle, path) as (
select *, false, array[row(g.f, g.t)] from graph g
union all
select g.*, path || row(g.f, g.t), row(g.f, g.t) = any(path)
select g.*, row(g.f, g.t) = any(path), path || row(g.f, g.t)
from graph g, search_graph sg
where g.f = sg.t and not cycle
where g.f = sg.t and not is_cycle
)
select * from search_graph order by path;
f | t | label | path | cycle
---+---+------------+-------------------------------------------+-------
1 | 2 | arc 1 -> 2 | {"(1,2)"} | f
2 | 3 | arc 2 -> 3 | {"(1,2)","(2,3)"} | f
1 | 3 | arc 1 -> 3 | {"(1,3)"} | f
1 | 4 | arc 1 -> 4 | {"(1,4)"} | f
4 | 5 | arc 4 -> 5 | {"(1,4)","(4,5)"} | f
5 | 1 | arc 5 -> 1 | {"(1,4)","(4,5)","(5,1)"} | f
1 | 2 | arc 1 -> 2 | {"(1,4)","(4,5)","(5,1)","(1,2)"} | f
2 | 3 | arc 2 -> 3 | {"(1,4)","(4,5)","(5,1)","(1,2)","(2,3)"} | f
1 | 3 | arc 1 -> 3 | {"(1,4)","(4,5)","(5,1)","(1,3)"} | f
1 | 4 | arc 1 -> 4 | {"(1,4)","(4,5)","(5,1)","(1,4)"} | t
2 | 3 | arc 2 -> 3 | {"(2,3)"} | f
4 | 5 | arc 4 -> 5 | {"(4,5)"} | f
5 | 1 | arc 5 -> 1 | {"(4,5)","(5,1)"} | f
1 | 2 | arc 1 -> 2 | {"(4,5)","(5,1)","(1,2)"} | f
2 | 3 | arc 2 -> 3 | {"(4,5)","(5,1)","(1,2)","(2,3)"} | f
1 | 3 | arc 1 -> 3 | {"(4,5)","(5,1)","(1,3)"} | f
1 | 4 | arc 1 -> 4 | {"(4,5)","(5,1)","(1,4)"} | f
4 | 5 | arc 4 -> 5 | {"(4,5)","(5,1)","(1,4)","(4,5)"} | t
5 | 1 | arc 5 -> 1 | {"(5,1)"} | f
1 | 2 | arc 1 -> 2 | {"(5,1)","(1,2)"} | f
2 | 3 | arc 2 -> 3 | {"(5,1)","(1,2)","(2,3)"} | f
1 | 3 | arc 1 -> 3 | {"(5,1)","(1,3)"} | f
1 | 4 | arc 1 -> 4 | {"(5,1)","(1,4)"} | f
4 | 5 | arc 4 -> 5 | {"(5,1)","(1,4)","(4,5)"} | f
5 | 1 | arc 5 -> 1 | {"(5,1)","(1,4)","(4,5)","(5,1)"} | t
f | t | label | is_cycle | path
---+---+------------+----------+-------------------------------------------
1 | 2 | arc 1 -> 2 | f | {"(1,2)"}
2 | 3 | arc 2 -> 3 | f | {"(1,2)","(2,3)"}
1 | 3 | arc 1 -> 3 | f | {"(1,3)"}
1 | 4 | arc 1 -> 4 | f | {"(1,4)"}
4 | 5 | arc 4 -> 5 | f | {"(1,4)","(4,5)"}
5 | 1 | arc 5 -> 1 | f | {"(1,4)","(4,5)","(5,1)"}
1 | 2 | arc 1 -> 2 | f | {"(1,4)","(4,5)","(5,1)","(1,2)"}
2 | 3 | arc 2 -> 3 | f | {"(1,4)","(4,5)","(5,1)","(1,2)","(2,3)"}
1 | 3 | arc 1 -> 3 | f | {"(1,4)","(4,5)","(5,1)","(1,3)"}
1 | 4 | arc 1 -> 4 | t | {"(1,4)","(4,5)","(5,1)","(1,4)"}
2 | 3 | arc 2 -> 3 | f | {"(2,3)"}
4 | 5 | arc 4 -> 5 | f | {"(4,5)"}
5 | 1 | arc 5 -> 1 | f | {"(4,5)","(5,1)"}
1 | 2 | arc 1 -> 2 | f | {"(4,5)","(5,1)","(1,2)"}
2 | 3 | arc 2 -> 3 | f | {"(4,5)","(5,1)","(1,2)","(2,3)"}
1 | 3 | arc 1 -> 3 | f | {"(4,5)","(5,1)","(1,3)"}
1 | 4 | arc 1 -> 4 | f | {"(4,5)","(5,1)","(1,4)"}
4 | 5 | arc 4 -> 5 | t | {"(4,5)","(5,1)","(1,4)","(4,5)"}
5 | 1 | arc 5 -> 1 | f | {"(5,1)"}
1 | 2 | arc 1 -> 2 | f | {"(5,1)","(1,2)"}
2 | 3 | arc 2 -> 3 | f | {"(5,1)","(1,2)","(2,3)"}
1 | 3 | arc 1 -> 3 | f | {"(5,1)","(1,3)"}
1 | 4 | arc 1 -> 4 | f | {"(5,1)","(1,4)"}
4 | 5 | arc 4 -> 5 | f | {"(5,1)","(1,4)","(4,5)"}
5 | 1 | arc 5 -> 1 | t | {"(5,1)","(1,4)","(4,5)","(5,1)"}
(25 rows)
--

View File

@ -308,22 +308,22 @@ insert into graph values
(4, 5, 'arc 4 -> 5'),
(5, 1, 'arc 5 -> 1');
with recursive search_graph(f, t, label, path, cycle) as (
select *, array[row(g.f, g.t)], false from graph g
with recursive search_graph(f, t, label, is_cycle, path) as (
select *, false, array[row(g.f, g.t)] from graph g
union all
select g.*, path || row(g.f, g.t), row(g.f, g.t) = any(path)
select g.*, row(g.f, g.t) = any(path), path || row(g.f, g.t)
from graph g, search_graph sg
where g.f = sg.t and not cycle
where g.f = sg.t and not is_cycle
)
select * from search_graph;
-- ordering by the path column has same effect as SEARCH DEPTH FIRST
with recursive search_graph(f, t, label, path, cycle) as (
select *, array[row(g.f, g.t)], false from graph g
with recursive search_graph(f, t, label, is_cycle, path) as (
select *, false, array[row(g.f, g.t)] from graph g
union all
select g.*, path || row(g.f, g.t), row(g.f, g.t) = any(path)
select g.*, row(g.f, g.t) = any(path), path || row(g.f, g.t)
from graph g, search_graph sg
where g.f = sg.t and not cycle
where g.f = sg.t and not is_cycle
)
select * from search_graph order by path;