Last active
December 25, 2015 14:08
-
-
Save devmug/6988466 to your computer and use it in GitHub Desktop.
postgres recursive query.
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
First the DDL: | |
CREATE TABLE node ( | |
id SERIAL, | |
label TEXT NOT NULL, -- name of the node | |
parent_id INT, | |
PRIMARY KEY(id) | |
); | |
NOTICE: CREATE TABLE will create implicit sequence "node_id_seq" for serial column "node.id" | |
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "node_pkey" for table "node" | |
CREATE TABLE | |
then some data: | |
test=> INSERT INTO node (label, parent_id) VALUES ('n1',NULL),('n2',1),('n3',2),('n4',3); | |
INSERT 0 4 | |
test=> INSERT INTO node (label) VALUES ('garbage1'),('garbage2'), ('garbage3'); | |
INSERT 0 3 | |
test=> INSERT INTO node (label,parent_id) VALUES ('garbage4',6); | |
INSERT 0 1 | |
test=> SELECT * FROM node; | |
id | label | parent_id | |
----+----------+----------- | |
1 | n1 | | |
2 | n2 | 1 | |
3 | n3 | 2 | |
4 | n4 | 3 | |
5 | garbage1 | | |
6 | garbage2 | | |
7 | garbage3 | | |
8 | garbage4 | 6 | |
(8 rows) | |
This performs a recursive query on every id in node: | |
test=> WITH RECURSIVE nodes_cte(id, label, parent_id, depth, path) AS ( | |
SELECT tn.id, tn.label, tn.parent_id, 1::INT AS depth, tn.id::TEXT AS path FROM node AS tn WHERE tn.parent_id IS NULL | |
UNION ALL | |
SELECT c.id, c.label, c.parent_id, p.depth + 1 AS depth, (p.path || '->' || c.id::TEXT) FROM nodes_cte AS p, node AS c WHERE c.parent_id = p.id | |
) | |
SELECT * FROM nodes_cte AS n ORDER BY n.id ASC; | |
id | label | parent_id | depth | path | |
----+----------+-----------+-------+------------ | |
1 | n1 | | 1 | 1 | |
2 | n2 | 1 | 2 | 1->2 | |
3 | n3 | 2 | 3 | 1->2->3 | |
4 | n4 | 3 | 4 | 1->2->3->4 | |
5 | garbage1 | | 1 | 5 | |
6 | garbage2 | | 1 | 6 | |
7 | garbage3 | | 1 | 7 | |
8 | garbage4 | 6 | 2 | 6->8 | |
(8 rows) | |
This gets all of the descendents WHERE node.id = 1: | |
test=> WITH RECURSIVE nodes_cte(id, label, parent_id, depth, path) AS ( | |
SELECT tn.id, tn.label, tn.parent_id, 1::INT AS depth, tn.id::TEXT AS path FROM node AS tn WHERE tn.id = 1 | |
UNION ALL | |
SELECT c.id, c.label, c.parent_id, p.depth + 1 AS depth, (p.path || '->' || c.id::TEXT) FROM nodes_cte AS p, node AS c WHERE c.parent_id = p.id | |
) | |
SELECT * FROM nodes_cte AS n; | |
id | label | parent_id | depth | path | |
----+-------+-----------+-------+------------ | |
1 | n1 | | 1 | 1 | |
2 | n2 | 1 | 2 | 1->2 | |
3 | n3 | 2 | 3 | 1->2->3 | |
4 | n4 | 3 | 4 | 1->2->3->4 | |
(4 rows) | |
The following will get the path of the node with id 4: | |
test=> WITH RECURSIVE nodes_cte(id, label, parent_id, depth, path) AS ( | |
SELECT tn.id, tn.label, tn.parent_id, 1::INT AS depth, tn.id::TEXT AS path FROM node AS tn WHERE tn.parent_id IS NULL | |
UNION ALL | |
SELECT c.id, c.label, c.parent_id, p.depth + 1 AS depth, (p.path || '->' || c.id::TEXT) FROM nodes_cte AS p, node AS c WHERE c.parent_id = p.id | |
) | |
SELECT * FROM nodes_cte AS n WHERE n.id = 4; | |
id | label | parent_id | depth | path | |
----+-------+-----------+-------+------------ | |
4 | n4 | 3 | 4 | 1->2->3->4 | |
(1 row) | |
And let's assume you want to limit your search to descendants with a depth less than three (note that depth hasn't been incremented yet): | |
test=> WITH RECURSIVE nodes_cte(id, label, parent_id, depth, path) AS ( | |
SELECT tn.id, tn.label, tn.parent_id, 1::INT AS depth, tn.id::TEXT AS path FROM node AS tn WHERE tn.id = 1 | |
UNION ALL | |
SELECT c.id, c.label, c.parent_id, p.depth + 1 AS depth, (p.path || '->' || c.id::TEXT) FROM nodes_cte AS p, node AS c WHERE c.parent_id = p.id AND p.depth < 2 | |
) | |
SELECT * FROM nodes_cte AS n; | |
id | label | parent_id | depth | path | |
----+-------+-----------+-------+------ | |
1 | n1 | | 1 | 1 | |
2 | n2 | 1 | 2 | 1->2 | |
(2 rows) | |
I'd recommend using an ARRAY data type instead of a string for demonstrating the "path", but the arrow is more illustrative of the parent<=>child relationship. | |
array example. | |
WITH RECURSIVE nodes_cte(id, label, parent_id, depth, path) AS ( | |
SELECT tn.id, | |
tn.label, | |
tn.parent_id, | |
1::INT AS depth, | |
array[tn.id] AS path | |
FROM node AS tn | |
WHERE tn.parent_id IS NULL | |
UNION ALL | |
SELECT c.id, | |
c.label, | |
c.parent_id, | |
p.depth + 1 AS depth, | |
p.path || c.id | |
FROM nodes_cte AS p, node AS c | |
WHERE c.parent_id = p.id | |
) | |
SELECT * FROM nodes_cte AS n ORDER BY n.id ASC; | |
id | label | parent_id | depth | path | |
----+----------+-----------+-------+----------- | |
1 | n1 | | 1 | {1} | |
2 | n2 | 1 | 2 | {1,2} | |
3 | n3 | 2 | 3 | {1,2,3} | |
4 | n4 | 3 | 4 | {1,2,3,4} | |
5 | garbage1 | | 1 | {5} | |
6 | garbage2 | | 1 | {6} | |
7 | garbage3 | | 1 | {7} | |
8 | garbage4 | 6 | 2 | {6,8} |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment