removing JHipster
This commit is contained in:
38
sql/00-util.sql
Normal file
38
sql/00-util.sql
Normal file
@ -0,0 +1,38 @@
|
||||
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);
|
657
sql/10-rbac-base.sql
Normal file
657
sql/10-rbac-base.sql
Normal file
@ -0,0 +1,657 @@
|
||||
|
||||
-- ========================================================
|
||||
-- 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
|
||||
);
|
||||
|
||||
CREATE TABLE RbacRole
|
||||
(
|
||||
uuid uuid primary key references RbacReference (uuid) ON DELETE CASCADE,
|
||||
name varchar(63) not null unique
|
||||
);
|
||||
|
||||
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
|
||||
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]+$'
|
||||
);
|
||||
|
||||
DROP TABLE IF EXISTS RbacObject;
|
||||
CREATE TABLE RbacObject
|
||||
(
|
||||
uuid uuid UNIQUE DEFAULT uuid_generate_v4(),
|
||||
objectTable varchar(64) not null,
|
||||
unique (objectTable, uuid)
|
||||
);
|
||||
|
||||
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,
|
||||
op RbacOp not null,
|
||||
unique (objectUuid, op)
|
||||
);
|
||||
|
||||
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 findRbacUser(userName varchar) -- TODO: rename to ...Id
|
||||
RETURNS uuid
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE sql AS $$
|
||||
SELECT uuid FROM RbacUser WHERE name = userName
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION getRbacUserId(userName varchar, whenNotExists RbacWhenNotExists)
|
||||
RETURNS uuid
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
userUuid uuid;
|
||||
BEGIN
|
||||
userUuid = findRbacUser(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 OR REPLACE FUNCTION createRole(roleName varchar)
|
||||
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, name) VALUES (referenceId, roleName);
|
||||
IF (referenceId IS NULL) THEN
|
||||
RAISE EXCEPTION 'referenceId for roleName "%" is unexpectedly null', roleName;
|
||||
end if;
|
||||
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(roleName varchar)
|
||||
RETURNS uuid
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE sql AS $$
|
||||
SELECT uuid FROM RbacRole WHERE name = roleName
|
||||
$$;
|
||||
|
||||
CREATE TYPE RbacWhenNotExists AS ENUM ('fail', 'create');
|
||||
|
||||
CREATE OR REPLACE FUNCTION getRoleId(roleName varchar, whenNotExists RbacWhenNotExists)
|
||||
RETURNS uuid
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
roleUuid uuid;
|
||||
BEGIN
|
||||
roleUuid = findRoleId(roleName);
|
||||
IF ( roleUuid IS NULL ) THEN
|
||||
IF ( whenNotExists = 'fail') THEN
|
||||
RAISE EXCEPTION 'RbacRole with name="%" not found', roleName;
|
||||
END IF;
|
||||
IF ( whenNotExists = 'create') THEN
|
||||
roleUuid = createRole(roleName);
|
||||
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
|
||||
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
|
||||
INSERT INTO RbacReference ("type") VALUES ('RbacPermission') RETURNING uuid INTO refId;
|
||||
INSERT INTO RbacPermission (uuid, objectUuid, op) VALUES (refId, forObjectUuid, permitOps[i]);
|
||||
END IF;
|
||||
permissionIds = permissionIds || refId;
|
||||
END LOOP;
|
||||
return permissionIds;
|
||||
END;
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION findPermissionId(forObjectTable varchar, 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
|
||||
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
|
||||
-- , doapply bool = true -- assumeV1
|
||||
)
|
||||
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
|
||||
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,
|
||||
-- objectTable varchar, -- TODO: maybe another optimization? but test perforamance for joins!
|
||||
subjectIds uuid[],
|
||||
maxDepth integer = 8,
|
||||
maxObjects integer = 16000)
|
||||
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 ascendantUuid = ANY(subjectIds)
|
||||
UNION ALL
|
||||
SELECT "grant".descendantUuid, "grant".ascendantUuid, level + 1 AS level
|
||||
FROM RbacGrants "grant"
|
||||
INNER JOIN grants recur ON recur.descendantUuid = "grant".ascendantUuid
|
||||
WHERE level <= maxDepth
|
||||
) SELECT descendantUuid
|
||||
FROM grants
|
||||
-- LIMIT maxObjects+1
|
||||
) as granted
|
||||
JOIN RbacPermission perm ON granted.descendantUuid=perm.uuid AND perm.op IN ('*', requiredOp);
|
||||
|
||||
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',
|
||||
HINT = 'Please assume a sub-role and try again.';
|
||||
END IF;
|
||||
END;
|
||||
$$;
|
||||
|
||||
abort;
|
||||
set local session authorization restricted;
|
||||
begin transaction;
|
||||
set local statement_timeout TO '60s';
|
||||
select count(*)
|
||||
from queryAccessibleObjectUuidsOfSubjectIds('view', ARRAY[findRbacUser('mike@hostsharing.net')], 4, 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[findRbacUser('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[findRbacUser('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
|
||||
)
|
||||
);
|
||||
$$;
|
||||
|
||||
SET SESSION AUTHORIZATION DEFAULT;
|
||||
CREATE ROLE admin;
|
||||
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO admin;
|
||||
CREATE ROLE restricted;
|
||||
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO restricted;
|
||||
|
||||
|
||||
-- ========================================================
|
||||
-- Current User
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
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 NULL;
|
||||
END;
|
||||
IF (currentSubject = '') THEN
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
RETURN string_to_array(currentSubject, ';');
|
||||
END; $$;
|
||||
|
||||
|
||||
-- ROLLBACK;
|
||||
SET SESSION AUTHORIZATION DEFAULT;
|
||||
CREATE OR REPLACE FUNCTION currentSubjectIds()
|
||||
RETURNS uuid[]
|
||||
STABLE LEAKPROOF
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
assumedRoles VARCHAR(63)[];
|
||||
currentUserId uuid;
|
||||
assumedRoleIds uuid[];
|
||||
assumedRoleId uuid;
|
||||
BEGIN
|
||||
currentUserId := currentUserId();
|
||||
assumedRoles := assumedRoles();
|
||||
IF ( assumedRoles IS NULL ) THEN
|
||||
RETURN 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;
|
||||
RETURN assumedRoleIds;
|
||||
END; $$;
|
89
sql/11-rbac-view.sql
Normal file
89
sql/11-rbac-view.sql
Normal file
@ -0,0 +1,89 @@
|
||||
|
||||
-- ========================================================
|
||||
-- Options for SELECT under RBAC rules
|
||||
-- --------------------------------------------------------
|
||||
|
||||
-- access control via view policy and isPermissionGrantedToSubject - way too slow (33 s 617ms for 1 million rows)
|
||||
SET SESSION AUTHORIZATION DEFAULT;
|
||||
CREATE ROLE admin;
|
||||
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO admin;
|
||||
CREATE ROLE restricted;
|
||||
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO restricted;
|
||||
|
||||
SET SESSION AUTHORIZATION DEFAULT;
|
||||
ALTER TABLE customer DISABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE customer ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE customer FORCE ROW LEVEL SECURITY;
|
||||
DROP POLICY IF EXISTS customer_policy ON customer;
|
||||
CREATE POLICY customer_policy ON customer
|
||||
FOR SELECT
|
||||
TO restricted
|
||||
USING (
|
||||
-- id=1000
|
||||
isPermissionGrantedToSubject(findPermissionId('customer', id, 'view'), currentUserId())
|
||||
);
|
||||
|
||||
SET SESSION AUTHORIZATION restricted;
|
||||
SET hsadminng.currentUser TO 'alex@example.com';
|
||||
SELECT * from customer;
|
||||
|
||||
-- access control via view-rule and isPermissionGrantedToSubject - way too slow (35 s 580 ms for 1 million rows)
|
||||
SET SESSION SESSION AUTHORIZATION DEFAULT;
|
||||
DROP VIEW cust_view;
|
||||
CREATE VIEW cust_view AS
|
||||
SELECT * FROM customer;
|
||||
CREATE OR REPLACE RULE "_RETURN" AS
|
||||
ON SELECT TO cust_view
|
||||
DO INSTEAD
|
||||
SELECT * FROM customer WHERE isPermissionGrantedToSubject(findPermissionId('customer', id, 'view'), currentUserId());
|
||||
SELECT * from cust_view LIMIT 10;
|
||||
|
||||
select queryAllPermissionsOfSubjectId(findRbacUser('mike@hostsharing.net'));
|
||||
|
||||
-- access control via view-rule with join to recursive permissions - really fast (38ms for 1 million rows)
|
||||
SET SESSION SESSION AUTHORIZATION DEFAULT;
|
||||
ALTER TABLE customer ENABLE ROW LEVEL SECURITY;
|
||||
DROP VIEW IF EXISTS cust_view;
|
||||
CREATE OR REPLACE VIEW cust_view AS
|
||||
SELECT *
|
||||
FROM customer;
|
||||
CREATE OR REPLACE RULE "_RETURN" AS
|
||||
ON SELECT TO cust_view
|
||||
DO INSTEAD
|
||||
SELECT c.uuid, c.reference, c.prefix FROM customer AS c
|
||||
JOIN queryAllPermissionsOfSubjectId(currentUserId()) AS p
|
||||
ON p.objectTable='customer' AND p.objectUuid=c.uuid AND p.op in ('*', 'view');
|
||||
GRANT ALL PRIVILEGES ON cust_view TO restricted;
|
||||
|
||||
SET SESSION SESSION AUTHORIZATION restricted;
|
||||
SET hsadminng.currentUser TO 'alex@example.com';
|
||||
SELECT * from cust_view;
|
||||
|
||||
|
||||
-- access control via view with join to recursive permissions - really fast (38ms for 1 million rows)
|
||||
SET SESSION SESSION AUTHORIZATION DEFAULT;
|
||||
ALTER TABLE customer ENABLE ROW LEVEL SECURITY;
|
||||
DROP VIEW IF EXISTS cust_view;
|
||||
CREATE OR REPLACE VIEW cust_view AS
|
||||
SELECT c.uuid, c.reference, c.prefix
|
||||
FROM customer AS c
|
||||
JOIN queryAllPermissionsOfSubjectId(currentUserId()) AS p
|
||||
ON p.objectUuid=c.uuid AND p.op in ('*', 'view');
|
||||
GRANT ALL PRIVILEGES ON cust_view TO restricted;
|
||||
|
||||
SET SESSION SESSION AUTHORIZATION restricted;
|
||||
-- SET hsadminng.currentUser TO 'alex@example.com';
|
||||
SET hsadminng.currentUser TO 'mike@hostsharing.net';
|
||||
-- SET hsadminng.currentUser TO 'aaaaouq@example.com';
|
||||
SELECT * from cust_view where reference=1144150;
|
||||
|
||||
select rr.uuid, rr.type from RbacGrants g
|
||||
join RbacReference RR on g.ascendantUuid = RR.uuid
|
||||
where g.descendantUuid in (
|
||||
select uuid from queryAllPermissionsOfSubjectId(findRbacUser('alex@example.com'))
|
||||
where objectTable='customer' and op in ('*', 'view'));
|
||||
|
||||
call grantRoleToUser(findRoleId('customer#aaa.admin'), findRbacUser('aaaaouq@example.com'));
|
||||
|
||||
select queryAllPermissionsOfSubjectId(findRbacUser('aaaaouq@example.com'));
|
||||
|
50
sql/19-rbac-tests.sql
Normal file
50
sql/19-rbac-tests.sql
Normal file
@ -0,0 +1,50 @@
|
||||
-- ========================================================
|
||||
-- Some Tests
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
select isGranted(findRoleId('administrators'), findRoleId('package#aaa00.owner'));
|
||||
select isGranted(findRoleId('package#aaa00.owner'), findRoleId('administrators'));
|
||||
-- call grantRoleToRole(findRoleId('package#aaa00.owner'), findRoleId('administrators'));
|
||||
-- call grantRoleToRole(findRoleId('administrators'), findRoleId('package#aaa00.owner'));
|
||||
|
||||
select count(*)
|
||||
FROM queryAllPermissionsOfSubjectIdForObjectUuids(findRbacUser('sven@hostsharing.net'),
|
||||
ARRAY(select uuid from customer where reference < 1100000));
|
||||
select count(*)
|
||||
FROM queryAllPermissionsOfSubjectId(findRbacUser('sven@hostsharing.net'));
|
||||
select *
|
||||
FROM queryAllPermissionsOfSubjectId(findRbacUser('alex@example.com'));
|
||||
select *
|
||||
FROM queryAllPermissionsOfSubjectId(findRbacUser('rosa@example.com'));
|
||||
|
||||
select *
|
||||
FROM queryAllRbacUsersWithPermissionsFor(findPermissionId('customer',
|
||||
(SELECT uuid FROM RbacObject WHERE objectTable = 'customer' LIMIT 1),
|
||||
'add-package'));
|
||||
select *
|
||||
FROM queryAllRbacUsersWithPermissionsFor(findPermissionId('package',
|
||||
(SELECT uuid FROM RbacObject WHERE objectTable = 'package' LIMIT 1),
|
||||
'delete'));
|
||||
|
||||
DO LANGUAGE plpgsql
|
||||
$$
|
||||
DECLARE
|
||||
userId uuid;
|
||||
result bool;
|
||||
BEGIN
|
||||
userId = findRbacUser('mike@hostsharing.net');
|
||||
result = (SELECT * FROM isPermissionGrantedToSubject(findPermissionId('package', 94928, 'add-package'), userId));
|
||||
IF (result) THEN
|
||||
RAISE EXCEPTION 'expected permission NOT to be granted, but it is';
|
||||
end if;
|
||||
|
||||
result = (SELECT * FROM isPermissionGrantedToSubject(findPermissionId('package', 94928, 'view'), userId));
|
||||
IF (NOT result) THEN
|
||||
RAISE EXCEPTION 'expected permission to be granted, but it is NOT';
|
||||
end if;
|
||||
|
||||
RAISE LOG 'isPermissionGrantedToSubjectId test passed';
|
||||
END;
|
||||
$$;
|
||||
|
18
sql/20-hs-base.sql
Normal file
18
sql/20-hs-base.sql
Normal file
@ -0,0 +1,18 @@
|
||||
|
||||
-- create administrators role with two assigned users
|
||||
do language plpgsql $$
|
||||
declare
|
||||
admins uuid ;
|
||||
begin
|
||||
admins = createRole('administrators');
|
||||
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;
|
134
sql/21-hs-customer.sql
Normal file
134
sql/21-hs-customer.sql
Normal file
@ -0,0 +1,134 @@
|
||||
|
||||
-- ========================================================
|
||||
-- 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 createRbacRulesForCustomer()
|
||||
RETURNS trigger
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
DECLARE
|
||||
adminUserNameUuid uuid;
|
||||
customerOwnerRoleId uuid;
|
||||
customerAdminRoleId uuid;
|
||||
BEGIN
|
||||
IF TG_OP <> 'INSERT' THEN
|
||||
RAISE EXCEPTION 'invalid usage of TRIGGER AFTER INSERT';
|
||||
END IF;
|
||||
|
||||
-- an owner role is created and assigned to the administrators group
|
||||
customerOwnerRoleId = createRole('customer#'||NEW.prefix||'.owner');
|
||||
call grantRoleToRole(customerOwnerRoleId, getRoleId('administrators', 'create'));
|
||||
-- ... and permissions for all ops are assigned
|
||||
call grantPermissionsToRole(customerOwnerRoleId,
|
||||
createPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*']));
|
||||
|
||||
-- ... also a customer admin role is created and granted to the customer owner role
|
||||
customerAdminRoleId = createRole('customer#'||NEW.prefix||'.admin');
|
||||
call grantRoleToRole(customerAdminRoleId, customerOwnerRoleId);
|
||||
-- ... to which a permission with view and add- ops is assigned
|
||||
call grantPermissionsToRole(customerAdminRoleId,
|
||||
createPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['view', 'add-package']));
|
||||
-- if a admin user is given for the customer,
|
||||
IF (NEW.adminUserName IS NOT NULL) THEN
|
||||
-- ... the customer admin role is also assigned to the admin user of the customer
|
||||
adminUserNameUuid = findRoleId(NEW.adminUserName);
|
||||
IF ( adminUserNameUuid IS NULL ) THEN
|
||||
adminUserNameUuid = createRbacUser(NEW.adminUserName);
|
||||
END IF;
|
||||
call grantRoleToUser(customerAdminRoleId, adminUserNameUuid);
|
||||
END IF;
|
||||
|
||||
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 RBAC restricted view
|
||||
|
||||
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
|
||||
ON target.uuid = allowedObjId;
|
||||
GRANT ALL PRIVILEGES ON customer_rv TO restricted;
|
||||
|
||||
|
||||
-- generate Customer test data
|
||||
|
||||
DO LANGUAGE plpgsql $$
|
||||
DECLARE
|
||||
currentTask varchar;
|
||||
custReference integer;
|
||||
custRowId uuid;
|
||||
custPrefix varchar;
|
||||
custAdminName varchar;
|
||||
BEGIN
|
||||
SET hsadminng.currentUser TO '';
|
||||
|
||||
FOR t IN 0..9999 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;
|
||||
$$;
|
117
sql/22-hs-packages.sql
Normal file
117
sql/22-hs-packages.sql
Normal file
@ -0,0 +1,117 @@
|
||||
|
||||
-- ========================================================
|
||||
-- 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)
|
||||
);
|
||||
|
||||
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;
|
||||
packageOwnerRoleId uuid;
|
||||
packageTenantRoleId 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 group
|
||||
packageOwnerRoleId = createRole('package#'||NEW.name||'.owner');
|
||||
call grantRoleToRole(packageOwnerRoleId, getRoleId('customer#'||parentCustomer.prefix||'.admin', 'fail'));
|
||||
|
||||
-- ... and permissions for all ops are assigned
|
||||
call grantPermissionsToRole(packageOwnerRoleId,
|
||||
createPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*']));
|
||||
|
||||
-- ... also a package tenant role is created and assigned to the package owner as well
|
||||
packageTenantRoleId = createRole('package#'||NEW.name||'.tenant');
|
||||
call grantRoleToRole(packageTenantRoleId, packageOwnerRoleId);
|
||||
|
||||
-- ... to which a permission with view operation is assigned
|
||||
call grantPermissionsToRole(packageTenantRoleId,
|
||||
createPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['view']));
|
||||
|
||||
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
|
||||
JOIN queryAccessibleObjectUuidsOfSubjectIds( 'view', currentSubjectIds()) AS allowedObjId
|
||||
ON target.uuid = allowedObjId;
|
||||
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
|
||||
FOR t IN 0..9 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;
|
||||
$$;
|
||||
|
106
sql/23-hs-unixuser.sql
Normal file
106
sql/23-hs-unixuser.sql
Normal file
@ -0,0 +1,106 @@
|
||||
|
||||
-- ========================================================
|
||||
-- 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),
|
||||
packageUuid uuid REFERENCES package(uuid)
|
||||
);
|
||||
|
||||
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;
|
||||
unixuserTenantRoleId 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 owner group
|
||||
unixuserOwnerRoleId = createRole('unixuser#'||NEW.name||'.owner');
|
||||
call grantRoleToRole(unixuserOwnerRoleId, getRoleId('package#'||parentPackage.name||'.owner', 'fail'));
|
||||
-- ... and permissions for all ops are assigned
|
||||
call grantPermissionsToRole(unixuserOwnerRoleId,
|
||||
createPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*']));
|
||||
|
||||
-- ... also a unixuser admin role is created and assigned to the unixuser owner as well
|
||||
unixuserAdminRoleId = createRole('unixuser#'||NEW.name||'.admin');
|
||||
call grantRoleToRole(unixuserAdminRoleId, unixuserOwnerRoleId);
|
||||
-- ... to which a permission with view operation is assigned
|
||||
call grantPermissionsToRole(unixuserAdminRoleId,
|
||||
createPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['edit', 'add-domain']));
|
||||
|
||||
-- ... also a unixuser tenant role is created and assigned to the unixuser admin
|
||||
unixuserTenantRoleId = createRole('unixuser#'||NEW.name||'.tenant');
|
||||
call grantRoleToRole(unixuserTenantRoleId, unixuserAdminRoleId);
|
||||
-- ... to which a permission with view operation is assigned
|
||||
call grantPermissionsToRole(unixuserTenantRoleId,
|
||||
createPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['view']));
|
||||
|
||||
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
|
||||
JOIN queryAccessibleObjectUuidsOfSubjectIds( 'view', currentSubjectIds()) AS allowedObjId
|
||||
ON target.uuid = allowedObjId;
|
||||
GRANT ALL PRIVILEGES ON unixuser_rv TO restricted;
|
||||
|
||||
|
||||
-- generate UnixUser test data
|
||||
|
||||
DO LANGUAGE plpgsql $$
|
||||
DECLARE
|
||||
pac package;
|
||||
pacAdmin varchar;
|
||||
currentTask varchar;
|
||||
BEGIN
|
||||
SET hsadminng.currentUser TO '';
|
||||
|
||||
FOR pac IN (SELECT * FROM package) 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;
|
||||
$$;
|
98
sql/24-hs-domain.sql
Normal file
98
sql/24-hs-domain.sql
Normal file
@ -0,0 +1,98 @@
|
||||
|
||||
-- ========================================================
|
||||
-- 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 createRbacRulesForDomain()
|
||||
RETURNS trigger
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
DECLARE
|
||||
parentUser unixuser;
|
||||
domainOwnerRoleId 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;
|
||||
|
||||
-- an owner role is created and assigned to the unix user admin
|
||||
RAISE NOTICE 'creating domain owner role: %', 'domain#'||NEW.name||'.owner';
|
||||
domainOwnerRoleId = getRoleId('domain#'||NEW.name||'.owner', 'create');
|
||||
call grantRoleToRole(domainOwnerRoleId, getRoleId('unixuser#'||parentUser.name||'.admin', 'fail'));
|
||||
-- ... and permissions for all ops are assigned
|
||||
call grantPermissionsToRole(domainOwnerRoleId,
|
||||
createPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*']));
|
||||
|
||||
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
|
||||
JOIN queryAccessibleObjectUuidsOfSubjectIds( 'view', currentSubjectIds()) AS allowedObjId
|
||||
ON target.uuid = allowedObjId;
|
||||
GRANT ALL PRIVILEGES ON domain_rv TO restricted;
|
||||
|
||||
|
||||
-- generate Domain test data
|
||||
|
||||
DO LANGUAGE plpgsql $$
|
||||
DECLARE
|
||||
uu unixuser;
|
||||
pac package;
|
||||
pacAdmin varchar;
|
||||
currentTask varchar;
|
||||
BEGIN
|
||||
SET hsadminng.currentUser TO '';
|
||||
|
||||
FOR uu IN (SELECT * FROM unixuser) LOOP
|
||||
IF ( random() < 0.3 ) THEN
|
||||
FOR t IN 0..2 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 || '.' || pac.name || '.example.org' , uu.uuid);
|
||||
|
||||
COMMIT;
|
||||
END LOOP;
|
||||
END IF;
|
||||
END LOOP;
|
||||
|
||||
END;
|
||||
$$;
|
||||
|
||||
|
122
sql/25-hs-emailaddress.sql
Normal file
122
sql/25-hs-emailaddress.sql
Normal file
@ -0,0 +1,122 @@
|
||||
|
||||
-- ========================================================
|
||||
-- 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 createRbacRulesForEMailAddress()
|
||||
RETURNS trigger
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
DECLARE
|
||||
eMailAddress varchar;
|
||||
parentDomain domain;
|
||||
eMailAddressOwnerRoleId uuid;
|
||||
eMailAddressTenantRoleId uuid;
|
||||
BEGIN
|
||||
IF TG_OP <> 'INSERT' THEN
|
||||
RAISE EXCEPTION 'invalid usage of TRIGGER AFTER INSERT';
|
||||
END IF;
|
||||
|
||||
SELECT * FROM domain WHERE uuid=NEW.domainUuid into parentDomain;
|
||||
eMailAddress = NEW.localPart || '@' || parentDomain.name;
|
||||
|
||||
-- an owner role is created and assigned to the domain owner
|
||||
eMailAddressOwnerRoleId = getRoleId('emailaddress#'||eMailAddress||'.owner', 'create');
|
||||
call grantRoleToRole(eMailAddressOwnerRoleId, getRoleId('domain#'||parentDomain.name||'.owner', 'fail'));
|
||||
-- ... and permissions for all ops are assigned
|
||||
call grantPermissionsToRole(eMailAddressOwnerRoleId,
|
||||
createPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*']));
|
||||
|
||||
-- a tenant role is created and assigned to a user with the new email address
|
||||
eMailAddressTenantRoleId = getRoleId('emailaddress#'||eMailAddress||'.tenant', 'create');
|
||||
call grantRoleToUser(eMailAddressTenantRoleId, getRbacUserId(eMailAddress, 'create'));
|
||||
-- ... and permissions for all ops are assigned
|
||||
call grantPermissionsToRole(eMailAddressTenantRoleId,
|
||||
createPermissions(forObjectUuid => NEW.uuid, permitOps => ARRAY['*'])); -- TODO '*' -> 'edit', 'view'
|
||||
|
||||
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
|
||||
|
||||
abort;
|
||||
set session authorization default ;
|
||||
START TRANSACTION;
|
||||
SET LOCAL hsadminng.currentUser = 'mike@hostsharing.net';
|
||||
SET LOCAL hsadminng.assumedRoles = 'customer#bbb.owner;customer#bbc.owner';
|
||||
-- SET LOCAL hsadminng.assumedRoles = 'package#bbb00.owner;package#bbb01.owner';
|
||||
|
||||
select count(*) from queryAccessibleObjectUuidsOfSubjectIds( 'view', currentSubjectIds(), 7) as a
|
||||
join rbacobject as o on a=o.uuid;
|
||||
|
||||
/* SELECT DISTINCT target.*
|
||||
FROM EMailAddress AS target
|
||||
JOIN queryAccessibleObjectUuidsOfSubjectIds( 'view', currentSubjectIds()) AS allowedObjId
|
||||
ON target.uuid = allowedObjId;*/
|
||||
END TRANSACTION;
|
||||
|
||||
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', currentSubjectIds()) AS allowedObjId
|
||||
ON target.uuid = allowedObjId;
|
||||
GRANT ALL PRIVILEGES ON EMailAddress_rv TO restricted;
|
||||
|
||||
|
||||
-- generate EMailAddress test data
|
||||
|
||||
DO LANGUAGE plpgsql $$
|
||||
DECLARE
|
||||
pac package;
|
||||
uu unixuser;
|
||||
dom domain;
|
||||
pacAdmin varchar;
|
||||
currentTask varchar;
|
||||
BEGIN
|
||||
SET hsadminng.currentUser TO '';
|
||||
|
||||
FOR dom IN (SELECT * FROM domain) LOOP
|
||||
FOR t IN 0..5 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';
|
||||
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;
|
||||
$$;
|
||||
|
||||
|
24
sql/29-hs-statistics.sql
Normal file
24
sql/29-hs-statistics.sql
Normal file
@ -0,0 +1,24 @@
|
||||
|
||||
-- ========================================================
|
||||
-- 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.9') 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;
|
62
sql/examples.sql
Normal file
62
sql/examples.sql
Normal file
@ -0,0 +1,62 @@
|
||||
-- ========================================================
|
||||
-- First Example Entity with History
|
||||
-- --------------------------------------------------------
|
||||
|
||||
CREATE TABLE IF NOT EXISTS customer (
|
||||
"id" SERIAL PRIMARY KEY,
|
||||
"reference" int not null unique, -- 10000-99999
|
||||
"prefix" character(3) unique
|
||||
);
|
||||
|
||||
CALL create_historicization('customer');
|
||||
|
||||
|
||||
-- ========================================================
|
||||
-- Second Example Entity with History
|
||||
-- --------------------------------------------------------
|
||||
|
||||
CREATE TABLE IF NOT EXISTS package_type (
|
||||
"id" serial PRIMARY KEY,
|
||||
"name" character varying(8)
|
||||
);
|
||||
|
||||
CALL create_historicization('package_type');
|
||||
|
||||
-- ========================================================
|
||||
-- Third Example Entity with History
|
||||
-- --------------------------------------------------------
|
||||
|
||||
CREATE TABLE IF NOT EXISTS package (
|
||||
"id" serial PRIMARY KEY,
|
||||
"name" character varying(5),
|
||||
"customer_id" INTEGER REFERENCES customer(id)
|
||||
);
|
||||
|
||||
CALL create_historicization('package');
|
||||
|
||||
|
||||
-- ========================================================
|
||||
-- query historical data
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
ABORT;
|
||||
BEGIN TRANSACTION;
|
||||
SET LOCAL hsadminng.currentUser TO 'mih42_customer_aaa';
|
||||
SET LOCAL hsadminng.currentTask TO 'adding customer_aaa';
|
||||
INSERT INTO package (customer_id, name) VALUES (10000, 'aaa00');
|
||||
COMMIT;
|
||||
|
||||
SET SESSION SESSION AUTHORIZATION DEFAULT;
|
||||
CREATE ROLE hs_sel_package_1000000;
|
||||
GRANT hs_sel_package_1000000 to hs_sel_customer_10000;
|
||||
|
||||
SET SESSION SESSION AUTHORIZATION mih42_customer_aaa;
|
||||
SELECT pg_has_role('hs_sel_package_1000000', 'MEMBER');
|
||||
|
||||
|
||||
-- Usage:
|
||||
|
||||
SET hsadminng.timestamp TO '2022-07-12 08:53:27.723315';
|
||||
SET hsadminng.timestamp TO '2022-07-12 11:38:27.723315';
|
||||
SELECT * FROM customer_hv p WHERE prefix = 'aaa';
|
166
sql/historization.sql
Normal file
166
sql/historization.sql
Normal file
@ -0,0 +1,166 @@
|
||||
|
||||
-- ========================================================
|
||||
-- Historization
|
||||
-- --------------------------------------------------------
|
||||
|
||||
CREATE TABLE "tx_history" (
|
||||
"tx_id" BIGINT NOT NULL UNIQUE,
|
||||
"tx_timestamp" TIMESTAMP NOT NULL,
|
||||
"user" VARCHAR(64) NOT NULL, -- references postgres user
|
||||
"task" VARCHAR NOT NULL
|
||||
);
|
||||
|
||||
CREATE TYPE "operation" AS ENUM ('INSERT', 'UPDATE', 'DELETE', 'TRUNCATE');
|
||||
|
||||
-- see https://www.postgresql.org/docs/current/plpgsql-trigger.html
|
||||
|
||||
CREATE OR REPLACE FUNCTION historicize()
|
||||
RETURNS trigger
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
DECLARE
|
||||
currentUser VARCHAR(64);
|
||||
currentTask varchar;
|
||||
"row" RECORD;
|
||||
"alive" BOOLEAN;
|
||||
"sql" varchar;
|
||||
BEGIN
|
||||
-- determine user_id
|
||||
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;
|
||||
RAISE NOTICE 'currentUser: %', currentUser;
|
||||
|
||||
-- determine task
|
||||
currentTask = current_setting('hsadminng.currentTask');
|
||||
IF (currentTask IS NULL OR length(currentTask) < 12) THEN
|
||||
RAISE EXCEPTION 'hsadminng.currentTask (%) must be defined and min 12 characters long, please use "SET LOCAL ...;"', currentTask;
|
||||
END IF;
|
||||
RAISE NOTICE 'currentTask: %', currentTask;
|
||||
|
||||
IF (TG_OP = 'INSERT') OR (TG_OP = 'UPDATE') THEN
|
||||
"row" := NEW;
|
||||
"alive" := TRUE;
|
||||
ELSE -- DELETE or TRUNCATE
|
||||
"row" := OLD;
|
||||
"alive" := FALSE;
|
||||
END IF;
|
||||
|
||||
sql := format('INSERT INTO tx_history VALUES (txid_current(), now(), %1L, %2L) ON CONFLICT DO NOTHING', currentUser, currentTask);
|
||||
RAISE NOTICE 'sql: %', sql;
|
||||
EXECUTE sql;
|
||||
sql := format('INSERT INTO %3$I_versions VALUES (DEFAULT, txid_current(), %1$L, %2$L, $1.*)', TG_OP, alive, TG_TABLE_NAME);
|
||||
RAISE NOTICE 'sql: %', sql;
|
||||
EXECUTE sql USING "row";
|
||||
|
||||
RETURN "row";
|
||||
END; $$;
|
||||
|
||||
CREATE OR REPLACE PROCEDURE create_historical_view(baseTable varchar)
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
createTriggerSQL varchar;
|
||||
viewName varchar;
|
||||
versionsTable varchar;
|
||||
createViewSQL varchar;
|
||||
baseCols varchar;
|
||||
BEGIN
|
||||
|
||||
viewName = quote_ident(format('%s_hv', baseTable));
|
||||
versionsTable = quote_ident(format('%s_versions', baseTable));
|
||||
baseCols = (SELECT string_agg(quote_ident(column_name), ', ')
|
||||
FROM information_schema.columns
|
||||
WHERE table_schema = 'public' AND table_name = baseTable);
|
||||
|
||||
createViewSQL = format(
|
||||
'CREATE OR REPLACE VIEW %1$s AS' ||
|
||||
'(' ||
|
||||
' SELECT %2$s' ||
|
||||
' FROM %3$s' ||
|
||||
' WHERE alive = TRUE' ||
|
||||
' AND version_id IN' ||
|
||||
' (' ||
|
||||
' SELECT max(vt.version_id) AS history_id' ||
|
||||
' FROM %3$s AS vt' ||
|
||||
' JOIN tx_history as txh ON vt.tx_id = txh.tx_id' ||
|
||||
' WHERE txh.tx_timestamp <= current_setting(''hsadminng.timestamp'')::timestamp' ||
|
||||
' GROUP BY id' ||
|
||||
' )' ||
|
||||
')',
|
||||
viewName, baseCols, versionsTable
|
||||
);
|
||||
RAISE NOTICE 'sql: %', createViewSQL;
|
||||
EXECUTE createViewSQL;
|
||||
|
||||
createTriggerSQL = 'CREATE TRIGGER ' || baseTable || '_historicize' ||
|
||||
' AFTER INSERT OR DELETE OR UPDATE ON ' || baseTable ||
|
||||
' FOR EACH ROW EXECUTE PROCEDURE historicize()';
|
||||
RAISE NOTICE 'sql: %', createTriggerSQL;
|
||||
EXECUTE createTriggerSQL;
|
||||
|
||||
END; $$;
|
||||
|
||||
CREATE OR REPLACE PROCEDURE create_historicization(baseTable varchar)
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
createHistTableSql varchar;
|
||||
createTriggerSQL varchar;
|
||||
viewName varchar;
|
||||
versionsTable varchar;
|
||||
createViewSQL varchar;
|
||||
baseCols varchar;
|
||||
BEGIN
|
||||
|
||||
-- create the history table
|
||||
createHistTableSql = '' ||
|
||||
'CREATE TABLE ' || baseTable || '_versions (' ||
|
||||
' version_id serial PRIMARY KEY,' ||
|
||||
' tx_id bigint NOT NULL REFERENCES tx_history(tx_id),' ||
|
||||
' trigger_op operation NOT NULL,' ||
|
||||
' alive boolean not null,' ||
|
||||
|
||||
' LIKE ' || baseTable ||
|
||||
' EXCLUDING CONSTRAINTS' ||
|
||||
' EXCLUDING STATISTICS' ||
|
||||
')';
|
||||
RAISE NOTICE 'sql: %', createHistTableSql;
|
||||
EXECUTE createHistTableSql;
|
||||
|
||||
-- create the historical view
|
||||
viewName = quote_ident(format('%s_hv', baseTable));
|
||||
versionsTable = quote_ident(format('%s_versions', baseTable));
|
||||
baseCols = (SELECT string_agg(quote_ident(column_name), ', ')
|
||||
FROM information_schema.columns
|
||||
WHERE table_schema = 'public' AND table_name = baseTable);
|
||||
|
||||
createViewSQL = format(
|
||||
'CREATE OR REPLACE VIEW %1$s AS' ||
|
||||
'(' ||
|
||||
' SELECT %2$s' ||
|
||||
' FROM %3$s' ||
|
||||
' WHERE alive = TRUE' ||
|
||||
' AND version_id IN' ||
|
||||
' (' ||
|
||||
' SELECT max(vt.version_id) AS history_id' ||
|
||||
' FROM %3$s AS vt' ||
|
||||
' JOIN tx_history as txh ON vt.tx_id = txh.tx_id' ||
|
||||
' WHERE txh.tx_timestamp <= current_setting(''hsadminng.timestamp'')::timestamp' ||
|
||||
' GROUP BY id' ||
|
||||
' )' ||
|
||||
')',
|
||||
viewName, baseCols, versionsTable
|
||||
);
|
||||
RAISE NOTICE 'sql: %', createViewSQL;
|
||||
EXECUTE createViewSQL;
|
||||
|
||||
createTriggerSQL = 'CREATE TRIGGER ' || baseTable || '_historicize' ||
|
||||
' AFTER INSERT OR DELETE OR UPDATE ON ' || baseTable ||
|
||||
' FOR EACH ROW EXECUTE PROCEDURE historicize()';
|
||||
RAISE NOTICE 'sql: %', createTriggerSQL;
|
||||
EXECUTE createTriggerSQL;
|
||||
|
||||
END; $$;
|
@ -1,105 +0,0 @@
|
||||
--
|
||||
-- Historization
|
||||
--
|
||||
|
||||
CREATE TABLE history (
|
||||
history_id serial PRIMARY KEY,
|
||||
history_transaction bigint NOT NULL UNIQUE,
|
||||
history_timestamp timestamp NOT NULL
|
||||
);
|
||||
|
||||
CREATE FUNCTION historicize() RETURNS trigger
|
||||
AS $$
|
||||
BEGIN
|
||||
IF (TG_OP = 'INSERT') OR (TG_OP = 'UPDATE') THEN
|
||||
EXECUTE 'INSERT INTO history VALUES (DEFAULT, txid_current(), now()) ON CONFLICT DO NOTHING';
|
||||
EXECUTE format('INSERT INTO %I_history VALUES (DEFAULT, txid_current(), False, $1.*)', TG_TABLE_NAME) USING NEW;
|
||||
RETURN NEW;
|
||||
ELSE
|
||||
EXECUTE 'INSERT INTO history VALUES (DEFAULT, txid_current(), now()) ON CONFLICT DO NOTHING';
|
||||
EXECUTE format('INSERT INTO %I_history VALUES (DEFAULT, txid_current(), True, $1.*)', TG_TABLE_NAME) USING OLD;
|
||||
RETURN OLD;
|
||||
END IF;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
--
|
||||
-- Entity with History
|
||||
--
|
||||
|
||||
CREATE TABLE person (
|
||||
id serial PRIMARY KEY,
|
||||
name character varying(50) NOT NULL UNIQUE,
|
||||
email character varying(50) NOT NULL UNIQUE
|
||||
);
|
||||
|
||||
CREATE TABLE person_history (
|
||||
history_id serial PRIMARY KEY,
|
||||
history_transaction bigint NOT NULL REFERENCES history(history_transaction),
|
||||
history_tombstone boolean NOT NULL,
|
||||
id integer NOT NULL,
|
||||
name character varying(50) NOT NULL,
|
||||
email character varying(50) NOT NULL
|
||||
);
|
||||
|
||||
CREATE TRIGGER person_historicize AFTER INSERT OR DELETE OR UPDATE ON person FOR EACH ROW EXECUTE PROCEDURE historicize();
|
||||
|
||||
--
|
||||
-- Sample data
|
||||
--
|
||||
|
||||
INSERT INTO person (name, email) VALUES ('michael', 'michael@hierweck.de');
|
||||
INSERT INTO person (name, email) VALUES ('annika', 'annika@hierweck.de');
|
||||
|
||||
UPDATE person SET email='mh@hierweck.de' WHERE name='michael';
|
||||
UPDATE person SET email='ah@hierweck.de' WHERE name='annika';
|
||||
|
||||
DELETE FROM person WHERE name='michael';
|
||||
DELETE FROM person WHERE name='annika';
|
||||
|
||||
INSERT INTO person (name, email) VALUES ('michael', 'michael@hierweck.de');
|
||||
INSERT INTO person (name, email) VALUES ('annika', 'annika@hierweck.de');
|
||||
|
||||
BEGIN;
|
||||
INSERT INTO person (name, email) VALUES ('mx', 'mx@hierweck.de');
|
||||
INSERT INTO person (name, email) VALUES ('ax', 'ax@hierweck.de');
|
||||
UPDATE person SET email='mxx@hierweck.de' WHERE name='mx';
|
||||
UPDATE person SET email='axx@hierweck.de' WHERE name='ax';
|
||||
COMMIT;
|
||||
|
||||
--
|
||||
-- Approach 1: Function
|
||||
--
|
||||
--
|
||||
-- Usage:
|
||||
--
|
||||
-- SELECT * FROM person_history(12345, 'name');
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION person_history(transaction bigint, VARIADIC groupby text[]) RETURNS TABLE (
|
||||
history_id integer,
|
||||
history_transaction bigint,
|
||||
history_tombstone boolean,
|
||||
id integer,
|
||||
name character varying(50),
|
||||
email character varying(50)
|
||||
)
|
||||
AS $$
|
||||
BEGIN
|
||||
RETURN QUERY EXECUTE format('SELECT * FROM person_history WHERE history_id IN (SELECT max(history_id) AS history_id FROM person_history WHERE history_transaction <= $1 GROUP BY %s)', array_to_string(groupby, ', ')) USING transaction;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
--
|
||||
-- Approach 2: View
|
||||
--
|
||||
-- Usage:
|
||||
--
|
||||
-- SET history_transaction = 12345;
|
||||
-- SELECT * FROM person_history_view;
|
||||
--
|
||||
|
||||
CREATE VIEW person_history_view
|
||||
AS (SELECT * FROM person_history WHERE history_id IN (SELECT max(history_id) AS history_id FROM person_history WHERE history_transaction <= current_setting('history.transaction')::bigint GROUP BY name));
|
18
sql/rbac-statistics.sql
Normal file
18
sql/rbac-statistics.sql
Normal file
@ -0,0 +1,18 @@
|
||||
|
||||
DROP VIEW "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;
|
301
sql/rbac.md
Normal file
301
sql/rbac.md
Normal file
@ -0,0 +1,301 @@
|
||||
## *hsadmin-ng*'s Role-Based-Access-Management (RBAC)
|
||||
|
||||
The requirements of *hsadmin-ng* include table-m row- and column-level-security for read and write access to business-objects.
|
||||
More precisely, any access has to be controlled according to given rules depending on the accessing users, their roles and the accessed business-object.
|
||||
Further, roles and business-objects are hierarchical.
|
||||
|
||||
To avoid misunderstandings, we are using the term "business-object" what's usually called a "domain-object".
|
||||
But as we are in the context of a webhosting infrastructure provider, "domain" would have a double meaning.
|
||||
|
||||
Our implementation is based on Role-Based-Access-Management (RBAC) in conjunction with views and triggers on the business-objects.
|
||||
As far as possible, we are using the same terms as defined in the RBAC standard, for our function names though, we chose more expressive names.
|
||||
|
||||
In RBAC, subjects can be assigned to roles, roles can be hierarchical and eventually have assigned permissions.
|
||||
A permission allows a specific operation (e.g. view or edit) on a specific (business-) object.
|
||||
|
||||
You can find the entity structure as a UML class diagram as follows:
|
||||
|
||||
```plantuml
|
||||
@startuml
|
||||
' left to right direction
|
||||
top to bottom direction
|
||||
|
||||
' hide the ugly E in a circle left to the entity name
|
||||
hide circle
|
||||
|
||||
' use right-angled line routing
|
||||
skinparam linetype ortho
|
||||
|
||||
package RBAC {
|
||||
|
||||
' forward declarations
|
||||
entity RbacUser
|
||||
entity RbacObject
|
||||
|
||||
together {
|
||||
|
||||
entity RbacRole
|
||||
entity RbacPermission
|
||||
enum RbacOperation
|
||||
|
||||
RbacUser -[hidden]> RbacRole
|
||||
RbacRole -[hidden]> RbacUser
|
||||
}
|
||||
|
||||
together {
|
||||
entity RbacGrant
|
||||
enum RbacReferenceType
|
||||
entity RbacReference
|
||||
}
|
||||
RbacReference -[hidden]> RbacReferenceType
|
||||
|
||||
entity RbacGrant {
|
||||
ascendantUuid: uuid(RbackReference)
|
||||
descendantUuid: uuid(RbackReference)
|
||||
auto
|
||||
}
|
||||
RbacGrant o-> RbacReference
|
||||
RbacGrant o-> RbacReference
|
||||
|
||||
enum RbacReferenceType {
|
||||
RbacUser
|
||||
RbacRole
|
||||
RbacPermission
|
||||
}
|
||||
RbacReferenceType ..> RbacUser
|
||||
RbacReferenceType ..> RbacRole
|
||||
RbacReferenceType ..> RbacPermission
|
||||
|
||||
entity RbacReference {
|
||||
*uuid : uuid <<generated>>
|
||||
--
|
||||
type : RbacReferenceType
|
||||
}
|
||||
RbacReference o--> RbacReferenceType
|
||||
entity RbacUser {
|
||||
*uuid : uuid <<generated>>
|
||||
--
|
||||
name : varchar
|
||||
}
|
||||
RbacUser o-- RbacReference
|
||||
|
||||
entity RbacRole {
|
||||
*uuid : uuid(RbacReference)
|
||||
--
|
||||
name : varchar
|
||||
}
|
||||
RbacRole o-- RbacReference
|
||||
|
||||
entity RbacPermission {
|
||||
*uuid : uuid(RbacReference)
|
||||
--
|
||||
objectUuid: RbacObject
|
||||
op: RbacOperation
|
||||
}
|
||||
RbacPermission o-- RbacReference
|
||||
RbacPermission o-- RbacOperation
|
||||
RbacPermission *-- RbacObject
|
||||
|
||||
enum RbacOperation {
|
||||
add-package
|
||||
add-domain
|
||||
add-unixuser
|
||||
...
|
||||
view
|
||||
edit
|
||||
delete
|
||||
}
|
||||
|
||||
entity RbacObject {
|
||||
*uuid : uuid <<generated>>
|
||||
--
|
||||
objectTable: varchar
|
||||
}
|
||||
RbacObject o- "Business Objects"
|
||||
}
|
||||
|
||||
package "Business Objects" {
|
||||
|
||||
entity package
|
||||
package *--u- RbacObject
|
||||
|
||||
entity customer
|
||||
customer *--u- RbacObject
|
||||
|
||||
entity "..." as moreBusinessObjects
|
||||
moreBusinessObjects *-u- RbacObject
|
||||
}
|
||||
|
||||
@enduml
|
||||
```
|
||||
|
||||
### The RBAC Entity Types
|
||||
|
||||
#### RbacReference
|
||||
|
||||
An *RbacReference* is a generalization of all entity types which participate in the hierarchical role system, defined via *RbacGrant*.
|
||||
|
||||
The primary key of the *RbacReference* and its referred object is always identical.
|
||||
|
||||
#### RbacUser
|
||||
|
||||
An *RbacUser* is a type of RBAC-subject which references a login account outside this system, identified by a name (usually an email-address).
|
||||
|
||||
*RbacUser*s can be assigned to multiple *RbacRole*s, through which they can get permissions to *RbacObject*s.
|
||||
|
||||
The primary key of the *RbacUser* is identical to its related *RbacReference*.
|
||||
|
||||
#### RbacRole
|
||||
|
||||
An *RbacRole* represents a collection of directly or indirectly assigned *RbacPermission*s.
|
||||
Each *RbacRole* can be assigned to *RbacUser*s or to another *RbacRole*.
|
||||
|
||||
Both kinds of assignments are represented via *RbacGrant*.
|
||||
|
||||
*RbacRole* entities can *RbacObject*s, or more precise
|
||||
|
||||
#### RbacPermission
|
||||
|
||||
An *RbacPermission* allows a specific *RbacOperation* on a specific *RbacObject*.
|
||||
|
||||
#### RbacOperation
|
||||
|
||||
An *RbacOperation* determines, <u>what</u> an *RbacPermission* allows to do.
|
||||
It can be one of:
|
||||
|
||||
- **add-...** - permits creating new instances of specific entity types underneath the object specified by the permission, e.g. "add-package"
|
||||
- **view** - permits reading the contents of the object specified by the permission
|
||||
- **edit** - change the contents of the object specified by the permission
|
||||
- **delete** - delete the object specified by the permission
|
||||
|
||||
This list is extensible according to the needs of the access rule system.
|
||||
|
||||
Please notice, that there is no **create-...** operation to create new instances of related business-object-types.
|
||||
For such a singleton business-object-type, e.g. *Organization" or "Hostsharing" has to be defined, and its single entity is referred in the permission.
|
||||
By this, the foreign key in *RbacPermission* can be defined as `NOT NULL`.
|
||||
|
||||
#### RbacGrant
|
||||
|
||||
The *RbacGrant* entities represent the access-rights structure from *RbacUser*s via hierarchical *RbacRoles* down to *RbacPermission*s.
|
||||
|
||||
The core SQL queries to determine access rights are all recursive queries on the *RbacGrant* table.
|
||||
|
||||
### Role naming
|
||||
|
||||
Automatically generated roles are named as such:
|
||||
|
||||
#### business-table#business-object-name.tenant
|
||||
This role is assigned to users who manage objects underneath the object which is accessible through the role.
|
||||
This rule usually gets only view permissions assigned.
|
||||
|
||||
**Example**
|
||||
|
||||
'dd'
|
||||
|
||||
## Example Users, Roles, Permissions and Business-Objects
|
||||
|
||||
```plantuml
|
||||
@startuml
|
||||
' left to right direction
|
||||
top to bottom direction
|
||||
|
||||
' hide the ugly E in a circle left to the entity name
|
||||
hide circle
|
||||
|
||||
' use right-angled line routing
|
||||
' skinparam linetype ortho
|
||||
|
||||
package RbacUsers {
|
||||
object UserMike
|
||||
object UserSuse
|
||||
object UserPaul
|
||||
}
|
||||
|
||||
package RbacRoles {
|
||||
object RoleAdministrators
|
||||
object RoleCustXyz_Owner
|
||||
object RoleCustXyz_Admin
|
||||
object RolePackXyz00_Owner
|
||||
}
|
||||
RbacUsers -[hidden]> RbacRoles
|
||||
|
||||
package RbacPermissions {
|
||||
object PermCustXyz_View
|
||||
object PermCustXyz_Edit
|
||||
object PermCustXyz_Delete
|
||||
object PermCustXyz_AddPackage
|
||||
object PermPackXyz00_View
|
||||
object PermPackXyz00_Edit
|
||||
object PermPackXyz00_Delete
|
||||
object PermPackXyz00_AddUser
|
||||
}
|
||||
RbacRoles -[hidden]> RbacPermissions
|
||||
|
||||
package BusinessObjects {
|
||||
object CustXyz
|
||||
object PackXyz00
|
||||
}
|
||||
RbacPermissions -[hidden]> BusinessObjects
|
||||
|
||||
UserMike o---> RoleAdministrators
|
||||
UserSuse o--> RoleCustXyz_Admin
|
||||
UserPaul o--> RolePackXyz00_Owner
|
||||
|
||||
RoleAdministrators o..> RoleCustXyz_Owner
|
||||
RoleCustXyz_Owner o-> RoleCustXyz_Admin
|
||||
RoleCustXyz_Admin o-> RolePackXyz00_Owner
|
||||
|
||||
RoleCustXyz_Owner o--> PermCustXyz_Edit
|
||||
RoleCustXyz_Owner o--> PermCustXyz_Delete
|
||||
RoleCustXyz_Admin o--> PermCustXyz_View
|
||||
RoleCustXyz_Admin o--> PermCustXyz_AddPackage
|
||||
RolePackXyz00_Owner o--> PermPackXyz00_View
|
||||
RolePackXyz00_Owner o--> PermPackXyz00_Edit
|
||||
RolePackXyz00_Owner o--> PermPackXyz00_Delete
|
||||
RolePackXyz00_Owner o--> PermPackXyz00_AddUser
|
||||
|
||||
PermCustXyz_View o--> CustXyz
|
||||
PermCustXyz_Edit o--> CustXyz
|
||||
PermCustXyz_Delete o--> CustXyz
|
||||
PermCustXyz_AddPackage o--> CustXyz
|
||||
PermPackXyz00_View o--> PackXyz00
|
||||
PermPackXyz00_Edit o--> PackXyz00
|
||||
PermPackXyz00_Delete o--> PackXyz00
|
||||
PermPackXyz00_AddUser o--> PackXyz00
|
||||
|
||||
@enduml
|
||||
```
|
||||
|
||||
|
||||
```plantuml
|
||||
@startuml
|
||||
left to right direction
|
||||
' top to bottom direction
|
||||
|
||||
' hide the ugly E in a circle left to the entity name
|
||||
hide circle
|
||||
|
||||
' use right-angled line routing
|
||||
' skinparam linetype ortho
|
||||
|
||||
package rbacPerms {
|
||||
cust
|
||||
}
|
||||
|
||||
package rbacRoles {
|
||||
entity administrators
|
||||
entity custXXX
|
||||
}
|
||||
|
||||
package rbacUsers {
|
||||
entity adminMike
|
||||
adminMike <-- administrators
|
||||
|
||||
entity adminSven
|
||||
entity custXXX
|
||||
entity pacAdmXXX00
|
||||
}
|
||||
|
||||
@enduml
|
||||
```
|
||||
|
0
sql/rbac.pdf
Normal file
0
sql/rbac.pdf
Normal file
2
sql/rbac.sql
Normal file
2
sql/rbac.sql
Normal file
@ -0,0 +1,2 @@
|
||||
|
||||
|
Reference in New Issue
Block a user