convert rbac*.sql files, except test-file, to Liquibase changesets
This commit is contained in:
@ -1,63 +0,0 @@
|
||||
abort;
|
||||
set local session authorization default;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION array_distinct(anyarray) RETURNS anyarray AS $f$
|
||||
SELECT array_agg(DISTINCT x) FROM unnest($1) t(x);
|
||||
$f$ LANGUAGE SQL IMMUTABLE;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION lastRowCount()
|
||||
RETURNS bigint
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
lastRowCount bigint;
|
||||
BEGIN
|
||||
GET DIAGNOSTICS lastRowCount = ROW_COUNT;
|
||||
RETURN lastRowCount;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- ========================================================
|
||||
-- Test Data helpers
|
||||
-- --------------------------------------------------------
|
||||
|
||||
CREATE OR REPLACE FUNCTION intToVarChar(i integer, len integer)
|
||||
RETURNS varchar
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
partial varchar;
|
||||
BEGIN
|
||||
SELECT chr(ascii('a') + i%26) INTO partial;
|
||||
IF len > 1 THEN
|
||||
RETURN intToVarChar(i/26, len-1) || partial;
|
||||
ELSE
|
||||
RETURN partial;
|
||||
END IF;
|
||||
END; $$;
|
||||
|
||||
select * from intToVarChar(211, 4);
|
||||
|
||||
CREATE OR REPLACE FUNCTION randomInRange(min INTEGER, max INTEGER)
|
||||
RETURNS INT
|
||||
RETURNS NULL ON NULL INPUT
|
||||
language 'plpgsql' AS $$
|
||||
BEGIN
|
||||
RETURN floor(random() * (max-min + 1) + min);
|
||||
END; $$;
|
||||
|
||||
select * from randomInRange(0, 4);
|
||||
|
||||
|
||||
-- ========================================================
|
||||
-- Test helpers
|
||||
-- --------------------------------------------------------
|
||||
|
||||
-- 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; $$;
|
@ -1,733 +0,0 @@
|
||||
|
||||
-- ========================================================
|
||||
-- RBAC
|
||||
-- --------------------------------------------------------
|
||||
|
||||
SET SESSION SESSION AUTHORIZATION DEFAULT;
|
||||
|
||||
-- https://arctype.com/blog/postgres-uuid/#creating-a-uuid-primary-key-using-uuid-osp-postgresql-example
|
||||
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
||||
|
||||
DROP TABLE IF EXISTS "RbacPermission";
|
||||
DROP TABLE IF EXISTS "RbacGrants";
|
||||
DROP TABLE IF EXISTS "RbacUser";
|
||||
DROP TABLE IF EXISTS RbacReference CASCADE;
|
||||
DROP TYPE IF EXISTS RbacOp CASCADE;
|
||||
DROP TYPE IF EXISTS ReferenceType CASCADE;
|
||||
|
||||
CREATE TYPE ReferenceType AS ENUM ('RbacUser', 'RbacRole', 'RbacPermission');
|
||||
|
||||
CREATE TABLE RbacReference
|
||||
(
|
||||
uuid uuid UNIQUE DEFAULT uuid_generate_v4(),
|
||||
type ReferenceType not null
|
||||
);
|
||||
|
||||
CREATE TABLE RbacUser
|
||||
(
|
||||
uuid uuid primary key references RbacReference (uuid) ON DELETE CASCADE,
|
||||
name varchar(63) not null unique
|
||||
);
|
||||
|
||||
-- DROP TABLE IF EXISTS RbacObject;
|
||||
CREATE TABLE RbacObject
|
||||
(
|
||||
uuid uuid PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
objectTable varchar(64) not null,
|
||||
unique (objectTable, uuid)
|
||||
);
|
||||
|
||||
CREATE TYPE RbacRoleType AS ENUM ('owner', 'admin', 'tenant');
|
||||
|
||||
CREATE TABLE RbacRole
|
||||
(
|
||||
uuid uuid primary key references RbacReference (uuid) ON DELETE CASCADE,
|
||||
objectUuid uuid references RbacObject(uuid) not null,
|
||||
roleType RbacRoleType not null
|
||||
);
|
||||
|
||||
CREATE TABLE RbacGrants
|
||||
(
|
||||
ascendantUuid uuid references RbacReference (uuid) ON DELETE CASCADE,
|
||||
descendantUuid uuid references RbacReference (uuid) ON DELETE CASCADE,
|
||||
follow boolean not null default true,
|
||||
primary key (ascendantUuid, descendantUuid)
|
||||
);
|
||||
CREATE INDEX ON RbacGrants (ascendantUuid);
|
||||
CREATE INDEX ON RbacGrants (descendantUuid);
|
||||
|
||||
-- DROP DOMAIN IF EXISTS RbacOp CASCADE;
|
||||
CREATE DOMAIN RbacOp AS VARCHAR(67)
|
||||
CHECK(
|
||||
VALUE = '*'
|
||||
OR VALUE = 'delete'
|
||||
OR VALUE = 'edit'
|
||||
OR VALUE = 'view'
|
||||
OR VALUE = 'assume'
|
||||
OR VALUE ~ '^add-[a-z]+$'
|
||||
);
|
||||
|
||||
CREATE OR REPLACE FUNCTION createRbacObject()
|
||||
RETURNS trigger
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
DECLARE
|
||||
objectUuid uuid;
|
||||
BEGIN
|
||||
IF TG_OP = 'INSERT' THEN
|
||||
INSERT INTO RbacObject (objectTable) VALUES (TG_TABLE_NAME) RETURNING uuid INTO objectUuid;
|
||||
NEW.uuid = objectUuid;
|
||||
RETURN NEW;
|
||||
ELSE
|
||||
RAISE EXCEPTION 'invalid usage of TRIGGER AFTER INSERT';
|
||||
END IF;
|
||||
END; $$;
|
||||
|
||||
|
||||
-- DROP TABLE IF EXISTS RbacPermission;
|
||||
CREATE TABLE RbacPermission
|
||||
( uuid uuid primary key references RbacReference (uuid) ON DELETE CASCADE,
|
||||
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 $$
|
||||
SELECT EXISTS (
|
||||
SELECT op
|
||||
FROM RbacPermission p
|
||||
WHERE p.objectUuid=forObjectUuid AND p.op in ('*', forOp)
|
||||
);
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION createRbacUser(userName varchar)
|
||||
RETURNS uuid
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE plpgsql AS $$
|
||||
declare
|
||||
objectId uuid;
|
||||
BEGIN
|
||||
INSERT INTO RbacReference (type) VALUES ('RbacUser') RETURNING uuid INTO objectId;
|
||||
INSERT INTO RbacUser (uuid, name) VALUES (objectid, userName);
|
||||
return objectId;
|
||||
END;
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION findRbacUserId(userName varchar)
|
||||
RETURNS uuid
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE sql AS $$
|
||||
SELECT uuid FROM RbacUser WHERE name = userName
|
||||
$$;
|
||||
|
||||
CREATE TYPE RbacWhenNotExists AS ENUM ('fail', 'create');
|
||||
|
||||
CREATE OR REPLACE FUNCTION getRbacUserId(userName varchar, whenNotExists RbacWhenNotExists)
|
||||
RETURNS uuid
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
userUuid uuid;
|
||||
BEGIN
|
||||
userUuid = findRbacUserId(userName);
|
||||
IF ( userUuid IS NULL ) THEN
|
||||
IF ( whenNotExists = 'fail') THEN
|
||||
RAISE EXCEPTION 'RbacUser with name="%" not found', userName;
|
||||
END IF;
|
||||
IF ( whenNotExists = 'create') THEN
|
||||
userUuid = createRbacUser(userName);
|
||||
END IF;
|
||||
END IF;
|
||||
return userUuid;
|
||||
END;
|
||||
$$;
|
||||
|
||||
CREATE TYPE RbacRoleDescriptor AS
|
||||
(
|
||||
objectTable varchar(63), -- TODO: needed? remove?
|
||||
objectUuid uuid,
|
||||
roleType RbacRoleType
|
||||
);
|
||||
|
||||
-- TODO: this ...
|
||||
CREATE OR REPLACE FUNCTION roleDescriptor(objectTable varchar(63), objectUuid uuid, roleType RbacRoleType )
|
||||
RETURNS RbacRoleDescriptor
|
||||
RETURNS NULL ON NULL INPUT
|
||||
STABLE LEAKPROOF
|
||||
LANGUAGE plpgsql AS $$
|
||||
BEGIN
|
||||
RETURN ROW(objectTable, objectUuid, roleType);
|
||||
END; $$;
|
||||
|
||||
CREATE FUNCTION new_emp() RETURNS emp AS $$
|
||||
SELECT text 'None' AS name,
|
||||
1000.0 AS salary,
|
||||
25 AS age,
|
||||
point '(2,2)' AS cubicle;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
DO LANGUAGE plpgsql $$
|
||||
DECLARE
|
||||
roleDesc RbacRoleDescriptor;
|
||||
BEGIN
|
||||
select * FROM roleDescriptor('global', gen_random_uuid(), 'admin') into roleDesc;
|
||||
RAISE NOTICE 'result: % % %', roleDesc.objecttable, roleDesc.objectuuid, roleDesc.roletype;
|
||||
END; $$;
|
||||
|
||||
-- TODO: ... or that?
|
||||
CREATE OR REPLACE FUNCTION roleDescriptor(objectTable varchar(63), objectUuid uuid, roleType RbacRoleType )
|
||||
RETURNS RbacRoleDescriptor
|
||||
RETURNS NULL ON NULL INPUT
|
||||
-- STABLE LEAKPROOF
|
||||
LANGUAGE sql AS $$
|
||||
SELECT objectTable, objectUuid, roleType::RbacRoleType;
|
||||
$$;
|
||||
|
||||
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION createRole(roleDescriptor RbacRoleDescriptor)
|
||||
RETURNS uuid
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE plpgsql AS $$
|
||||
declare
|
||||
referenceId uuid;
|
||||
BEGIN
|
||||
INSERT INTO RbacReference (type) VALUES ('RbacRole') RETURNING uuid INTO referenceId;
|
||||
INSERT INTO RbacRole (uuid, objectUuid, roleType) VALUES (referenceId, roleDescriptor.objectUuid, roleDescriptor.roleType);
|
||||
return referenceId;
|
||||
END;
|
||||
$$;
|
||||
|
||||
|
||||
CREATE OR REPLACE PROCEDURE deleteRole(roleUUid uuid)
|
||||
LANGUAGE plpgsql AS $$
|
||||
BEGIN
|
||||
DELETE FROM RbacRole WHERE uuid=roleUUid;
|
||||
END;
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION findRoleId(roleDescriptor RbacRoleDescriptor)
|
||||
RETURNS uuid
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE sql AS $$
|
||||
SELECT uuid FROM RbacRole WHERE objectUuid = roleDescriptor.objectUuid AND roleType = roleDescriptor.roleType;
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION getRoleId(roleDescriptor RbacRoleDescriptor, whenNotExists RbacWhenNotExists)
|
||||
RETURNS uuid
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
roleUuid uuid;
|
||||
BEGIN
|
||||
roleUuid = findRoleId(roleDescriptor);
|
||||
IF ( roleUuid IS NULL ) THEN
|
||||
IF ( whenNotExists = 'fail') THEN
|
||||
RAISE EXCEPTION 'RbacRole "%#%.%" not found', roleDescriptor.objectTable, roleDescriptor.objectUuid, roleDescriptor.roleType;
|
||||
END IF;
|
||||
IF ( whenNotExists = 'create') THEN
|
||||
roleUuid = createRole(roleDescriptor);
|
||||
END IF;
|
||||
END IF;
|
||||
return roleUuid;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- select getRoleId('hostmaster', 'create');
|
||||
|
||||
CREATE OR REPLACE FUNCTION createPermissions(forObjectUuid uuid, permitOps RbacOp[])
|
||||
RETURNS uuid[]
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
refId uuid;
|
||||
permissionIds uuid[] = ARRAY[]::uuid[];
|
||||
BEGIN
|
||||
RAISE NOTICE 'createPermission for: % %', forObjectUuid, permitOps;
|
||||
IF ( forObjectUuid IS NULL ) THEN
|
||||
RAISE EXCEPTION 'forObjectUuid must not be null';
|
||||
END IF;
|
||||
IF ( array_length(permitOps, 1) > 1 AND '*' = any(permitOps) ) THEN
|
||||
RAISE EXCEPTION '"*" operation must not be assigned along with other operations: %', permitOps;
|
||||
END IF;
|
||||
|
||||
FOR i IN array_lower(permitOps, 1)..array_upper(permitOps, 1) LOOP
|
||||
refId = (SELECT uuid FROM RbacPermission WHERE objectUuid=forObjectUuid AND op=permitOps[i]);
|
||||
IF (refId IS NULL) THEN
|
||||
RAISE NOTICE 'createPermission: % %', forObjectUuid, permitOps[i];
|
||||
INSERT INTO RbacReference ("type") VALUES ('RbacPermission') RETURNING uuid INTO refId;
|
||||
INSERT INTO RbacPermission (uuid, objectUuid, op) VALUES (refId, forObjectUuid, permitOps[i]);
|
||||
END IF;
|
||||
RAISE NOTICE 'addPermission: %', refId;
|
||||
permissionIds = permissionIds || refId;
|
||||
END LOOP;
|
||||
|
||||
RAISE NOTICE 'createPermissions returning: %', permissionIds;
|
||||
return permissionIds;
|
||||
END;
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION findPermissionId(forObjectUuid uuid, forOp RbacOp)
|
||||
RETURNS uuid
|
||||
RETURNS NULL ON NULL INPUT
|
||||
STABLE LEAKPROOF
|
||||
LANGUAGE sql AS $$
|
||||
SELECT uuid FROM RbacPermission p
|
||||
WHERE p.objectUuid=forObjectUuid AND p.op in ('*', forOp)
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION assertReferenceType(argument varchar, referenceId uuid, expectedType ReferenceType)
|
||||
RETURNS ReferenceType
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
actualType ReferenceType;
|
||||
BEGIN
|
||||
actualType = (SELECT type FROM RbacReference WHERE uuid=referenceId);
|
||||
IF ( actualType <> expectedType ) THEN
|
||||
RAISE EXCEPTION '% must reference a %, but got a %', argument, expectedType, actualType;
|
||||
end if;
|
||||
RETURN expectedType;
|
||||
END; $$;
|
||||
|
||||
CREATE OR REPLACE PROCEDURE grantPermissionsToRole(roleUuid uuid, permissionIds uuid[])
|
||||
LANGUAGE plpgsql AS $$
|
||||
BEGIN
|
||||
RAISE NOTICE 'grantPermissionsToRole: % -> %', roleUuid, permissionIds;
|
||||
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]);
|
||||
END LOOP;
|
||||
END;
|
||||
$$;
|
||||
|
||||
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');
|
||||
|
||||
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, follow) VALUES (superRoleId, subRoleId, doFollow)
|
||||
ON CONFLICT DO NOTHING ; -- TODO: remove?
|
||||
END; $$;
|
||||
|
||||
CREATE OR REPLACE PROCEDURE revokeRoleFromRole(subRoleId uuid, superRoleId uuid)
|
||||
LANGUAGE plpgsql AS $$
|
||||
BEGIN
|
||||
perform assertReferenceType('superRoleId (ascendant)', superRoleId, 'RbacRole');
|
||||
perform assertReferenceType('subRoleId (descendant)', subRoleId, 'RbacRole');
|
||||
|
||||
IF ( isGranted(subRoleId, superRoleId) ) THEN
|
||||
DELETE FROM RbacGrants WHERE ascendantUuid=superRoleId AND descendantUuid=subRoleId;
|
||||
END IF;
|
||||
END; $$;
|
||||
|
||||
CREATE OR REPLACE PROCEDURE grantRoleToUser(roleId uuid, userId uuid)
|
||||
LANGUAGE plpgsql AS $$
|
||||
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)
|
||||
ON CONFLICT DO NOTHING ; -- TODO: remove?
|
||||
END; $$;
|
||||
|
||||
abort;
|
||||
set local session authorization default;
|
||||
|
||||
CREATE OR REPLACE FUNCTION queryAccessibleObjectUuidsOfSubjectIds(
|
||||
requiredOp RbacOp,
|
||||
forObjectTable varchar, -- reduces the result set, but is not really faster when used in restricted view
|
||||
subjectIds uuid[],
|
||||
maxObjects integer = 8000)
|
||||
RETURNS SETOF uuid
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
foundRows bigint;
|
||||
BEGIN
|
||||
RETURN QUERY SELECT DISTINCT perm.objectUuid
|
||||
FROM (
|
||||
WITH RECURSIVE grants AS (
|
||||
SELECT descendantUuid, ascendantUuid, 1 AS level
|
||||
FROM RbacGrants
|
||||
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 follow
|
||||
) SELECT descendantUuid
|
||||
FROM grants
|
||||
) 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
|
||||
LIMIT maxObjects+1;
|
||||
|
||||
foundRows = lastRowCount();
|
||||
IF foundRows > maxObjects THEN
|
||||
RAISE EXCEPTION 'Too many accessible objects, limit is %, found %.', maxObjects, foundRows
|
||||
USING
|
||||
ERRCODE = 'P0003',
|
||||
HINT = 'Please assume a sub-role and try again.';
|
||||
END IF;
|
||||
END;
|
||||
$$;
|
||||
|
||||
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;
|
||||
set local session authorization restricted;
|
||||
begin transaction;
|
||||
set local statement_timeout TO '15s';
|
||||
select count(*)
|
||||
from queryAccessibleObjectUuidsOfSubjectIds('view', 'customer', ARRAY[findRbacUserId('mike@hostsharing.net')], 10000);
|
||||
end transaction;
|
||||
|
||||
---
|
||||
|
||||
abort;
|
||||
set local session authorization default;
|
||||
CREATE OR REPLACE FUNCTION queryRequiredPermissionsOfSubjectIds(requiredOp RbacOp, subjectIds uuid[])
|
||||
RETURNS SETOF RbacPermission
|
||||
STRICT
|
||||
LANGUAGE sql AS $$
|
||||
SELECT DISTINCT *
|
||||
FROM RbacPermission
|
||||
WHERE op = '*' OR op = requiredOp
|
||||
AND uuid IN (
|
||||
WITH RECURSIVE grants AS (
|
||||
SELECT DISTINCT
|
||||
descendantUuid,
|
||||
ascendantUuid
|
||||
FROM RbacGrants
|
||||
WHERE
|
||||
ascendantUuid = ANY(subjectIds)
|
||||
UNION ALL
|
||||
SELECT
|
||||
"grant".descendantUuid,
|
||||
"grant".ascendantUuid
|
||||
FROM RbacGrants "grant"
|
||||
INNER JOIN grants recur ON recur.descendantUuid = "grant".ascendantUuid
|
||||
) SELECT
|
||||
descendantUuid
|
||||
FROM grants
|
||||
);
|
||||
$$;
|
||||
|
||||
abort;
|
||||
set local session authorization restricted;
|
||||
begin transaction;
|
||||
-- set local statement_timeout TO '5s';
|
||||
set local statement_timeout TO '5min';
|
||||
select count(*) from queryRequiredPermissionsOfSubjectIds('view', ARRAY[findRbacUserId('mike@hostsharing.net')]);
|
||||
end transaction;
|
||||
|
||||
---
|
||||
|
||||
abort;
|
||||
set local session authorization default;
|
||||
CREATE OR REPLACE FUNCTION queryAllPermissionsOfSubjectIds(subjectIds uuid[])
|
||||
RETURNS SETOF RbacPermission
|
||||
STRICT
|
||||
LANGUAGE sql AS $$
|
||||
SELECT DISTINCT * FROM RbacPermission WHERE uuid IN (
|
||||
WITH RECURSIVE grants AS (
|
||||
SELECT DISTINCT
|
||||
descendantUuid,
|
||||
ascendantUuid
|
||||
FROM RbacGrants
|
||||
WHERE
|
||||
ascendantUuid = ANY(subjectIds)
|
||||
UNION ALL
|
||||
SELECT
|
||||
"grant".descendantUuid,
|
||||
"grant".ascendantUuid
|
||||
FROM RbacGrants "grant"
|
||||
INNER JOIN grants recur ON recur.descendantUuid = "grant".ascendantUuid
|
||||
) SELECT
|
||||
descendantUuid
|
||||
FROM grants
|
||||
);
|
||||
$$;
|
||||
|
||||
abort;
|
||||
set local session authorization restricted;
|
||||
begin transaction;
|
||||
set local statement_timeout TO '5s';
|
||||
select count(*) from queryAllPermissionsOfSubjectIds(ARRAY[findRbacUserId('mike@hostsharing.net')]);
|
||||
end transaction;
|
||||
|
||||
---
|
||||
/*
|
||||
CREATE OR REPLACE FUNCTION queryAllPermissionsOfSubjectId(subjectId uuid) -- TODO: remove?
|
||||
RETURNS SETOF RbacPermission
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE sql AS $$
|
||||
SELECT * FROM RbacPermission WHERE uuid IN (
|
||||
WITH RECURSIVE grants AS (
|
||||
SELECT
|
||||
descendantUuid,
|
||||
ascendantUuid
|
||||
FROM
|
||||
RbacGrants
|
||||
WHERE
|
||||
ascendantUuid = subjectId
|
||||
UNION ALL
|
||||
SELECT
|
||||
"grant".descendantUuid,
|
||||
"grant".ascendantUuid
|
||||
FROM RbacGrants "grant"
|
||||
INNER JOIN grants recur ON recur.descendantUuid = "grant".ascendantUuid
|
||||
) SELECT
|
||||
descendantUuid
|
||||
FROM
|
||||
grants
|
||||
);
|
||||
$$;*/
|
||||
|
||||
---
|
||||
|
||||
CREATE OR REPLACE FUNCTION queryAllRbacUsersWithPermissionsFor(objectId uuid)
|
||||
RETURNS SETOF RbacUser
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE sql AS $$
|
||||
SELECT * FROM RbacUser WHERE uuid IN (
|
||||
WITH RECURSIVE grants AS (
|
||||
SELECT
|
||||
descendantUuid,
|
||||
ascendantUuid
|
||||
FROM
|
||||
RbacGrants
|
||||
WHERE
|
||||
descendantUuid = objectId
|
||||
UNION ALL
|
||||
SELECT
|
||||
"grant".descendantUuid,
|
||||
"grant".ascendantUuid
|
||||
FROM
|
||||
RbacGrants "grant"
|
||||
INNER JOIN grants recur ON recur.ascendantUuid = "grant".descendantUuid
|
||||
) SELECT
|
||||
ascendantUuid
|
||||
FROM
|
||||
grants
|
||||
);
|
||||
$$;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION findGrantees(grantedId uuid)
|
||||
RETURNS SETOF RbacReference
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE sql AS $$
|
||||
SELECT reference.*
|
||||
FROM (
|
||||
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
|
||||
) as grantee
|
||||
JOIN RbacReference reference ON reference.uuid=grantee.ascendantUuid;
|
||||
$$;
|
||||
|
||||
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"
|
||||
INNER JOIN grants recur ON recur.ascendantUuid = "grant".descendantUuid
|
||||
) SELECT
|
||||
ascendantUuid
|
||||
FROM
|
||||
grants
|
||||
);
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION isPermissionGrantedToSubject(permissionId uuid, subjectId uuid)
|
||||
RETURNS BOOL
|
||||
STABLE LEAKPROOF
|
||||
LANGUAGE sql AS $$
|
||||
SELECT EXISTS (
|
||||
SELECT * FROM RbacUser WHERE uuid IN (
|
||||
WITH RECURSIVE grants AS (
|
||||
SELECT
|
||||
descendantUuid,
|
||||
ascendantUuid
|
||||
FROM
|
||||
RbacGrants g
|
||||
WHERE
|
||||
g.descendantUuid = permissionId
|
||||
UNION ALL
|
||||
SELECT
|
||||
g.descendantUuid,
|
||||
g.ascendantUuid
|
||||
FROM
|
||||
RbacGrants g
|
||||
INNER JOIN grants recur ON recur.ascendantUuid = g.descendantUuid
|
||||
) SELECT
|
||||
ascendantUuid
|
||||
FROM
|
||||
grants
|
||||
WHERE ascendantUuid=subjectId
|
||||
)
|
||||
);
|
||||
$$;
|
||||
|
||||
-- ========================================================
|
||||
-- current user + assumed roles
|
||||
-- --------------------------------------------------------
|
||||
|
||||
CREATE OR REPLACE FUNCTION currentUser()
|
||||
RETURNS varchar(63)
|
||||
STABLE LEAKPROOF
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
currentUser VARCHAR(63);
|
||||
BEGIN
|
||||
BEGIN
|
||||
currentUser := current_setting('hsadminng.currentUser');
|
||||
EXCEPTION WHEN OTHERS THEN
|
||||
currentUser := NULL;
|
||||
END;
|
||||
IF (currentUser IS NULL OR currentUser = '') THEN
|
||||
RAISE EXCEPTION 'hsadminng.currentUser must be defined, please use "SET LOCAL ...;"';
|
||||
END IF;
|
||||
RETURN currentUser;
|
||||
END; $$;
|
||||
|
||||
SET SESSION AUTHORIZATION DEFAULT;
|
||||
CREATE OR REPLACE FUNCTION currentUserId()
|
||||
RETURNS uuid
|
||||
STABLE LEAKPROOF
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
currentUser VARCHAR(63);
|
||||
currentUserId uuid;
|
||||
BEGIN
|
||||
currentUser := currentUser();
|
||||
currentUserId = (SELECT uuid FROM RbacUser WHERE name = currentUser);
|
||||
RETURN currentUserId;
|
||||
END; $$;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION assumedRoles()
|
||||
RETURNS varchar(63)[]
|
||||
STABLE LEAKPROOF
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
currentSubject VARCHAR(63);
|
||||
BEGIN
|
||||
BEGIN
|
||||
currentSubject := current_setting('hsadminng.assumedRoles');
|
||||
EXCEPTION WHEN OTHERS THEN
|
||||
RETURN ARRAY[]::varchar[];
|
||||
END;
|
||||
IF (currentSubject = '') THEN
|
||||
RETURN ARRAY[]::varchar[];
|
||||
END IF;
|
||||
RETURN string_to_array(currentSubject, ';');
|
||||
END; $$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION findUuidByIdName(objectTable varchar, objectIdName varchar)
|
||||
RETURNS uuid
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
|
||||
BEGIN
|
||||
/*sql = 'E ' || baseTable || '_historicize' ||
|
||||
' AFTER INSERT OR DELETE OR UPDATE ON ' || baseTable ||
|
||||
' FOR EACH ROW EXECUTE PROCEDURE historicize()';
|
||||
RAISE NOTICE 'sql: %', createTriggerSQL;
|
||||
EXECUTE createTriggerSQ*/
|
||||
|
||||
RETURN customerUuidByIdName(objectIdName);
|
||||
END; $$;
|
||||
|
||||
ROLLBACK;
|
||||
SET SESSION AUTHORIZATION DEFAULT;
|
||||
CREATE OR REPLACE FUNCTION currentSubjectIds()
|
||||
RETURNS uuid[]
|
||||
STABLE LEAKPROOF
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
currentUserId uuid;
|
||||
roleNames VARCHAR(63)[];
|
||||
roleName VARCHAR(63);
|
||||
objectTableToAssume VARCHAR(63);
|
||||
objectNameToAssume VARCHAR(63);
|
||||
objectUuidToAssume uuid;
|
||||
roleTypeToAssume RbacRoleType;
|
||||
roleIdsToAssume uuid[];
|
||||
roleUuidToAssume uuid;
|
||||
BEGIN
|
||||
currentUserId := currentUserId();
|
||||
roleNames := assumedRoles();
|
||||
IF ( CARDINALITY(roleNames) = 0 ) THEN
|
||||
RETURN ARRAY[currentUserId];
|
||||
END IF;
|
||||
|
||||
RAISE NOTICE 'assuming roles: %', roleNames;
|
||||
|
||||
FOREACH roleName IN ARRAY roleNames LOOP
|
||||
roleName = overlay(roleName placing '#' from length(roleName) + 1 - strpos(reverse(roleName), '.'));
|
||||
objectTableToAssume = split_part(roleName, '#', 1);
|
||||
objectNameToAssume = split_part(roleName, '#', 2);
|
||||
roleTypeToAssume = split_part(roleName, '#', 3);
|
||||
|
||||
objectUuidToAssume = findUuidByIdName(objectTableToAssume, objectNameToAssume);
|
||||
|
||||
-- TODO: either the result needs to be cached at least per transaction or we need to get rid of SELCT in a loop
|
||||
SELECT uuid AS roleuuidToAssume
|
||||
FROM RbacRole r
|
||||
WHERE r.objectUuid=objectUuidToAssume AND r.roleType=roleTypeToAssume INTO roleUuidToAssume;
|
||||
IF ( NOT isGranted(currentUserId, roleUuidToAssume) ) THEN
|
||||
RAISE EXCEPTION 'user % has no permission to assume role %', currentUser(), roleUuidToAssume;
|
||||
END IF;
|
||||
roleIdsToAssume := roleIdsToAssume || roleUuidToAssume;
|
||||
END LOOP;
|
||||
|
||||
RETURN roleIdsToAssume;
|
||||
END; $$;
|
@ -1,198 +0,0 @@
|
||||
|
||||
|
||||
-- ========================================================
|
||||
-- Role-Hierarcy helper functions
|
||||
-- --------------------------------------------------------
|
||||
|
||||
-- PERMISSIONS --------------------------------------------
|
||||
|
||||
-- drop type RbacPermissions;
|
||||
CREATE TYPE RbacPermissions AS
|
||||
(
|
||||
permissionUuids uuid[]
|
||||
);
|
||||
|
||||
CREATE OR REPLACE FUNCTION grantingPermissions(forObjectUuid uuid, permitOps RbacOp[])
|
||||
RETURNS RbacPermissions
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
BEGIN
|
||||
RETURN ROW(createPermissions(forObjectUuid, permitOps))::RbacPermissions;
|
||||
END; $$;
|
||||
|
||||
-- SUPER ROLES --------------------------------------------
|
||||
|
||||
-- drop type RbacSuperRoles;
|
||||
CREATE TYPE RbacSuperRoles AS
|
||||
(
|
||||
roleUuids uuid[]
|
||||
);
|
||||
|
||||
-- drop function beneathRoles(roleDescriptors RbacRoleDescriptor[])
|
||||
CREATE OR REPLACE FUNCTION beneathRoles(roleDescriptors RbacRoleDescriptor[])
|
||||
RETURNS RbacSuperRoles
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
DECLARE
|
||||
superRoleDescriptor RbacRoleDescriptor;
|
||||
superRoleUuids uuid[] := ARRAY[]::uuid[];
|
||||
BEGIN
|
||||
FOREACH superRoleDescriptor IN ARRAY roleDescriptors LOOP
|
||||
superRoleUuids := superRoleUuids || getRoleId(superRoleDescriptor, 'fail');
|
||||
END LOOP;
|
||||
|
||||
RETURN ROW(superRoleUuids)::RbacSuperRoles;
|
||||
END; $$;
|
||||
|
||||
-- drop function beneathRole(roleDescriptor RbacRoleDescriptor)
|
||||
CREATE OR REPLACE FUNCTION beneathRole(roleDescriptor RbacRoleDescriptor)
|
||||
RETURNS RbacSuperRoles
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
BEGIN
|
||||
RETURN beneathRoles(ARRAY[roleDescriptor]);
|
||||
END; $$;
|
||||
|
||||
-- drop function beneathRole(roleUuid uuid);
|
||||
CREATE OR REPLACE FUNCTION beneathRole(roleUuid uuid)
|
||||
RETURNS RbacSuperRoles
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
BEGIN
|
||||
RETURN ROW(ARRAY[roleUuid]::uuid[])::RbacSuperRoles;
|
||||
END; $$;
|
||||
|
||||
-- drop function asTopLevelRole(roleName varchar);
|
||||
CREATE OR REPLACE FUNCTION asTopLevelRole()
|
||||
RETURNS RbacSuperRoles
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
BEGIN
|
||||
RETURN ROW(ARRAY[]::uuid[])::RbacSuperRoles;
|
||||
END; $$;
|
||||
|
||||
-- SUB ROLES ----------------------------------------------
|
||||
|
||||
CREATE TYPE RbacSubRoles AS
|
||||
(
|
||||
roleUuids uuid[]
|
||||
);
|
||||
|
||||
-- drop FUNCTION beingItselfA(roleUuid uuid)
|
||||
CREATE OR REPLACE FUNCTION beingItselfA(roleUuid uuid)
|
||||
RETURNS RbacSubRoles
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
BEGIN
|
||||
RETURN ROW(ARRAY[roleUuid]::uuid[])::RbacSubRoles;
|
||||
END; $$;
|
||||
|
||||
-- drop FUNCTION beingItselfA(roleDescriptor RbacRoleDescriptor)
|
||||
CREATE OR REPLACE FUNCTION beingItselfA(roleDescriptor RbacRoleDescriptor)
|
||||
RETURNS RbacSubRoles
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
BEGIN
|
||||
RETURN beingItselfA(getRoleId(roleDescriptor, 'fail'));
|
||||
END; $$;
|
||||
|
||||
-- USERS --------------------------------------------------
|
||||
|
||||
-- drop type RbacUsers;
|
||||
CREATE TYPE RbacUsers AS
|
||||
(
|
||||
userUuids uuid[]
|
||||
);
|
||||
|
||||
-- drop function withUsers(userNames varchar);
|
||||
CREATE OR REPLACE FUNCTION withUsers(userNames varchar[])
|
||||
RETURNS RbacUsers
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
DECLARE
|
||||
userName varchar;
|
||||
userUuids uuid[] := ARRAY[]::uuid[];
|
||||
BEGIN
|
||||
FOREACH userName IN ARRAY userNames LOOP
|
||||
userUuids := userUuids || getRbacUserId(userName, 'fail');
|
||||
END LOOP;
|
||||
|
||||
RETURN ROW(userUuids)::RbacUsers;
|
||||
END; $$;
|
||||
|
||||
|
||||
-- DROP FUNCTION withUser(userName varchar, whenNotExists RbacWhenNotExists);
|
||||
CREATE OR REPLACE FUNCTION withUser(userName varchar, whenNotExists RbacWhenNotExists = 'fail')
|
||||
RETURNS RbacUsers
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE plpgsql AS $$
|
||||
BEGIN
|
||||
RETURN ROW(ARRAY[getRbacUserId(userName, whenNotExists )]);
|
||||
END; $$;
|
||||
|
||||
-- ROLE NAME BUILDER --------------------------------------
|
||||
|
||||
|
||||
-- CREATE ROLE MAIN FUNCTION ------------------------------
|
||||
|
||||
CREATE OR REPLACE FUNCTION createRole(
|
||||
roleDescriptor RbacRoleDescriptor,
|
||||
permissions RbacPermissions,
|
||||
superRoles RbacSuperRoles,
|
||||
subRoles RbacSubRoles = null,
|
||||
users RbacUsers = null
|
||||
)
|
||||
RETURNS uuid
|
||||
CALLED ON NULL INPUT
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
roleUuid uuid;
|
||||
superRoleUuid uuid;
|
||||
subRoleUuid uuid;
|
||||
userUuid uuid;
|
||||
BEGIN
|
||||
RAISE NOTICE 'will createRole for %', roleDescriptor;
|
||||
RAISE NOTICE 'will createRole for % % %', roleDescriptor.objecttable, roleDescriptor.objectuuid, roleDescriptor.roletype;
|
||||
roleUuid = createRole(roleDescriptor);
|
||||
|
||||
call grantPermissionsToRole(roleUuid, permissions.permissionUuids);
|
||||
|
||||
IF superRoles IS NOT NULL THEN
|
||||
FOREACH superRoleUuid IN ARRAY superRoles.roleuUids LOOP
|
||||
call grantRoleToRole(roleUuid, superRoleUuid);
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
IF subRoles IS NOT NULL THEN
|
||||
FOREACH subRoleUuid IN ARRAY subRoles.roleuUids LOOP
|
||||
call grantRoleToRole(subRoleUuid, roleUuid);
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
IF users IS NOT NULL THEN
|
||||
FOREACH userUuid IN ARRAY users.useruUids LOOP
|
||||
call grantRoleToUser(roleUuid, userUuid);
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
RETURN roleUuid;
|
||||
END; $$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION createRole(
|
||||
roleDescriptor RbacRoleDescriptor,
|
||||
permissions RbacPermissions,
|
||||
users RbacUsers = null
|
||||
)
|
||||
RETURNS uuid
|
||||
CALLED ON NULL INPUT
|
||||
LANGUAGE plpgsql AS $$
|
||||
BEGIN
|
||||
RETURN createRole(roleDescriptor, permissions, null, null, users);
|
||||
END; $$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION createRole(
|
||||
roleDescriptor RbacRoleDescriptor,
|
||||
permissions RbacPermissions,
|
||||
subRoles RbacSubRoles,
|
||||
users RbacUsers = null
|
||||
)
|
||||
RETURNS uuid
|
||||
CALLED ON NULL INPUT
|
||||
LANGUAGE plpgsql AS $$
|
||||
BEGIN
|
||||
RETURN createRole(roleDescriptor, permissions, null, subRoles, users);
|
||||
END; $$;
|
||||
|
||||
|
@ -1,18 +0,0 @@
|
||||
|
||||
DROP VIEW IF EXISTS "RbacStatisticsV";
|
||||
CREATE VIEW "RbacStatisticsV" AS
|
||||
SELECT no, to_char("count", '9 999 999 999') as "count", "table"
|
||||
FROM (
|
||||
select 1 as no, count(*) as "count", 'login users' as "table" from RbacUser
|
||||
UNION
|
||||
select 2 as no, count(*) as "count", 'roles' as "table" from RbacRole
|
||||
UNION
|
||||
select 3 as no, count(*) as "count", 'permissions' as "table" from RbacPermission
|
||||
UNION
|
||||
select 4 as no, count(*) as "count", 'references' as "table" from RbacReference
|
||||
UNION
|
||||
select 5 as no, count(*) as "count", 'grants' as "table" from RbacGrants
|
||||
UNION
|
||||
select 6 as no, count(*) as "count", 'objects' as "table" from RbacObject
|
||||
) as totals
|
||||
ORDER BY totals.no;
|
@ -1,38 +0,0 @@
|
||||
|
||||
|
||||
|
||||
CREATE TABLE Hostsharing
|
||||
(
|
||||
uuid uuid PRIMARY KEY REFERENCES RbacObject(uuid)
|
||||
);
|
||||
CREATE UNIQUE INDEX Hostsharing_Singleton ON Hostsharing ((0));
|
||||
|
||||
|
||||
INSERT INTO RbacObject (objecttable) VALUES ('hostsharing');
|
||||
INSERT INTO Hostsharing (uuid) VALUES ((SELECT uuid FROM RbacObject WHERE objectTable='hostsharing'));
|
||||
|
||||
CREATE OR REPLACE FUNCTION hostsharingAdmin()
|
||||
RETURNS RbacRoleDescriptor
|
||||
RETURNS NULL ON NULL INPUT
|
||||
STABLE LEAKPROOF
|
||||
LANGUAGE sql AS $$
|
||||
SELECT 'global', (SELECT uuid FROM RbacObject WHERE objectTable='hostsharing'), 'admin'::RbacRoleType;
|
||||
$$;
|
||||
|
||||
-- create administrators role with two assigned users
|
||||
do language plpgsql $$
|
||||
declare
|
||||
admins uuid ;
|
||||
begin
|
||||
admins = createRole(hostsharingAdmin());
|
||||
call grantRoleToUser(admins, createRbacUser('mike@hostsharing.net'));
|
||||
call grantRoleToUser(admins, createRbacUser('sven@hostsharing.net'));
|
||||
commit;
|
||||
end;
|
||||
$$;
|
||||
|
||||
|
||||
BEGIN TRANSACTION;
|
||||
SET LOCAL hsadminng.currentUser = 'mike@hostsharing.net';
|
||||
select * from RbacUser where uuid=currentUserId();
|
||||
END TRANSACTION;
|
@ -1,169 +0,0 @@
|
||||
|
||||
-- ========================================================
|
||||
-- Customer example with RBAC
|
||||
-- --------------------------------------------------------
|
||||
|
||||
SET SESSION SESSION AUTHORIZATION DEFAULT ;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS customer (
|
||||
uuid uuid UNIQUE REFERENCES RbacObject(uuid),
|
||||
reference int not null unique CHECK (reference BETWEEN 10000 AND 99999),
|
||||
prefix character(3) unique,
|
||||
adminUserName varchar(63)
|
||||
);
|
||||
|
||||
DROP TRIGGER IF EXISTS createRbacObjectForCustomer_Trigger ON customer;
|
||||
CREATE TRIGGER createRbacObjectForCustomer_Trigger
|
||||
BEFORE INSERT ON customer
|
||||
FOR EACH ROW EXECUTE PROCEDURE createRbacObject();
|
||||
|
||||
CREATE OR REPLACE FUNCTION customerOwner(customer customer)
|
||||
RETURNS RbacRoleDescriptor
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
begin
|
||||
return roleDescriptor('customer', customer.uuid, 'owner');
|
||||
end; $$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION customerAdmin(customer customer)
|
||||
RETURNS RbacRoleDescriptor
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
begin
|
||||
return roleDescriptor('customer', customer.uuid, 'admin');
|
||||
end; $$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION customerTenant(customer customer)
|
||||
RETURNS RbacRoleDescriptor
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
begin
|
||||
return roleDescriptor('customer', customer.uuid, 'tenant');
|
||||
end; $$;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION createRbacRulesForCustomer()
|
||||
RETURNS trigger
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
DECLARE
|
||||
customerOwnerUuid uuid;
|
||||
customerAdminUuid uuid;
|
||||
BEGIN
|
||||
IF TG_OP <> 'INSERT' THEN
|
||||
RAISE EXCEPTION 'invalid usage of TRIGGER AFTER INSERT';
|
||||
END IF;
|
||||
|
||||
-- the owner role with full access for Hostsharing administrators
|
||||
customerOwnerUuid = createRole(
|
||||
customerOwner(NEW),
|
||||
grantingPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*']),
|
||||
beneathRole(hostsharingAdmin())
|
||||
);
|
||||
|
||||
-- the admin role for the customer's admins, who can view and add products
|
||||
customerAdminUuid = createRole(
|
||||
customerAdmin(NEW),
|
||||
grantingPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['view', 'add-package']),
|
||||
-- NO auto follow for customer owner to avoid exploding permissions for administrators
|
||||
withUser(NEW.adminUserName, 'create') -- implicitly ignored if null
|
||||
);
|
||||
|
||||
-- allow the customer owner role (thus administrators) to assume the customer admin role
|
||||
call grantRoleToRole(customerAdminUuid, customerOwnerUuid, FALSE);
|
||||
|
||||
-- the tenant role which later can be used by owners+admins of sub-objects
|
||||
perform createRole(
|
||||
customerTenant(NEW),
|
||||
grantingPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['view'])
|
||||
);
|
||||
|
||||
RETURN NEW;
|
||||
END; $$;
|
||||
|
||||
DROP TRIGGER IF EXISTS createRbacRulesForCustomer_Trigger ON customer;
|
||||
CREATE TRIGGER createRbacRulesForCustomer_Trigger
|
||||
AFTER INSERT ON customer
|
||||
FOR EACH ROW EXECUTE PROCEDURE createRbacRulesForCustomer();
|
||||
|
||||
CREATE OR REPLACE FUNCTION deleteRbacRulesForCustomer()
|
||||
RETURNS trigger
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
DECLARE
|
||||
objectTable varchar = 'customer';
|
||||
BEGIN
|
||||
IF TG_OP = 'DELETE' THEN
|
||||
|
||||
-- delete the owner role (for admininstrators)
|
||||
call deleteRole(findRoleId(objectTable||'#'||NEW.prefix||'.owner'));
|
||||
|
||||
-- delete the customer admin role
|
||||
call deleteRole(findRoleId(objectTable||'#'||NEW.prefix||'.admin'));
|
||||
ELSE
|
||||
RAISE EXCEPTION 'invalid usage of TRIGGER BEFORE DELETE';
|
||||
END IF;
|
||||
END; $$;
|
||||
|
||||
DROP TRIGGER IF EXISTS deleteRbacRulesForCustomer_Trigger ON customer;
|
||||
CREATE TRIGGER deleteRbacRulesForCustomer_Trigger
|
||||
BEFORE DELETE ON customer
|
||||
FOR EACH ROW EXECUTE PROCEDURE deleteRbacRulesForCustomer();
|
||||
|
||||
-- create a restricted view to access the textual customer ids a idName
|
||||
SET SESSION SESSION AUTHORIZATION DEFAULT;
|
||||
-- ALTER TABLE customer ENABLE ROW LEVEL SECURITY;
|
||||
DROP VIEW IF EXISTS customer_iv;
|
||||
CREATE OR REPLACE VIEW customer_iv AS
|
||||
SELECT DISTINCT target.uuid, target.prefix as idName
|
||||
FROM customer AS target;
|
||||
-- TODO: Is it ok that everybody has access to this information?
|
||||
GRANT ALL PRIVILEGES ON customer_iv TO restricted;
|
||||
|
||||
CREATE OR REPLACE FUNCTION customerUuidByIdName(idName varchar)
|
||||
RETURNS uuid
|
||||
LANGUAGE sql STRICT AS $$
|
||||
SELECT uuid FROM customer_iv iv WHERE iv.idName=customerUuidByIdName.idName;
|
||||
$$;
|
||||
|
||||
-- create RBAC restricted view
|
||||
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 queryAccessibleObjectUuidsOfSubjectIds( 'view', 'customer', currentSubjectIds()));
|
||||
GRANT ALL PRIVILEGES ON customer_rv TO restricted;
|
||||
|
||||
|
||||
-- generate Customer test data
|
||||
|
||||
SET SESSION SESSION AUTHORIZATION DEFAULT;
|
||||
DO LANGUAGE plpgsql $$
|
||||
DECLARE
|
||||
currentTask varchar;
|
||||
custReference integer;
|
||||
custRowId uuid;
|
||||
custPrefix varchar;
|
||||
custAdminName varchar;
|
||||
BEGIN
|
||||
SET hsadminng.currentUser TO '';
|
||||
|
||||
FOR t IN 0..9 LOOP
|
||||
currentTask = 'creating RBAC test customer #' || t;
|
||||
SET LOCAL hsadminng.currentUser TO 'mike@hostsharing.net';
|
||||
SET LOCAL hsadminng.assumedRoles = '';
|
||||
SET LOCAL hsadminng.currentTask TO currentTask;
|
||||
|
||||
-- When a new customer is created,
|
||||
custReference = 10000 + t;
|
||||
custRowId = uuid_generate_v4();
|
||||
custPrefix = intToVarChar(t, 3 );
|
||||
custAdminName = 'admin@' || custPrefix || '.example.com';
|
||||
|
||||
raise notice 'creating customer %:%', custReference, custPrefix;
|
||||
insert into customer (reference, prefix, adminUserName)
|
||||
VALUES (custReference, custPrefix, custAdminName);
|
||||
|
||||
COMMIT;
|
||||
|
||||
END LOOP;
|
||||
|
||||
END;
|
||||
$$;
|
@ -1,149 +0,0 @@
|
||||
|
||||
-- ========================================================
|
||||
-- Package example with RBAC
|
||||
-- --------------------------------------------------------
|
||||
|
||||
SET SESSION SESSION AUTHORIZATION DEFAULT ;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS package (
|
||||
uuid uuid UNIQUE REFERENCES RbacObject(uuid),
|
||||
name character varying(5),
|
||||
customerUuid uuid REFERENCES customer(uuid)
|
||||
);
|
||||
|
||||
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; $$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION packageAdmin(pac package)
|
||||
RETURNS RbacRoleDescriptor
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE plpgsql AS $$
|
||||
begin
|
||||
return roleDescriptor('package', pac.uuid, 'admin');
|
||||
end; $$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION packageTenant(pac package)
|
||||
RETURNS RbacRoleDescriptor
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE plpgsql AS $$
|
||||
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()
|
||||
RETURNS trigger
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
DECLARE
|
||||
parentCustomer customer;
|
||||
packageOwnerRoleUuid uuid;
|
||||
packageAdminRoleUuid uuid;
|
||||
BEGIN
|
||||
IF TG_OP <> 'INSERT' THEN
|
||||
RAISE EXCEPTION 'invalid usage of TRIGGER AFTER INSERT';
|
||||
END IF;
|
||||
|
||||
SELECT * FROM customer AS c WHERE c.uuid=NEW.customerUuid INTO parentCustomer;
|
||||
|
||||
-- an owner role is created and assigned to the customer's admin role
|
||||
packageOwnerRoleUuid = createRole(
|
||||
packageOwner(NEW),
|
||||
grantingPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*']),
|
||||
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']),
|
||||
beneathRole(packageOwnerRoleUuid)
|
||||
);
|
||||
|
||||
-- and a package tenant role is created and assigned to the package admin as well
|
||||
perform createRole(
|
||||
packageTenant(NEW),
|
||||
grantingPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY ['view']),
|
||||
beneathRole(packageAdminRoleUuid),
|
||||
beingItselfA(customerTenant(parentCustomer))
|
||||
);
|
||||
|
||||
RETURN NEW;
|
||||
END; $$;
|
||||
|
||||
DROP TRIGGER IF EXISTS createRbacRulesForPackage_Trigger ON package;
|
||||
CREATE TRIGGER createRbacRulesForPackage_Trigger
|
||||
AFTER INSERT ON package
|
||||
FOR EACH ROW EXECUTE PROCEDURE createRbacRulesForPackage();
|
||||
|
||||
CREATE OR REPLACE FUNCTION deleteRbacRulesForPackage()
|
||||
RETURNS trigger
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
BEGIN
|
||||
IF TG_OP = 'DELETE' THEN
|
||||
-- TODO
|
||||
ELSE
|
||||
RAISE EXCEPTION 'invalid usage of TRIGGER BEFORE DELETE';
|
||||
END IF;
|
||||
END; $$;
|
||||
|
||||
DROP TRIGGER IF EXISTS deleteRbacRulesForPackage_Trigger ON customer;
|
||||
CREATE TRIGGER deleteRbacRulesForPackage_Trigger
|
||||
BEFORE DELETE ON customer
|
||||
FOR EACH ROW EXECUTE PROCEDURE deleteRbacRulesForPackage();
|
||||
|
||||
-- create RBAC-restricted view
|
||||
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 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;
|
||||
$$;
|
||||
|
@ -1,152 +0,0 @@
|
||||
|
||||
-- ========================================================
|
||||
-- UnixUser example with RBAC
|
||||
-- --------------------------------------------------------
|
||||
|
||||
SET SESSION SESSION AUTHORIZATION DEFAULT ;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS UnixUser (
|
||||
uuid uuid UNIQUE REFERENCES RbacObject(uuid),
|
||||
name character varying(32),
|
||||
comment character varying(96),
|
||||
packageUuid uuid REFERENCES package(uuid)
|
||||
);
|
||||
|
||||
CREATE OR REPLACE FUNCTION unixUserOwner(uu UnixUser)
|
||||
RETURNS RbacRoleDescriptor
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE plpgsql AS $$
|
||||
begin
|
||||
return roleDescriptor('unixuser', uu.uuid, 'owner');
|
||||
end; $$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION unixUserAdmin(uu UnixUser)
|
||||
RETURNS RbacRoleDescriptor
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE plpgsql AS $$
|
||||
begin
|
||||
return roleDescriptor('unixuser', uu.uuid, 'admin');
|
||||
end; $$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION unixUserTenant(uu UnixUser)
|
||||
RETURNS RbacRoleDescriptor
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE plpgsql AS $$
|
||||
begin
|
||||
return roleDescriptor('unixuser', uu.uuid, 'tenant');
|
||||
end; $$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION createUnixUserTenantRoleIfNotExists(unixUser UnixUser)
|
||||
RETURNS uuid
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
unixUserTenantRoleDesc RbacRoleDescriptor;
|
||||
unixUserTenantRoleUuid uuid;
|
||||
BEGIN
|
||||
unixUserTenantRoleDesc = unixUserTenant(unixUser);
|
||||
unixUserTenantRoleUuid = findRoleId(unixUserTenantRoleDesc);
|
||||
IF unixUserTenantRoleUuid IS NOT NULL THEN
|
||||
RETURN unixUserTenantRoleUuid;
|
||||
END IF;
|
||||
|
||||
RETURN createRole(
|
||||
unixUserTenantRoleDesc,
|
||||
grantingPermissions(forObjectUuid => unixUser.uuid, permitOps => ARRAY['view']),
|
||||
beneathRole(unixUserAdmin(unixUser))
|
||||
);
|
||||
END; $$;
|
||||
|
||||
|
||||
DROP TRIGGER IF EXISTS createRbacObjectForUnixUser_Trigger ON UnixUser;
|
||||
CREATE TRIGGER createRbacObjectForUnixUser_Trigger
|
||||
BEFORE INSERT ON UnixUser
|
||||
FOR EACH ROW EXECUTE PROCEDURE createRbacObject();
|
||||
|
||||
CREATE OR REPLACE FUNCTION createRbacRulesForUnixUser()
|
||||
RETURNS trigger
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
DECLARE
|
||||
parentPackage package;
|
||||
unixuserOwnerRoleId uuid;
|
||||
unixuserAdminRoleId uuid;
|
||||
BEGIN
|
||||
IF TG_OP <> 'INSERT' THEN
|
||||
RAISE EXCEPTION 'invalid usage of TRIGGER AFTER INSERT';
|
||||
END IF;
|
||||
|
||||
SELECT * FROM package WHERE uuid=NEW.packageUuid into parentPackage;
|
||||
|
||||
-- an owner role is created and assigned to the package's admin group
|
||||
unixuserOwnerRoleId = createRole(
|
||||
unixUserOwner(NEW),
|
||||
grantingPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*']),
|
||||
beneathRole(packageAdmin(parentPackage))
|
||||
);
|
||||
|
||||
-- and a unixuser admin role is created and assigned to the unixuser owner as well
|
||||
unixuserAdminRoleId = createRole(
|
||||
unixUserAdmin(NEW),
|
||||
grantingPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['edit']),
|
||||
beneathRole(unixuserOwnerRoleId),
|
||||
beingItselfA(packageTenant(parentPackage))
|
||||
);
|
||||
|
||||
-- a tenent role is only created on demand
|
||||
|
||||
RETURN NEW;
|
||||
END; $$;
|
||||
|
||||
DROP TRIGGER IF EXISTS createRbacRulesForUnixUser_Trigger ON UnixUser;
|
||||
CREATE TRIGGER createRbacRulesForUnixUser_Trigger
|
||||
AFTER INSERT ON UnixUser
|
||||
FOR EACH ROW EXECUTE PROCEDURE createRbacRulesForUnixUser();
|
||||
|
||||
-- TODO: CREATE OR REPLACE FUNCTION deleteRbacRulesForUnixUser()
|
||||
|
||||
|
||||
-- create RBAC-restricted view
|
||||
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 queryAccessibleObjectUuidsOfSubjectIds( 'view', 'unixuser', currentSubjectIds()));
|
||||
GRANT ALL PRIVILEGES ON unixuser_rv TO restricted;
|
||||
|
||||
|
||||
-- generate UnixUser test data
|
||||
|
||||
DO LANGUAGE plpgsql $$
|
||||
DECLARE
|
||||
pac record;
|
||||
pacAdmin varchar;
|
||||
currentTask varchar;
|
||||
BEGIN
|
||||
SET hsadminng.currentUser TO '';
|
||||
|
||||
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;
|
||||
pacAdmin = 'admin@' || pac.name || '.example.com';
|
||||
SET LOCAL hsadminng.currentUser TO 'mike@hostsharing.net'; -- TODO: use a package-admin
|
||||
SET LOCAL hsadminng.assumedRoles = '';
|
||||
SET LOCAL hsadminng.currentTask TO currentTask;
|
||||
|
||||
INSERT INTO unixuser (name, packageUuid)
|
||||
VALUES (pac.name||'-'|| intToVarChar(t, 4), pac.uuid);
|
||||
|
||||
COMMIT;
|
||||
END LOOP;
|
||||
END LOOP;
|
||||
|
||||
END;
|
||||
$$;
|
@ -1,144 +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),
|
||||
unixUserUuid uuid REFERENCES unixuser(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 UnixUser;
|
||||
parentPackage package;
|
||||
domainOwnerRoleUuid uuid;
|
||||
domainAdminRoleUuid uuid;
|
||||
BEGIN
|
||||
IF TG_OP <> 'INSERT' THEN
|
||||
RAISE EXCEPTION 'invalid usage of TRIGGER AFTER INSERT';
|
||||
END IF;
|
||||
|
||||
SELECT * FROM UnixUser WHERE uuid=NEW.unixUserUuid into parentUser;
|
||||
SELECT * FROM Package WHERE uuid=parentUser.packageuuid into parentPackage;
|
||||
|
||||
-- a domain owner role is created and assigned to the unixuser's admin role
|
||||
domainOwnerRoleUuid = createRole(
|
||||
domainOwner(NEW),
|
||||
grantingPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*']),
|
||||
beneathRole(packageAdmin(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(createUnixUserTenantRoleIfNotExists(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();
|
||||
|
||||
-- TODO: CREATE OR REPLACE FUNCTION deleteRbacRulesForDomain()
|
||||
|
||||
|
||||
-- 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 DISTINCT target.*
|
||||
FROM Domain AS target
|
||||
WHERE target.uuid IN (SELECT queryAccessibleObjectUuidsOfSubjectIds( 'view', 'domain', currentSubjectIds()));
|
||||
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 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;
|
||||
RAISE NOTICE 'task: %', currentTask;
|
||||
|
||||
SELECT * FROM package WHERE uuid=uu.packageUuid INTO pac;
|
||||
pacAdmin = 'admin@' || pac.name || '.example.com';
|
||||
SET LOCAL hsadminng.currentUser TO pacAdmin;
|
||||
SET LOCAL hsadminng.assumedRoles = '';
|
||||
SET LOCAL hsadminng.currentTask TO currentTask;
|
||||
|
||||
INSERT INTO Domain (name, unixUserUuid)
|
||||
VALUES ('dom-' || t || '.' || uu.name || '.example.org' , uu.uuid);
|
||||
|
||||
COMMIT;
|
||||
END LOOP;
|
||||
END IF;
|
||||
END LOOP;
|
||||
|
||||
END;
|
||||
$$;
|
||||
|
||||
|
@ -1,123 +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 unixuser u ON u.uuid = d.unixuseruuid
|
||||
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 unixuser 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();
|
||||
|
||||
-- TODO: CREATE OR REPLACE FUNCTION deleteRbacRulesForEMailAddress()
|
||||
|
||||
|
||||
-- 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 DISTINCT target.*
|
||||
FROM EMailAddress AS target
|
||||
WHERE target.uuid IN (SELECT queryAccessibleObjectUuidsOfSubjectIds( 'view', 'emailaddress', currentSubjectIds()));
|
||||
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 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;
|
||||
|
||||
pacAdmin = 'admin@' || dom.packageName || '.example.com';
|
||||
SET LOCAL hsadminng.currentUser TO pacAdmin;
|
||||
SET LOCAL hsadminng.assumedRoles = '';
|
||||
SET LOCAL hsadminng.currentTask TO currentTask;
|
||||
|
||||
INSERT INTO EMailAddress (localPart, domainUuid)
|
||||
VALUES ('local' || t, dom.uuid);
|
||||
|
||||
COMMIT;
|
||||
END LOOP;
|
||||
END LOOP;
|
||||
END;
|
||||
$$;
|
||||
|
||||
|
@ -1,6 +1,15 @@
|
||||
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;
|
||||
|
@ -1,26 +0,0 @@
|
||||
|
||||
-- ========================================================
|
||||
-- Some Business Table Statistics
|
||||
-- --------------------------------------------------------
|
||||
|
||||
DROP VIEW IF EXISTS "BusinessTableStatisticsV";
|
||||
CREATE VIEW "BusinessTableStatisticsV" AS
|
||||
SELECT no, to_char("count", '999 999 999') as "count", to_char("required", '999 999 999') as "required", to_char("count"::float/"required"::float, '990.999') as "factor", "table"
|
||||
FROM (select 1 as no, count(*) as "count", 7000 as "required", 'customers' as "table"
|
||||
from customer
|
||||
UNION
|
||||
select 2 as no, count(*) as "count", 15000 as "required", 'packages' as "table"
|
||||
from package
|
||||
UNION
|
||||
select 3 as no, count(*) as "count", 150000 as "required", 'unixuser' as "table"
|
||||
from unixuser
|
||||
UNION
|
||||
select 4 as no, count(*) as "count", 100000 as "required", 'domain' as "table"
|
||||
from domain
|
||||
UNION
|
||||
select 5 as no, count(*) as "count", 500000 as "required", 'emailaddress' as "table"
|
||||
from emailaddress
|
||||
) totals
|
||||
ORDER BY totals.no;
|
||||
|
||||
SELECT * FROM "BusinessTableStatisticsV";
|
Reference in New Issue
Block a user