From 2b630aadbca31aa989c9a7b10edb46fb28d24ced Mon Sep 17 00:00:00 2001 From: Michael Hoennig Date: Fri, 29 Jul 2022 12:37:40 +0200 Subject: [PATCH] hs-package SQL-Scripts in Liquibase and some bugfixes --- .../db/changelog/2022-07-28-005-rbac-base.sql | 45 +++--- .../2022-07-28-020-rbac-role-builder.sql | 8 ++ ...sql => 2022-07-29-070-hs-package-rbac.sql} | 134 +++++++++--------- .../2022-07-29-070-hs-package-test-data.sql | 62 ++++++++ .../changelog/2022-07-29-070-hs-package.sql | 13 ++ .../db/changelog/db.changelog-master.yaml | 6 + 6 files changed, 181 insertions(+), 87 deletions(-) rename src/main/resources/db/changelog/{22-hs-packages.sql => 2022-07-29-070-hs-package-rbac.sql} (54%) create mode 100644 src/main/resources/db/changelog/2022-07-29-070-hs-package-test-data.sql create mode 100644 src/main/resources/db/changelog/2022-07-29-070-hs-package.sql diff --git a/src/main/resources/db/changelog/2022-07-28-005-rbac-base.sql b/src/main/resources/db/changelog/2022-07-28-005-rbac-base.sql index 7006b0e3..df406c35 100644 --- a/src/main/resources/db/changelog/2022-07-28-005-rbac-base.sql +++ b/src/main/resources/db/changelog/2022-07-28-005-rbac-base.sql @@ -45,9 +45,12 @@ declare objectId uuid; begin insert - into RbacReference (type) values ('RbacUser') returning uuid into objectId; + into RbacReference (type) + values ('RbacUser') + returning uuid into objectId; insert - into RbacUser (uuid, name) values (objectid, userName); + into RbacUser (uuid, name) + values (objectid, userName); return objectId; end; $$; @@ -103,7 +106,9 @@ declare begin if TG_OP = 'INSERT' then insert - into RbacObject (objectTable) values (TG_TABLE_NAME) returning uuid into objectUuid; + into RbacObject (objectTable) + values (TG_TABLE_NAME) + returning uuid into objectUuid; NEW.uuid = objectUuid; return NEW; else @@ -153,9 +158,12 @@ declare referenceId uuid; begin insert - into RbacReference (type) values ('RbacRole') returning uuid into referenceId; + into RbacReference (type) + values ('RbacRole') + returning uuid into referenceId; insert - into RbacRole (uuid, objectUuid, roleType) values (referenceId, roleDescriptor.objectUuid, roleDescriptor.roleType); + into RbacRole (uuid, objectUuid, roleType) + values (referenceId, roleDescriptor.objectUuid, roleDescriptor.roleType); return referenceId; end; $$; @@ -254,9 +262,12 @@ begin if (refId is null) then raise notice 'createPermission: % %', forObjectUuid, permitOps[i]; insert - into RbacReference ("type") values ('RbacPermission') returning uuid into refId; + into RbacReference ("type") + values ('RbacPermission') + returning uuid into refId; insert - into RbacPermission (uuid, objectUuid, op) values (refId, forObjectUuid, permitOps[i]); + into RbacPermission (uuid, objectUuid, op) + values (refId, forObjectUuid, permitOps[i]); end if; raise notice 'addPermission: %', refId; permissionIds = permissionIds || refId; @@ -357,14 +368,16 @@ create or replace procedure grantPermissionsToRole(roleUuid uuid, permissionIds language plpgsql as $$ begin raise notice 'grantPermissionsToRole: % -> %', roleUuid, permissionIds; + if cardinality(permissionIds) = 0 then return; end if; + for i in array_lower(permissionIds, 1)..array_upper(permissionIds, 1) loop perform assertReferenceType('roleId (ascendant)', roleUuid, 'RbacRole'); perform assertReferenceType('permissionId (descendant)', permissionIds[i], 'RbacPermission'); - -- INSERT INTO RbacGrants (ascendantUuid, descendantUuid, apply) VALUES (roleId, permissionIds[i], true); -- assumeV1 insert - into RbacGrants (ascendantUuid, descendantUuid) values (roleUuid, permissionIds[i]); + into RbacGrants (ascendantUuid, descendantUuid, follow) + values (roleUuid, permissionIds[i], true); end loop; end; $$; @@ -379,7 +392,6 @@ begin raise exception 'Cyclic role grant detected between % and %', subRoleId, superRoleId; end if; - -- INSERT INTO RbacGrants (ascendantUuid, descendantUuid, apply) VALUES (superRoleId, subRoleId, doapply); -- assumeV1 insert into RbacGrants (ascendantUuid, descendantUuid, follow) values (superRoleId, subRoleId, doFollow) @@ -403,10 +415,9 @@ begin perform assertReferenceType('roleId (ascendant)', roleId, 'RbacRole'); perform assertReferenceType('userId (descendant)', userId, 'RbacUser'); - -- INSERT INTO RbacGrants (ascendantUuid, descendantUuid, apply) VALUES (userId, roleId, true); -- assumeV1 insert - into RbacGrants (ascendantUuid, descendantUuid) - values (userId, roleId) + into RbacGrants (ascendantUuid, descendantUuid, follow) + values (userId, roleId, true) on conflict do nothing; -- TODO: remove? end; $$; --// @@ -646,10 +657,10 @@ end; $$; --changeset rbac-base-pgsql-roles:1 endDelimiter:--// -- ------------------------------------------------------------------ -CREATE ROLE admin; -GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO admin; +create role admin; +grant all privileges on all tables in schema public to admin; -CREATE ROLE restricted; -GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO restricted; +create role restricted; +grant all privileges on all tables in schema public to restricted; --// diff --git a/src/main/resources/db/changelog/2022-07-28-020-rbac-role-builder.sql b/src/main/resources/db/changelog/2022-07-28-020-rbac-role-builder.sql index 2c71640b..35ec5ea8 100644 --- a/src/main/resources/db/changelog/2022-07-28-020-rbac-role-builder.sql +++ b/src/main/resources/db/changelog/2022-07-28-020-rbac-role-builder.sql @@ -21,6 +21,14 @@ begin return row (createPermissions(forObjectUuid, permitOps))::RbacPermissions; end; $$; +create or replace function withoutPermissions() + returns RbacPermissions + language plpgsql + strict as $$ +begin + return row (array[]::uuid[]); +end; $$; + --// --changeset rbac-role-builder-super-roles:1 endDelimiter:--// diff --git a/src/main/resources/db/changelog/22-hs-packages.sql b/src/main/resources/db/changelog/2022-07-29-070-hs-package-rbac.sql similarity index 54% rename from src/main/resources/db/changelog/22-hs-packages.sql rename to src/main/resources/db/changelog/2022-07-29-070-hs-package-rbac.sql index 91d91cc9..2555ab87 100644 --- a/src/main/resources/db/changelog/22-hs-packages.sql +++ b/src/main/resources/db/changelog/2022-07-29-070-hs-package-rbac.sql @@ -1,22 +1,28 @@ --- ======================================================== --- Package example with RBAC --- -------------------------------------------------------- +--liquibase formatted sql -set session session authorization default; +-- ============================================================================ +--changeset hs-package-rbac-CREATE-OBJECT:1 endDelimiter:--// +-- ---------------------------------------------------------------------------- +/* + Creates the related RbacObject through a BEFORE INSERT TRIGGER. + */ +drop trigger if exists createRbacObjectForPackage_Trigger on package; +create trigger createRbacObjectForPackage_Trigger + before insert + on package + for each row +execute procedure createRbacObject(); +--// -create table if not exists package -( - uuid uuid unique references RbacObject (uuid), - name character varying(5), - customerUuid uuid references customer (uuid) -); + +-- ============================================================================ +--changeset hs-package-rbac-ROLE-DESCRIPTORS:1 endDelimiter:--// +-- ---------------------------------------------------------------------------- create or replace function packageOwner(pac package) returns RbacRoleDescriptor returns null on null input language plpgsql as $$ -declare - roleDesc RbacRoleDescriptor; begin return roleDescriptor('package', pac.uuid, 'admin'); end; $$; @@ -36,16 +42,16 @@ create or replace function packageTenant(pac package) begin return roleDescriptor('package', pac.uuid, 'tenant'); end; $$; +--// -drop trigger if exists createRbacObjectForPackage_Trigger on package; -create trigger createRbacObjectForPackage_Trigger - before insert - on package - for each row -execute procedure createRbacObject(); - -create or replace function createRbacRulesForPackage() +-- ============================================================================ +--changeset hs-package-rbac-ROLES-CREATION:1 endDelimiter:--// +-- ---------------------------------------------------------------------------- +/* + Creates the roles and their assignments for a new package for the AFTER INSERT TRIGGER. + */ +create or replace function createRbacRolesForPackage() returns trigger language plpgsql strict as $$ @@ -63,14 +69,14 @@ begin -- an owner role is created and assigned to the customer's admin role packageOwnerRoleUuid = createRole( packageOwner(NEW), - grantingPermissions(forObjectUuid => NEW.uuid, permitOps => array ['*']), + withoutPermissions(), beneathRole(customerAdmin(parentCustomer)) ); -- an owner role is created and assigned to the package owner role packageAdminRoleUuid = createRole( packageAdmin(NEW), - grantingPermissions(forObjectUuid => NEW.uuid, permitOps => array ['edit', 'add-unixuser', 'add-domain']), + grantingPermissions(forObjectUuid => NEW.uuid, permitOps => array ['add-unixuser', 'add-domain']), beneathRole(packageOwnerRoleUuid) ); @@ -85,12 +91,25 @@ begin return NEW; end; $$; -drop trigger if exists createRbacRulesForPackage_Trigger on package; -create trigger createRbacRulesForPackage_Trigger +/* + An AFTER INSERT TRIGGER which creates the role structure for a new package. + */ + +drop trigger if exists createRbacRolesForPackage_Trigger on package; +create trigger createRbacRolesForPackage_Trigger after insert on package for each row -execute procedure createRbacRulesForPackage(); +execute procedure createRbacRolesForPackage(); +--// + +-- ============================================================================ +--changeset hs-package-rbac-ROLES-REMOVAL:1 endDelimiter:--// +-- ---------------------------------------------------------------------------- + +/* + Deletes the roles and their assignments of a deleted package for the BEFORE DELETE TRIGGER. + */ create or replace function deleteRbacRulesForPackage() returns trigger @@ -98,64 +117,39 @@ create or replace function deleteRbacRulesForPackage() strict as $$ begin if TG_OP = 'DELETE' then - -- TODO + call deleteRole(findRoleId(packageOwner(OLD))); + call deleteRole(findRoleId(packageAdmin(OLD))); + call deleteRole(findRoleId(packageTenant(OLD))); else raise exception 'invalid usage of TRIGGER BEFORE DELETE'; end if; end; $$; -drop trigger if exists deleteRbacRulesForPackage_Trigger on customer; +/* + An BEFORE DELETE TRIGGER which deletes the role structure of a package. + */ + +drop trigger if exists deleteRbacRulesForPackage_Trigger on package; create trigger deleteRbacRulesForPackage_Trigger before delete - on customer + on package for each row execute procedure deleteRbacRulesForPackage(); +--// --- create RBAC-restricted view -set session session authorization default; --- ALTER TABLE package ENABLE ROW LEVEL SECURITY; + +-- ============================================================================ +--changeset hs-customer-rbac-IDENTITY-VIEW:1 endDelimiter:--// +-- ---------------------------------------------------------------------------- + +/* + Creates a view to the customer main table which maps the identifying name + (in this case, the prefix) to the objectUuid. + */ drop view if exists package_rv; create or replace view package_rv as select distinct target.* from package as target where target.uuid in (select queryAccessibleObjectUuidsOfSubjectIds('view', 'package', currentSubjectIds())); grant all privileges on package_rv to restricted; - - --- generate Package test data - -do language plpgsql $$ - declare - cust customer; - pacName varchar; - currentTask varchar; - custAdmin varchar; - begin - set hsadminng.currentUser to ''; - - for cust in (select * from customer) - loop - -- CONTINUE WHEN cust.reference < 18000; - - for t in 0..randominrange(1, 2) - loop - pacName = cust.prefix || to_char(t, 'fm00'); - currentTask = 'creating RBAC test package #' || pacName || ' for customer ' || cust.prefix || ' #' || - cust.uuid; - raise notice 'task: %', currentTask; - - custAdmin = 'admin@' || cust.prefix || '.example.com'; - set local hsadminng.currentUser to custAdmin; - set local hsadminng.assumedRoles = ''; - set local hsadminng.currentTask to currentTask; - - insert - into package (name, customerUuid) - values (pacName, cust.uuid); - - commit; - end loop; - end loop; - end; -$$; - +--// diff --git a/src/main/resources/db/changelog/2022-07-29-070-hs-package-test-data.sql b/src/main/resources/db/changelog/2022-07-29-070-hs-package-test-data.sql new file mode 100644 index 00000000..6e08b1e0 --- /dev/null +++ b/src/main/resources/db/changelog/2022-07-29-070-hs-package-test-data.sql @@ -0,0 +1,62 @@ +--liquibase formatted sql + +-- ============================================================================ +--changeset hs-package-TEST-DATA-GENERATOR:1 endDelimiter:--// +-- ---------------------------------------------------------------------------- +/* + Creates test data for the package main table. + */ +create or replace procedure createPackageTestData( + minCustomerReference integer, -- skip customers with reference below this + doCommitAfterEach boolean -- only for mass data creation outside of Liquibase +) + language plpgsql as $$ + declare + cust customer; + pacName varchar; + currentTask varchar; + custAdmin varchar; + begin + set hsadminng.currentUser to ''; + + for cust in (select * from customer) + loop + CONTINUE WHEN cust.reference < minCustomerReference; + + for t in 0..randominrange(1, 2) + loop + pacName = cust.prefix || to_char(t, 'fm00'); + currentTask = 'creating RBAC test package #' || pacName || ' for customer ' || cust.prefix || ' #' || + cust.uuid; + raise notice 'task: %', currentTask; + + custAdmin = 'admin@' || cust.prefix || '.example.com'; + set local hsadminng.currentUser to custAdmin; + set local hsadminng.assumedRoles = ''; + set local hsadminng.currentTask to currentTask; + + insert + into package (name, customerUuid) + values (pacName, cust.uuid); + end loop; + end loop; + + if doCommitAfterEach then + commit; + end if; + end; +$$; +--// + + +-- ============================================================================ +--changeset hs-package-TEST-DATA-GENERATION:1 –context=dev,tc endDelimiter:--// +-- ---------------------------------------------------------------------------- + +do language plpgsql $$ + begin + call createPackageTestData(0, false); + end; +$$; +--// + diff --git a/src/main/resources/db/changelog/2022-07-29-070-hs-package.sql b/src/main/resources/db/changelog/2022-07-29-070-hs-package.sql new file mode 100644 index 00000000..95b925d5 --- /dev/null +++ b/src/main/resources/db/changelog/2022-07-29-070-hs-package.sql @@ -0,0 +1,13 @@ +--liquibase formatted sql + +-- ============================================================================ +--changeset hs-package-MAIN-TABLE:1 endDelimiter:--// +-- ---------------------------------------------------------------------------- + +create table if not exists package +( + uuid uuid unique references RbacObject (uuid), + name character varying(5), + customerUuid uuid references customer (uuid) +); +--// diff --git a/src/main/resources/db/changelog/db.changelog-master.yaml b/src/main/resources/db/changelog/db.changelog-master.yaml index e7be8ebc..ea0e640f 100644 --- a/src/main/resources/db/changelog/db.changelog-master.yaml +++ b/src/main/resources/db/changelog/db.changelog-master.yaml @@ -21,5 +21,11 @@ databaseChangeLog: file: db/changelog/2022-07-29-061-hs-customer-rbac.sql - include: file: db/changelog/2022-07-29-062-hs-customer-test-data.sql + - include: + file: db/changelog/2022-07-29-070-hs-package.sql + - include: + file: db/changelog/2022-07-29-070-hs-package-rbac.sql + - include: + file: db/changelog/2022-07-29-070-hs-package-test-data.sql