From 4fa5000efe932cab6801b13940965b1eb36b4e25 Mon Sep 17 00:00:00 2001 From: Jon Betts Date: Mon, 1 May 2023 15:12:55 +0100 Subject: [PATCH] Add denomalized name columns to join tables Metabase doesn't handle joins which result in duplicated column names. It causes the columns to get confused, like 'name'. Adding these to the join tables is both convenient and works around the issue. --- .../03_organization_group/01_create_view.sql | 57 ++++++++++++------- .../02_group_roles/01_create_view.sql | 49 +++++++++++----- .../03_organization_roles/01_create_view.sql | 52 +++++++++++------ 3 files changed, 108 insertions(+), 50 deletions(-) diff --git a/report/data_tasks/report/create_from_scratch/04_lms/04_groups/03_organization_group/01_create_view.sql b/report/data_tasks/report/create_from_scratch/04_lms/04_groups/03_organization_group/01_create_view.sql index 70d64d53..383ec957 100644 --- a/report/data_tasks/report/create_from_scratch/04_lms/04_groups/03_organization_group/01_create_view.sql +++ b/report/data_tasks/report/create_from_scratch/04_lms/04_groups/03_organization_group/01_create_view.sql @@ -3,26 +3,45 @@ DROP MATERIALIZED VIEW IF EXISTS lms.organization_group CASCADE; CREATE MATERIALIZED VIEW lms.organization_group AS ( -- Use distinct here to simplify the model from LMS. We want one row per -- org, rather than each org / lms-group combo - SELECT DISTINCT group_id, organization_id - FROM ( - SELECT - CONCAT('us-', group_id) AS group_id, - CASE - WHEN organization_id IS NULL THEN NULL - ELSE CONCAT('us-', organization_id) - END AS organization_id - FROM - lms_us.group_map + WITH organization_group AS ( + SELECT DISTINCT group_id, organization_id + FROM ( + SELECT + CONCAT('us-', group_id) AS group_id, + CASE + WHEN organization_id IS NULL THEN NULL + ELSE CONCAT('us-', organization_id) + END AS organization_id + FROM + lms_us.group_map + + UNION ALL - UNION ALL + SELECT + CONCAT('ca-', group_id) AS group_id, + CASE + WHEN organization_id IS NULL THEN NULL + ELSE CONCAT('ca-', organization_id) + END AS organization_id + FROM + lms_ca.group_map + ) AS data + ) SELECT - CONCAT('ca-', group_id) AS group_id, - CASE - WHEN organization_id IS NULL THEN NULL - ELSE CONCAT('ca-', organization_id) - END AS organization_id - FROM - lms_ca.group_map - ) AS data + -- We will include the group and organization names here even though + -- we could get it from the tables directly to avoid issues in Metabase. + -- It doesn't handle multiple columns with the same name (like `name`) + -- properly. + organizations.id AS organization_id, + organizations.name AS organization_name, + organizations.public_id AS organization_public_id, + groups.id AS group_id, + groups.name AS group_name + FROM organization_group + JOIN lms.organizations ON + organizations.id = organization_group.organization_id + JOIN lms.groups ON + groups.id = organization_group.group_id + ORDER BY organization_id, group_id ) WITH NO DATA; diff --git a/report/data_tasks/report/create_from_scratch/04_lms/05_users/02_group_roles/01_create_view.sql b/report/data_tasks/report/create_from_scratch/04_lms/05_users/02_group_roles/01_create_view.sql index acdc3eaf..443f1cda 100644 --- a/report/data_tasks/report/create_from_scratch/04_lms/05_users/02_group_roles/01_create_view.sql +++ b/report/data_tasks/report/create_from_scratch/04_lms/05_users/02_group_roles/01_create_view.sql @@ -1,24 +1,43 @@ DROP MATERIALIZED VIEW IF EXISTS lms.group_roles CASCADE; CREATE MATERIALIZED VIEW lms.group_roles AS ( - SELECT - group_id, - user_id, - role - FROM ( + WITH group_roles AS ( SELECT - CONCAT('us-', group_id) AS group_id, - CONCAT('us-', user_id) AS user_id, + group_id, + user_id, role - FROM lms_us.group_roles + FROM ( + SELECT + CONCAT('us-', group_id) AS group_id, + CONCAT('us-', user_id) AS user_id, + role + FROM lms_us.group_roles - UNION ALL + UNION ALL - SELECT - CONCAT('ca-', group_id) AS group_id, - CONCAT('ca-', user_id) AS user_id, - role - FROM lms_ca.group_roles - ) AS data + SELECT + CONCAT('ca-', group_id) AS group_id, + CONCAT('ca-', user_id) AS user_id, + role + FROM lms_ca.group_roles + ) AS data + ORDER BY group_id, user_id + ) + + SELECT + -- We will include the group and user names here even though we could + -- get it from the tables directly to avoid issues in Metabase. + -- It doesn't handle multiple columns with the same name (like `name`) + -- properly. + groups.id AS group_id, + groups.name AS group_name, + role, + users.id AS user_id, + users.display_name AS user_display_name + FROM group_roles + JOIN lms.groups ON + groups.id = group_roles.group_id + JOIN lms.users ON + users.id = group_roles.user_id ORDER BY group_id, user_id ) WITH NO DATA; diff --git a/report/data_tasks/report/create_from_scratch/04_lms/05_users/03_organization_roles/01_create_view.sql b/report/data_tasks/report/create_from_scratch/04_lms/05_users/03_organization_roles/01_create_view.sql index 0d9d9705..88192c16 100644 --- a/report/data_tasks/report/create_from_scratch/04_lms/05_users/03_organization_roles/01_create_view.sql +++ b/report/data_tasks/report/create_from_scratch/04_lms/05_users/03_organization_roles/01_create_view.sql @@ -1,24 +1,44 @@ DROP MATERIALIZED VIEW IF EXISTS lms.organization_roles CASCADE; CREATE MATERIALIZED VIEW lms.organization_roles AS ( - SELECT - organization_id, - user_id, - role - FROM ( + WITH organization_roles AS ( SELECT - CONCAT('us-', organization_id) AS organization_id, - CONCAT('us-', user_id) AS user_id, - role - FROM lms_us.organization_roles + organization_id, + role, + user_id + FROM ( + SELECT + CONCAT('us-', organization_id) AS organization_id, + CONCAT('us-', user_id) AS user_id, + role + FROM lms_us.organization_roles - UNION ALL + UNION ALL - SELECT - CONCAT('ca-', organization_id) AS organization_id, - CONCAT('ca-', user_id) AS user_id, - role - FROM lms_ca.organization_roles - ) AS data + SELECT + CONCAT('ca-', organization_id) AS organization_id, + CONCAT('ca-', user_id) AS user_id, + role + FROM lms_ca.organization_roles + ) AS data + ORDER BY organization_id, user_id + ) + + SELECT + -- We will include the organization and user names here even though we + -- could get it from the tables directly to avoid issues in Metabase. + -- It doesn't handle multiple columns with the same name (like `name`) + -- properly. + organizations.id AS organization_id, + organizations.name AS organizations_name, + organizations.public_id AS organization_public_id, + role, + users.id AS user_id, + users.display_name AS user_display_name + FROM organization_roles + JOIN lms.organizations ON + organizations.id = organization_roles.organization_id + JOIN lms.users ON + users.id = organization_roles.user_id ORDER BY organization_id, user_id ) WITH NO DATA;