From 56a652bfe9c07d73db119b9073539b9fa9f1a087 Mon Sep 17 00:00:00 2001 From: Ewan Cahen Date: Wed, 7 Aug 2024 14:58:53 +0200 Subject: [PATCH] fix: don't show duplicate maintainers --- database/008-community.sql | 55 ++++++++++++++++--------------- database/100-create-api-views.sql | 53 ++++++++++++++--------------- 2 files changed, 56 insertions(+), 52 deletions(-) diff --git a/database/008-community.sql b/database/008-community.sql index 7cbaed11e..e46676c67 100644 --- a/database/008-community.sql +++ b/database/008-community.sql @@ -206,40 +206,43 @@ BEGIN END IF; RETURN QUERY - -- primary maintainer of community - SELECT - community.primary_maintainer AS maintainer, - ARRAY_AGG(login_for_account."name") AS name, - ARRAY_AGG(login_for_account.email) AS email, - ARRAY_AGG(login_for_account.home_organisation) AS affiliation, - TRUE AS is_primary - FROM - community - INNER JOIN - login_for_account ON community.primary_maintainer = login_for_account.account - WHERE - community.id = community_id - GROUP BY - community.id,community.primary_maintainer - -- append second selection - UNION - -- other maintainers of community + WITH maintainer_ids AS ( + -- primary maintainer of community + SELECT + community.primary_maintainer AS maintainer, + TRUE AS is_primary + FROM + community + WHERE + community.id = community_id + -- append second selection + UNION ALL + -- other maintainers of community + SELECT + maintainer_for_community.maintainer, + FALSE AS is_primary + FROM + maintainer_for_community + WHERE + maintainer_for_community.community = community_id + -- primary as first record + ORDER BY is_primary DESC + ) SELECT - maintainer_for_community.maintainer, + maintainer_ids.maintainer AS maintainer, ARRAY_AGG(login_for_account."name") AS name, ARRAY_AGG(login_for_account.email) AS email, ARRAY_AGG(login_for_account.home_organisation) AS affiliation, - FALSE AS is_primary + BOOL_OR(maintainer_ids.is_primary) AS is_primary FROM - maintainer_for_community + maintainer_ids INNER JOIN - login_for_account ON maintainer_for_community.maintainer = login_for_account.account - WHERE - maintainer_for_community.community = community_id + login_for_account ON login_for_account.account = maintainer_ids.maintainer GROUP BY - maintainer_for_community.community, maintainer_for_community.maintainer + maintainer_ids.maintainer -- primary as first record - ORDER BY is_primary DESC; + ORDER BY + is_primary DESC; RETURN; END $$; diff --git a/database/100-create-api-views.sql b/database/100-create-api-views.sql index 1bacb250b..8299c2913 100644 --- a/database/100-create-api-views.sql +++ b/database/100-create-api-views.sql @@ -707,40 +707,41 @@ BEGIN END IF; RETURN QUERY - -- primary maintainer of organisation - SELECT - organisation.primary_maintainer AS maintainer, - ARRAY_AGG(login_for_account."name") AS name, - ARRAY_AGG(login_for_account.email) AS email, - ARRAY_AGG(login_for_account.home_organisation) AS affiliation, - TRUE AS is_primary - FROM - organisation - INNER JOIN - login_for_account ON organisation.primary_maintainer = login_for_account.account - WHERE - organisation.id = organisation_id - GROUP BY - organisation.id,organisation.primary_maintainer - -- append second selection - UNION - -- other maintainers of organisation + WITH maintainer_ids AS ( + -- primary maintainer of organisation + SELECT + organisation.primary_maintainer AS maintainer, + TRUE AS is_primary + FROM + organisation + WHERE + organisation.id = organisation_id + -- append second selection + UNION ALL + -- other maintainers of organisation + SELECT + maintainer_for_organisation.maintainer AS maintainer, + FALSE AS is_primary + FROM + maintainer_for_organisation + WHERE + maintainer_for_organisation.organisation = organisation_id + ) SELECT - maintainer_for_organisation.maintainer, + maintainer_ids.maintainer AS maintainer, ARRAY_AGG(login_for_account."name") AS name, ARRAY_AGG(login_for_account.email) AS email, ARRAY_AGG(login_for_account.home_organisation) AS affiliation, - FALSE AS is_primary + BOOL_OR(maintainer_ids.is_primary) AS is_primary FROM - maintainer_for_organisation + maintainer_ids INNER JOIN - login_for_account ON maintainer_for_organisation.maintainer = login_for_account.account - WHERE - maintainer_for_organisation.organisation = organisation_id + login_for_account ON login_for_account.account = maintainer_ids.maintainer GROUP BY - maintainer_for_organisation.organisation, maintainer_for_organisation.maintainer + maintainer_ids.maintainer -- primary as first record - ORDER BY is_primary DESC; + ORDER BY + is_primary DESC; RETURN; END $$;