diff --git a/sql/10-rbac-base.sql b/sql/10-rbac-base.sql index 2219c00c..07120878 100644 --- a/sql/10-rbac-base.sql +++ b/sql/10-rbac-base.sql @@ -83,11 +83,15 @@ END; $$; -- DROP TABLE IF EXISTS RbacPermission; CREATE TABLE RbacPermission ( uuid uuid primary key references RbacReference (uuid) ON DELETE CASCADE, - objectUuid uuid not null, + objectUuid uuid not null references RbacObject, op RbacOp not null, unique (objectUuid, op) ); +-- SET SESSION SESSION AUTHORIZATION DEFAULT; +-- alter table rbacpermission add constraint rbacpermission_objectuuid_fkey foreign key (objectUuid) references rbacobject(uuid); +-- alter table rbacpermission drop constraint rbacpermission_objectuuid; + CREATE OR REPLACE FUNCTION hasPermission(forObjectUuid uuid, forOp RbacOp) RETURNS bool LANGUAGE sql AS $$ @@ -311,9 +315,9 @@ set local session authorization default; CREATE OR REPLACE FUNCTION queryAccessibleObjectUuidsOfSubjectIds( requiredOp RbacOp, - forObjectTable varchar, -- TODO: test performance in joins! + forObjectTable varchar, -- reduces the result set, but is not really faster when used in restricted view subjectIds uuid[], - maxObjects integer = 16000) + maxObjects integer = 8000) RETURNS SETOF uuid RETURNS NULL ON NULL INPUT LANGUAGE plpgsql AS $$ @@ -336,7 +340,8 @@ CREATE OR REPLACE FUNCTION queryAccessibleObjectUuidsOfSubjectIds( ) as granted JOIN RbacPermission perm ON granted.descendantUuid=perm.uuid AND perm.op IN ('*', requiredOp) - JOIN RbacObject obj ON obj.uuid=perm.objectUuid AND obj.objectTable=forObjectTable; + JOIN RbacObject obj ON obj.uuid=perm.objectUuid AND obj.objectTable=forObjectTable + LIMIT maxObjects+1; foundRows = lastRowCount(); IF foundRows > maxObjects THEN @@ -350,8 +355,10 @@ $$; SET SESSION AUTHORIZATION DEFAULT; CREATE ROLE admin; +GRANT USAGE ON SCHEMA public TO admin; GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO admin; CREATE ROLE restricted; +GRANT USAGE ON SCHEMA public TO restricted; GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO restricted; abort; diff --git a/sql/21-hs-customer.sql b/sql/21-hs-customer.sql index 3d861d19..0c77dea6 100644 --- a/sql/21-hs-customer.sql +++ b/sql/21-hs-customer.sql @@ -108,6 +108,17 @@ CREATE TRIGGER deleteRbacRulesForCustomer_Trigger -- create RBAC restricted view +-- automatically updatable, but slow with WHERE IN +SET SESSION SESSION AUTHORIZATION DEFAULT; +ALTER TABLE customer ENABLE ROW LEVEL SECURITY; +DROP VIEW IF EXISTS customer_rv; +CREATE OR REPLACE VIEW customer_rv AS + SELECT DISTINCT target.* + FROM customer AS target + WHERE target.uuid IN (SELECT uuid FROM queryAccessibleObjectUuidsOfSubjectIds( 'view', 'customer', currentSubjectIds())); +GRANT ALL PRIVILEGES ON customer_rv TO restricted; + +-- not automatically updatable, but fast with JOIN SET SESSION SESSION AUTHORIZATION DEFAULT; ALTER TABLE customer ENABLE ROW LEVEL SECURITY; DROP VIEW IF EXISTS customer_rv; @@ -121,6 +132,7 @@ GRANT ALL PRIVILEGES ON customer_rv TO restricted; -- generate Customer test data +SET SESSION SESSION AUTHORIZATION DEFAULT; DO LANGUAGE plpgsql $$ DECLARE currentTask varchar; diff --git a/sql/22-hs-packages.sql b/sql/22-hs-packages.sql index 676f9b1f..483725b4 100644 --- a/sql/22-hs-packages.sql +++ b/sql/22-hs-packages.sql @@ -98,8 +98,19 @@ CREATE TRIGGER deleteRbacRulesForPackage_Trigger BEFORE DELETE ON customer FOR EACH ROW EXECUTE PROCEDURE deleteRbacRulesForPackage(); --- create RBAC restricted view +-- create RBAC-restricted view +-- automatically updatable, but slow with WHERE IN +SET SESSION SESSION AUTHORIZATION DEFAULT; +ALTER TABLE package ENABLE ROW LEVEL SECURITY; +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 uuid FROM queryAccessibleObjectUuidsOfSubjectIds( 'view', 'package', currentSubjectIds())); +GRANT ALL PRIVILEGES ON package_rv TO restricted; + +-- not automatically updatable, but fast with JOIN SET SESSION SESSION AUTHORIZATION DEFAULT; ALTER TABLE package ENABLE ROW LEVEL SECURITY; DROP VIEW IF EXISTS package_rv; @@ -124,6 +135,8 @@ DO LANGUAGE plpgsql $$ 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; diff --git a/sql/23-hs-unixuser.sql b/sql/23-hs-unixuser.sql index dcc992a6..cfeccfb0 100644 --- a/sql/23-hs-unixuser.sql +++ b/sql/23-hs-unixuser.sql @@ -101,8 +101,19 @@ CREATE TRIGGER createRbacRulesForUnixUser_Trigger -- TODO: CREATE OR REPLACE FUNCTION deleteRbacRulesForUnixUser() --- create RBAC restricted view +-- create RBAC-restricted view +-- automatically updatable, but slow with WHERE IN +SET SESSION SESSION AUTHORIZATION DEFAULT; +ALTER TABLE unixuser ENABLE ROW LEVEL SECURITY; +DROP VIEW IF EXISTS unixuser_rv; +CREATE OR REPLACE VIEW unixuser_rv AS + SELECT DISTINCT target.* + FROM unixuser AS target + WHERE target.uuid IN (SELECT uuid FROM queryAccessibleObjectUuidsOfSubjectIds( 'view', 'unixuser', currentSubjectIds())); +GRANT ALL PRIVILEGES ON unixuser_rv TO restricted; + +-- not automatically updatable, but fast with JOIN SET SESSION SESSION AUTHORIZATION DEFAULT; ALTER TABLE unixuser ENABLE ROW LEVEL SECURITY; DROP VIEW IF EXISTS unixuser_rv; @@ -118,13 +129,19 @@ GRANT ALL PRIVILEGES ON unixuser_rv TO restricted; DO LANGUAGE plpgsql $$ DECLARE - pac package; + pac record; pacAdmin varchar; currentTask varchar; BEGIN SET hsadminng.currentUser TO ''; - FOR pac IN (SELECT * FROM package) LOOP + FOR pac IN ( + SELECT p.uuid, p.name + FROM package p + JOIN customer c ON p.customeruuid = c.uuid + -- WHERE c.reference >= 18000 + ) LOOP + FOR t IN 0..9 LOOP currentTask = 'creating RBAC test unixuser #' || t || ' for package ' || pac.name|| ' #' || pac.uuid; RAISE NOTICE 'task: %', currentTask; diff --git a/sql/24-hs-domain.sql b/sql/24-hs-domain.sql index ce730f40..856d55f6 100644 --- a/sql/24-hs-domain.sql +++ b/sql/24-hs-domain.sql @@ -85,8 +85,19 @@ CREATE TRIGGER createRbacRulesForDomain_Trigger -- TODO: CREATE OR REPLACE FUNCTION deleteRbacRulesForDomain() --- create RBAC restricted view +-- create RBAC-restricted view +-- automatically updatable, but slow with WHERE IN +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 DISTINCT target.* + FROM Domain AS target + WHERE target.uuid IN (SELECT uuid FROM queryAccessibleObjectUuidsOfSubjectIds( 'view', 'domain', currentSubjectIds())); +GRANT ALL PRIVILEGES ON domain_rv TO restricted; + +-- not automatically updatable, but fast with JOIN SET SESSION SESSION AUTHORIZATION DEFAULT; ALTER TABLE Domain ENABLE ROW LEVEL SECURITY; DROP VIEW IF EXISTS domain_rv; @@ -97,19 +108,24 @@ CREATE OR REPLACE VIEW domain_rv AS ON target.uuid = allowedObjId; GRANT ALL PRIVILEGES ON domain_rv TO restricted; - -- generate Domain test data DO LANGUAGE plpgsql $$ DECLARE - uu unixuser; + uu record; pac package; pacAdmin varchar; currentTask varchar; BEGIN SET hsadminng.currentUser TO ''; - FOR uu IN (SELECT * FROM unixuser) LOOP + FOR uu IN ( + SELECT u.uuid, u.name, u.packageuuid, c.reference + FROM unixuser 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 UnixUser ' || uu.name|| ' #' || uu.uuid; diff --git a/sql/25-hs-emailaddress.sql b/sql/25-hs-emailaddress.sql index 49c25d06..df9d575c 100644 --- a/sql/25-hs-emailaddress.sql +++ b/sql/25-hs-emailaddress.sql @@ -73,39 +73,51 @@ CREATE TRIGGER createRbacRulesForEMailAddress_Trigger -- TODO: CREATE OR REPLACE FUNCTION deleteRbacRulesForEMailAddress() --- create RBAC restricted view +-- create RBAC-restricted view +-- automatically updatable, but slow with WHERE IN 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 DISTINCT target.* FROM EMailAddress AS target - JOIN queryAccessibleObjectUuidsOfSubjectIds( 'view', 'emailaddress', currentSubjectIds()) AS allowedObjId - ON target.uuid = allowedObjId; + WHERE target.uuid IN (SELECT DISTINCT uuid FROM queryAccessibleObjectUuidsOfSubjectIds( 'view', 'emailaddress', currentSubjectIds())); GRANT ALL PRIVILEGES ON EMailAddress_rv TO restricted; +-- not automatically updatable, but fast with JOIN +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 DISTINCT uuid FROM queryAccessibleObjectUuidsOfSubjectIds( 'view', 'emailaddress', currentSubjectIds())); +GRANT ALL PRIVILEGES ON EMailAddress_rv TO restricted; -- generate EMailAddress test data DO LANGUAGE plpgsql $$ DECLARE - pac package; - uu unixuser; - dom domain; + dom record; pacAdmin varchar; currentTask varchar; BEGIN SET hsadminng.currentUser TO ''; - FOR dom IN (SELECT * FROM domain) LOOP + FOR dom IN ( + SELECT d.uuid, d.name, p.name as packageName + FROM domain d + JOIN unixuser u ON u.uuid = d.unixuseruuid + 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; - SELECT * FROM unixuser WHERE uuid=dom.unixuserUuid INTO uu; - SELECT * FROM package WHERE uuid=uu.packageUuid INTO pac; - pacAdmin = 'admin@' || pac.name || '.example.com'; + pacAdmin = 'admin@' || dom.packageName || '.example.com'; SET LOCAL hsadminng.currentUser TO pacAdmin; SET LOCAL hsadminng.assumedRoles = ''; SET LOCAL hsadminng.currentTask TO currentTask; diff --git a/sql/28--hs-tests.sql b/sql/28--hs-tests.sql index ae1e73e7..6b095349 100644 --- a/sql/28--hs-tests.sql +++ b/sql/28--hs-tests.sql @@ -1,73 +1,113 @@ +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 = 'mike@hostsharing.net'; - PERFORM * from customer_rv c where c.prefix='aab'; + SET LOCAL hsadminng.assumedRoles = ''; + -- SELECT * + SELECT count(*) INTO resultCount + from 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 = 'mike@hostsharing.net'; SET LOCAL hsadminng.assumedRoles = ''; - PERFORM * FROM customer_rv; + -- SELECT * + SELECT count(*) INTO resultCount + FROM 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 = ''; - PERFORM * FROM package_rv; + -- SELECT * + SELECT count(*) INTO resultCount + FROM 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 = ''; - PERFORM * FROM unixuser_rv; + -- SELECT * + SELECT count(*) INTO resultCount + FROM unixuser_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 = 'mike@hostsharing.net'; SET LOCAL hsadminng.assumedRoles = 'customer#aaa.admin;customer#aab.admin'; - PERFORM * FROM package_rv p; + -- SELECT * + SELECT count(*) INTO resultCount + FROM package_rv p; + call expectBetween(resultCount, 2, 10); -- hostsharing admin assuming two customer admin roles and listing all accessible unixusers SET SESSION SESSION AUTHORIZATION restricted; SET LOCAL hsadminng.currentUser = 'mike@hostsharing.net'; SET LOCAL hsadminng.assumedRoles = 'customer#aab.admin;customer#aac.admin'; - PERFORM c.prefix, c.reference, uu.* + -- SELECT c.prefix, c.reference, uu.* + SELECT count(*) INTO resultCount FROM unixuser_rv uu JOIN package_rv p ON p.uuid = uu.packageuuid JOIN customer_rv c ON c.uuid = p.customeruuid; + call expectBetween(resultCount, 30, 50); -- hostsharing admin assuming two customer admin roles and listing all accessible domains + -- ABORT; START TRANSACTION; SET SESSION SESSION AUTHORIZATION restricted; SET LOCAL hsadminng.currentUser = 'mike@hostsharing.net'; SET LOCAL hsadminng.assumedRoles = 'customer#aac.admin;customer#aad.admin'; - PERFORM p.name, uu.name, dom.name + -- SELECT p.name, uu.name, dom.name + SELECT count(*) INTO resultCount FROM domain_rv dom JOIN unixuser_rv uu ON uu.uuid = dom.unixuseruuid JOIN package_rv p ON p.uuid = uu.packageuuid JOIN customer_rv c ON c.uuid = p.customeruuid; + call expectBetween(resultCount, 30, 50); -- 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 = 'mike@hostsharing.net'; - SET LOCAL hsadminng.assumedRoles = 'customer#aad.admin;customer#aae.admin'; - PERFORM c.prefix, p.name as "package", ema.localPart || '@' || dom.name as "email-address" + SET LOCAL hsadminng.assumedRoles = 'customer#aae.admin;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 unixuser_rv uu ON uu.uuid = dom.unixuseruuid JOIN package_rv p ON p.uuid = uu.packageuuid JOIN customer_rv c ON c.uuid = p.customeruuid; + call expectBetween(resultCount, 100, 300); + + -- ~170ms END; $$; /* === with 7000 customers === -1. [2022-07-26 09:17:19] completed in 801 ms -2. [2022-07-26 09:17:32] completed in 649 ms -3. [2022-07-26 09:17:51] completed in 670 ms +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 @@ -76,5 +116,19 @@ no count required factor table 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 unixuser +4 149 946 100 000 1.499 domain +5 749 730 500 000 1.499 emailaddress + */