I would need to see the table defs for "docorder" to do this completely.
The parents + kids version: # 1. make parents cte parents_cte = session.query(TreeNode).filter(TreeNode.name == "subnode4").cte("parents", recursive=True) p2 = session.query(TreeNode).filter(TreeNode.id == parents_cte.c.parent_id) parents_cte = parents_cte.union(p2) # 2. make kids cte kids_cte = session.query(TreeNode).filter(TreeNode.name == "subnode4").cte("kids", recursive=True) k2 = session.query(TreeNode).filter(TreeNode.parent_id == kids_cte.c.parent_id) kids_cte = kids_cte.union(k2) # 3. SELECT from both CTEs and create a union, then a subquery from sqlalchemy import union treenode_rows = union(parents_cte.select(), kids_cte.select()).alias("n") 4. SELECT TreeNode entities from the subuqery (docs: https://docs.sqlalchemy.org/en/13/orm/tutorial.html#selecting-entities-from-subqueries) from sqlalchemy.orm import aliased treenode_alias = aliased(TreeNode, treenode_rows) # 5. select rows print(session.query(treenode_alias).order_by(treenode_alias.id).all()) this looks like exactly your first query if I'm not mistaken and it returns TreeNode objects per aliased(). hope this gets you started. On Tue, Nov 10, 2020, at 2:55 PM, kris wrote: > > A more complete version of the SQL to be returned as TreeNode > > WITH RECURSIVE > docorder AS ( select id, rn from ...), > parents AS > (SELECT tree.id AS id, tree.parent_id AS parent_id, tree.name AS name > FROM tree > WHERE tree.name = 'subnode4' > UNION SELECT tree.id AS tree_id, tree.parent_id AS tree_parent_id, > tree.name AS tree_name > FROM tree, parents > WHERE tree.id = parents.parent_id), > kids AS > (SELECT tree.id AS id, tree.parent_id AS parent_id, tree.name AS name > FROM tree > WHERE tree.name = 'subnode4' > UNION SELECT tree.id AS tree_id, tree.parent_id AS tree_parent_id, > tree.name AS tree_name > FROM tree, kids > WHERE tree.parent_id = kids.id) > SELECT n.id, n.parent_id, n.name > FROM ( > SELECT parents.id, parents.parent_id, parents.name > FROM parents > UNION > SELECT kids.id, kids.parent_id, kids.name > FROM kids) AS n, > docorder > WHERE n.id = docorder.id > ORDER BY docorder.rn, n.parent_id > > > > > -- > SQLAlchemy - > The Python SQL Toolkit and Object Relational Mapper > > http://www.sqlalchemy.org/ > > To post example code, please provide an MCVE: Minimal, Complete, and > Verifiable Example. See http://stackoverflow.com/help/mcve for a full > description. > --- > You received this message because you are subscribed to the Google Groups > "sqlalchemy" group. > To unsubscribe from this group and stop receiving emails from it, send an > email to sqlalchemy+unsubscr...@googlegroups.com. > To view this discussion on the web visit > https://groups.google.com/d/msgid/sqlalchemy/ae4cfacb-ef3f-4d78-961d-45f8ee09f846n%40googlegroups.com > > <https://groups.google.com/d/msgid/sqlalchemy/ae4cfacb-ef3f-4d78-961d-45f8ee09f846n%40googlegroups.com?utm_medium=email&utm_source=footer>. -- SQLAlchemy - The Python SQL Toolkit and Object Relational Mapper http://www.sqlalchemy.org/ To post example code, please provide an MCVE: Minimal, Complete, and Verifiable Example. See http://stackoverflow.com/help/mcve for a full description. --- You received this message because you are subscribed to the Google Groups "sqlalchemy" group. To unsubscribe from this group and stop receiving emails from it, send an email to sqlalchemy+unsubscr...@googlegroups.com. To view this discussion on the web visit https://groups.google.com/d/msgid/sqlalchemy/f938d44d-bcc4-4043-82b1-9c2f8c65cc60%40www.fastmail.com.