Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add denomalized name columns to join tables #211

Merged
merged 1 commit into from
May 3, 2023
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
Expand Up @@ -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,
Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I've included the public id, because we nearly always want it in our reports, and it saves us a join. You can't present the name without it as a link, as the dashboard uses the public id as the key.

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;
Original file line number Diff line number Diff line change
@@ -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;
Original file line number Diff line number Diff line change
@@ -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;