Sunday, August 16. 2009Using Recursive Common table expressions to represent Tree structuresPrinter FriendlyComments
Display comments as
(Linear | Threaded)
Great topic!
A couple of observations: * Unless the length 1000 has some significance, use TEXT instead of VARCHAR(1000). * It might well be both faster and more correct to push items into an array and use array_to_string() in the outer SELECT, and it won't be subject to sorting anomalies. WITH RECURSIVE supplytree AS ( SELECT si_id, si_item, si_parentid, ARRAY[si_item] AS si_item_array FROM supplyitem WHERE si_parentid IS NULL UNION ALL SELECT si.si_id,si.si_item, si.si_parentid, sp.si_item_array || si.si_item As si_item_array FROM supplyitem As si JOIN supplytree AS sp ON (si.si_parentid = sp.si_id) ) SELECT si_id, array_to_string(si_item_array, '->') AS si_item_fullname FROM supplytree ORDER BY si_item_array;
Have thought about using ltree ?
http://www.postgresql.org/docs/current/static/ltree.html I'am not saying than WITH RECURSIVE is bad .. just that, there are simpler solution sometimes ;-)
Good point. We haven't explored the use of ltree so will have to give it a test drive sometime. I think the only thing against it is that its a PostgreSQL specific feature where as the CTE is more ANSI portable (except for possiblyt the word RECURSIVE)
Sabra,
Couple of ways -- you could write a function as we demonstrated in linked article, but that is not as suitable for multiple sets since it would probably do a subquery for each record. You coulde also take our example and limit with a WHERE clause but that is much slower than it could be. The other way would be to recurse backward from the child to the parent. So instead of starting at parent nodes -- you start at the child node and keep on unioning until you hit a parent with no parent. Will have to write that up sometime.
many thanks for this great example.i implemented the child to parent recursion in case someone needs it:
--Recursive query (introduced in 8.4 returns fully qualified name) WITH RECURSIVE supplytree AS (SELECT si_id, si_item, si_parentid, CAST(si_item As varchar(1000)) As si_item_fullname FROM supplyitem WHERE si_item in( '40 lb') UNION ALL SELECT si.si_id,si.si_item, si.si_parentid, CAST(si.si_item || '->' || sp.si_item_fullname As varchar(1000)) As si_item_fullname FROM supplyitem As si INNER JOIN supplytree AS sp ON (si.si_id = sp.si_parentid) ) SELECT si_id, si_item_fullname FROM supplytree where si_parentid is null ORDER BY si_item_fullname;
this is most easy
table tema -field tema_id (is the identificator) -field nombre (is the name) -field padre_id (is the parent id) WITH RECURSIVE tema_tree AS ( SELECT tema_id, nombre, padre_id, nombre||'' full_name FROM tema WHERE padre_id IS NULL UNION ALL SELECT t.tema_id, t.nombre, t.padre_id, tt.full_name||' -> '||t.nombre full_name FROM tema t JOIN tema_tree tt ON t.padre_id = tt.tema_id ) SELECT tema_id, full_name FROM tema_tree ORDER BY 2 |
Entry's LinksQuicksearchCalendar
Categories
Blog Administration |
This post was mentioned on Twitter by roblb: Using Recursive Common table expressions to represent Tree structures: A very long time ago, we wrote .. http://bit.ly/Flne3 #postgres
Tracked: Jan 04, 21:19
Tracked: Aug 20, 00:58