mirror of
https://github.com/postgres/postgres.git
synced 2025-07-28 23:42:10 +03:00
Add docs and regression test about sorting the output of a recursive query in
depth-first search order. Upon close reading of SQL:2008, it seems that the spec's SEARCH DEPTH FIRST and SEARCH BREADTH FIRST options do not actually guarantee any particular result order: what they do is provide a constructed column that the user can then sort on in the outer query. So this is actually just as much functionality ...
This commit is contained in:
@ -499,6 +499,44 @@ select * from search_graph;
|
||||
2 | 3 | arc 2 -> 3 | {"(1,4)","(4,5)","(5,1)","(1,2)","(2,3)"} | f
|
||||
(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
|
||||
union all
|
||||
select g.*, path || row(g.f, g.t), row(g.f, g.t) = any(path)
|
||||
from graph g, search_graph sg
|
||||
where g.f = sg.t and not 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
|
||||
(25 rows)
|
||||
|
||||
--
|
||||
-- test multiple WITH queries
|
||||
--
|
||||
|
@ -272,6 +272,16 @@ with recursive search_graph(f, t, label, path, cycle) as (
|
||||
)
|
||||
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
|
||||
union all
|
||||
select g.*, path || row(g.f, g.t), row(g.f, g.t) = any(path)
|
||||
from graph g, search_graph sg
|
||||
where g.f = sg.t and not cycle
|
||||
)
|
||||
select * from search_graph order by path;
|
||||
|
||||
--
|
||||
-- test multiple WITH queries
|
||||
--
|
||||
|
Reference in New Issue
Block a user