Skip to content

Commit

Permalink
[1607] Implemented CTE to obtain entire tree hierarchy from the given…
Browse files Browse the repository at this point in the history
… Group instance. Unfortunately the CTE only recurses one level when we ask Sqlalchemy to return Group instances, whereas asking for field names makes sure it recurses through the entire depth of the tree.
  • Loading branch information
rossjones committed Feb 16, 2012
1 parent eb0d5e3 commit 35bba3d
Showing 1 changed file with 22 additions and 8 deletions.
30 changes: 22 additions & 8 deletions ckan/model/group.py
Original file line number Diff line number Diff line change
Expand Up @@ -137,14 +137,15 @@ def add_child(self, object_instance):
member = Member(group=self, table_id=getattr(object_instance,'id'), table_name=object_type_string)
Session.add(member)

def get_children_groups(self):
# TODO: Investigate Using members_of_type gives an error about
# group appearing too many times in query
members = Session.query(Member).\
filter_by(state=vdm.sqlalchemy.State.ACTIVE).\
filter(Member.table_name == "group").\
filter(Member.group_id == self.id).all()
return [ Group.get( m.table_id ) for m in members ]
def get_children_groups(self, type='group'):
# Returns a list of dicts where each dict contains "id", "name", and "title"
# When querying with a CTE specifying a model in the query parameter causes
# problems as it returns only the first level deep apparently not recursing
# any deeper than that. If we simplify and request only specific fields then
# if returns the full depth of the hierarchy.
results = Session.query("id","name", "title").\
from_statement(HIERARCHY_CTE).params(id=self.id,type=type).all()
return [ { "id":idf, "name": name, "title": title } for idf,name,title in results ]

def active_packages(self, load_eager=True):
query = Session.query(Package).\
Expand Down Expand Up @@ -251,3 +252,16 @@ def __repr__(self):
#TODO
MemberRevision.related_packages = lambda self: [self.continuity.package]

HIERARCHY_CTE = """
WITH RECURSIVE subtree(id) AS (
SELECT M.* FROM public.member AS M
WHERE M.table_name = 'group' AND M.state = 'active'
UNION ALL
SELECT M.* FROM public.member M, subtree SG
WHERE M.table_id = SG.group_id AND M.table_name = 'group' AND
M.state = 'active' )
SELECT G.* FROM subtree AS ST
INNER JOIN public.group G ON G.id = ST.table_id
WHERE group_id = :id AND G.type = :type
"""

0 comments on commit 35bba3d

Please sign in to comment.