convert rbac*.sql files, except test-file, to Liquibase changesets
This commit is contained in:
parent
6c33bbe780
commit
d234ac3227
@ -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,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;
|
||||
|
@ -0,0 +1,9 @@
|
||||
--liquibase formatted sql
|
||||
|
||||
--changeset template:1 endDelimiter:--//
|
||||
|
||||
/*
|
||||
|
||||
*/
|
||||
|
||||
--//
|
@ -0,0 +1,18 @@
|
||||
--liquibase formatted sql
|
||||
|
||||
--changeset last-row-count:1 endDelimiter:--//
|
||||
|
||||
/*
|
||||
Returns the row count from the result of the previous query.
|
||||
Other than the native statement it's usable in an expression.
|
||||
*/
|
||||
create or replace function lastRowCount()
|
||||
returns bigint
|
||||
language plpgsql as $$
|
||||
declare
|
||||
lastRowCount bigint;
|
||||
begin
|
||||
get diagnostics lastrowCount = row_count;
|
||||
return lastRowCount;
|
||||
end; $$;
|
||||
--//
|
@ -0,0 +1,25 @@
|
||||
--liquibase formatted sql
|
||||
|
||||
--changeset int-to-var:1 endDelimiter:--//
|
||||
|
||||
/*
|
||||
Returns a textual representation of an integer number to be used as generated test data.
|
||||
|
||||
Examples :
|
||||
intToVarChar(0, 3) => 'aaa'
|
||||
intToVarChar(1, 3) => 'aab'
|
||||
*/
|
||||
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; $$;
|
||||
--//
|
@ -0,0 +1,23 @@
|
||||
--liquibase formatted sql
|
||||
|
||||
--changeset random-in-range:1 endDelimiter:--//
|
||||
|
||||
/*
|
||||
Returns a random integer in the given range (both included),
|
||||
to be used for test data generation.
|
||||
|
||||
Example:
|
||||
randomInRange(0, 4) might return any of 0, 1, 2, 3, 4
|
||||
*/
|
||||
create or replace function randomInRange(min integer, max integer)
|
||||
returns integer
|
||||
returns null on null input
|
||||
language 'plpgsql' AS $$
|
||||
begin
|
||||
return floor(random() * (max-min + 1) + min);
|
||||
end; $$;
|
||||
--//
|
||||
|
||||
|
||||
|
||||
|
@ -0,0 +1,9 @@
|
||||
--liquibase formatted sql
|
||||
|
||||
--changeset uuid-ossp-extension:1 endDelimiter:--//
|
||||
|
||||
/*
|
||||
Makes improved uuid generation available.
|
||||
*/
|
||||
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
||||
--//
|
@ -7,14 +7,12 @@ 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";
|
||||
--liquibase formatted sql
|
||||
|
||||
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;
|
||||
--changeset rbac-base-reference:1 endDelimiter:--//
|
||||
/*
|
||||
|
||||
*/
|
||||
CREATE TYPE ReferenceType AS ENUM ('RbacUser', 'RbacRole', 'RbacPermission');
|
||||
|
||||
CREATE TABLE RbacReference
|
||||
@ -23,88 +21,31 @@ CREATE TABLE RbacReference
|
||||
type ReferenceType not null
|
||||
);
|
||||
|
||||
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; $$;
|
||||
|
||||
--//
|
||||
|
||||
--changeset rbac-base-user:1 endDelimiter:--//
|
||||
/*
|
||||
|
||||
*/
|
||||
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
|
||||
@ -122,7 +63,7 @@ CREATE OR REPLACE FUNCTION findRbacUserId(userName varchar)
|
||||
RETURNS uuid
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE sql AS $$
|
||||
SELECT uuid FROM RbacUser WHERE name = userName
|
||||
SELECT uuid FROM RbacUser WHERE name = userName
|
||||
$$;
|
||||
|
||||
CREATE TYPE RbacWhenNotExists AS ENUM ('fail', 'create');
|
||||
@ -147,46 +88,65 @@ BEGIN
|
||||
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; $$;
|
||||
--changeset rbac-base-object:1 endDelimiter:--//
|
||||
/*
|
||||
|
||||
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;
|
||||
*/
|
||||
CREATE TABLE RbacObject
|
||||
(
|
||||
uuid uuid PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
objectTable varchar(64) not null,
|
||||
unique (objectTable, uuid)
|
||||
);
|
||||
|
||||
DO LANGUAGE plpgsql $$
|
||||
CREATE OR REPLACE FUNCTION createRbacObject()
|
||||
RETURNS trigger
|
||||
LANGUAGE plpgsql STRICT AS $$
|
||||
DECLARE
|
||||
roleDesc RbacRoleDescriptor;
|
||||
objectUuid uuid;
|
||||
BEGIN
|
||||
select * FROM roleDescriptor('global', gen_random_uuid(), 'admin') into roleDesc;
|
||||
RAISE NOTICE 'result: % % %', roleDesc.objecttable, roleDesc.objectuuid, roleDesc.roletype;
|
||||
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; $$;
|
||||
|
||||
-- TODO: ... or that?
|
||||
|
||||
--//
|
||||
|
||||
--changeset rbac-base-role:1 endDelimiter:--//
|
||||
/*
|
||||
|
||||
*/
|
||||
|
||||
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 TYPE RbacRoleDescriptor AS
|
||||
(
|
||||
objectTable varchar(63), -- TODO: needed? remove?
|
||||
objectUuid uuid,
|
||||
roleType RbacRoleType
|
||||
);
|
||||
|
||||
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;
|
||||
$$;
|
||||
SELECT objectTable, objectUuid, roleType::RbacRoleType;
|
||||
$$;
|
||||
|
||||
|
||||
|
||||
@ -216,7 +176,7 @@ 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;
|
||||
SELECT uuid FROM RbacRole WHERE objectUuid = roleDescriptor.objectUuid AND roleType = roleDescriptor.roleType;
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION getRoleId(roleDescriptor RbacRoleDescriptor, whenNotExists RbacWhenNotExists)
|
||||
@ -239,7 +199,41 @@ BEGIN
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- select getRoleId('hostmaster', 'create');
|
||||
--changeset rbac-base-permission:1 endDelimiter:--//
|
||||
/*
|
||||
|
||||
*/
|
||||
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 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 createPermissions(forObjectUuid uuid, permitOps RbacOp[])
|
||||
RETURNS uuid[]
|
||||
@ -281,18 +275,103 @@ CREATE OR REPLACE FUNCTION findPermissionId(forObjectUuid uuid, forOp RbacOp)
|
||||
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; $$;
|
||||
--//
|
||||
|
||||
--changeset rbac-base-grants:1 endDelimiter:--//
|
||||
/*
|
||||
|
||||
*/
|
||||
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);
|
||||
|
||||
|
||||
--//
|
||||
|
||||
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
|
||||
)
|
||||
);
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE PROCEDURE grantPermissionsToRole(roleUuid uuid, permissionIds uuid[])
|
||||
LANGUAGE plpgsql AS $$
|
||||
@ -344,10 +423,12 @@ BEGIN
|
||||
INSERT INTO RbacGrants (ascendantUuid, descendantUuid) VALUES (userId, roleId)
|
||||
ON CONFLICT DO NOTHING ; -- TODO: remove?
|
||||
END; $$;
|
||||
--//
|
||||
|
||||
abort;
|
||||
set local session authorization default;
|
||||
--changeset rbac-base-query-accessible-object-uuids:1 endDelimiter:--//
|
||||
/*
|
||||
|
||||
*/
|
||||
CREATE OR REPLACE FUNCTION queryAccessibleObjectUuidsOfSubjectIds(
|
||||
requiredOp RbacOp,
|
||||
forObjectTable varchar, -- reduces the result set, but is not really faster when used in restricted view
|
||||
@ -388,27 +469,13 @@ CREATE OR REPLACE FUNCTION queryAccessibleObjectUuidsOfSubjectIds(
|
||||
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;
|
||||
--changeset rbac-base-query-granted-permissions:1 endDelimiter:--//
|
||||
/*
|
||||
|
||||
---
|
||||
|
||||
abort;
|
||||
set local session authorization default;
|
||||
CREATE OR REPLACE FUNCTION queryRequiredPermissionsOfSubjectIds(requiredOp RbacOp, subjectIds uuid[])
|
||||
*/
|
||||
CREATE OR REPLACE FUNCTION queryGrantedPermissionsOfSubjectIds(requiredOp RbacOp, subjectIds uuid[])
|
||||
RETURNS SETOF RbacPermission
|
||||
STRICT
|
||||
LANGUAGE sql AS $$
|
||||
@ -435,78 +502,12 @@ CREATE OR REPLACE FUNCTION queryRequiredPermissionsOfSubjectIds(requiredOp RbacO
|
||||
);
|
||||
$$;
|
||||
|
||||
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;
|
||||
|
||||
---
|
||||
--changeset rbac-base-query-users-with-permission-for-object:1 endDelimiter:--//
|
||||
/*
|
||||
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
|
||||
@ -535,90 +536,12 @@ SELECT * FROM RbacUser WHERE uuid IN (
|
||||
);
|
||||
$$;
|
||||
|
||||
--//
|
||||
|
||||
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
|
||||
-- --------------------------------------------------------
|
||||
--changeset rbac-current-user:1 endDelimiter:--//
|
||||
/*
|
||||
|
||||
*/
|
||||
CREATE OR REPLACE FUNCTION currentUser()
|
||||
RETURNS varchar(63)
|
||||
STABLE LEAKPROOF
|
||||
@ -637,7 +560,6 @@ BEGIN
|
||||
RETURN currentUser;
|
||||
END; $$;
|
||||
|
||||
SET SESSION AUTHORIZATION DEFAULT;
|
||||
CREATE OR REPLACE FUNCTION currentUserId()
|
||||
RETURNS uuid
|
||||
STABLE LEAKPROOF
|
||||
@ -652,6 +574,12 @@ BEGIN
|
||||
END; $$;
|
||||
|
||||
|
||||
--//
|
||||
|
||||
--changeset rbac-assumed-roles:1 endDelimiter:--//
|
||||
/*
|
||||
|
||||
*/
|
||||
CREATE OR REPLACE FUNCTION assumedRoles()
|
||||
RETURNS varchar(63)[]
|
||||
STABLE LEAKPROOF
|
||||
@ -670,24 +598,27 @@ BEGIN
|
||||
RETURN string_to_array(currentSubject, ';');
|
||||
END; $$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION pureIdentifier(rawIdentifier varchar)
|
||||
RETURNS uuid
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE plpgsql AS $$
|
||||
begin
|
||||
return regexp_replace(rawIdentifier, '\W+', '');
|
||||
end; $$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION findUuidByIdName(objectTable varchar, objectIdName varchar)
|
||||
RETURNS uuid
|
||||
RETURNS NULL ON NULL INPUT
|
||||
LANGUAGE plpgsql AS $$
|
||||
DECLARE
|
||||
|
||||
sql varchar;
|
||||
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);
|
||||
objectTable := pureIdentifier(objectTable);
|
||||
objectIdName := pureIdentifier(objectIdName);
|
||||
sql := objectTable || 'UuidByIdName(' || objectIdName || ');';
|
||||
EXECUTE sql;
|
||||
END; $$;
|
||||
|
||||
ROLLBACK;
|
||||
SET SESSION AUTHORIZATION DEFAULT;
|
||||
CREATE OR REPLACE FUNCTION currentSubjectIds()
|
||||
RETURNS uuid[]
|
||||
STABLE LEAKPROOF
|
||||
@ -731,3 +662,4 @@ BEGIN
|
||||
|
||||
RETURN roleIdsToAssume;
|
||||
END; $$;
|
||||
--//
|
12
src/main/resources/db/changelog/db.changelog-master.yaml
Normal file
12
src/main/resources/db/changelog/db.changelog-master.yaml
Normal file
@ -0,0 +1,12 @@
|
||||
databaseChangeLog:
|
||||
- include:
|
||||
file: db/changelog/2022-07-28-001-last-row-count.sql
|
||||
- include:
|
||||
file: db/changelog/2022-07-28-002-int-to-var.sql
|
||||
- include:
|
||||
file: db/changelog/2022-07-28-003-random-in-range.sql
|
||||
- include:
|
||||
file: db/changelog/2022-07-28-004-uuid-ossp-extension.sql
|
||||
- include:
|
||||
file: db/changelog/2022-07-28-005-rbac-base.sql
|
||||
|
Loading…
Reference in New Issue
Block a user