diff --git a/sql/24-hs-domain.sql b/sql/24-hs-domain.sql deleted file mode 100644 index d40ec6ef..00000000 --- a/sql/24-hs-domain.sql +++ /dev/null @@ -1,148 +0,0 @@ --- ======================================================== --- Domain example with RBAC --- -------------------------------------------------------- - -set session session authorization default; - -create table if not exists Domain -( - uuid uuid unique references RbacObject (uuid), - name character varying(32), - domainUuid uuid references domain (uuid) -); - -drop trigger if exists createRbacObjectForDomain_Trigger on Domain; -create trigger createRbacObjectForDomain_Trigger - before insert - on Domain - for each row -execute procedure createRbacObject(); - -create or replace function domainOwner(dom Domain) - returns RbacRoleDescriptor - returns null on null input - language plpgsql as $$ -begin - return roleDescriptor('domain', dom.uuid, 'owner'); -end; $$; - -create or replace function domainAdmin(dom Domain) - returns RbacRoleDescriptor - returns null on null input - language plpgsql as $$ -begin - return roleDescriptor('domain', dom.uuid, 'admin'); -end; $$; - -create or replace function domainTenant(dom Domain) - returns RbacRoleDescriptor - returns null on null input - language plpgsql as $$ -begin - return roleDescriptor('domain', dom.uuid, 'tenant'); -end; $$; - - -create or replace function createRbacRulesForDomain() - returns trigger - language plpgsql - strict as $$ -declare - parentUser domain; - parentPackage package; - domainOwnerRoleUuid uuid; - domainAdminRoleUuid uuid; -begin - if TG_OP <> 'INSERT' then - raise exception 'invalid usage of TRIGGER AFTER INSERT'; - end if; - - select * from domain where uuid = NEW.domainUuid into parentUser; - select * from Package where uuid = parentUser.packageuuid into parentPackage; - - -- a domain owner role is created and assigned to the domain's admin role - domainOwnerRoleUuid = createRole( - domainOwner(NEW), - grantingPermissions(forObjectUuid => NEW.uuid, permitOps => array ['*']), - beneathRole(testPackageAdmin(parentPackage)) - ); - - -- a domain admin role is created and assigned to the domain's owner role - domainAdminRoleUuid = createRole( - domainAdmin(NEW), - grantingPermissions(forObjectUuid => NEW.uuid, permitOps => array ['edit', 'add-emailaddress']), - beneathRole(domainOwnerRoleUuid) - ); - - -- and a domain tenant role is created and assigned to the domain's admiin role - perform createRole( - domainTenant(NEW), - grantingPermissions(forObjectUuid => NEW.uuid, permitOps => array ['*']), - beneathRole(domainAdminRoleUuid), - beingItselfA(createdomainTenantRoleIfNotExists(parentUser)) - ); - - return NEW; -end; $$; - -drop trigger if exists createRbacRulesForDomain_Trigger on Domain; -create trigger createRbacRulesForDomain_Trigger - after insert - on Domain - for each row -execute procedure createRbacRulesForDomain(); - --- create RBAC-restricted view -set session session authorization default; --- ALTER TABLE Domain ENABLE ROW LEVEL SECURITY; -drop view if exists domain_rv; -create or replace view domain_rv as -select target.* - from Domain as target - where target.uuid in (select queryAccessibleObjectUuidsOfSubjectIds('view', 'domain', currentSubjectsUuids())); -grant all privileges on domain_rv to restricted; - - --- generate Domain test data - -do language plpgsql $$ - declare - uu record; - pac package; - pacAdmin varchar; - currentTask varchar; - begin - set hsadminng.currentUser to ''; - - for uu in (select u.uuid, u.name, u.packageuuid, c.reference - from domain u - join package p on u.packageuuid = p.uuid - join customer c on p.customeruuid = c.uuid - -- WHERE c.reference >= 18000 - ) - loop - if (random() < 0.3) then - for t in 0..1 - loop - currentTask = 'creating RBAC test Domain #' || t || ' for domain ' || uu.name || ' #' || uu.uuid; - raise notice 'task: %', currentTask; - - select * from package where uuid = uu.packageUuid into pac; - pacAdmin = 'admin@' || pac.name || '.example.com'; - execute format('set local hsadminng.currentTask to %L', currentTask); - execute format('set local hsadminng.currentUser to %L', pacAdmin); - set local hsadminng.assumedRoles = ''; - - insert - into Domain (name, domainUuid) - values ('dom-' || t || '.' || uu.name || '.example.org', uu.uuid); - - commit; - end loop; - end if; - end loop; - - end; -$$; - - diff --git a/sql/25-hs-emailaddress.sql b/sql/25-hs-emailaddress.sql deleted file mode 100644 index 0beedce9..00000000 --- a/sql/25-hs-emailaddress.sql +++ /dev/null @@ -1,129 +0,0 @@ --- ======================================================== --- EMailAddress example with RBAC --- -------------------------------------------------------- - -set session session authorization default; - -create table if not exists EMailAddress -( - uuid uuid unique references RbacObject (uuid), - localPart character varying(64), - domainUuid uuid references domain (uuid) -); - -drop trigger if exists createRbacObjectForEMailAddress_Trigger on EMailAddress; -create trigger createRbacObjectForEMailAddress_Trigger - before insert - on EMailAddress - for each row -execute procedure createRbacObject(); - -create or replace function emailAddressOwner(emAddr EMailAddress) - returns RbacRoleDescriptor - returns null on null input - language plpgsql as $$ -begin - return roleDescriptor('emailaddress', emAddr.uuid, 'owner'); -end; $$; - -create or replace function emailAddressAdmin(emAddr EMailAddress) - returns RbacRoleDescriptor - returns null on null input - language plpgsql as $$ -begin - return roleDescriptor('emailaddress', emAddr.uuid, 'admin'); -end; $$; - -create or replace function createRbacRulesForEMailAddress() - returns trigger - language plpgsql - strict as $$ -declare - parentDomain Domain; - eMailAddressOwnerRoleUuid uuid; -begin - if TG_OP <> 'INSERT' then - raise exception 'invalid usage of TRIGGER AFTER INSERT'; - end if; - - select d.* - from domain d - left join domain u on u.uuid = d.domainuuid - where d.uuid = NEW.domainUuid - into parentDomain; - - -- an owner role is created and assigned to the domains's admin group - eMailAddressOwnerRoleUuid = createRole( - emailAddressOwner(NEW), - grantingPermissions(forObjectUuid => NEW.uuid, permitOps => array ['*']), - beneathRole(domainAdmin(parentDomain)) - ); - - -- and an admin role is created and assigned to the domain owner as well - perform createRole( - emailAddressAdmin(NEW), - grantingPermissions(forObjectUuid => NEW.uuid, permitOps => array ['edit']), - beneathRole(eMailAddressOwnerRoleUuid), - beingItselfA(domainTenant(parentDomain)) - ); - - return NEW; -end; $$; - -drop trigger if exists createRbacRulesForEMailAddress_Trigger on EMailAddress; -create trigger createRbacRulesForEMailAddress_Trigger - after insert - on EMailAddress - for each row -execute procedure createRbacRulesForEMailAddress(); - - --- create RBAC-restricted view -set session session authorization default; --- ALTER TABLE EMailAddress ENABLE ROW LEVEL SECURITY; -drop view if exists EMailAddress_rv; -create or replace view EMailAddress_rv as -select target.* - from EMailAddress as target - where target.uuid in (select queryAccessibleObjectUuidsOfSubjectIds('view', 'emailaddress', currentSubjectsUuids())); -grant all privileges on EMailAddress_rv to restricted; - --- generate EMailAddress test data - -do language plpgsql $$ - declare - dom record; - pacAdmin varchar; - currentTask varchar; - begin - set hsadminng.currentUser to ''; - - for dom in (select d.uuid, d.name, p.name as packageName - from domain d - join domain u on u.uuid = d.domainuuid - join package p on u.packageuuid = p.uuid - join customer c on p.customeruuid = c.uuid - -- WHERE c.reference >= 18000 - ) - loop - for t in 0..4 - loop - currentTask = 'creating RBAC test EMailAddress #' || t || ' for Domain ' || dom.name; - raise notice 'task: %', currentTask; - - pacAdmin = 'admin@' || dom.packageName || '.example.com'; - execute format('set local hsadminng.currentTask to %L', currentTask); - execute format('set local hsadminng.currentUser to %L', pacAdmin); - set local hsadminng.assumedRoles = ''; - - insert - into EMailAddress (localPart, domainUuid) - values ('local' || t, dom.uuid); - - commit; - end loop; - end loop; - end; -$$; - - diff --git a/sql/28-hs-tests.sql b/sql/28-hs-tests.sql deleted file mode 100644 index 3e10c2f5..00000000 --- a/sql/28-hs-tests.sql +++ /dev/null @@ -1,134 +0,0 @@ -ABORT; -SET SESSION SESSION AUTHORIZATION DEFAULT; - --- there are some random ractors in test data generation, thus a range has to be accepted -CREATE OR REPLACE PROCEDURE expectBetween(actualCount integer, expectedFrom integer, expectedTo integer) - LANGUAGE plpgsql AS $$ -BEGIN - IF NOT actualCount BETWEEN expectedFrom AND expectedTo THEN - RAISE EXCEPTION 'count expected to be between % and %, but got %', expectedFrom, expectedTo, actualCount; -END IF; -END; $$; - -DO LANGUAGE plpgsql $$ -DECLARE - resultCount integer; -BEGIN - - -- hostmaster accessing a single customer - SET SESSION SESSION AUTHORIZATION restricted; - SET LOCAL hsadminng.currentUser = 'alex@hostsharing.net'; - SET LOCAL hsadminng.assumedRoles = ''; - -- SELECT * - SELECT count(*) INTO resultCount - from test_customer_rv c - where c.prefix='aab'; - call expectBetween(resultCount, 1, 1); - - -- hostmaster listing all customers - SET SESSION SESSION AUTHORIZATION restricted; - SET LOCAL hsadminng.currentUser = 'alex@hostsharing.net'; - SET LOCAL hsadminng.assumedRoles = ''; - -- SELECT * - SELECT count(*) INTO resultCount - FROM test_customer_rv; - call expectBetween(resultCount, 10, 20000); - - -- customer admin listing all their packages - SET SESSION SESSION AUTHORIZATION restricted; - SET LOCAL hsadminng.currentUser = 'admin@aae.example.com'; - SET LOCAL hsadminng.assumedRoles = ''; - -- SELECT * - SELECT count(*) INTO resultCount - FROM test_package_rv; - call expectBetween(resultCount, 2, 10); - - -- cutomer admin listing all their unix users - SET SESSION SESSION AUTHORIZATION restricted; - SET LOCAL hsadminng.currentUser = 'admin@aae.example.com'; - SET LOCAL hsadminng.assumedRoles = ''; - -- SELECT * - SELECT count(*) INTO resultCount - FROM domain_rv; - call expectBetween(resultCount, 20, 50); - - -- hostsharing admin assuming customer role and listing all accessible packages - SET SESSION SESSION AUTHORIZATION restricted; - SET LOCAL hsadminng.currentUser = 'alex@hostsharing.net'; - SET LOCAL hsadminng.assumedRoles = 'test_customer#aaa.admin;test_customer#aab.admin'; - -- SELECT * - SELECT count(*) INTO resultCount - FROM test_package_rv p; - call expectBetween(resultCount, 2, 10); - - -- hostsharing admin assuming two customer admin roles and listing all accessible domains - SET SESSION SESSION AUTHORIZATION restricted; - SET LOCAL hsadminng.currentUser = 'alex@hostsharing.net'; - SET LOCAL hsadminng.assumedRoles = 'test_customer#aab.admin;test_customer#aac.admin'; - -- SELECT c.prefix, c.reference, uu.* - SELECT count(*) INTO resultCount - FROM domain_rv uu - JOIN test_package_rv p ON p.uuid = uu.packageuuid - JOIN test_customer_rv c ON c.uuid = p.customeruuid; - call expectBetween(resultCount, 40, 60); - - -- hostsharing admin assuming two customer admin roles and listing all accessible domains - -- ABORT; START TRANSACTION; - SET SESSION SESSION AUTHORIZATION restricted; - SET LOCAL hsadminng.currentUser = 'alex@hostsharing.net'; - SET LOCAL hsadminng.assumedRoles = 'test_customer#aac.admin;test_customer#aad.admin'; - -- SELECT p.name, uu.name, dom.name - SELECT count(*) INTO resultCount - FROM domain_rv dom - JOIN domain_rv uu ON uu.uuid = dom.domainuuid - JOIN test_package_rv p ON p.uuid = uu.packageuuid - JOIN test_customer_rv c ON c.uuid = p.customeruuid; - call expectBetween(resultCount, 20, 40); - - -- hostsharing admin assuming two customer admin roles and listing all accessible email addresses - -- ABORT; START TRANSACTION; - SET SESSION SESSION AUTHORIZATION restricted; - SET LOCAL hsadminng.currentUser = 'alex@hostsharing.net'; - SET LOCAL hsadminng.assumedRoles = 'test_customer#aae.admin;test_customer#aaf.admin'; - -- SELECT c.prefix, p.name as "package", ema.localPart || '@' || dom.name as "email-address" - SELECT count(*) INTO resultCount - FROM emailaddress_rv ema - JOIN domain_rv dom ON dom.uuid = ema.domainuuid - JOIN domain_rv uu ON uu.uuid = dom.domainuuid - JOIN test_package_rv p ON p.uuid = uu.packageuuid - JOIN test_customer_rv c ON c.uuid = p.customeruuid; - call expectBetween(resultCount, 100, 300); - - -- ~170ms -END; $$; - -/* -=== with 7000 customers === - -1. 7105 vs 801 ms -2. 960 vs. 649 ms -3. 970 vs. 670 ms - -no count required factor table -1 7 000 7 000 1.000 customers -2 17 436 15 000 1.162 packages -3 174 360 150 000 1.162 domain -4 105 206 100 000 1.052 domain -5 526 030 500 000 1.052 emailaddress - -=== with 10000 customers (+43%) === - -1. 7491 vs. 1189 ms (-1%) -2. 1049 ms (+31%) -3. 1028 ms (+53%) -in average +9,33% - -no count required factor table -1 10 000 7 000 1.429 customers -2 24 904 15 000 1.660 packages -3 249 040 150 000 1.660 domain -4 149 946 100 000 1.499 domain -5 749 730 500 000 1.499 emailaddress - - - */