|
| 1 | +-- Org membership is now associated with a specific role within the org, this simplifies things, |
| 2 | +-- makes the data more consistent, no need to rely on triggers, and makes it much easier to display in the UI. |
| 3 | + |
| 4 | + |
| 5 | +-- SANITY CHECK: |
| 6 | +-- SELECT org_user.handle, member_user.handle, role.ref |
| 7 | +-- FROM orgs org |
| 8 | +-- JOIN role_memberships rm ON rm.resource_id = org.resource_id |
| 9 | +-- JOIN users member_user ON rm.subject_id = member_user.subject_id |
| 10 | +-- JOIN roles role ON role.id = rm.role_id |
| 11 | +-- JOIN users org_user ON org.user_id = org_user.id; |
| 12 | + |
| 13 | +-- SELECT org_user.handle, member_user.handle |
| 14 | +-- FROM org_members om |
| 15 | +-- JOIN users org_user ON om.organization_user_id = org_user.id |
| 16 | +-- JOIN users member_user ON om.member_user_id = member_user.id |
| 17 | +-- ; |
| 18 | + |
| 19 | + |
| 20 | +ALTER TABLE org_members |
| 21 | + ADD COLUMN role_id UUID REFERENCES roles(id) NULL; |
| 22 | + |
| 23 | +-- set all existing org members to be maintiners |
| 24 | +UPDATE org_members |
| 25 | + SET role_id = (SELECT id FROM roles WHERE ref = 'org_maintainer' LIMIT 1); |
| 26 | + |
| 27 | +-- Elevate the current org owners to have the org_owner role |
| 28 | +UPDATE org_members |
| 29 | + SET role_id = (SELECT id FROM roles WHERE ref = 'org_owner' LIMIT 1) |
| 30 | + WHERE EXISTS ( |
| 31 | + SELECT |
| 32 | + FROM orgs org |
| 33 | + JOIN users u ON org_members.member_user_id = u.id |
| 34 | + JOIN role_memberships rm ON rm.subject_id = u.subject_id AND rm.resource_id = org.resource_id |
| 35 | + JOIN roles r ON rm.role_id = r.id |
| 36 | + WHERE org.id = org_members.org_id |
| 37 | + AND r.ref = 'org_owner' |
| 38 | + ); |
| 39 | + |
| 40 | +ALTER TABLE org_members |
| 41 | + ALTER COLUMN role_id SET NOT NULL; |
| 42 | + |
| 43 | +-- Now add a check that each org always has an owner. |
| 44 | +CREATE OR REPLACE FUNCTION check_orgs_have_an_owner() |
| 45 | +RETURNS trigger AS $$ |
| 46 | +BEGIN |
| 47 | + IF NOT EXISTS ( |
| 48 | + SELECT |
| 49 | + FROM org_members om |
| 50 | + WHERE om.org_id = OLD.org_id |
| 51 | + AND om.role_id = (SELECT id FROM roles WHERE ref = 'org_owner' LIMIT 1) |
| 52 | + ) THEN |
| 53 | + RAISE EXCEPTION 'Each organization must have at least one owner.'; |
| 54 | + END IF; |
| 55 | + RETURN NULL; |
| 56 | +END; |
| 57 | +$$ LANGUAGE plpgsql; |
| 58 | + |
| 59 | +CREATE TRIGGER check_org_owners_trigger |
| 60 | + AFTER UPDATE OR DELETE ON org_members |
| 61 | + FOR EACH ROW |
| 62 | + EXECUTE FUNCTION check_orgs_have_an_owner(); |
| 63 | + |
| 64 | +-- Split out view containing all the direct subject<->resource permissions. |
| 65 | +-- |
| 66 | +-- This view expands the roles into their individual permissions |
| 67 | +-- but does not consider resource hierarchy or group memberships |
| 68 | +CREATE OR REPLACE VIEW direct_resource_permissions(subject_id, resource_id, permission) AS ( |
| 69 | + SELECT rm.subject_id, rm.resource_id, permission |
| 70 | + FROM role_memberships rm |
| 71 | + JOIN roles r ON rm.role_id = r.id |
| 72 | + , UNNEST(r.permissions) AS permission |
| 73 | + UNION |
| 74 | + -- Include permissions from org membership roles |
| 75 | + SELECT u.subject_id, org.resource_id, permission |
| 76 | + FROM org_members om |
| 77 | + JOIN users u ON om.member_user_id = u.id |
| 78 | + JOIN roles r ON om.role_id = r.id |
| 79 | + JOIN orgs org ON om.org_id = org.id |
| 80 | + , UNNEST(r.permissions) AS permission |
| 81 | + UNION |
| 82 | + -- Include public resource permissions |
| 83 | + SELECT NULL, prp.resource_id, permission |
| 84 | + FROM public_resource_permissions prp |
| 85 | +); |
| 86 | + |
| 87 | + |
| 88 | +-- This view builds on top of direct_resource_permissions to include inherited permissions |
| 89 | +CREATE OR REPLACE VIEW subject_resource_permissions(subject_id, resource_id, permission) AS ( |
| 90 | + SELECT drp.subject_id, drp.resource_id, drp.permission |
| 91 | + FROM direct_resource_permissions drp |
| 92 | + UNION |
| 93 | + -- Inherit permissions from parent resources |
| 94 | + SELECT drp.subject_id, rh.resource_id, drp.permission |
| 95 | + FROM direct_resource_permissions drp |
| 96 | + JOIN resource_hierarchy rh ON drp.resource_id = rh.parent_resource_id |
| 97 | +); |
| 98 | + |
| 99 | +-- -- SANITY CHECK |
| 100 | +-- SELECT rm.subject_id, r.ref |
| 101 | +-- FROM role_memberships rm |
| 102 | +-- JOIN roles r ON rm.role_id = r.id |
| 103 | +-- -- JOIN users u ON rm.subject_id = u.subject_id |
| 104 | +-- WHERE |
| 105 | +-- r.ref::text IN ('org_viewer', 'org_maintainer', 'org_contributor', 'org_admin', 'org_owner', 'org_default'); |
| 106 | + |
| 107 | +DELETE FROM role_memberships rm |
| 108 | + USING roles r |
| 109 | + WHERE |
| 110 | + rm.role_id = r.id |
| 111 | + AND r.ref::text IN ('org_viewer', 'org_maintainer', 'org_contributor', 'org_admin', 'org_owner', 'org_default'); |
| 112 | + |
| 113 | +-- SANITY CHECK |
| 114 | +-- SELECT org_user.handle, member_user.handle, role.ref |
| 115 | +-- FROM org_members om |
| 116 | +-- JOIN users org_user ON om.organization_user_id = org_user.id |
| 117 | +-- JOIN users member_user ON om.member_user_id = member_user.id |
| 118 | +-- JOIN roles role ON role.id = om.role_id |
| 119 | +-- ; |
0 commit comments