2022-07-28 16:55:21 +02:00
|
|
|
--liquibase formatted sql
|
2022-07-22 13:31:37 +02:00
|
|
|
|
2022-08-02 11:51:36 +02:00
|
|
|
-- ============================================================================
|
|
|
|
--changeset rbac-base-REFERENCE:1 endDelimiter:--//
|
|
|
|
-- ----------------------------------------------------------------------------
|
2022-07-28 16:55:21 +02:00
|
|
|
/*
|
2022-07-22 13:31:37 +02:00
|
|
|
|
2022-07-28 16:55:21 +02:00
|
|
|
*/
|
2022-07-29 08:46:04 +02:00
|
|
|
create type ReferenceType as enum ('RbacUser', 'RbacRole', 'RbacPermission');
|
2022-07-22 13:31:37 +02:00
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
create table RbacReference
|
2022-07-22 13:31:37 +02:00
|
|
|
(
|
2022-07-29 08:46:04 +02:00
|
|
|
uuid uuid unique default uuid_generate_v4(),
|
2022-07-22 13:31:37 +02:00
|
|
|
type ReferenceType not null
|
|
|
|
);
|
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
create or replace function assertReferenceType(argument varchar, referenceId uuid, expectedType ReferenceType)
|
|
|
|
returns ReferenceType
|
|
|
|
language plpgsql as $$
|
|
|
|
declare
|
2022-07-28 16:55:21 +02:00
|
|
|
actualType ReferenceType;
|
2022-07-29 08:46:04 +02:00
|
|
|
begin
|
2022-09-26 10:57:22 +02:00
|
|
|
if referenceId is null then
|
|
|
|
raise exception '% must be a % and not null', argument, expectedType;
|
|
|
|
end if;
|
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
actualType = (select type from RbacReference where uuid = referenceId);
|
|
|
|
if (actualType <> expectedType) then
|
|
|
|
raise exception '% must reference a %, but got a %', argument, expectedType, actualType;
|
2022-07-28 16:55:21 +02:00
|
|
|
end if;
|
2022-07-29 08:46:04 +02:00
|
|
|
return expectedType;
|
|
|
|
end; $$;
|
2022-07-28 16:55:21 +02:00
|
|
|
--//
|
2022-07-22 13:31:37 +02:00
|
|
|
|
2022-08-02 11:51:36 +02:00
|
|
|
-- ============================================================================
|
|
|
|
--changeset rbac-base-USER:1 endDelimiter:--//
|
|
|
|
-- ----------------------------------------------------------------------------
|
2022-07-28 16:55:21 +02:00
|
|
|
/*
|
2022-07-27 12:32:54 +02:00
|
|
|
|
2022-07-28 16:55:21 +02:00
|
|
|
*/
|
2022-07-29 08:46:04 +02:00
|
|
|
create table RbacUser
|
2022-07-28 16:55:21 +02:00
|
|
|
(
|
2022-07-29 08:46:04 +02:00
|
|
|
uuid uuid primary key references RbacReference (uuid) on delete cascade,
|
2022-07-28 16:55:21 +02:00
|
|
|
name varchar(63) not null unique
|
|
|
|
);
|
2022-07-22 13:31:37 +02:00
|
|
|
|
2022-08-24 12:52:28 +02:00
|
|
|
call create_journal('RbacUser');
|
2022-08-24 12:01:54 +02:00
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
create or replace function createRbacUser(userName varchar)
|
|
|
|
returns uuid
|
|
|
|
returns null on null input
|
|
|
|
language plpgsql as $$
|
2022-07-22 13:31:37 +02:00
|
|
|
declare
|
|
|
|
objectId uuid;
|
2022-07-29 08:46:04 +02:00
|
|
|
begin
|
|
|
|
insert
|
2022-07-29 12:37:40 +02:00
|
|
|
into RbacReference (type)
|
|
|
|
values ('RbacUser')
|
|
|
|
returning uuid into objectId;
|
2022-07-29 08:46:04 +02:00
|
|
|
insert
|
2022-07-29 12:37:40 +02:00
|
|
|
into RbacUser (uuid, name)
|
|
|
|
values (objectid, userName);
|
2022-07-22 13:31:37 +02:00
|
|
|
return objectId;
|
2022-07-29 08:46:04 +02:00
|
|
|
end;
|
2022-07-22 13:31:37 +02:00
|
|
|
$$;
|
|
|
|
|
2022-08-12 17:56:39 +02:00
|
|
|
create or replace function createRbacUser(refUuid uuid, userName varchar)
|
|
|
|
returns uuid
|
|
|
|
called on null input
|
|
|
|
language plpgsql as $$
|
|
|
|
begin
|
|
|
|
insert
|
|
|
|
into RbacReference as r (uuid, type)
|
2022-08-13 16:47:36 +02:00
|
|
|
values (coalesce(refUuid, uuid_generate_v4()), 'RbacUser')
|
2022-08-12 17:56:39 +02:00
|
|
|
returning r.uuid into refUuid;
|
|
|
|
insert
|
|
|
|
into RbacUser (uuid, name)
|
|
|
|
values (refUuid, userName);
|
|
|
|
return refUuid;
|
|
|
|
end;
|
|
|
|
$$;
|
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
create or replace function findRbacUserId(userName varchar)
|
|
|
|
returns uuid
|
|
|
|
returns null on null input
|
|
|
|
language sql as $$
|
|
|
|
select uuid from RbacUser where name = userName
|
2022-07-22 13:31:37 +02:00
|
|
|
$$;
|
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
create type RbacWhenNotExists as enum ('fail', 'create');
|
2022-07-25 16:38:21 +02:00
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
create or replace function getRbacUserId(userName varchar, whenNotExists RbacWhenNotExists)
|
|
|
|
returns uuid
|
|
|
|
returns null on null input
|
|
|
|
language plpgsql as $$
|
|
|
|
declare
|
2022-07-22 13:31:37 +02:00
|
|
|
userUuid uuid;
|
2022-07-29 08:46:04 +02:00
|
|
|
begin
|
2022-07-25 16:38:21 +02:00
|
|
|
userUuid = findRbacUserId(userName);
|
2022-07-29 08:46:04 +02:00
|
|
|
if (userUuid is null) then
|
|
|
|
if (whenNotExists = 'fail') then
|
|
|
|
raise exception 'RbacUser with name="%" not found', userName;
|
|
|
|
end if;
|
|
|
|
if (whenNotExists = 'create') then
|
2022-07-22 13:31:37 +02:00
|
|
|
userUuid = createRbacUser(userName);
|
2022-07-29 08:46:04 +02:00
|
|
|
end if;
|
|
|
|
end if;
|
2022-07-22 13:31:37 +02:00
|
|
|
return userUuid;
|
2022-07-29 08:46:04 +02:00
|
|
|
end;
|
2022-07-22 13:31:37 +02:00
|
|
|
$$;
|
|
|
|
|
2022-07-28 16:55:21 +02:00
|
|
|
--//
|
2022-07-27 19:54:05 +02:00
|
|
|
|
2022-08-02 11:51:36 +02:00
|
|
|
-- ============================================================================
|
|
|
|
--changeset rbac-base-OBJECT:1 endDelimiter:--//
|
|
|
|
-- ----------------------------------------------------------------------------
|
2022-07-28 16:55:21 +02:00
|
|
|
/*
|
2022-07-27 19:54:05 +02:00
|
|
|
|
2022-07-28 16:55:21 +02:00
|
|
|
*/
|
2022-07-29 08:46:04 +02:00
|
|
|
create table RbacObject
|
2022-07-28 16:55:21 +02:00
|
|
|
(
|
2022-07-29 08:46:04 +02:00
|
|
|
uuid uuid primary key default uuid_generate_v4(),
|
2022-07-28 16:55:21 +02:00
|
|
|
objectTable varchar(64) not null,
|
|
|
|
unique (objectTable, uuid)
|
|
|
|
);
|
2022-07-27 19:54:05 +02:00
|
|
|
|
2022-08-24 12:52:28 +02:00
|
|
|
call create_journal('RbacObject');
|
2022-08-24 12:01:54 +02:00
|
|
|
|
2022-09-13 10:58:54 +02:00
|
|
|
--//
|
|
|
|
|
|
|
|
|
|
|
|
-- ============================================================================
|
|
|
|
--changeset rbac-base-GENERATE-RELATED-OBJECT:1 endDelimiter:--//
|
|
|
|
-- ----------------------------------------------------------------------------
|
|
|
|
|
|
|
|
/*
|
|
|
|
Inserts related RbacObject for use in the BEFORE ONSERT TRIGGERs on the business objects.
|
|
|
|
*/
|
|
|
|
create or replace function insertRelatedRbacObject()
|
2022-07-29 08:46:04 +02:00
|
|
|
returns trigger
|
|
|
|
language plpgsql
|
|
|
|
strict as $$
|
|
|
|
declare
|
2022-07-28 16:55:21 +02:00
|
|
|
objectUuid uuid;
|
2022-07-29 08:46:04 +02:00
|
|
|
begin
|
|
|
|
if TG_OP = 'INSERT' then
|
2022-08-04 09:09:06 +02:00
|
|
|
if NEW.uuid is null then
|
|
|
|
insert
|
|
|
|
into RbacObject (objectTable)
|
|
|
|
values (TG_TABLE_NAME)
|
|
|
|
returning uuid into objectUuid;
|
|
|
|
NEW.uuid = objectUuid;
|
|
|
|
else
|
|
|
|
insert
|
|
|
|
into RbacObject (uuid, objectTable)
|
|
|
|
values (NEW.uuid, TG_TABLE_NAME)
|
|
|
|
returning uuid into objectUuid;
|
|
|
|
end if;
|
2022-07-29 08:46:04 +02:00
|
|
|
return NEW;
|
|
|
|
else
|
|
|
|
raise exception 'invalid usage of TRIGGER AFTER INSERT';
|
|
|
|
end if;
|
|
|
|
end; $$;
|
2022-09-13 10:58:54 +02:00
|
|
|
|
|
|
|
/*
|
|
|
|
Deletes related RbacObject for use in the BEFORE DELETE TRIGGERs on the business objects.
|
|
|
|
*/
|
|
|
|
create or replace function deleteRelatedRbacObject()
|
|
|
|
returns trigger
|
|
|
|
language plpgsql
|
|
|
|
strict as $$
|
|
|
|
begin
|
|
|
|
if TG_OP = 'DELETE' then
|
|
|
|
delete from RbacObject where rbacobject.uuid = old.uuid;
|
|
|
|
else
|
|
|
|
raise exception 'invalid usage of TRIGGER BEFORE DELETE';
|
|
|
|
end if;
|
|
|
|
return old;
|
|
|
|
end; $$;
|
|
|
|
|
|
|
|
|
2022-08-02 11:51:36 +02:00
|
|
|
-- ============================================================================
|
|
|
|
--changeset rbac-base-ROLE:1 endDelimiter:--//
|
|
|
|
-- ----------------------------------------------------------------------------
|
2022-07-28 16:55:21 +02:00
|
|
|
/*
|
|
|
|
|
|
|
|
*/
|
|
|
|
|
2022-10-12 15:48:56 +02:00
|
|
|
create type RbacRoleType as enum ('owner', 'admin', 'agent', 'tenant', 'guest');
|
2022-07-28 16:55:21 +02:00
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
create table RbacRole
|
2022-07-28 16:55:21 +02:00
|
|
|
(
|
2022-09-13 10:58:54 +02:00
|
|
|
uuid uuid primary key references RbacReference (uuid) on delete cascade initially deferred, -- initially deferred
|
|
|
|
objectUuid uuid not null references RbacObject (uuid) initially deferred,
|
|
|
|
roleType RbacRoleType not null,
|
2022-08-04 09:09:06 +02:00
|
|
|
unique (objectUuid, roleType)
|
2022-07-28 16:55:21 +02:00
|
|
|
);
|
|
|
|
|
2022-08-24 12:52:28 +02:00
|
|
|
call create_journal('RbacRole');
|
2022-08-24 12:01:54 +02:00
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
create type RbacRoleDescriptor as
|
2022-07-28 16:55:21 +02:00
|
|
|
(
|
2022-09-07 12:25:12 +02:00
|
|
|
objectTable varchar(63), -- for human readability and easier debugging
|
2022-07-29 08:46:04 +02:00
|
|
|
objectUuid uuid,
|
|
|
|
roleType RbacRoleType
|
2022-07-28 16:55:21 +02:00
|
|
|
);
|
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
create or replace function roleDescriptor(objectTable varchar(63), objectUuid uuid, roleType RbacRoleType)
|
|
|
|
returns RbacRoleDescriptor
|
|
|
|
returns null on null input
|
2022-08-03 06:12:16 +02:00
|
|
|
stable leakproof
|
2022-07-29 08:46:04 +02:00
|
|
|
language sql as $$
|
|
|
|
select objectTable, objectUuid, roleType::RbacRoleType;
|
2022-07-28 16:55:21 +02:00
|
|
|
$$;
|
2022-07-27 19:54:05 +02:00
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
create or replace function createRole(roleDescriptor RbacRoleDescriptor)
|
|
|
|
returns uuid
|
|
|
|
returns null on null input
|
|
|
|
language plpgsql as $$
|
2022-07-22 13:31:37 +02:00
|
|
|
declare
|
|
|
|
referenceId uuid;
|
2022-07-29 08:46:04 +02:00
|
|
|
begin
|
|
|
|
insert
|
2022-07-29 12:37:40 +02:00
|
|
|
into RbacReference (type)
|
|
|
|
values ('RbacRole')
|
|
|
|
returning uuid into referenceId;
|
2022-07-29 08:46:04 +02:00
|
|
|
insert
|
2022-07-29 12:37:40 +02:00
|
|
|
into RbacRole (uuid, objectUuid, roleType)
|
|
|
|
values (referenceId, roleDescriptor.objectUuid, roleDescriptor.roleType);
|
2022-07-22 13:31:37 +02:00
|
|
|
return referenceId;
|
2022-07-29 08:46:04 +02:00
|
|
|
end;
|
2022-07-22 13:31:37 +02:00
|
|
|
$$;
|
|
|
|
|
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
create or replace procedure deleteRole(roleUUid uuid)
|
|
|
|
language plpgsql as $$
|
|
|
|
begin
|
2022-09-12 16:27:17 +02:00
|
|
|
--raise exception '% deleting role uuid %', currentsubjectsuuids(), roleUUid;
|
2022-07-29 08:46:04 +02:00
|
|
|
delete from RbacRole where uuid = roleUUid;
|
|
|
|
end;
|
2022-07-22 13:31:37 +02:00
|
|
|
$$;
|
|
|
|
|
2022-08-13 16:47:36 +02:00
|
|
|
create or replace function findRoleId(roleIdName varchar)
|
|
|
|
returns uuid
|
|
|
|
returns null on null input
|
|
|
|
language plpgsql as $$
|
|
|
|
declare
|
|
|
|
roleParts text;
|
|
|
|
roleTypeFromRoleIdName RbacRoleType;
|
|
|
|
objectNameFromRoleIdName text;
|
|
|
|
objectTableFromRoleIdName text;
|
|
|
|
objectUuidOfRole uuid;
|
|
|
|
roleUuid uuid;
|
|
|
|
begin
|
2022-09-07 12:25:12 +02:00
|
|
|
-- TODO.refact: extract function toRbacRoleDescriptor(roleIdName varchar) + find other occurrences
|
2022-08-13 16:47:36 +02:00
|
|
|
roleParts = overlay(roleIdName placing '#' from length(roleIdName) + 1 - strpos(reverse(roleIdName), '.'));
|
|
|
|
objectTableFromRoleIdName = split_part(roleParts, '#', 1);
|
|
|
|
objectNameFromRoleIdName = split_part(roleParts, '#', 2);
|
|
|
|
roleTypeFromRoleIdName = split_part(roleParts, '#', 3);
|
|
|
|
objectUuidOfRole = findObjectUuidByIdName(objectTableFromRoleIdName, objectNameFromRoleIdName);
|
|
|
|
|
|
|
|
select uuid
|
|
|
|
from RbacRole
|
|
|
|
where objectUuid = objectUuidOfRole
|
|
|
|
and roleType = roleTypeFromRoleIdName
|
|
|
|
into roleUuid;
|
|
|
|
return roleUuid;
|
|
|
|
end; $$;
|
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
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;
|
2022-07-22 13:31:37 +02:00
|
|
|
$$;
|
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
create or replace function getRoleId(roleDescriptor RbacRoleDescriptor, whenNotExists RbacWhenNotExists)
|
|
|
|
returns uuid
|
|
|
|
returns null on null input
|
|
|
|
language plpgsql as $$
|
|
|
|
declare
|
2022-07-22 13:31:37 +02:00
|
|
|
roleUuid uuid;
|
2022-07-29 08:46:04 +02:00
|
|
|
begin
|
2022-07-27 19:54:05 +02:00
|
|
|
roleUuid = findRoleId(roleDescriptor);
|
2022-07-29 08:46:04 +02:00
|
|
|
if (roleUuid is null) then
|
|
|
|
if (whenNotExists = 'fail') then
|
|
|
|
raise exception 'RbacRole "%#%.%" not found', roleDescriptor.objectTable, roleDescriptor.objectUuid, roleDescriptor.roleType;
|
|
|
|
end if;
|
|
|
|
if (whenNotExists = 'create') then
|
2022-07-27 19:54:05 +02:00
|
|
|
roleUuid = createRole(roleDescriptor);
|
2022-07-29 08:46:04 +02:00
|
|
|
end if;
|
|
|
|
end if;
|
2022-07-22 13:31:37 +02:00
|
|
|
return roleUuid;
|
2022-07-29 08:46:04 +02:00
|
|
|
end;
|
2022-07-22 13:31:37 +02:00
|
|
|
$$;
|
|
|
|
|
2022-09-12 16:27:17 +02:00
|
|
|
|
|
|
|
-- ============================================================================
|
2022-09-13 10:58:54 +02:00
|
|
|
--changeset rbac-base-BEFORE-DELETE-ROLE-TRIGGER:1 endDelimiter:--//
|
2022-09-12 16:27:17 +02:00
|
|
|
-- ----------------------------------------------------------------------------
|
|
|
|
|
|
|
|
/*
|
|
|
|
RbacRole BEFORE DELETE TRIGGER function which deletes all related roles.
|
|
|
|
*/
|
2022-09-13 10:58:54 +02:00
|
|
|
create or replace function deleteRbacGrantsOfRbacRole()
|
2022-09-12 16:27:17 +02:00
|
|
|
returns trigger
|
|
|
|
language plpgsql
|
|
|
|
strict as $$
|
|
|
|
begin
|
|
|
|
if TG_OP = 'DELETE' then
|
|
|
|
delete from RbacGrants g where old.uuid in (g.grantedbyroleuuid, g.ascendantuuid, g.descendantuuid);
|
|
|
|
else
|
|
|
|
raise exception 'invalid usage of TRIGGER BEFORE DELETE';
|
|
|
|
end if;
|
|
|
|
return old;
|
|
|
|
end; $$;
|
|
|
|
|
|
|
|
/*
|
|
|
|
Installs the RbacRole BEFORE DELETE TRIGGER.
|
|
|
|
*/
|
2022-09-13 10:58:54 +02:00
|
|
|
create trigger deleteRbacGrantsOfRbacRole_Trigger
|
2022-09-12 16:27:17 +02:00
|
|
|
before delete
|
|
|
|
on RbacRole
|
|
|
|
for each row
|
2022-09-13 10:58:54 +02:00
|
|
|
execute procedure deleteRbacGrantsOfRbacRole();
|
|
|
|
--//
|
|
|
|
|
|
|
|
|
|
|
|
-- ============================================================================
|
|
|
|
--changeset rbac-base-BEFORE-DELETE-OBJECT-TRIGGER:1 endDelimiter:--//
|
|
|
|
-- ----------------------------------------------------------------------------
|
|
|
|
|
|
|
|
/*
|
|
|
|
RbacObject BEFORE DELETE TRIGGER function which deletes all related roles.
|
|
|
|
*/
|
|
|
|
create or replace function deleteRbacRolesOfRbacObject()
|
|
|
|
returns trigger
|
|
|
|
language plpgsql
|
|
|
|
strict as $$
|
|
|
|
begin
|
|
|
|
if TG_OP = 'DELETE' then
|
|
|
|
delete from RbacPermission p where p.objectuuid = old.uuid;
|
|
|
|
delete from RbacRole r where r.objectUuid = old.uuid;
|
|
|
|
else
|
|
|
|
raise exception 'invalid usage of TRIGGER BEFORE DELETE';
|
|
|
|
end if;
|
|
|
|
return old;
|
|
|
|
end; $$;
|
|
|
|
|
|
|
|
/*
|
|
|
|
Installs the RbacRole BEFORE DELETE TRIGGER.
|
|
|
|
*/
|
|
|
|
create trigger deleteRbacRolesOfRbacObject_Trigger
|
|
|
|
before delete
|
|
|
|
on RbacObject
|
|
|
|
for each row
|
|
|
|
execute procedure deleteRbacRolesOfRbacObject();
|
2022-09-12 16:27:17 +02:00
|
|
|
--//
|
|
|
|
|
|
|
|
|
2022-08-02 11:51:36 +02:00
|
|
|
-- ============================================================================
|
|
|
|
--changeset rbac-base-PERMISSION:1 endDelimiter:--//
|
|
|
|
-- ----------------------------------------------------------------------------
|
2022-07-28 16:55:21 +02:00
|
|
|
/*
|
|
|
|
|
|
|
|
*/
|
2022-07-29 08:46:04 +02:00
|
|
|
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]+$'
|
2022-10-20 20:11:31 +02:00
|
|
|
or VALUE ~ '^new-[a-z-]+$'
|
2022-07-28 16:55:21 +02:00
|
|
|
);
|
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
create table RbacPermission
|
|
|
|
(
|
|
|
|
uuid uuid primary key references RbacReference (uuid) on delete cascade,
|
|
|
|
objectUuid uuid not null references RbacObject,
|
|
|
|
op RbacOp not null,
|
2022-07-28 16:55:21 +02:00
|
|
|
unique (objectUuid, op)
|
|
|
|
);
|
|
|
|
|
2022-08-24 12:52:28 +02:00
|
|
|
call create_journal('RbacPermission');
|
2022-08-24 12:01:54 +02:00
|
|
|
|
2022-08-02 11:51:36 +02:00
|
|
|
create or replace function permissionExists(forObjectUuid uuid, forOp RbacOp)
|
2022-07-29 08:46:04 +02:00
|
|
|
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[]
|
|
|
|
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
|
2022-07-29 12:37:40 +02:00
|
|
|
into RbacReference ("type")
|
|
|
|
values ('RbacPermission')
|
|
|
|
returning uuid into refId;
|
2022-07-29 08:46:04 +02:00
|
|
|
insert
|
2022-07-29 12:37:40 +02:00
|
|
|
into RbacPermission (uuid, objectUuid, op)
|
|
|
|
values (refId, forObjectUuid, permitOps[i]);
|
2022-07-29 08:46:04 +02:00
|
|
|
end if;
|
|
|
|
permissionIds = permissionIds || refId;
|
|
|
|
end loop;
|
|
|
|
|
2022-07-22 13:31:37 +02:00
|
|
|
return permissionIds;
|
2022-07-29 08:46:04 +02:00
|
|
|
end;
|
2022-07-22 13:31:37 +02:00
|
|
|
$$;
|
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
create or replace function findPermissionId(forObjectUuid uuid, forOp RbacOp)
|
|
|
|
returns uuid
|
|
|
|
returns null on null input
|
|
|
|
stable leakproof
|
|
|
|
language sql as $$
|
|
|
|
select uuid
|
|
|
|
from RbacPermission p
|
|
|
|
where p.objectUuid = forObjectUuid
|
|
|
|
and p.op in ('*', forOp)
|
2022-07-22 13:31:37 +02:00
|
|
|
$$;
|
|
|
|
|
2022-07-28 16:55:21 +02:00
|
|
|
--//
|
|
|
|
|
2022-08-02 11:51:36 +02:00
|
|
|
-- ============================================================================
|
|
|
|
--changeset rbac-base-GRANTS:1 endDelimiter:--//
|
|
|
|
-- ----------------------------------------------------------------------------
|
2022-07-28 16:55:21 +02:00
|
|
|
/*
|
2022-08-13 16:47:36 +02:00
|
|
|
Table to store grants / role- or permission assignments to users or roles.
|
2022-07-28 16:55:21 +02:00
|
|
|
*/
|
2022-07-29 08:46:04 +02:00
|
|
|
create table RbacGrants
|
2022-07-28 16:55:21 +02:00
|
|
|
(
|
2022-08-24 12:01:54 +02:00
|
|
|
uuid uuid primary key default uuid_generate_v4(),
|
2022-09-12 16:27:17 +02:00
|
|
|
grantedByRoleUuid uuid references RbacRole (uuid),
|
|
|
|
ascendantUuid uuid references RbacReference (uuid),
|
|
|
|
descendantUuid uuid references RbacReference (uuid),
|
2022-08-16 10:46:41 +02:00
|
|
|
assumed boolean not null default true, -- auto assumed (true) vs. needs assumeRoles (false)
|
2022-08-24 12:01:54 +02:00
|
|
|
unique (ascendantUuid, descendantUuid)
|
2022-07-28 16:55:21 +02:00
|
|
|
);
|
2022-07-29 08:46:04 +02:00
|
|
|
create index on RbacGrants (ascendantUuid);
|
|
|
|
create index on RbacGrants (descendantUuid);
|
2022-07-28 16:55:21 +02:00
|
|
|
|
2022-08-24 12:52:28 +02:00
|
|
|
call create_journal('RbacGrants');
|
2022-07-28 16:55:21 +02:00
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
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;
|
2022-07-28 16:55:21 +02:00
|
|
|
$$;
|
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
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);
|
2022-07-28 16:55:21 +02:00
|
|
|
$$;
|
|
|
|
|
2022-08-03 06:12:16 +02:00
|
|
|
create or replace function isGranted(granteeIds uuid[], grantedId uuid)
|
|
|
|
returns bool
|
|
|
|
returns null on null input
|
|
|
|
language plpgsql as $$
|
|
|
|
declare
|
|
|
|
granteeId uuid;
|
|
|
|
begin
|
2022-09-07 12:25:12 +02:00
|
|
|
-- TODO.perf: needs optimization
|
2022-08-13 16:47:36 +02:00
|
|
|
foreach granteeId in array granteeIds
|
|
|
|
loop
|
2022-08-03 06:12:16 +02:00
|
|
|
if isGranted(granteeId, grantedId) then
|
|
|
|
return true;
|
|
|
|
end if;
|
|
|
|
end loop;
|
|
|
|
return false;
|
|
|
|
end; $$;
|
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
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)
|
2022-07-28 16:55:21 +02:00
|
|
|
);
|
|
|
|
$$;
|
2022-07-22 13:31:37 +02:00
|
|
|
|
2022-08-05 14:31:54 +02:00
|
|
|
create or replace function hasGlobalRoleGranted(userUuid uuid)
|
|
|
|
returns bool
|
|
|
|
stable leakproof
|
|
|
|
language sql as $$
|
|
|
|
select exists(
|
|
|
|
select r.uuid
|
2022-08-13 16:47:36 +02:00
|
|
|
from RbacGrants as g
|
|
|
|
join RbacRole as r on r.uuid = g.descendantuuid
|
|
|
|
join RbacObject as o on o.uuid = r.objectuuid
|
|
|
|
where g.ascendantuuid = userUuid
|
|
|
|
and o.objecttable = 'global'
|
2022-08-05 14:31:54 +02:00
|
|
|
);
|
|
|
|
$$;
|
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
create or replace procedure grantPermissionsToRole(roleUuid uuid, permissionIds uuid[])
|
|
|
|
language plpgsql as $$
|
|
|
|
begin
|
2022-07-29 12:37:40 +02:00
|
|
|
if cardinality(permissionIds) = 0 then return; end if;
|
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
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
|
2022-08-16 10:46:41 +02:00
|
|
|
into RbacGrants (ascendantUuid, descendantUuid, assumed)
|
|
|
|
values (roleUuid, permissionIds[i], true)
|
2022-08-02 11:51:36 +02:00
|
|
|
on conflict do nothing; -- allow granting multiple times
|
2022-07-29 08:46:04 +02:00
|
|
|
end loop;
|
|
|
|
end;
|
2022-07-22 13:31:37 +02:00
|
|
|
$$;
|
|
|
|
|
2022-08-13 16:47:36 +02:00
|
|
|
create or replace procedure grantRoleToRole(subRoleId uuid, superRoleId uuid, doAssume bool = true)
|
2022-07-29 08:46:04 +02:00
|
|
|
language plpgsql as $$
|
|
|
|
begin
|
2022-07-22 13:31:37 +02:00
|
|
|
perform assertReferenceType('superRoleId (ascendant)', superRoleId, 'RbacRole');
|
2022-07-29 08:46:04 +02:00
|
|
|
perform assertReferenceType('subRoleId (descendant)', subRoleId, 'RbacRole');
|
2022-07-22 13:31:37 +02:00
|
|
|
|
2022-08-16 10:46:41 +02:00
|
|
|
if isGranted(subRoleId, superRoleId) then
|
2022-08-05 14:31:54 +02:00
|
|
|
raise exception '[400] Cyclic role grant detected between % and %', subRoleId, superRoleId;
|
2022-07-29 08:46:04 +02:00
|
|
|
end if;
|
2022-07-22 13:31:37 +02:00
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
insert
|
2022-08-16 10:46:41 +02:00
|
|
|
into RbacGrants (ascendantuuid, descendantUuid, assumed)
|
|
|
|
values (superRoleId, subRoleId, doAssume)
|
2022-08-02 11:51:36 +02:00
|
|
|
on conflict do nothing; -- allow granting multiple times
|
2022-07-29 08:46:04 +02:00
|
|
|
end; $$;
|
2022-07-22 13:31:37 +02:00
|
|
|
|
2022-09-15 13:32:01 +02:00
|
|
|
|
|
|
|
create or replace procedure grantRoleToRole(subRole RbacRoleDescriptor, superRole RbacRoleDescriptor, doAssume bool = true)
|
|
|
|
language plpgsql as $$
|
|
|
|
declare
|
|
|
|
superRoleId uuid;
|
|
|
|
subRoleId uuid;
|
|
|
|
begin
|
|
|
|
superRoleId := findRoleId(superRole);
|
|
|
|
subRoleId := findRoleId(subRole);
|
|
|
|
|
|
|
|
perform assertReferenceType('superRoleId (ascendant)', superRoleId, 'RbacRole');
|
|
|
|
perform assertReferenceType('subRoleId (descendant)', subRoleId, 'RbacRole');
|
|
|
|
|
|
|
|
if isGranted(subRoleId, superRoleId) then
|
|
|
|
raise exception '[400] Cyclic role grant detected between % and %', subRoleId, superRoleId;
|
|
|
|
end if;
|
|
|
|
|
|
|
|
insert
|
|
|
|
into RbacGrants (ascendantuuid, descendantUuid, assumed)
|
|
|
|
values (superRoleId, subRoleId, doAssume)
|
|
|
|
on conflict do nothing; -- allow granting multiple times
|
|
|
|
end; $$;
|
|
|
|
|
2022-09-26 10:57:22 +02:00
|
|
|
create or replace procedure grantRoleToRoleIfNotNull(subRole RbacRoleDescriptor, superRole RbacRoleDescriptor, doAssume bool = true)
|
2022-07-29 08:46:04 +02:00
|
|
|
language plpgsql as $$
|
2022-09-26 10:57:22 +02:00
|
|
|
declare
|
|
|
|
superRoleId uuid;
|
|
|
|
subRoleId uuid;
|
2022-07-29 08:46:04 +02:00
|
|
|
begin
|
2022-09-26 10:57:22 +02:00
|
|
|
superRoleId := findRoleId(superRole);
|
|
|
|
if ( subRoleId is null ) then return; end if;
|
|
|
|
subRoleId := findRoleId(subRole);
|
|
|
|
|
2022-07-22 13:31:37 +02:00
|
|
|
perform assertReferenceType('superRoleId (ascendant)', superRoleId, 'RbacRole');
|
2022-07-29 08:46:04 +02:00
|
|
|
perform assertReferenceType('subRoleId (descendant)', subRoleId, 'RbacRole');
|
2022-07-22 13:31:37 +02:00
|
|
|
|
2022-09-26 10:57:22 +02:00
|
|
|
if isGranted(subRoleId, superRoleId) then
|
|
|
|
raise exception '[400] Cyclic role grant detected between % and %', subRoleId, superRoleId;
|
2022-09-15 13:32:01 +02:00
|
|
|
end if;
|
2022-09-26 10:57:22 +02:00
|
|
|
|
|
|
|
insert
|
|
|
|
into RbacGrants (ascendantuuid, descendantUuid, assumed)
|
|
|
|
values (superRoleId, subRoleId, doAssume)
|
|
|
|
on conflict do nothing; -- allow granting multiple times
|
2022-09-15 13:32:01 +02:00
|
|
|
end; $$;
|
|
|
|
|
|
|
|
create or replace procedure revokeRoleFromRole(subRole RbacRoleDescriptor, superRole RbacRoleDescriptor)
|
|
|
|
language plpgsql as $$
|
|
|
|
declare
|
|
|
|
superRoleId uuid;
|
|
|
|
subRoleId uuid;
|
|
|
|
begin
|
|
|
|
superRoleId := findRoleId(superRole);
|
|
|
|
subRoleId := findRoleId(subRole);
|
|
|
|
|
|
|
|
perform assertReferenceType('superRoleId (ascendant)', superRoleId, 'RbacRole');
|
|
|
|
perform assertReferenceType('subRoleId (descendant)', subRoleId, 'RbacRole');
|
|
|
|
|
|
|
|
if (isGranted(superRoleId, subRoleId)) then
|
2022-07-29 08:46:04 +02:00
|
|
|
delete from RbacGrants where ascendantUuid = superRoleId and descendantUuid = subRoleId;
|
2022-09-15 13:32:01 +02:00
|
|
|
else
|
|
|
|
raise exception 'cannot revoke role % (%) from % (% because it is not granted',
|
|
|
|
subRole, subRoleId, superRole, superRoleId;
|
2022-07-29 08:46:04 +02:00
|
|
|
end if;
|
|
|
|
end; $$;
|
2022-07-22 13:31:37 +02:00
|
|
|
|
2022-08-02 11:51:36 +02:00
|
|
|
-- ============================================================================
|
|
|
|
--changeset rbac-base-QUERY-ACCESSIBLE-OBJECT-UUIDS:1 endDelimiter:--//
|
|
|
|
-- ----------------------------------------------------------------------------
|
2022-07-28 16:55:21 +02:00
|
|
|
/*
|
2022-07-25 16:38:21 +02:00
|
|
|
|
2022-07-28 16:55:21 +02:00
|
|
|
*/
|
2022-07-29 08:46:04 +02:00
|
|
|
create or replace function queryAccessibleObjectUuidsOfSubjectIds(
|
|
|
|
requiredOp RbacOp,
|
|
|
|
forObjectTable varchar, -- reduces the result set, but is not really faster when used in restricted view
|
|
|
|
subjectIds uuid[],
|
|
|
|
maxObjects integer = 8000)
|
|
|
|
returns setof uuid
|
|
|
|
returns null on null input
|
|
|
|
language plpgsql as $$
|
|
|
|
declare
|
|
|
|
foundRows bigint;
|
|
|
|
begin
|
|
|
|
return query select distinct perm.objectUuid
|
|
|
|
from (with recursive grants as (select descendantUuid, ascendantUuid, 1 as level
|
|
|
|
from RbacGrants
|
2022-08-13 16:47:36 +02:00
|
|
|
where assumed
|
2022-07-29 08:46:04 +02:00
|
|
|
and ascendantUuid = any (subjectIds)
|
|
|
|
union
|
|
|
|
distinct
|
|
|
|
select "grant".descendantUuid, "grant".ascendantUuid, level + 1 as level
|
|
|
|
from RbacGrants "grant"
|
|
|
|
inner join grants recur on recur.descendantUuid = "grant".ascendantUuid
|
2022-08-13 16:47:36 +02:00
|
|
|
where assumed)
|
2022-07-29 08:46:04 +02:00
|
|
|
select descendantUuid
|
|
|
|
from grants) as granted
|
|
|
|
join RbacPermission perm
|
|
|
|
on granted.descendantUuid = perm.uuid and perm.op in ('*', requiredOp)
|
|
|
|
join RbacObject obj on obj.uuid = perm.objectUuid and obj.objectTable = forObjectTable
|
|
|
|
limit maxObjects + 1;
|
|
|
|
|
|
|
|
foundRows = lastRowCount();
|
|
|
|
if foundRows > maxObjects then
|
2022-08-05 14:31:54 +02:00
|
|
|
raise exception '[400] Too many accessible objects, limit is %, found %.', maxObjects, foundRows
|
2022-07-29 08:46:04 +02:00
|
|
|
using
|
|
|
|
errcode = 'P0003',
|
|
|
|
hint = 'Please assume a sub-role and try again.';
|
|
|
|
end if;
|
|
|
|
end;
|
2022-07-22 13:31:37 +02:00
|
|
|
$$;
|
|
|
|
|
2022-07-28 16:55:21 +02:00
|
|
|
--//
|
|
|
|
|
2022-08-02 11:51:36 +02:00
|
|
|
-- ============================================================================
|
|
|
|
--changeset rbac-base-QUERY-GRANTED-PERMISSIONS:1 endDelimiter:--//
|
|
|
|
-- ----------------------------------------------------------------------------
|
2022-07-28 16:55:21 +02:00
|
|
|
/*
|
2022-08-04 17:19:45 +02:00
|
|
|
Returns all permissions accessible to the given subject UUID (user or role).
|
2022-07-28 16:55:21 +02:00
|
|
|
*/
|
2022-08-04 17:19:45 +02:00
|
|
|
create or replace function queryPermissionsGrantedToSubjectId(subjectId uuid)
|
2022-07-29 08:46:04 +02:00
|
|
|
returns setof RbacPermission
|
|
|
|
strict
|
|
|
|
language sql as $$
|
2022-08-13 16:47:36 +02:00
|
|
|
-- @formatter:off
|
2022-08-04 17:19:45 +02:00
|
|
|
select *
|
2022-07-29 08:46:04 +02:00
|
|
|
from RbacPermission
|
2022-08-04 17:19:45 +02:00
|
|
|
where uuid in (
|
|
|
|
with recursive grants as (
|
|
|
|
select distinct 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
|
|
|
|
);
|
|
|
|
-- @formatter:on
|
2022-07-22 13:31:37 +02:00
|
|
|
$$;
|
2022-07-28 16:55:21 +02:00
|
|
|
--//
|
2022-07-22 13:31:37 +02:00
|
|
|
|
2022-08-02 11:51:36 +02:00
|
|
|
-- ============================================================================
|
|
|
|
--changeset rbac-base-QUERY-USERS-WITH-PERMISSION-FOR-OBJECT:1 endDelimiter:--//
|
|
|
|
-- ----------------------------------------------------------------------------
|
2022-07-27 19:54:05 +02:00
|
|
|
/*
|
2022-08-04 17:19:45 +02:00
|
|
|
Returns all user UUIDs which have any permission for the given object UUID.
|
2022-07-28 16:55:21 +02:00
|
|
|
*/
|
2022-07-22 13:31:37 +02:00
|
|
|
|
2022-07-29 08:46:04 +02:00
|
|
|
create or replace function queryAllRbacUsersWithPermissionsFor(objectId uuid)
|
|
|
|
returns setof RbacUser
|
|
|
|
returns null on null input
|
|
|
|
language sql as $$
|
|
|
|
select *
|
|
|
|
from RbacUser
|
2022-08-14 16:44:26 +02:00
|
|
|
where uuid in (
|
|
|
|
-- @formatter:off
|
|
|
|
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
|
|
|
|
)
|
|
|
|
-- @formatter:on
|
|
|
|
select ascendantUuid
|
|
|
|
from grants);
|
2022-07-22 13:31:37 +02:00
|
|
|
$$;
|
2022-07-28 16:55:21 +02:00
|
|
|
--//
|
2022-07-22 13:31:37 +02:00
|
|
|
|
2022-07-29 11:38:51 +02:00
|
|
|
|
|
|
|
-- ============================================================================
|
2022-08-02 11:51:36 +02:00
|
|
|
--changeset rbac-base-PGSQL-ROLES:1 endDelimiter:--//
|
|
|
|
-- ----------------------------------------------------------------------------
|
2022-07-29 11:38:51 +02:00
|
|
|
|
2022-07-29 12:37:40 +02:00
|
|
|
create role admin;
|
|
|
|
grant all privileges on all tables in schema public to admin;
|
2022-07-29 11:38:51 +02:00
|
|
|
|
2022-07-29 12:37:40 +02:00
|
|
|
create role restricted;
|
|
|
|
grant all privileges on all tables in schema public to restricted;
|
2022-07-29 11:38:51 +02:00
|
|
|
|
|
|
|
--//
|