diff --git a/api/endpoints/organizations.py b/api/endpoints/organizations.py index 5f1e0b7..78ccd71 100644 --- a/api/endpoints/organizations.py +++ b/api/endpoints/organizations.py @@ -1,8 +1,10 @@ import logging + +import sqlalchemy from flask_restx import Resource from flask import request from flask_api import status - +from collections import namedtuple from api.models.job_queue import JobQueue from api.models.organization import Organization as Organization_db from api.models.organization_job_queue import OrganizationJobQueue @@ -33,18 +35,39 @@ def get(self): Lists the hierarchy of organizations using MAAP :return: """ - top_query = db.session.query(Organization_db) - top_query = top_query.filter(Organization_db.parent_org_id is not None) - top_query = top_query.cte('cte', recursive=True) - bot_query = db.session.query(Organization_db) - bot_query = bot_query.join(top_query, Organization_db.parent_org_id == top_query.c.id) + result = [] + otree = db.session.execute(sqlalchemy.text('select * from org_tree order by row_number')) + + queues_query = db.session.query( + JobQueue, OrganizationJobQueue, + ).filter( + JobQueue.id == OrganizationJobQueue.job_queue_id + ).order_by(JobQueue.queue_name).all() - recursive_q = top_query.union(bot_query) - orgs = db.session.query(recursive_q) + Record = namedtuple('Record', otree.keys()) + org_tree_records = [Record(*r) for r in otree.fetchall()] + for r in org_tree_records: + org = { + 'id': r.id, + 'name': r.name, + 'depth': r.depth, + 'member_count': r.member_count, + 'default_job_limit_count': r.default_job_limit_count, + 'default_job_limit_hours': r.default_job_limit_hours, + 'job_queues': [] + } + + for q in queues_query: + if q.OrganizationJobQueue.org_id == r.id: + org['job_queues'].append({ + 'id': q.JobQueue.id, + 'queue_name': q.JobQueue.queue_name, + 'queue_description': q.JobQueue.queue_description + }) + + result.append(org) - organization_schema = OrganizationSchema() - result = [json.loads(organization_schema.dumps(p)) for p in orgs] return result @api.doc(security='ApiKeyAuth') diff --git a/sql/materialized_views/org_tree.sql b/sql/materialized_views/org_tree.sql new file mode 100644 index 0000000..069c57d --- /dev/null +++ b/sql/materialized_views/org_tree.sql @@ -0,0 +1,37 @@ +WITH RECURSIVE + node_rec AS (SELECT 1 AS row_count, + 0 AS member_count, + 1 AS depth, + organization.id, + organization.name, + organization.parent_org_id, + organization.default_job_limit_count, + organization.default_job_limit_hours, + organization.creation_date + FROM organization + WHERE organization.parent_org_id IS NULL + UNION ALL + SELECT 1 AS row_count, + 0 AS member_count, + r.depth + 1, + n.id, + n.name, + n.parent_org_id, + n.default_job_limit_count, + n.default_job_limit_hours, + n.creation_date + FROM node_rec r + JOIN organization n ON n.parent_org_id = r.id) SEARCH DEPTH FIRST BY name, + id SET path + SELECT row_number() OVER (ORDER BY node_rec.path, node_rec.name) AS row_number, + ( SELECT count(*) AS count + FROM organization_membership + WHERE organization_membership.org_id = node_rec.id) AS member_count, + node_rec.depth, + node_rec.id, + node_rec.name, + node_rec.default_job_limit_count, + node_rec.default_job_limit_hours + FROM node_rec + WHERE node_rec.parent_org_id IS NOT NULL + ORDER BY node_rec.path, node_rec.name \ No newline at end of file