From 377b63ca3d12b5d389c22edce7f7ecc85a0735f0 Mon Sep 17 00:00:00 2001
From: Michael Hoennig <michael@hoennig.de>
Date: Fri, 22 Jul 2022 16:52:49 +0200
Subject: [PATCH] RbacGrants with follow=false for customer.owner to
 customer.admin

---
 sql/10-rbac-base.sql       | 134 +++++++++++++++++++++----------------
 sql/21-hs-customer.sql     |   5 +-
 sql/22-hs-packages.sql     |   2 +-
 sql/23-hs-unixuser.sql     |   2 +-
 sql/24-hs-domain.sql       |   2 +-
 sql/25-hs-emailaddress.sql |   2 +-
 sql/28-hs-tests.sql        |  87 ++++++++++++++++++++++++
 7 files changed, 170 insertions(+), 64 deletions(-)
 create mode 100644 sql/28-hs-tests.sql

diff --git a/sql/10-rbac-base.sql b/sql/10-rbac-base.sql
index 1f783077..f67ec657 100644
--- a/sql/10-rbac-base.sql
+++ b/sql/10-rbac-base.sql
@@ -39,7 +39,7 @@ CREATE TABLE RbacGrants
 (
     ascendantUuid uuid references RbacReference (uuid) ON DELETE CASCADE,
     descendantUuid uuid references RbacReference (uuid) ON DELETE CASCADE,
-    -- apply bool not null, -- alternative 1 to implement assumable roles
+    follow boolean not null default true,
     primary key (ascendantUuid, descendantUuid)
 );
 CREATE INDEX ON RbacGrants (ascendantUuid);
@@ -254,23 +254,19 @@ BEGIN
 END;
 $$;
 
-CREATE OR REPLACE PROCEDURE grantRoleToRole(subRoleId uuid, superRoleId uuid
-        -- , doapply bool = true -- assumeV1
-        )
+CREATE OR REPLACE PROCEDURE grantRoleToRole(subRoleId uuid, superRoleId uuid, doFollow bool = true )
     LANGUAGE plpgsql AS $$
 BEGIN
     perform assertReferenceType('superRoleId (ascendant)', superRoleId, 'RbacRole');
     perform assertReferenceType('subRoleId (descendant)',  subRoleId, 'RbacRole');
 
-    RAISE NOTICE 'granting subRole % to superRole %', subRoleId, superRoleId; -- TODO: remove
-
     IF ( isGranted(subRoleId, superRoleId) ) THEN
         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) VALUES (superRoleId, subRoleId)
-        ON CONFLICT DO NOTHING ; -- TODO: remove
+    INSERT INTO RbacGrants (ascendantUuid, descendantUuid, follow)VALUES (superRoleId, subRoleId, doFollow)
+    ON CONFLICT DO NOTHING ; -- TODO: remove?
 END; $$;
 
 CREATE OR REPLACE PROCEDURE revokeRoleFromRole(subRoleId uuid, superRoleId uuid)
@@ -298,40 +294,52 @@ END; $$;
 abort;
 set local session authorization default;
 
+CREATE OR REPLACE FUNCTION nextLevel(level integer, maxDepth integer)
+    RETURNS INTEGER
+    LANGUAGE plpgsql AS $$
+    BEGIN
+        IF (level > maxDepth) THEN
+            RAISE WARNING 'Role assignment depth exceeded %/%.', level, maxDepth;
+        END IF;
+        RETURN level+1;
+    END;
+$$;
+
+
 CREATE OR REPLACE FUNCTION queryAccessibleObjectUuidsOfSubjectIds(
             requiredOp RbacOp,
-            -- objectTable varchar, -- TODO: maybe another optimization? but test perforamance for joins!
+            forObjectTable varchar, -- TODO: test perforamance in joins!
             subjectIds uuid[],
-            maxDepth integer = 8,
             maxObjects integer = 16000)
     RETURNS SETOF uuid
     RETURNS NULL ON NULL INPUT
     LANGUAGE plpgsql AS $$
     DECLARE
-        foundRows bigint;
+        foundRows     bigint;
     BEGIN
-         RETURN QUERY SELECT DISTINCT perm.objectUuid
+        RETURN QUERY SELECT DISTINCT perm.objectUuid
           FROM (
                WITH RECURSIVE grants AS (
                    SELECT descendantUuid, ascendantUuid, 1 AS level
                        FROM RbacGrants
-                       WHERE ascendantUuid = ANY(subjectIds)
-                   UNION ALL
-                   SELECT "grant".descendantUuid, "grant".ascendantUuid, level + 1 AS level
+                       WHERE follow AND ascendantUuid = ANY(subjectIds)
+                   UNION DISTINCT
+                   SELECT "grant".descendantUuid, "grant".ascendantUuid, level+1 AS level
                         FROM RbacGrants "grant"
                         INNER JOIN grants recur ON recur.descendantUuid = "grant".ascendantUuid
-                   WHERE level <= maxDepth
+                       WHERE follow
                ) SELECT descendantUuid
                FROM grants
-               -- LIMIT maxObjects+1
            ) as granted
-         JOIN RbacPermission perm ON granted.descendantUuid=perm.uuid AND perm.op IN ('*', requiredOp);
+         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;
 
          foundRows = lastRowCount();
          IF foundRows > maxObjects THEN
              RAISE EXCEPTION 'Too many accessible objects, limit is %, found %.', maxObjects, foundRows
                  USING
-                     ERRCODE = 'P0003', -- 'HS-ADMIN-NG:ACC-OBJ-EXC',
+                     ERRCODE = 'P0003',
                      HINT = 'Please assume a sub-role and try again.';
          END IF;
     END;
@@ -340,9 +348,9 @@ $$;
 abort;
 set local session authorization restricted;
 begin transaction;
-set local statement_timeout TO '60s';
+set local statement_timeout TO '5s';
 select count(*)
-  from queryAccessibleObjectUuidsOfSubjectIds('view', ARRAY[findRbacUser('mike@hostsharing.net')], 4, 10000);
+  from queryAccessibleObjectUuidsOfSubjectIds('view', 'customer', ARRAY[findRbacUser('mike@hostsharing.net')],  10000);
 end transaction;
 
 ---
@@ -510,27 +518,20 @@ CREATE OR REPLACE FUNCTION isGranted(granteeId uuid, grantedId uuid)
     RETURNS bool
     RETURNS NULL ON NULL INPUT
     LANGUAGE sql AS $$
-SELECT granteeId=grantedId OR granteeId IN (
-    WITH RECURSIVE grants AS (
-        SELECT
-            descendantUuid,
-            ascendantUuid
-        FROM
-            RbacGrants
-        WHERE
-                descendantUuid = grantedId
-        UNION ALL
-        SELECT
-            "grant".descendantUuid,
-            "grant".ascendantUuid
-        FROM
-            RbacGrants "grant"
+        SELECT granteeId=grantedId OR granteeId IN (
+            WITH RECURSIVE grants AS (
+                SELECT descendantUuid, ascendantUuid
+                FROM RbacGrants
+                WHERE descendantUuid = grantedId
+                UNION ALL
+                SELECT "grant".descendantUuid, "grant".ascendantUuid
+                FROM RbacGrants "grant"
                 INNER JOIN grants recur ON recur.ascendantUuid = "grant".descendantUuid
-    ) SELECT
-        ascendantUuid
-    FROM
-        grants
-);
+            ) SELECT
+                ascendantUuid
+            FROM
+                grants
+        );
 $$;
 
 CREATE OR REPLACE FUNCTION isPermissionGrantedToSubject(permissionId uuid, subjectId uuid)
@@ -617,17 +618,17 @@ DECLARE
 BEGIN
     BEGIN
         currentSubject := current_setting('hsadminng.assumedRoles');
-    EXCEPTION WHEN OTHERS THEN
-        RETURN NULL;
-    END;
-    IF (currentSubject = '') THEN
-        RETURN NULL;
-    END IF;
-    RETURN string_to_array(currentSubject, ';');
-END; $$;
+        EXCEPTION WHEN OTHERS THEN
+            RETURN ARRAY[]::varchar[];
+        END;
+        IF (currentSubject = '') THEN
+            RETURN ARRAY[]::varchar[];
+        END IF;
+        RETURN string_to_array(currentSubject, ';');
+    END; $$;
 
 
--- ROLLBACK;
+ROLLBACK;
 SET SESSION AUTHORIZATION DEFAULT;
 CREATE OR REPLACE FUNCTION currentSubjectIds()
     RETURNS uuid[]
@@ -641,17 +642,36 @@ DECLARE
 BEGIN
     currentUserId := currentUserId();
     assumedRoles := assumedRoles();
-    IF ( assumedRoles IS NULL ) THEN
-        RETURN currentUserId;
+    IF ( CARDINALITY(assumedRoles) = 0 ) THEN
+        RETURN ARRAY[currentUserId];
     END IF;
 
     RAISE NOTICE 'assuming roles: %', assumedRoles;
 
     SELECT ARRAY_AGG(uuid) FROM RbacRole WHERE name = ANY(assumedRoles) INTO assumedRoleIds;
-    FOREACH assumedRoleId IN ARRAY assumedRoleIds LOOP
-        IF ( NOT isGranted(currentUserId, assumedRoleId) ) THEN
-            RAISE EXCEPTION 'user % has no permission to assume role %', currentUser(), assumedRoleId;
-        END IF;
-    END LOOP;
+    IF assumedRoleIds IS NOT NULL THEN
+        FOREACH assumedRoleId IN ARRAY assumedRoleIds LOOP
+            IF ( NOT isGranted(currentUserId, assumedRoleId) ) THEN
+                RAISE EXCEPTION 'user % has no permission to assume role %', currentUser(), assumedRoleId;
+            END IF;
+        END LOOP;
+    END IF;
     RETURN assumedRoleIds;
 END; $$;
+
+rollback;
+set session authorization default;
+CREATE OR REPLACE FUNCTION maxGrantDepth()
+    RETURNS integer
+    STABLE LEAKPROOF
+    LANGUAGE plpgsql AS $$
+DECLARE
+    maxGrantDepth VARCHAR(63);
+BEGIN
+    BEGIN
+        maxGrantDepth := current_setting('hsadminng.maxGrantDepth');
+    EXCEPTION WHEN OTHERS THEN
+        maxGrantDepth := NULL;
+    END;
+    RETURN coalesce(maxGrantDepth, '8')::integer;
+END; $$;
diff --git a/sql/21-hs-customer.sql b/sql/21-hs-customer.sql
index 5e050cd4..2a93ad0a 100644
--- a/sql/21-hs-customer.sql
+++ b/sql/21-hs-customer.sql
@@ -38,7 +38,7 @@ BEGIN
 
     -- ... also a customer admin role is created and granted to the customer owner role
     customerAdminRoleId = createRole('customer#'||NEW.prefix||'.admin');
-    call grantRoleToRole(customerAdminRoleId, customerOwnerRoleId);
+    call grantRoleToRole(customerAdminRoleId, customerOwnerRoleId, false);
     -- ... to which a permission with view and add- ops is assigned
     call grantPermissionsToRole(customerAdminRoleId,
         createPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['view', 'add-package']));
@@ -88,12 +88,11 @@ CREATE TRIGGER deleteRbacRulesForCustomer_Trigger
 
 SET SESSION SESSION AUTHORIZATION DEFAULT;
 ALTER TABLE customer ENABLE ROW LEVEL SECURITY;
-DROP VIEW IF EXISTS cust_view;
 DROP VIEW IF EXISTS customer_rv;
 CREATE OR REPLACE VIEW customer_rv AS
     SELECT DISTINCT target.*
       FROM customer AS target
-      JOIN queryAccessibleObjectUuidsOfSubjectIds( 'view', currentSubjectIds()) AS allowedObjId
+      JOIN queryAccessibleObjectUuidsOfSubjectIds( 'view', 'customer', currentSubjectIds()) AS allowedObjId
            ON target.uuid = allowedObjId;
 GRANT ALL PRIVILEGES ON customer_rv TO restricted;
 
diff --git a/sql/22-hs-packages.sql b/sql/22-hs-packages.sql
index 7322e3b1..4f0e76d4 100644
--- a/sql/22-hs-packages.sql
+++ b/sql/22-hs-packages.sql
@@ -78,7 +78,7 @@ DROP VIEW IF EXISTS package_rv;
 CREATE OR REPLACE VIEW package_rv AS
     SELECT DISTINCT target.*
       FROM package AS target
-     JOIN queryAccessibleObjectUuidsOfSubjectIds( 'view', currentSubjectIds()) AS allowedObjId
+     JOIN queryAccessibleObjectUuidsOfSubjectIds( 'view', 'package', currentSubjectIds()) AS allowedObjId
           ON target.uuid = allowedObjId;
 GRANT ALL PRIVILEGES ON package_rv TO restricted;
 
diff --git a/sql/23-hs-unixuser.sql b/sql/23-hs-unixuser.sql
index 77ed62b6..91b92c98 100644
--- a/sql/23-hs-unixuser.sql
+++ b/sql/23-hs-unixuser.sql
@@ -71,7 +71,7 @@ DROP VIEW IF EXISTS unixuser_rv;
 CREATE OR REPLACE VIEW unixuser_rv AS
     SELECT DISTINCT target.*
      FROM unixuser AS target
-     JOIN queryAccessibleObjectUuidsOfSubjectIds( 'view', currentSubjectIds()) AS allowedObjId
+     JOIN queryAccessibleObjectUuidsOfSubjectIds( 'view', 'unixuser', currentSubjectIds()) AS allowedObjId
           ON target.uuid = allowedObjId;
 GRANT ALL PRIVILEGES ON unixuser_rv TO restricted;
 
diff --git a/sql/24-hs-domain.sql b/sql/24-hs-domain.sql
index f19e1f97..dc4afdef 100644
--- a/sql/24-hs-domain.sql
+++ b/sql/24-hs-domain.sql
@@ -56,7 +56,7 @@ DROP VIEW IF EXISTS domain_rv;
 CREATE OR REPLACE VIEW domain_rv AS
     SELECT DISTINCT target.*
       FROM Domain AS target
-      JOIN queryAccessibleObjectUuidsOfSubjectIds( 'view', currentSubjectIds()) AS allowedObjId
+      JOIN queryAccessibleObjectUuidsOfSubjectIds( 'view', 'domain', currentSubjectIds()) AS allowedObjId
            ON target.uuid = allowedObjId;
 GRANT ALL PRIVILEGES ON domain_rv TO restricted;
 
diff --git a/sql/25-hs-emailaddress.sql b/sql/25-hs-emailaddress.sql
index 6956fded..7a37d9c2 100644
--- a/sql/25-hs-emailaddress.sql
+++ b/sql/25-hs-emailaddress.sql
@@ -81,7 +81,7 @@ DROP VIEW IF EXISTS EMailAddress_rv;
 CREATE OR REPLACE VIEW EMailAddress_rv AS
     SELECT DISTINCT target.*
     FROM EMailAddress AS target
-    JOIN queryAccessibleObjectUuidsOfSubjectIds( 'view', currentSubjectIds()) AS allowedObjId
+    JOIN queryAccessibleObjectUuidsOfSubjectIds( 'view', 'emailaddress', currentSubjectIds()) AS allowedObjId
          ON target.uuid = allowedObjId;
 GRANT ALL PRIVILEGES ON EMailAddress_rv TO restricted;
 
diff --git a/sql/28-hs-tests.sql b/sql/28-hs-tests.sql
new file mode 100644
index 00000000..029ba24f
--- /dev/null
+++ b/sql/28-hs-tests.sql
@@ -0,0 +1,87 @@
+
+
+-- hostmaster listing all customers
+ROLLBACK;
+BEGIN TRANSACTION;
+SET SESSION SESSION AUTHORIZATION restricted;
+SET LOCAL hsadminng.currentUser = 'mike@hostsharing.net';
+SET LOCAL hsadminng.assumedRoles = '';
+SELECT * FROM customer_rv;
+END TRANSACTION;
+
+-- customer admin listing all their packages
+ROLLBACK;
+BEGIN TRANSACTION;
+SET SESSION SESSION AUTHORIZATION restricted;
+SET LOCAL hsadminng.currentUser = 'admin@aae.example.com';
+SET LOCAL hsadminng.assumedRoles = '';
+SELECT * FROM package_rv;
+END TRANSACTION;
+
+
+-- cutomer admin listing all their unix users
+ROLLBACK;
+BEGIN TRANSACTION;
+SET SESSION SESSION AUTHORIZATION restricted;
+SET LOCAL hsadminng.currentUser = 'admin@aae.example.com';
+SET LOCAL hsadminng.assumedRoles = '';
+
+SELECT * FROM unixuser_rv;
+END TRANSACTION;
+
+
+-- hostsharing admin assuming customer role and listing all accessible packages
+ROLLBACK;
+BEGIN TRANSACTION;
+SET SESSION SESSION AUTHORIZATION restricted;
+SET LOCAL hsadminng.currentUser = 'mike@hostsharing.net';
+SET LOCAL hsadminng.assumedRoles = 'customer#bbb.admin;customer#bbc.admin';
+SELECT * FROM package_rv p;
+END TRANSACTION;
+
+-- hostsharing admin assuming two customer admin role and listing all accessible unixusers
+ROLLBACK;
+BEGIN TRANSACTION;
+SET SESSION SESSION AUTHORIZATION restricted;
+SET LOCAL hsadminng.currentUser = 'mike@hostsharing.net';
+SET LOCAL hsadminng.assumedRoles = 'customer#bbb.admin;customer#bbc.admin';
+
+SELECT c.prefix, c.reference, uu.*
+FROM unixuser_rv uu
+         JOIN package_rv p ON p.uuid = uu.packageuuid
+         JOIN customer_rv c ON c.uuid = p.customeruuid;
+END TRANSACTION;
+
+BEGIN TRANSACTION;
+SET SESSION SESSION AUTHORIZATION restricted;
+SET LOCAL hsadminng.currentUser = 'mike@hostsharing.net';
+SET LOCAL hsadminng.assumedRoles = 'customer#bbb.admin;customer#bbc.admin';
+
+SELECT p.name, uu.name, dom.name
+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;
+END TRANSACTION;
+
+BEGIN TRANSACTION;
+SET SESSION SESSION AUTHORIZATION restricted;
+SET LOCAL hsadminng.currentUser = 'mike@hostsharing.net';
+SET LOCAL hsadminng.assumedRoles = 'customer#bbb.admin;customer#bbc.admin';
+-- TODO: we need tenant roles on parent objects
+-- SET LOCAL hsadminng.assumedRoles = 'package#bbb03.owner;package#bbb08.owner';
+
+SELECT p.name as "package", ema.localPart || '@' || dom.name as "email-address"
+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;
+END TRANSACTION;
+
+ROLLBACK;
+BEGIN TRANSACTION;
+SET SESSION SESSION AUTHORIZATION restricted;
+SET LOCAL hsadminng.currentUser = 'mike@hostsharing.net';
+select * from customer_rv c where c.prefix='bbb';
+END TRANSACTION;