introduce separate database-schemas base+rbac (#103)
Co-authored-by: Michael Hoennig <michael@hoennig.de> Co-authored-by: Michael Hönnig <michael@hoennig.de> Reviewed-on: https://dev.hostsharing.net/hostsharing/hs.hsadmin.ng/pulls/103 Reviewed-by: Marc Sandlus <marc.sandlus@hostsharing.net>
This commit is contained in:
@@ -0,0 +1,8 @@
|
||||
--liquibase formatted sql
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset michael.hoennig:rbac-SCHEMA endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
CREATE SCHEMA rbac;
|
||||
--//
|
@@ -1,30 +1,30 @@
|
||||
--liquibase formatted sql
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-REFERENCE:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-base-REFERENCE endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
|
||||
*/
|
||||
create type ReferenceType as enum ('RbacUser', 'RbacRole', 'RbacPermission');
|
||||
create type rbac.ReferenceType as enum ('rbac.subject', 'rbac.role', 'rbac.permission');
|
||||
|
||||
create table RbacReference
|
||||
create table rbac.reference
|
||||
(
|
||||
uuid uuid unique default uuid_generate_v4(),
|
||||
type ReferenceType not null
|
||||
type rbac.ReferenceType not null
|
||||
);
|
||||
|
||||
create or replace function assertReferenceType(argument varchar, referenceId uuid, expectedType ReferenceType)
|
||||
returns ReferenceType
|
||||
create or replace function rbac.assertReferenceType(argument varchar, referenceId uuid, expectedType rbac.ReferenceType)
|
||||
returns rbac.ReferenceType
|
||||
language plpgsql as $$
|
||||
declare
|
||||
actualType ReferenceType;
|
||||
actualType rbac.ReferenceType;
|
||||
begin
|
||||
if referenceId is null then
|
||||
raise exception '% must be a % and not null', argument, expectedType;
|
||||
end if;
|
||||
|
||||
actualType = (select type from RbacReference where uuid = referenceId);
|
||||
actualType = (select type from rbac.reference where uuid = referenceId);
|
||||
if (actualType <> expectedType) then
|
||||
raise exception '% must reference a %, but got a %', argument, expectedType, actualType;
|
||||
end if;
|
||||
@@ -33,20 +33,20 @@ end; $$;
|
||||
--//
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-USER:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-base-SUBJECT endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
|
||||
*/
|
||||
create table RbacUser
|
||||
create table rbac.subject
|
||||
(
|
||||
uuid uuid primary key references RbacReference (uuid) on delete cascade,
|
||||
uuid uuid primary key references rbac.reference (uuid) on delete cascade,
|
||||
name varchar(63) not null unique
|
||||
);
|
||||
|
||||
call create_journal('RbacUser');
|
||||
call base.create_journal('rbac.subject');
|
||||
|
||||
create or replace function createRbacUser(userName varchar)
|
||||
create or replace function rbac.create_subject(subjectName varchar)
|
||||
returns uuid
|
||||
returns null on null input
|
||||
language plpgsql as $$
|
||||
@@ -54,47 +54,47 @@ declare
|
||||
objectId uuid;
|
||||
begin
|
||||
insert
|
||||
into RbacReference (type)
|
||||
values ('RbacUser')
|
||||
into rbac.reference (type)
|
||||
values ('rbac.subject')
|
||||
returning uuid into objectId;
|
||||
insert
|
||||
into RbacUser (uuid, name)
|
||||
values (objectid, userName);
|
||||
into rbac.subject (uuid, name)
|
||||
values (objectid, subjectName);
|
||||
return objectId;
|
||||
end;
|
||||
$$;
|
||||
|
||||
create or replace function createRbacUser(refUuid uuid, userName varchar)
|
||||
create or replace function rbac.create_subject(refUuid uuid, subjectName varchar)
|
||||
returns uuid
|
||||
called on null input
|
||||
language plpgsql as $$
|
||||
begin
|
||||
insert
|
||||
into RbacReference as r (uuid, type)
|
||||
values (coalesce(refUuid, uuid_generate_v4()), 'RbacUser')
|
||||
into rbac.reference as r (uuid, type)
|
||||
values (coalesce(refUuid, uuid_generate_v4()), 'rbac.subject')
|
||||
returning r.uuid into refUuid;
|
||||
insert
|
||||
into RbacUser (uuid, name)
|
||||
values (refUuid, userName);
|
||||
into rbac.subject (uuid, name)
|
||||
values (refUuid, subjectName);
|
||||
return refUuid;
|
||||
end;
|
||||
$$;
|
||||
|
||||
create or replace function findRbacUserId(userName varchar)
|
||||
create or replace function rbac.find_subject_id(subjectName varchar)
|
||||
returns uuid
|
||||
returns null on null input
|
||||
language sql as $$
|
||||
select uuid from RbacUser where name = userName
|
||||
select uuid from rbac.subject where name = subjectName
|
||||
$$;
|
||||
--//
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-OBJECT:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-base-OBJECT endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
|
||||
*/
|
||||
create table RbacObject
|
||||
create table rbac.object
|
||||
(
|
||||
uuid uuid primary key default uuid_generate_v4(),
|
||||
serialId serial, -- TODO.perf: only needed for reverse deletion of temp test data
|
||||
@@ -102,19 +102,19 @@ create table RbacObject
|
||||
unique (objectTable, uuid)
|
||||
);
|
||||
|
||||
call create_journal('RbacObject');
|
||||
call base.create_journal('rbac.object');
|
||||
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-GENERATE-RELATED-OBJECT:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-base-GENERATE-RELATED-OBJECT endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
/*
|
||||
Inserts related RbacObject for use in the BEFORE ONSERT TRIGGERs on the business objects.
|
||||
Inserts related rbac.object for use in the BEFORE INSERT TRIGGERs on the business objects.
|
||||
*/
|
||||
create or replace function insertRelatedRbacObject()
|
||||
create or replace function rbac.insert_related_object()
|
||||
returns trigger
|
||||
language plpgsql
|
||||
strict as $$
|
||||
@@ -124,13 +124,13 @@ begin
|
||||
if TG_OP = 'INSERT' then
|
||||
if NEW.uuid is null then
|
||||
insert
|
||||
into RbacObject (objectTable)
|
||||
into rbac.object (objectTable)
|
||||
values (TG_TABLE_NAME)
|
||||
returning uuid into objectUuid;
|
||||
NEW.uuid = objectUuid;
|
||||
else
|
||||
insert
|
||||
into RbacObject (uuid, objectTable)
|
||||
into rbac.object (uuid, objectTable)
|
||||
values (NEW.uuid, TG_TABLE_NAME)
|
||||
returning uuid into objectUuid;
|
||||
end if;
|
||||
@@ -141,75 +141,79 @@ begin
|
||||
end; $$;
|
||||
|
||||
/*
|
||||
Deletes related RbacObject for use in the BEFORE DELETE TRIGGERs on the business objects.
|
||||
Deletes related rbac.object for use in the BEFORE DELETE TRIGGERs on the business objects.
|
||||
Through cascades all related rbac roles and grants are going to be deleted as well.
|
||||
*/
|
||||
create or replace function deleteRelatedRbacObject()
|
||||
create or replace function rbac.delete_related_rbac_rules_tf()
|
||||
returns trigger
|
||||
language plpgsql
|
||||
strict as $$
|
||||
begin
|
||||
if TG_OP = 'DELETE' then
|
||||
delete from RbacObject where rbacobject.uuid = old.uuid;
|
||||
delete from rbac.object where rbac.object.uuid = old.uuid;
|
||||
else
|
||||
raise exception 'invalid usage of TRIGGER BEFORE DELETE';
|
||||
end if;
|
||||
return old;
|
||||
end; $$;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-ROLE:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-base-ROLE endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
|
||||
*/
|
||||
create type rbac.RoleType as enum ('OWNER', 'ADMIN', 'AGENT', 'TENANT', 'GUEST', 'REFERRER');
|
||||
|
||||
create type RbacRoleType as enum ('OWNER', 'ADMIN', 'AGENT', 'TENANT', 'GUEST', 'REFERRER');
|
||||
|
||||
create table RbacRole
|
||||
create table rbac.role
|
||||
(
|
||||
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,
|
||||
uuid uuid primary key references rbac.reference (uuid) on delete cascade initially deferred, -- initially deferred
|
||||
objectUuid uuid not null references rbac.object (uuid) initially deferred,
|
||||
roleType rbac.RoleType not null,
|
||||
unique (objectUuid, roleType)
|
||||
);
|
||||
|
||||
call create_journal('RbacRole');
|
||||
call base.create_journal('rbac.role');
|
||||
--//
|
||||
|
||||
create type RbacRoleDescriptor as
|
||||
|
||||
-- ============================================================================
|
||||
--changeset michael.hoennig:rbac-base-ROLE-DESCRIPTOR endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create type rbac.RoleDescriptor as
|
||||
(
|
||||
objectTable varchar(63), -- for human readability and easier debugging
|
||||
objectUuid uuid,
|
||||
roleType RbacRoleType,
|
||||
roleType rbac.RoleType,
|
||||
assumed boolean
|
||||
);
|
||||
|
||||
create or replace function assumed()
|
||||
create or replace function rbac.assumed()
|
||||
returns boolean
|
||||
stable -- leakproof
|
||||
language sql as $$
|
||||
select true;
|
||||
$$;
|
||||
|
||||
create or replace function unassumed()
|
||||
create or replace function rbac.unassumed()
|
||||
returns boolean
|
||||
stable -- leakproof
|
||||
language sql as $$
|
||||
select false;
|
||||
$$;
|
||||
|
||||
|
||||
create or replace function roleDescriptor(
|
||||
objectTable varchar(63), objectUuid uuid, roleType RbacRoleType,
|
||||
create or replace function rbac.roleDescriptorOf(
|
||||
objectTable varchar(63), objectUuid uuid, roleType rbac.RoleType,
|
||||
assumed boolean = true) -- just for DSL readability, belongs actually to the grant
|
||||
returns RbacRoleDescriptor
|
||||
returns rbac.RoleDescriptor
|
||||
returns null on null input
|
||||
stable -- leakproof
|
||||
language sql as $$
|
||||
select objectTable, objectUuid, roleType::RbacRoleType, assumed;
|
||||
select objectTable, objectUuid, roleType::rbac.RoleType, assumed;
|
||||
$$;
|
||||
|
||||
create or replace function createRole(roleDescriptor RbacRoleDescriptor)
|
||||
create or replace function rbac.createRole(roleDescriptor rbac.RoleDescriptor)
|
||||
returns uuid
|
||||
returns null on null input
|
||||
language plpgsql as $$
|
||||
@@ -217,60 +221,65 @@ declare
|
||||
referenceId uuid;
|
||||
begin
|
||||
insert
|
||||
into RbacReference (type)
|
||||
values ('RbacRole')
|
||||
into rbac.reference (type)
|
||||
values ('rbac.role')
|
||||
returning uuid into referenceId;
|
||||
insert
|
||||
into RbacRole (uuid, objectUuid, roleType)
|
||||
into rbac.role (uuid, objectUuid, roleType)
|
||||
values (referenceId, roleDescriptor.objectUuid, roleDescriptor.roleType);
|
||||
return referenceId;
|
||||
end;
|
||||
$$;
|
||||
--//
|
||||
|
||||
|
||||
create or replace procedure deleteRole(roleUUid uuid)
|
||||
-- ============================================================================
|
||||
--changeset michael.hoennig:rbac-base-ROLE-FUNCTIONS endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace procedure rbac.deleteRole(roleUUid uuid)
|
||||
language plpgsql as $$
|
||||
begin
|
||||
--raise exception '% deleting role uuid %', currentsubjectsuuids(), roleUUid;
|
||||
delete from RbacRole where uuid = roleUUid;
|
||||
--raise exception '% deleting role uuid %', rbac.currentSubjectOrAssumedRolesUuids(), roleUUid;
|
||||
delete from rbac.role where uuid = roleUUid;
|
||||
end;
|
||||
$$;
|
||||
|
||||
create or replace function findRoleId(roleIdName varchar)
|
||||
create or replace function rbac.findRoleId(roleIdName varchar)
|
||||
returns uuid
|
||||
returns null on null input
|
||||
language plpgsql as $$
|
||||
declare
|
||||
roleParts text;
|
||||
roleTypeFromRoleIdName RbacRoleType;
|
||||
roleTypeFromRoleIdName rbac.RoleType;
|
||||
objectNameFromRoleIdName text;
|
||||
objectTableFromRoleIdName text;
|
||||
objectUuidOfRole uuid;
|
||||
roleUuid uuid;
|
||||
begin
|
||||
-- TODO.refa: extract function toRbacRoleDescriptor(roleIdName varchar) + find other occurrences
|
||||
-- TODO.refa: extract function rbac.toRoleDescriptor(roleIdName varchar) + find other occurrences
|
||||
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);
|
||||
objectUuidOfRole = base.findObjectUuidByIdName(objectTableFromRoleIdName, objectNameFromRoleIdName);
|
||||
|
||||
select uuid
|
||||
from RbacRole
|
||||
from rbac.role
|
||||
where objectUuid = objectUuidOfRole
|
||||
and roleType = roleTypeFromRoleIdName
|
||||
into roleUuid;
|
||||
return roleUuid;
|
||||
end; $$;
|
||||
|
||||
create or replace function findRoleId(roleDescriptor RbacRoleDescriptor)
|
||||
create or replace function rbac.findRoleId(roleDescriptor rbac.RoleDescriptor)
|
||||
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 rbac.role where objectUuid = roleDescriptor.objectUuid and roleType = roleDescriptor.roleType;
|
||||
$$;
|
||||
|
||||
create or replace function getRoleId(roleDescriptor RbacRoleDescriptor)
|
||||
create or replace function rbac.getRoleId(roleDescriptor rbac.RoleDescriptor)
|
||||
returns uuid
|
||||
language plpgsql as $$
|
||||
declare
|
||||
@@ -278,29 +287,30 @@ declare
|
||||
begin
|
||||
assert roleDescriptor is not null, 'roleDescriptor must not be null';
|
||||
|
||||
roleUuid := findRoleId(roleDescriptor);
|
||||
roleUuid := rbac.findRoleId(roleDescriptor);
|
||||
if (roleUuid is null) then
|
||||
raise exception 'RbacRole "%#%.%" not found', roleDescriptor.objectTable, roleDescriptor.objectUuid, roleDescriptor.roleType;
|
||||
raise exception 'rbac.role "%#%.%" not found', roleDescriptor.objectTable, roleDescriptor.objectUuid, roleDescriptor.roleType;
|
||||
end if;
|
||||
return roleUuid;
|
||||
end;
|
||||
$$;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-BEFORE-DELETE-ROLE-TRIGGER:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-base-BEFORE-DELETE-ROLE-TRIGGER endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
/*
|
||||
RbacRole BEFORE DELETE TRIGGER function which deletes all related roles.
|
||||
rbac.role BEFORE DELETE TRIGGER function which deletes all related roles.
|
||||
*/
|
||||
create or replace function deleteRbacGrantsOfRbacRole()
|
||||
create or replace function rbac.delete_grants_of_role_tf()
|
||||
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);
|
||||
delete from rbac.grants g where old.uuid in (g.grantedbyroleuuid, g.ascendantuuid, g.descendantuuid);
|
||||
else
|
||||
raise exception 'invalid usage of TRIGGER BEFORE DELETE';
|
||||
end if;
|
||||
@@ -308,31 +318,31 @@ begin
|
||||
end; $$;
|
||||
|
||||
/*
|
||||
Installs the RbacRole BEFORE DELETE TRIGGER.
|
||||
Installs the rbac.role BEFORE DELETE TRIGGER.
|
||||
*/
|
||||
create trigger deleteRbacGrantsOfRbacRole_Trigger
|
||||
create trigger delete_grants_of_role_tg
|
||||
before delete
|
||||
on RbacRole
|
||||
on rbac.role
|
||||
for each row
|
||||
execute procedure deleteRbacGrantsOfRbacRole();
|
||||
execute procedure rbac.delete_grants_of_role_tf();
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-BEFORE-DELETE-OBJECT-TRIGGER:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-base-BEFORE-DELETE-OBJECT-TRIGGER endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
/*
|
||||
RbacObject BEFORE DELETE TRIGGER function which deletes all related roles.
|
||||
rbac.object BEFORE DELETE TRIGGER function which deletes all related roles.
|
||||
*/
|
||||
create or replace function deleteRbacRolesOfRbacObject()
|
||||
create or replace function rbac.delete_roles_of_object_tf()
|
||||
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;
|
||||
delete from rbac.permission p where p.objectuuid = old.uuid;
|
||||
delete from rbac.role r where r.objectUuid = old.uuid;
|
||||
else
|
||||
raise exception 'invalid usage of TRIGGER BEFORE DELETE';
|
||||
end if;
|
||||
@@ -340,23 +350,20 @@ begin
|
||||
end; $$;
|
||||
|
||||
/*
|
||||
Installs the RbacRole BEFORE DELETE TRIGGER.
|
||||
Installs the rbac.role BEFORE DELETE TRIGGER.
|
||||
*/
|
||||
create trigger deleteRbacRolesOfRbacObject_Trigger
|
||||
create trigger delete_roles_of_object_tg
|
||||
before delete
|
||||
on RbacObject
|
||||
on rbac.object
|
||||
for each row
|
||||
execute procedure deleteRbacRolesOfRbacObject();
|
||||
execute procedure rbac.delete_roles_of_object_tf();
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-PERMISSION:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-base-PERMISSION endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
|
||||
*/
|
||||
create domain RbacOp as varchar(6)
|
||||
create domain rbac.RbacOp as varchar(6)
|
||||
check (
|
||||
VALUE = 'DELETE'
|
||||
or VALUE = 'UPDATE'
|
||||
@@ -365,23 +372,23 @@ create domain RbacOp as varchar(6)
|
||||
or VALUE = 'ASSUME'
|
||||
);
|
||||
|
||||
create table RbacPermission
|
||||
create table rbac.permission
|
||||
(
|
||||
uuid uuid primary key references RbacReference (uuid) on delete cascade,
|
||||
objectUuid uuid not null references RbacObject,
|
||||
op RbacOp not null,
|
||||
uuid uuid primary key references rbac.reference (uuid) on delete cascade,
|
||||
objectUuid uuid not null references rbac.object,
|
||||
op rbac.RbacOp not null,
|
||||
opTableName varchar(60)
|
||||
);
|
||||
-- TODO.perf: check if these indexes are really useful
|
||||
create index on RbacPermission (objectUuid, op);
|
||||
create index on RbacPermission (opTableName, op);
|
||||
create index on rbac.permission (objectUuid, op);
|
||||
create index on rbac.permission (opTableName, op);
|
||||
|
||||
ALTER TABLE RbacPermission
|
||||
ALTER TABLE rbac.permission
|
||||
ADD CONSTRAINT RbacPermission_uc UNIQUE NULLS NOT DISTINCT (objectUuid, op, opTableName);
|
||||
|
||||
call create_journal('RbacPermission');
|
||||
call base.create_journal('rbac.permission');
|
||||
|
||||
create or replace function createPermission(forObjectUuid uuid, forOp RbacOp, forOpTableName text = null)
|
||||
create or replace function rbac.createPermission(forObjectUuid uuid, forOp rbac.RbacOp, forOpTableName text = null)
|
||||
returns uuid
|
||||
language plpgsql as $$
|
||||
declare
|
||||
@@ -398,50 +405,50 @@ begin
|
||||
end if;
|
||||
|
||||
permissionUuid := (
|
||||
select uuid from RbacPermission
|
||||
select uuid from rbac.permission
|
||||
where objectUuid = forObjectUuid
|
||||
and op = forOp and opTableName is not distinct from forOpTableName);
|
||||
if (permissionUuid is null) then
|
||||
insert into RbacReference ("type")
|
||||
values ('RbacPermission')
|
||||
insert into rbac.reference ("type")
|
||||
values ('rbac.permission')
|
||||
returning uuid into permissionUuid;
|
||||
begin
|
||||
insert into RbacPermission (uuid, objectUuid, op, opTableName)
|
||||
insert into rbac.permission (uuid, objectUuid, op, opTableName)
|
||||
values (permissionUuid, forObjectUuid, forOp, forOpTableName);
|
||||
exception
|
||||
when others then
|
||||
raise exception 'insert into RbacPermission (uuid, objectUuid, op, opTableName)
|
||||
raise exception 'insert into rbac.permission (uuid, objectUuid, op, opTableName)
|
||||
values (%, %, %, %);', permissionUuid, forObjectUuid, forOp, forOpTableName;
|
||||
end;
|
||||
end if;
|
||||
return permissionUuid;
|
||||
end; $$;
|
||||
|
||||
create or replace function findEffectivePermissionId(forObjectUuid uuid, forOp RbacOp, forOpTableName text = null)
|
||||
create or replace function rbac.findEffectivePermissionId(forObjectUuid uuid, forOp rbac.RbacOp, forOpTableName text = null)
|
||||
returns uuid
|
||||
returns null on null input
|
||||
stable -- leakproof
|
||||
language sql as $$
|
||||
select uuid
|
||||
from RbacPermission p
|
||||
from rbac.permission p
|
||||
where p.objectUuid = forObjectUuid
|
||||
and (forOp = 'SELECT' or p.op = forOp) -- all other RbacOp include 'SELECT'
|
||||
and (forOp = 'SELECT' or p.op = forOp) -- all other rbac.RbacOp include 'SELECT'
|
||||
and p.opTableName = forOpTableName
|
||||
$$;
|
||||
|
||||
create or replace function findPermissionId(forObjectUuid uuid, forOp RbacOp, forOpTableName text = null)
|
||||
create or replace function rbac.findPermissionId(forObjectUuid uuid, forOp rbac.RbacOp, forOpTableName text = null)
|
||||
returns uuid
|
||||
returns null on null input
|
||||
stable -- leakproof
|
||||
language sql as $$
|
||||
select uuid
|
||||
from RbacPermission p
|
||||
from rbac.permission p
|
||||
where p.objectUuid = forObjectUuid
|
||||
and p.op = forOp
|
||||
and p.opTableName = forOpTableName
|
||||
$$;
|
||||
|
||||
create or replace function getPermissionId(forObjectUuid uuid, forOp RbacOp, forOpTableName text = null)
|
||||
create or replace function rbac.getPermissionId(forObjectUuid uuid, forOp rbac.RbacOp, forOpTableName text = null)
|
||||
returns uuid
|
||||
stable -- leakproof
|
||||
language plpgsql as $$
|
||||
@@ -449,7 +456,7 @@ declare
|
||||
permissionUuid uuid;
|
||||
begin
|
||||
select uuid into permissionUuid
|
||||
from RbacPermission p
|
||||
from rbac.permission p
|
||||
where p.objectUuid = forObjectUuid
|
||||
and p.op = forOp
|
||||
and forOpTableName is null or p.opTableName = forOpTableName;
|
||||
@@ -461,17 +468,17 @@ end; $$;
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-duplicate-role-grant-exception:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-base-duplicate-role-grant-exception endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace procedure raiseDuplicateRoleGrantException(subRoleId uuid, superRoleId uuid)
|
||||
create or replace procedure rbac.raiseDuplicateRoleGrantException(subRoleId uuid, superRoleId uuid)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
subRoleIdName text;
|
||||
superRoleIdName text;
|
||||
begin
|
||||
select roleIdName from rbacRole_ev where uuid=subRoleId into subRoleIdName;
|
||||
select roleIdName from rbacRole_ev where uuid=superRoleId into superRoleIdName;
|
||||
select roleIdName from rbac.role_ev where uuid=subRoleId into subRoleIdName;
|
||||
select roleIdName from rbac.role_ev where uuid=superRoleId into superRoleIdName;
|
||||
raise exception '[400] Duplicate role grant detected: role % (%) already granted to % (%)', subRoleId, subRoleIdName, superRoleId, superRoleIdName;
|
||||
end;
|
||||
$$;
|
||||
@@ -479,54 +486,54 @@ $$;
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-GRANTS:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-base-GRANTS endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
Table to store grants / role- or permission assignments to users or roles.
|
||||
Table to store grants / role- or permission assignments to subjects or roles.
|
||||
*/
|
||||
create table RbacGrants
|
||||
create table rbac.grants
|
||||
(
|
||||
uuid uuid primary key default uuid_generate_v4(),
|
||||
grantedByTriggerOf uuid references RbacObject (uuid) on delete cascade initially deferred ,
|
||||
grantedByRoleUuid uuid references RbacRole (uuid),
|
||||
ascendantUuid uuid references RbacReference (uuid),
|
||||
descendantUuid uuid references RbacReference (uuid),
|
||||
grantedByTriggerOf uuid references rbac.object (uuid) on delete cascade initially deferred ,
|
||||
grantedByRoleUuid uuid references rbac.role (uuid),
|
||||
ascendantUuid uuid references rbac.reference (uuid),
|
||||
descendantUuid uuid references rbac.reference (uuid),
|
||||
assumed boolean not null default true, -- auto assumed (true) vs. needs assumeRoles (false)
|
||||
unique (ascendantUuid, descendantUuid),
|
||||
constraint rbacGrant_createdBy check ( grantedByRoleUuid is null or grantedByTriggerOf is null) );
|
||||
create index on RbacGrants (ascendantUuid);
|
||||
create index on RbacGrants (descendantUuid);
|
||||
create index on rbac.grants (ascendantUuid);
|
||||
create index on rbac.grants (descendantUuid);
|
||||
|
||||
call create_journal('RbacGrants');
|
||||
create or replace function findGrantees(grantedId uuid)
|
||||
returns setof RbacReference
|
||||
call base.create_journal('rbac.grants');
|
||||
create or replace function rbac.findGrantees(grantedId uuid)
|
||||
returns setof rbac.reference
|
||||
returns null on null input
|
||||
language sql as $$
|
||||
with recursive grants as (
|
||||
select descendantUuid, ascendantUuid
|
||||
from RbacGrants
|
||||
from rbac.grants
|
||||
where descendantUuid = grantedId
|
||||
union all
|
||||
select g.descendantUuid, g.ascendantUuid
|
||||
from RbacGrants g
|
||||
from rbac.grants g
|
||||
inner join grants on grants.ascendantUuid = g.descendantUuid
|
||||
)
|
||||
select ref.*
|
||||
from grants
|
||||
join RbacReference ref on ref.uuid = grants.ascendantUuid;
|
||||
join rbac.reference ref on ref.uuid = grants.ascendantUuid;
|
||||
$$;
|
||||
|
||||
create or replace function isGranted(granteeIds uuid[], grantedId uuid)
|
||||
create or replace function rbac.isGranted(granteeIds uuid[], grantedId uuid)
|
||||
returns bool
|
||||
returns null on null input
|
||||
language sql as $$
|
||||
with recursive grants as (
|
||||
select descendantUuid, ascendantUuid
|
||||
from RbacGrants
|
||||
from rbac.grants
|
||||
where descendantUuid = grantedId
|
||||
union all
|
||||
select "grant".descendantUuid, "grant".ascendantUuid
|
||||
from RbacGrants "grant"
|
||||
from rbac.grants "grant"
|
||||
inner join grants recur on recur.ascendantUuid = "grant".descendantUuid
|
||||
)
|
||||
select exists (
|
||||
@@ -536,23 +543,23 @@ select exists (
|
||||
) or grantedId = any(granteeIds);
|
||||
$$;
|
||||
|
||||
create or replace function isGranted(granteeId uuid, grantedId uuid)
|
||||
create or replace function rbac.isGranted(granteeId uuid, grantedId uuid)
|
||||
returns bool
|
||||
returns null on null input
|
||||
language sql as $$
|
||||
select * from isGranted(array[granteeId], grantedId);
|
||||
select * from rbac.isGranted(array[granteeId], grantedId);
|
||||
$$;
|
||||
create or replace function isPermissionGrantedToSubject(permissionId uuid, subjectId uuid)
|
||||
create or replace function rbac.isPermissionGrantedToSubject(permissionId uuid, subjectId uuid)
|
||||
returns BOOL
|
||||
stable -- leakproof
|
||||
language sql as $$
|
||||
with recursive grants as (
|
||||
select descendantUuid, ascendantUuid
|
||||
from RbacGrants
|
||||
from rbac.grants
|
||||
where descendantUuid = permissionId
|
||||
union all
|
||||
select g.descendantUuid, g.ascendantUuid
|
||||
from RbacGrants g
|
||||
from rbac.grants g
|
||||
inner join grants on grants.ascendantUuid = g.descendantUuid
|
||||
)
|
||||
select exists(
|
||||
@@ -562,117 +569,117 @@ select exists(
|
||||
);
|
||||
$$;
|
||||
|
||||
create or replace function hasInsertPermission(objectUuid uuid, tableName text )
|
||||
create or replace function rbac.hasInsertPermission(objectUuid uuid, tableName text )
|
||||
returns BOOL
|
||||
stable -- leakproof
|
||||
language plpgsql as $$
|
||||
declare
|
||||
permissionUuid uuid;
|
||||
begin
|
||||
permissionUuid = findPermissionId(objectUuid, 'INSERT'::RbacOp, tableName);
|
||||
permissionUuid = rbac.findPermissionId(objectUuid, 'INSERT'::rbac.RbacOp, tableName);
|
||||
return permissionUuid is not null;
|
||||
end;
|
||||
$$;
|
||||
|
||||
create or replace function hasGlobalRoleGranted(userUuid uuid)
|
||||
create or replace function rbac.hasGlobalRoleGranted(forAscendantUuid uuid)
|
||||
returns bool
|
||||
stable -- leakproof
|
||||
language sql as $$
|
||||
select exists(
|
||||
select r.uuid
|
||||
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'
|
||||
from rbac.grants as g
|
||||
join rbac.role as r on r.uuid = g.descendantuuid
|
||||
join rbac.object as o on o.uuid = r.objectuuid
|
||||
where g.ascendantuuid = forAscendantUuid
|
||||
and o.objecttable = 'rbac.global'
|
||||
);
|
||||
$$;
|
||||
|
||||
create or replace procedure grantPermissionToRole(permissionUuid uuid, roleUuid uuid)
|
||||
create or replace procedure rbac.grantPermissionToRole(permissionUuid uuid, roleUuid uuid)
|
||||
language plpgsql as $$
|
||||
begin
|
||||
perform assertReferenceType('roleId (ascendant)', roleUuid, 'RbacRole');
|
||||
perform assertReferenceType('permissionId (descendant)', permissionUuid, 'RbacPermission');
|
||||
perform rbac.assertReferenceType('roleId (ascendant)', roleUuid, 'rbac.role');
|
||||
perform rbac.assertReferenceType('permissionId (descendant)', permissionUuid, 'rbac.permission');
|
||||
|
||||
insert
|
||||
into RbacGrants (grantedByTriggerOf, ascendantUuid, descendantUuid, assumed)
|
||||
values (currentTriggerObjectUuid(), roleUuid, permissionUuid, true)
|
||||
into rbac.grants (grantedByTriggerOf, ascendantUuid, descendantUuid, assumed)
|
||||
values (rbac.currentTriggerObjectUuid(), roleUuid, permissionUuid, true)
|
||||
on conflict do nothing; -- allow granting multiple times
|
||||
end;
|
||||
$$;
|
||||
|
||||
create or replace procedure grantPermissionToRole(permissionUuid uuid, roleDesc RbacRoleDescriptor)
|
||||
create or replace procedure rbac.grantPermissionToRole(permissionUuid uuid, roleDesc rbac.RoleDescriptor)
|
||||
language plpgsql as $$
|
||||
begin
|
||||
call grantPermissionToRole(permissionUuid, findRoleId(roleDesc));
|
||||
call rbac.grantPermissionToRole(permissionUuid, rbac.findRoleId(roleDesc));
|
||||
end;
|
||||
$$;
|
||||
|
||||
create or replace procedure grantRoleToRole(subRoleId uuid, superRoleId uuid, doAssume bool = true)
|
||||
create or replace procedure rbac.grantRoleToRole(subRoleId uuid, superRoleId uuid, doAssume bool = true)
|
||||
language plpgsql as $$
|
||||
begin
|
||||
perform assertReferenceType('superRoleId (ascendant)', superRoleId, 'RbacRole');
|
||||
perform assertReferenceType('subRoleId (descendant)', subRoleId, 'RbacRole');
|
||||
perform rbac.assertReferenceType('superRoleId (ascendant)', superRoleId, 'rbac.role');
|
||||
perform rbac.assertReferenceType('subRoleId (descendant)', subRoleId, 'rbac.role');
|
||||
|
||||
if isGranted(subRoleId, superRoleId) then
|
||||
call raiseDuplicateRoleGrantException(subRoleId, superRoleId);
|
||||
if rbac.isGranted(subRoleId, superRoleId) then
|
||||
call rbac.raiseDuplicateRoleGrantException(subRoleId, superRoleId);
|
||||
end if;
|
||||
|
||||
insert
|
||||
into RbacGrants (grantedByTriggerOf, ascendantuuid, descendantUuid, assumed)
|
||||
values (currentTriggerObjectUuid(), superRoleId, subRoleId, doAssume)
|
||||
into rbac.grants (grantedByTriggerOf, ascendantuuid, descendantUuid, assumed)
|
||||
values (rbac.currentTriggerObjectUuid(), superRoleId, subRoleId, doAssume)
|
||||
on conflict do nothing; -- allow granting multiple times
|
||||
end; $$;
|
||||
|
||||
|
||||
create or replace procedure grantRoleToRole(subRole RbacRoleDescriptor, superRole RbacRoleDescriptor, doAssume bool = true)
|
||||
create or replace procedure rbac.grantRoleToRole(subRole rbac.RoleDescriptor, superRole rbac.RoleDescriptor, doAssume bool = true)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
superRoleId uuid;
|
||||
subRoleId uuid;
|
||||
begin
|
||||
-- TODO.refa: maybe separate method grantRoleToRoleIfNotNull(...) for NULLABLE references
|
||||
-- TODO.refa: maybe separate method rbac.grantRoleToRoleIfNotNull(...) for NULLABLE references
|
||||
if superRole.objectUuid is null or subRole.objectuuid is null then
|
||||
return;
|
||||
end if;
|
||||
|
||||
superRoleId := findRoleId(superRole);
|
||||
subRoleId := findRoleId(subRole);
|
||||
superRoleId := rbac.findRoleId(superRole);
|
||||
subRoleId := rbac.findRoleId(subRole);
|
||||
|
||||
perform assertReferenceType('superRoleId (ascendant)', superRoleId, 'RbacRole');
|
||||
perform assertReferenceType('subRoleId (descendant)', subRoleId, 'RbacRole');
|
||||
perform rbac.assertReferenceType('superRoleId (ascendant)', superRoleId, 'rbac.role');
|
||||
perform rbac.assertReferenceType('subRoleId (descendant)', subRoleId, 'rbac.role');
|
||||
|
||||
if isGranted(subRoleId, superRoleId) then
|
||||
call raiseDuplicateRoleGrantException(subRoleId, superRoleId);
|
||||
if rbac.isGranted(subRoleId, superRoleId) then
|
||||
call rbac.raiseDuplicateRoleGrantException(subRoleId, superRoleId);
|
||||
end if;
|
||||
|
||||
insert
|
||||
into RbacGrants (grantedByTriggerOf, ascendantuuid, descendantUuid, assumed)
|
||||
values (currentTriggerObjectUuid(), superRoleId, subRoleId, doAssume)
|
||||
into rbac.grants (grantedByTriggerOf, ascendantuuid, descendantUuid, assumed)
|
||||
values (rbac.currentTriggerObjectUuid(), superRoleId, subRoleId, doAssume)
|
||||
on conflict do nothing; -- allow granting multiple times
|
||||
end; $$;
|
||||
|
||||
create or replace procedure revokeRoleFromRole(subRole RbacRoleDescriptor, superRole RbacRoleDescriptor)
|
||||
create or replace procedure rbac.revokeRoleFromRole(subRole rbac.RoleDescriptor, superRole rbac.RoleDescriptor)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
superRoleId uuid;
|
||||
subRoleId uuid;
|
||||
begin
|
||||
superRoleId := findRoleId(superRole);
|
||||
subRoleId := findRoleId(subRole);
|
||||
superRoleId := rbac.findRoleId(superRole);
|
||||
subRoleId := rbac.findRoleId(subRole);
|
||||
|
||||
perform assertReferenceType('superRoleId (ascendant)', superRoleId, 'RbacRole');
|
||||
perform assertReferenceType('subRoleId (descendant)', subRoleId, 'RbacRole');
|
||||
perform rbac.assertReferenceType('superRoleId (ascendant)', superRoleId, 'rbac.role');
|
||||
perform rbac.assertReferenceType('subRoleId (descendant)', subRoleId, 'rbac.role');
|
||||
|
||||
if (isGranted(superRoleId, subRoleId)) then
|
||||
delete from RbacGrants where ascendantUuid = superRoleId and descendantUuid = subRoleId;
|
||||
if (rbac.isGranted(superRoleId, subRoleId)) then
|
||||
delete from rbac.grants where ascendantUuid = superRoleId and descendantUuid = subRoleId;
|
||||
else
|
||||
raise exception 'cannot revoke role % (%) from % (%) because it is not granted',
|
||||
subRole, subRoleId, superRole, superRoleId;
|
||||
end if;
|
||||
end; $$;
|
||||
|
||||
create or replace procedure revokePermissionFromRole(permissionId UUID, superRole RbacRoleDescriptor)
|
||||
create or replace procedure rbac.revokePermissionFromRole(permissionId UUID, superRole rbac.RoleDescriptor)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
superRoleId uuid;
|
||||
@@ -680,18 +687,18 @@ declare
|
||||
objectTable text;
|
||||
objectUuid uuid;
|
||||
begin
|
||||
superRoleId := findRoleId(superRole);
|
||||
superRoleId := rbac.findRoleId(superRole);
|
||||
|
||||
perform assertReferenceType('superRoleId (ascendant)', superRoleId, 'RbacRole');
|
||||
perform assertReferenceType('permission (descendant)', permissionId, 'RbacPermission');
|
||||
perform rbac.assertReferenceType('superRoleId (ascendant)', superRoleId, 'rbac.role');
|
||||
perform rbac.assertReferenceType('permission (descendant)', permissionId, 'rbac.permission');
|
||||
|
||||
if (isGranted(superRoleId, permissionId)) then
|
||||
delete from RbacGrants where ascendantUuid = superRoleId and descendantUuid = permissionId;
|
||||
if (rbac.isGranted(superRoleId, permissionId)) then
|
||||
delete from rbac.grants where ascendantUuid = superRoleId and descendantUuid = permissionId;
|
||||
else
|
||||
select p.op, o.objectTable, o.uuid
|
||||
from rbacGrants g
|
||||
join rbacPermission p on p.uuid=g.descendantUuid
|
||||
join rbacobject o on o.uuid=p.objectUuid
|
||||
from rbac.grants g
|
||||
join rbac.permission p on p.uuid=g.descendantUuid
|
||||
join rbac.object o on o.uuid=p.objectUuid
|
||||
where g.uuid=permissionId
|
||||
into permissionOp, objectTable, objectUuid;
|
||||
|
||||
@@ -701,13 +708,13 @@ begin
|
||||
end; $$;
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-QUERY-ACCESSIBLE-OBJECT-UUIDS:1 runOnChange=true endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-base-QUERY-ACCESSIBLE-OBJECT-UUIDS runOnChange=true endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
|
||||
*/
|
||||
create or replace function queryAccessibleObjectUuidsOfSubjectIds(
|
||||
requiredOp RbacOp,
|
||||
create or replace function rbac.queryAccessibleObjectUuidsOfSubjectIds(
|
||||
requiredOp rbac.RbacOp,
|
||||
forObjectTable varchar,
|
||||
subjectIds uuid[],
|
||||
maxObjects integer = 8000)
|
||||
@@ -720,12 +727,12 @@ begin
|
||||
return query
|
||||
WITH RECURSIVE grants AS (
|
||||
SELECT descendantUuid, ascendantUuid, 1 AS level
|
||||
FROM RbacGrants
|
||||
FROM rbac.grants
|
||||
WHERE assumed
|
||||
AND ascendantUuid = any(subjectIds)
|
||||
UNION ALL
|
||||
SELECT g.descendantUuid, g.ascendantUuid, grants.level + 1 AS level
|
||||
FROM RbacGrants g
|
||||
FROM rbac.grants g
|
||||
INNER JOIN grants ON grants.descendantUuid = g.ascendantUuid
|
||||
WHERE g.assumed
|
||||
),
|
||||
@@ -735,13 +742,13 @@ begin
|
||||
)
|
||||
SELECT DISTINCT perm.objectUuid
|
||||
FROM granted
|
||||
JOIN RbacPermission perm ON granted.descendantUuid = perm.uuid
|
||||
JOIN RbacObject obj ON obj.uuid = perm.objectUuid
|
||||
JOIN rbac.permission perm ON granted.descendantUuid = perm.uuid
|
||||
JOIN rbac.object obj ON obj.uuid = perm.objectUuid
|
||||
WHERE (requiredOp = 'SELECT' OR perm.op = requiredOp)
|
||||
AND obj.objectTable = forObjectTable
|
||||
LIMIT maxObjects+1;
|
||||
|
||||
foundRows = lastRowCount();
|
||||
foundRows = base.lastRowCount();
|
||||
if foundRows > maxObjects then
|
||||
raise exception '[400] Too many accessible objects, limit is %, found %.', maxObjects, foundRows
|
||||
using
|
||||
@@ -753,26 +760,26 @@ $$;
|
||||
--//
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-QUERY-GRANTED-PERMISSIONS:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-base-QUERY-GRANTED-PERMISSIONS endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
Returns all permissions accessible to the given subject UUID (user or role).
|
||||
Returns all permissions accessible to the given subject UUID (subject or role).
|
||||
*/
|
||||
create or replace function queryPermissionsGrantedToSubjectId(subjectId uuid)
|
||||
returns setof RbacPermission
|
||||
create or replace function rbac.queryPermissionsGrantedToSubjectId(subjectId uuid)
|
||||
returns setof rbac.permission
|
||||
strict
|
||||
language sql as $$
|
||||
with recursive grants as (
|
||||
select descendantUuid, ascendantUuid
|
||||
from RbacGrants
|
||||
from rbac.grants
|
||||
where ascendantUuid = subjectId
|
||||
union all
|
||||
select g.descendantUuid, g.ascendantUuid
|
||||
from RbacGrants g
|
||||
from rbac.grants g
|
||||
inner join grants on grants.descendantUuid = g.ascendantUuid
|
||||
)
|
||||
select perm.*
|
||||
from RbacPermission perm
|
||||
from rbac.permission perm
|
||||
where perm.uuid in (
|
||||
select descendantUuid
|
||||
from grants
|
||||
@@ -782,27 +789,27 @@ $$;
|
||||
--//
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-QUERY-USERS-WITH-PERMISSION-FOR-OBJECT:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-base-QUERY-SUBJECTS-WITH-PERMISSION-FOR-OBJECT endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
Returns all user UUIDs which have any permission for the given object UUID.
|
||||
Returns all subject UUIDs which have any permission for the given object UUID.
|
||||
*/
|
||||
|
||||
create or replace function queryAllRbacUsersWithPermissionsFor(objectId uuid)
|
||||
returns setof RbacUser
|
||||
create or replace function rbac.queryAllRbacSubjectsWithPermissionsFor(objectId uuid)
|
||||
returns setof rbac.subject
|
||||
returns null on null input
|
||||
language sql as $$
|
||||
select *
|
||||
from RbacUser
|
||||
from rbac.subject
|
||||
where uuid in (
|
||||
-- @formatter:off
|
||||
with recursive grants as (
|
||||
select descendantUuid, ascendantUuid
|
||||
from RbacGrants
|
||||
from rbac.grants
|
||||
where descendantUuid = objectId
|
||||
union all
|
||||
select "grant".descendantUuid, "grant".ascendantUuid
|
||||
from RbacGrants "grant"
|
||||
from rbac.grants "grant"
|
||||
inner join grants recur on recur.ascendantUuid = "grant".descendantUuid
|
||||
)
|
||||
-- @formatter:on
|
||||
@@ -813,7 +820,7 @@ $$;
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-PGSQL-ROLES:1 context:dev,tc endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-base-PGSQL-ROLES context:dev,tc endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
do $$
|
||||
|
@@ -0,0 +1,125 @@
|
||||
--liquibase formatted sql
|
||||
|
||||
-- ============================================================================
|
||||
--changeset michael.hoennig:rbac-user-grant-GRANT-ROLE-TO-USER endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace function rbac.assumedRoleUuid()
|
||||
returns uuid
|
||||
stable -- leakproof
|
||||
language plpgsql as $$
|
||||
declare
|
||||
currentSubjectOrAssumedRolesUuids uuid[];
|
||||
begin
|
||||
-- exactly one role must be assumed, not none not more than one
|
||||
if cardinality(base.assumedRoles()) <> 1 then
|
||||
raise exception '[400] Granting roles to user is only possible if exactly one role is assumed, given: %', base.assumedRoles();
|
||||
end if;
|
||||
|
||||
currentSubjectOrAssumedRolesUuids := rbac.currentSubjectOrAssumedRolesUuids();
|
||||
return currentSubjectOrAssumedRolesUuids[1];
|
||||
end; $$;
|
||||
|
||||
create or replace procedure rbac.grantRoleToSubjectUnchecked(grantedByRoleUuid uuid, grantedRoleUuid uuid, subjectUuid uuid, doAssume boolean = true)
|
||||
language plpgsql as $$
|
||||
begin
|
||||
perform rbac.assertReferenceType('grantingRoleUuid', grantedByRoleUuid, 'rbac.role');
|
||||
perform rbac.assertReferenceType('roleId (descendant)', grantedRoleUuid, 'rbac.role');
|
||||
perform rbac.assertReferenceType('subjectUuid (ascendant)', subjectUuid, 'rbac.subject');
|
||||
|
||||
insert
|
||||
into rbac.grants (grantedByRoleUuid, ascendantUuid, descendantUuid, assumed)
|
||||
values (grantedByRoleUuid, subjectUuid, grantedRoleUuid, doAssume)
|
||||
-- TODO: check if grantedByRoleUuid+doAssume are the same, otherwise raise exception?
|
||||
on conflict do nothing; -- allow granting multiple times
|
||||
end; $$;
|
||||
|
||||
create or replace procedure rbac.grantRoleToSubject(grantedByRoleUuid uuid, grantedRoleUuid uuid, subjectUuid uuid, doAssume boolean = true)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
grantedByRoleIdName text;
|
||||
grantedRoleIdName text;
|
||||
begin
|
||||
perform rbac.assertReferenceType('grantingRoleUuid', grantedByRoleUuid, 'rbac.role');
|
||||
perform rbac.assertReferenceType('grantedRoleUuid (descendant)', grantedRoleUuid, 'rbac.role');
|
||||
perform rbac.assertReferenceType('subjectUuid (ascendant)', subjectUuid, 'rbac.subject');
|
||||
|
||||
assert grantedByRoleUuid is not null, 'grantedByRoleUuid must not be null';
|
||||
assert grantedRoleUuid is not null, 'grantedRoleUuid must not be null';
|
||||
assert subjectUuid is not null, 'subjectUuid must not be null';
|
||||
|
||||
if NOT rbac.isGranted(rbac.currentSubjectOrAssumedRolesUuids(), grantedByRoleUuid) then
|
||||
select roleIdName from rbac.role_ev where uuid=grantedByRoleUuid into grantedByRoleIdName;
|
||||
raise exception '[403] Access to granted-by-role % (%) forbidden for % (%)',
|
||||
grantedByRoleIdName, grantedByRoleUuid, base.currentSubjects(), rbac.currentSubjectOrAssumedRolesUuids();
|
||||
end if;
|
||||
if NOT rbac.isGranted(grantedByRoleUuid, grantedRoleUuid) then
|
||||
select roleIdName from rbac.role_ev where uuid=grantedByRoleUuid into grantedByRoleIdName;
|
||||
select roleIdName from rbac.role_ev where uuid=grantedRoleUuid into grantedRoleIdName;
|
||||
raise exception '[403] Access to granted role % (%) forbidden for % (%)',
|
||||
grantedRoleIdName, grantedRoleUuid, grantedByRoleIdName, grantedByRoleUuid;
|
||||
end if;
|
||||
|
||||
insert
|
||||
into rbac.grants (grantedByRoleUuid, ascendantUuid, descendantUuid, assumed)
|
||||
values (grantedByRoleUuid, subjectUuid, grantedRoleUuid, doAssume);
|
||||
-- TODO.impl: What should happen on multiple grants? What if options (doAssume) are not the same?
|
||||
-- Most powerful or latest grant wins? What about managed?
|
||||
-- on conflict do nothing; -- allow granting multiple times
|
||||
end; $$;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset michael.hoennig:rbac-user-grant-REVOKE-ROLE-FROM-USER endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace procedure rbac.checkRevokeRoleFromSubjectPreconditions(grantedByRoleUuid uuid, grantedRoleUuid uuid, subjectUuid uuid)
|
||||
language plpgsql as $$
|
||||
begin
|
||||
perform rbac.assertReferenceType('grantedByRoleUuid', grantedByRoleUuid, 'rbac.role');
|
||||
perform rbac.assertReferenceType('grantedRoleUuid (descendant)', grantedRoleUuid, 'rbac.role');
|
||||
perform rbac.assertReferenceType('subjectUuid (ascendant)', subjectUuid, 'rbac.subject');
|
||||
|
||||
if NOT rbac.isGranted(rbac.currentSubjectOrAssumedRolesUuids(), grantedByRoleUuid) then
|
||||
raise exception '[403] Revoking role created by % is forbidden for %.', grantedByRoleUuid, base.currentSubjects();
|
||||
end if;
|
||||
|
||||
if NOT rbac.isGranted(grantedByRoleUuid, grantedRoleUuid) then
|
||||
raise exception '[403] Revoking role % is forbidden for %.', grantedRoleUuid, base.currentSubjects();
|
||||
end if;
|
||||
|
||||
--raise exception 'rbac.isGranted(%, %)', rbac.currentSubjectOrAssumedRolesUuids(), grantedByRoleUuid;
|
||||
if NOT rbac.isGranted(rbac.currentSubjectOrAssumedRolesUuids(), grantedByRoleUuid) then
|
||||
raise exception '[403] Revoking role granted by % is forbidden for %.', grantedByRoleUuid, base.currentSubjects();
|
||||
end if;
|
||||
|
||||
if NOT rbac.isGranted(subjectUuid, grantedRoleUuid) then
|
||||
raise exception '[404] No such grant found granted by % for subject % to role %.', grantedByRoleUuid, subjectUuid, grantedRoleUuid;
|
||||
end if;
|
||||
end; $$;
|
||||
|
||||
create or replace procedure rbac.revokeRoleFromSubject(grantedByRoleUuid uuid, grantedRoleUuid uuid, subjectUuid uuid)
|
||||
language plpgsql as $$
|
||||
begin
|
||||
call rbac.checkRevokeRoleFromSubjectPreconditions(grantedByRoleUuid, grantedRoleUuid, subjectUuid);
|
||||
|
||||
raise INFO 'delete from rbac.grants where ascendantUuid = % and descendantUuid = %', subjectUuid, grantedRoleUuid;
|
||||
delete from rbac.grants as g
|
||||
where g.ascendantUuid = subjectUuid and g.descendantUuid = grantedRoleUuid
|
||||
and g.grantedByRoleUuid = revokeRoleFromSubject.grantedByRoleUuid;
|
||||
end; $$;
|
||||
--//
|
||||
|
||||
-- ============================================================================
|
||||
--changeset michael.hoennig:rbac-user-grant-REVOKE-PERMISSION-FROM-ROLE endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace procedure rbac.revokePermissionFromRole(permissionUuid uuid, superRoleUuid uuid)
|
||||
language plpgsql as $$
|
||||
begin
|
||||
raise INFO 'delete from rbac.grants where ascendantUuid = % and descendantUuid = %', superRoleUuid, permissionUuid;
|
||||
delete from rbac.grants as g
|
||||
where g.ascendantUuid = superRoleUuid and g.descendantUuid = permissionUuid;
|
||||
end; $$;
|
||||
--//
|
@@ -1,125 +0,0 @@
|
||||
--liquibase formatted sql
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-user-grant-GRANT-ROLE-TO-USER:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace function assumedRoleUuid()
|
||||
returns uuid
|
||||
stable -- leakproof
|
||||
language plpgsql as $$
|
||||
declare
|
||||
currentSubjectsUuids uuid[];
|
||||
begin
|
||||
-- exactly one role must be assumed, not none not more than one
|
||||
if cardinality(assumedRoles()) <> 1 then
|
||||
raise exception '[400] Granting roles to user is only possible if exactly one role is assumed, given: %', assumedRoles();
|
||||
end if;
|
||||
|
||||
currentSubjectsUuids := currentSubjectsUuids();
|
||||
return currentSubjectsUuids[1];
|
||||
end; $$;
|
||||
|
||||
create or replace procedure grantRoleToUserUnchecked(grantedByRoleUuid uuid, grantedRoleUuid uuid, userUuid uuid, doAssume boolean = true)
|
||||
language plpgsql as $$
|
||||
begin
|
||||
perform assertReferenceType('grantingRoleUuid', grantedByRoleUuid, 'RbacRole');
|
||||
perform assertReferenceType('roleId (descendant)', grantedRoleUuid, 'RbacRole');
|
||||
perform assertReferenceType('userId (ascendant)', userUuid, 'RbacUser');
|
||||
|
||||
insert
|
||||
into RbacGrants (grantedByRoleUuid, ascendantUuid, descendantUuid, assumed)
|
||||
values (grantedByRoleUuid, userUuid, grantedRoleUuid, doAssume)
|
||||
-- TODO: check if grantedByRoleUuid+doAssume are the same, otherwise raise exception?
|
||||
on conflict do nothing; -- allow granting multiple times
|
||||
end; $$;
|
||||
|
||||
create or replace procedure grantRoleToUser(grantedByRoleUuid uuid, grantedRoleUuid uuid, userUuid uuid, doAssume boolean = true)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
grantedByRoleIdName text;
|
||||
grantedRoleIdName text;
|
||||
begin
|
||||
perform assertReferenceType('grantingRoleUuid', grantedByRoleUuid, 'RbacRole');
|
||||
perform assertReferenceType('grantedRoleUuid (descendant)', grantedRoleUuid, 'RbacRole');
|
||||
perform assertReferenceType('userUuid (ascendant)', userUuid, 'RbacUser');
|
||||
|
||||
assert grantedByRoleUuid is not null, 'grantedByRoleUuid must not be null';
|
||||
assert grantedRoleUuid is not null, 'grantedRoleUuid must not be null';
|
||||
assert userUuid is not null, 'userUuid must not be null';
|
||||
|
||||
if NOT isGranted(currentSubjectsUuids(), grantedByRoleUuid) then
|
||||
select roleIdName from rbacRole_ev where uuid=grantedByRoleUuid into grantedByRoleIdName;
|
||||
raise exception '[403] Access to granted-by-role % (%) forbidden for % (%)',
|
||||
grantedByRoleIdName, grantedByRoleUuid, currentSubjects(), currentSubjectsUuids();
|
||||
end if;
|
||||
if NOT isGranted(grantedByRoleUuid, grantedRoleUuid) then
|
||||
select roleIdName from rbacRole_ev where uuid=grantedByRoleUuid into grantedByRoleIdName;
|
||||
select roleIdName from rbacRole_ev where uuid=grantedRoleUuid into grantedRoleIdName;
|
||||
raise exception '[403] Access to granted role % (%) forbidden for % (%)',
|
||||
grantedRoleIdName, grantedRoleUuid, grantedByRoleIdName, grantedByRoleUuid;
|
||||
end if;
|
||||
|
||||
insert
|
||||
into RbacGrants (grantedByRoleUuid, ascendantUuid, descendantUuid, assumed)
|
||||
values (grantedByRoleUuid, userUuid, grantedRoleUuid, doAssume);
|
||||
-- TODO.impl: What should happen on mupltiple grants? What if options (doAssume) are not the same?
|
||||
-- Most powerful or latest grant wins? What about managed?
|
||||
-- on conflict do nothing; -- allow granting multiple times
|
||||
end; $$;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-user-grant-REVOKE-ROLE-FROM-USER:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace procedure checkRevokeRoleFromUserPreconditions(grantedByRoleUuid uuid, grantedRoleUuid uuid, userUuid uuid)
|
||||
language plpgsql as $$
|
||||
begin
|
||||
perform assertReferenceType('grantedByRoleUuid', grantedByRoleUuid, 'RbacRole');
|
||||
perform assertReferenceType('grantedRoleUuid (descendant)', grantedRoleUuid, 'RbacRole');
|
||||
perform assertReferenceType('userUuid (ascendant)', userUuid, 'RbacUser');
|
||||
|
||||
if NOT isGranted(currentSubjectsUuids(), grantedByRoleUuid) then
|
||||
raise exception '[403] Revoking role created by % is forbidden for %.', grantedByRoleUuid, currentSubjects();
|
||||
end if;
|
||||
|
||||
if NOT isGranted(grantedByRoleUuid, grantedRoleUuid) then
|
||||
raise exception '[403] Revoking role % is forbidden for %.', grantedRoleUuid, currentSubjects();
|
||||
end if;
|
||||
|
||||
--raise exception 'isGranted(%, %)', currentSubjectsUuids(), grantedByRoleUuid;
|
||||
if NOT isGranted(currentSubjectsUuids(), grantedByRoleUuid) then
|
||||
raise exception '[403] Revoking role granted by % is forbidden for %.', grantedByRoleUuid, currentSubjects();
|
||||
end if;
|
||||
|
||||
if NOT isGranted(userUuid, grantedRoleUuid) then
|
||||
raise exception '[404] No such grant found granted by % for user % to role %.', grantedByRoleUuid, userUuid, grantedRoleUuid;
|
||||
end if;
|
||||
end; $$;
|
||||
|
||||
create or replace procedure revokeRoleFromUser(grantedByRoleUuid uuid, grantedRoleUuid uuid, userUuid uuid)
|
||||
language plpgsql as $$
|
||||
begin
|
||||
call checkRevokeRoleFromUserPreconditions(grantedByRoleUuid, grantedRoleUuid, userUuid);
|
||||
|
||||
raise INFO 'delete from RbacGrants where ascendantUuid = % and descendantUuid = %', userUuid, grantedRoleUuid;
|
||||
delete from RbacGrants as g
|
||||
where g.ascendantUuid = userUuid and g.descendantUuid = grantedRoleUuid
|
||||
and g.grantedByRoleUuid = revokeRoleFromUser.grantedByRoleUuid;
|
||||
end; $$;
|
||||
--//
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-user-grant-REVOKE-PERMISSION-FROM-ROLE:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace procedure revokePermissionFromRole(permissionUuid uuid, superRoleUuid uuid)
|
||||
language plpgsql as $$
|
||||
begin
|
||||
raise INFO 'delete from RbacGrants where ascendantUuid = % and descendantUuid = %', superRoleUuid, permissionUuid;
|
||||
delete from RbacGrants as g
|
||||
where g.ascendantUuid = superRoleUuid and g.descendantUuid = permissionUuid;
|
||||
end; $$;
|
||||
--//
|
@@ -2,28 +2,28 @@
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-context-DETERMINE:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-context-DETERMINE endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace function determineCurrentUserUuid(currentUser varchar)
|
||||
create or replace function rbac.determineCurrentSubjectUuid(currentSubject varchar)
|
||||
returns uuid
|
||||
stable -- leakproof
|
||||
language plpgsql as $$
|
||||
declare
|
||||
currentUserUuid uuid;
|
||||
currentSubjectUuid uuid;
|
||||
begin
|
||||
if currentUser = '' then
|
||||
if currentSubject = '' then
|
||||
return null;
|
||||
end if;
|
||||
|
||||
select uuid from RbacUser where name = currentUser into currentUserUuid;
|
||||
if currentUserUuid is null then
|
||||
raise exception '[401] user % given in `defineContext(...)` does not exist', currentUser;
|
||||
select uuid from rbac.subject where name = currentSubject into currentSubjectUuid;
|
||||
if currentSubjectUuid is null then
|
||||
raise exception '[401] subject % given in `base.defineContext(...)` does not exist', currentSubject;
|
||||
end if;
|
||||
return currentUserUuid;
|
||||
return currentSubjectUuid;
|
||||
end; $$;
|
||||
|
||||
create or replace function determineCurrentSubjectsUuids(currentUserUuid uuid, assumedRoles varchar)
|
||||
create or replace function rbac.determinecurrentsubjectorassumedrolesuuids(currentSubjectOrAssumedRolesUuids uuid, assumedRoles varchar)
|
||||
returns uuid[]
|
||||
stable -- leakproof
|
||||
language plpgsql as $$
|
||||
@@ -33,11 +33,11 @@ declare
|
||||
objectTableToAssume varchar(63);
|
||||
objectNameToAssume varchar(63);
|
||||
objectUuidToAssume uuid;
|
||||
roleTypeToAssume RbacRoleType;
|
||||
roleTypeToAssume rbac.RoleType;
|
||||
roleIdsToAssume uuid[];
|
||||
roleUuidToAssume uuid;
|
||||
begin
|
||||
if currentUserUuid is null then
|
||||
if currentSubjectOrAssumedRolesUuids is null then
|
||||
if length(coalesce(assumedRoles, '')) > 0 then
|
||||
raise exception '[403] undefined has no permission to assume role %', assumedRoles;
|
||||
else
|
||||
@@ -45,7 +45,7 @@ begin
|
||||
end if;
|
||||
end if;
|
||||
if length(coalesce(assumedRoles, '')) = 0 then
|
||||
return array [currentUserUuid];
|
||||
return array [currentSubjectOrAssumedRolesUuids];
|
||||
end if;
|
||||
|
||||
foreach roleName in array string_to_array(assumedRoles, ';')
|
||||
@@ -55,21 +55,21 @@ begin
|
||||
objectNameToAssume = split_part(roleNameParts, '#', 2);
|
||||
roleTypeToAssume = split_part(roleNameParts, '#', 3);
|
||||
|
||||
objectUuidToAssume = findObjectUuidByIdName(objectTableToAssume, objectNameToAssume);
|
||||
objectUuidToAssume = base.findObjectUuidByIdName(objectTableToAssume, objectNameToAssume);
|
||||
if objectUuidToAssume is null then
|
||||
raise exception '[401] object % cannot be found in table %', objectNameToAssume, objectTableToAssume;
|
||||
raise exception '[401] object % cannot be found in table % (from roleNameParts=%)', objectNameToAssume, objectTableToAssume, roleNameParts;
|
||||
end if;
|
||||
|
||||
select uuid
|
||||
from RbacRole r
|
||||
from rbac.role r
|
||||
where r.objectUuid = objectUuidToAssume
|
||||
and r.roleType = roleTypeToAssume
|
||||
into roleUuidToAssume;
|
||||
if roleUuidToAssume is null then
|
||||
raise exception '[403] role % does not exist or is not accessible for user %', roleName, currentUser();
|
||||
raise exception '[403] role % does not exist or is not accessible for subject %', roleName, base.currentSubject();
|
||||
end if;
|
||||
if not isGranted(currentUserUuid, roleUuidToAssume) then
|
||||
raise exception '[403] user % has no permission to assume role %', currentUser(), roleName;
|
||||
if not rbac.isGranted(currentSubjectOrAssumedRolesUuids, roleUuidToAssume) then
|
||||
raise exception '[403] subject % has no permission to assume role %', base.currentSubject(), roleName;
|
||||
end if;
|
||||
roleIdsToAssume := roleIdsToAssume || roleUuidToAssume;
|
||||
end loop;
|
||||
@@ -78,102 +78,102 @@ begin
|
||||
end; $$;
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-context-CONTEXT-DEFINED:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-context-CONTEXT-DEFINED endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
Callback which is called after the context has been (re-) defined.
|
||||
This function will be overwritten by later changesets.
|
||||
*/
|
||||
create or replace procedure contextDefined(
|
||||
create or replace procedure base.contextDefined(
|
||||
currentTask varchar(127),
|
||||
currentRequest text,
|
||||
currentUser varchar(63),
|
||||
currentSubject varchar(63),
|
||||
assumedRoles varchar(1023)
|
||||
)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
currentUserUuid uuid;
|
||||
currentSubjectUuid uuid;
|
||||
begin
|
||||
execute format('set local hsadminng.currentTask to %L', currentTask);
|
||||
|
||||
execute format('set local hsadminng.currentRequest to %L', currentRequest);
|
||||
|
||||
execute format('set local hsadminng.currentUser to %L', currentUser);
|
||||
select determineCurrentUserUuid(currentUser) into currentUserUuid;
|
||||
execute format('set local hsadminng.currentUserUuid to %L', coalesce(currentUserUuid::text, ''));
|
||||
execute format('set local hsadminng.currentSubject to %L', currentSubject);
|
||||
select rbac.determineCurrentSubjectUuid(currentSubject) into currentSubjectUuid;
|
||||
execute format('set local hsadminng.currentSubjectUuid to %L', coalesce(currentSubjectUuid::text, ''));
|
||||
|
||||
execute format('set local hsadminng.assumedRoles to %L', assumedRoles);
|
||||
execute format('set local hsadminng.currentSubjectsUuids to %L',
|
||||
(select array_to_string(determinecurrentSubjectsUuids(currentUserUuid, assumedRoles), ';')));
|
||||
execute format('set local hsadminng.currentSubjectOrAssumedRolesUuids to %L',
|
||||
(select array_to_string(rbac.determinecurrentsubjectorassumedrolesuuids(currentSubjectUuid, assumedRoles), ';')));
|
||||
|
||||
raise notice 'Context defined as: %, %, %, [%]', currentTask, currentRequest, currentUser, assumedRoles;
|
||||
raise notice 'Context defined as: %, %, %, [%]', currentTask, currentRequest, currentSubject, assumedRoles;
|
||||
end; $$;
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-context-CURRENT-USER-ID:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-context-current-subject-ID endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
Returns the uuid of the current user as set via `defineContext(...)`.
|
||||
Returns the uuid of the current subject as set via `base.defineContext(...)`.
|
||||
*/
|
||||
|
||||
create or replace function currentUserUuid()
|
||||
create or replace function rbac.currentSubjectUuid()
|
||||
returns uuid
|
||||
stable -- leakproof
|
||||
language plpgsql as $$
|
||||
declare
|
||||
currentUserUuid text;
|
||||
currentUserName text;
|
||||
currentSubjectUuid text;
|
||||
currentSubjectName text;
|
||||
begin
|
||||
begin
|
||||
currentUserUuid := current_setting('hsadminng.currentUserUuid');
|
||||
currentSubjectUuid := current_setting('hsadminng.currentSubjectUuid');
|
||||
exception
|
||||
when others then
|
||||
currentUserUuid := null;
|
||||
currentSubjectUuid := null;
|
||||
end;
|
||||
if (currentUserUuid is null or currentUserUuid = '') then
|
||||
currentUserName := currentUser();
|
||||
if (length(currentUserName) > 0) then
|
||||
raise exception '[401] currentUserUuid cannot be determined, unknown user name "%"', currentUserName;
|
||||
if (currentSubjectUuid is null or currentSubjectUuid = '') then
|
||||
currentSubjectName := base.currentSubject();
|
||||
if (length(currentSubjectName) > 0) then
|
||||
raise exception '[401] currentSubjectUuid cannot be determined, unknown subject name "%"', currentSubjectName;
|
||||
else
|
||||
raise exception '[401] currentUserUuid cannot be determined, please call `defineContext(...)` first;"';
|
||||
raise exception '[401] currentSubjectUuid cannot be determined, please call `base.defineContext(...)` first;"';
|
||||
end if;
|
||||
end if;
|
||||
return currentUserUuid::uuid;
|
||||
return currentSubjectUuid::uuid;
|
||||
end; $$;
|
||||
--//
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-context-CURRENT-SUBJECT-UUIDS:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-context-CURRENT-SUBJECT-UUIDS endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
Returns the uuid of the current user as set via `defineContext(...)`,
|
||||
or, if any, the uuids of all assumed roles as set via `defineContext(...)`
|
||||
Returns the uuid of the current subject as set via `base.defineContext(...)`,
|
||||
or, if any, the uuids of all assumed roles as set via `base.defineContext(...)`
|
||||
or empty array, if context is not defined.
|
||||
*/
|
||||
create or replace function currentSubjectsUuids()
|
||||
create or replace function rbac.currentSubjectOrAssumedRolesUuids()
|
||||
returns uuid[]
|
||||
stable -- leakproof
|
||||
language plpgsql as $$
|
||||
declare
|
||||
currentSubjectsUuids text;
|
||||
currentUserName text;
|
||||
currentSubjectOrAssumedRolesUuids text;
|
||||
currentSubjectName text;
|
||||
begin
|
||||
begin
|
||||
currentSubjectsUuids := current_setting('hsadminng.currentSubjectsUuids');
|
||||
currentSubjectOrAssumedRolesUuids := current_setting('hsadminng.currentSubjectOrAssumedRolesUuids');
|
||||
exception
|
||||
when others then
|
||||
currentSubjectsUuids := null;
|
||||
currentSubjectOrAssumedRolesUuids := null;
|
||||
end;
|
||||
if (currentSubjectsUuids is null or length(currentSubjectsUuids) = 0 ) then
|
||||
currentUserName := currentUser();
|
||||
if (length(currentUserName) > 0) then
|
||||
raise exception '[401] currentSubjectsUuids (%) cannot be determined, unknown user name "%"', currentSubjectsUuids, currentUserName;
|
||||
if (currentSubjectOrAssumedRolesUuids is null or length(currentSubjectOrAssumedRolesUuids) = 0 ) then
|
||||
currentSubjectName := base.currentSubject();
|
||||
if (length(currentSubjectName) > 0) then
|
||||
raise exception '[401] currentSubjectOrAssumedRolesUuids (%) cannot be determined, unknown subject name "%"', currentSubjectOrAssumedRolesUuids, currentSubjectName;
|
||||
else
|
||||
raise exception '[401] currentSubjectsUuids cannot be determined, please call `defineContext(...)` with a valid user;"';
|
||||
raise exception '[401] currentSubjectOrAssumedRolesUuids cannot be determined, please call `base.defineContext(...)` with a valid subject;"';
|
||||
end if;
|
||||
end if;
|
||||
return string_to_array(currentSubjectsUuids, ';');
|
||||
return string_to_array(currentSubjectOrAssumedRolesUuids, ';');
|
||||
end; $$;
|
||||
--//
|
||||
|
||||
|
@@ -1,63 +1,63 @@
|
||||
--liquibase formatted sql
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-ROLE-ENHANCED-VIEW:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-views-ROLE-ENHANCED-VIEW endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
Creates a view to the role table with additional columns
|
||||
for easier human readability.
|
||||
*/
|
||||
drop view if exists rbacrole_ev;
|
||||
create or replace view rbacrole_ev as
|
||||
drop view if exists rbac.role_ev;
|
||||
create or replace view rbac.role_ev as
|
||||
select (objectTable || '#' || objectIdName || ':' || roleType) as roleIdName, *
|
||||
-- @formatter:off
|
||||
from (
|
||||
select r.*,
|
||||
o.objectTable, findIdNameByObjectUuid(o.objectTable, o.uuid) as objectIdName
|
||||
from rbacrole as r
|
||||
join rbacobject as o on o.uuid = r.objectuuid
|
||||
o.objectTable, base.findIdNameByObjectUuid(o.objectTable, o.uuid) as objectIdName
|
||||
from rbac.role as r
|
||||
join rbac.object as o on o.uuid = r.objectuuid
|
||||
) as unordered
|
||||
-- @formatter:on
|
||||
order by roleIdName;
|
||||
--//
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-ROLE-RESTRICTED-VIEW:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-views-ROLE-RESTRICTED-VIEW endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
Creates a view to the role table with row-level limitation
|
||||
based on the grants of the current user or assumed roles.
|
||||
*/
|
||||
drop view if exists rbacrole_rv;
|
||||
create or replace view rbacrole_rv as
|
||||
drop view if exists rbac.role_rv;
|
||||
create or replace view rbac.role_rv as
|
||||
select *
|
||||
-- @formatter:off
|
||||
from (
|
||||
select r.*, o.objectTable,
|
||||
findIdNameByObjectUuid(o.objectTable, o.uuid) as objectIdName
|
||||
from rbacrole as r
|
||||
join rbacobject as o on o.uuid = r.objectuuid
|
||||
where isGranted(currentSubjectsUuids(), r.uuid)
|
||||
base.findIdNameByObjectUuid(o.objectTable, o.uuid) as objectIdName
|
||||
from rbac.role as r
|
||||
join rbac.object as o on o.uuid = r.objectuuid
|
||||
where rbac.isGranted(rbac.currentSubjectOrAssumedRolesUuids(), r.uuid)
|
||||
) as unordered
|
||||
-- @formatter:on
|
||||
order by objectTable || '#' || objectIdName || ':' || roleType;
|
||||
grant all privileges on rbacrole_rv to ${HSADMINNG_POSTGRES_RESTRICTED_USERNAME};
|
||||
grant all privileges on rbac.role_rv to ${HSADMINNG_POSTGRES_RESTRICTED_USERNAME};
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-GRANT-ENHANCED-VIEW:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-views-GRANT-ENHANCED-VIEW endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
Creates a view to the grants table with additional columns
|
||||
for easier human readability.
|
||||
*/
|
||||
drop view if exists rbacgrants_ev;
|
||||
create or replace view rbacgrants_ev as
|
||||
drop view if exists rbac.grants_ev;
|
||||
create or replace view rbac.grants_ev as
|
||||
-- @formatter:off
|
||||
select x.grantUuid as uuid,
|
||||
x.grantedByTriggerOf as grantedByTriggerOf,
|
||||
go.objectTable || '#' || findIdNameByObjectUuid(go.objectTable, go.uuid) || ':' || r.roletype as grantedByRoleIdName,
|
||||
go.objectTable || '#' || base.findIdNameByObjectUuid(go.objectTable, go.uuid) || ':' || r.roletype as grantedByRoleIdName,
|
||||
x.ascendingIdName as ascendantIdName,
|
||||
x.descendingIdName as descendantIdName,
|
||||
x.grantedByRoleUuid,
|
||||
@@ -72,33 +72,33 @@ create or replace view rbacgrants_ev as
|
||||
|
||||
coalesce(
|
||||
'user:' || au.name,
|
||||
'role:' || aro.objectTable || '#' || findIdNameByObjectUuid(aro.objectTable, aro.uuid) || ':' || ar.roletype
|
||||
'role:' || aro.objectTable || '#' || base.findIdNameByObjectUuid(aro.objectTable, aro.uuid) || ':' || ar.roletype
|
||||
) as ascendingIdName,
|
||||
aro.objectTable, aro.uuid,
|
||||
( case
|
||||
when dro is not null
|
||||
then ('role:' || dro.objectTable || '#' || findIdNameByObjectUuid(dro.objectTable, dro.uuid) || ':' || dr.roletype)
|
||||
then ('role:' || dro.objectTable || '#' || base.findIdNameByObjectUuid(dro.objectTable, dro.uuid) || ':' || dr.roletype)
|
||||
when dp.op = 'INSERT'
|
||||
then 'perm:' || dpo.objecttable || '#' || findIdNameByObjectUuid(dpo.objectTable, dpo.uuid) || ':' || dp.op || '>' || dp.opTableName
|
||||
else 'perm:' || dpo.objecttable || '#' || findIdNameByObjectUuid(dpo.objectTable, dpo.uuid) || ':' || dp.op
|
||||
then 'perm:' || dpo.objecttable || '#' || base.findIdNameByObjectUuid(dpo.objectTable, dpo.uuid) || ':' || dp.op || '>' || dp.opTableName
|
||||
else 'perm:' || dpo.objecttable || '#' || base.findIdNameByObjectUuid(dpo.objectTable, dpo.uuid) || ':' || dp.op
|
||||
end
|
||||
) as descendingIdName,
|
||||
dro.objectTable, dro.uuid,
|
||||
dp.op, dp.optablename
|
||||
from rbacgrants as g
|
||||
from rbac.grants as g
|
||||
|
||||
left outer join rbacrole as ar on ar.uuid = g.ascendantUuid
|
||||
left outer join rbacobject as aro on aro.uuid = ar.objectuuid
|
||||
left outer join rbacuser as au on au.uuid = g.ascendantUuid
|
||||
left outer join rbac.role as ar on ar.uuid = g.ascendantUuid
|
||||
left outer join rbac.object as aro on aro.uuid = ar.objectuuid
|
||||
left outer join rbac.subject as au on au.uuid = g.ascendantUuid
|
||||
|
||||
left outer join rbacrole as dr on dr.uuid = g.descendantUuid
|
||||
left outer join rbacobject as dro on dro.uuid = dr.objectuuid
|
||||
left outer join rbacpermission dp on dp.uuid = g.descendantUuid
|
||||
left outer join rbacobject as dpo on dpo.uuid = dp.objectUuid
|
||||
left outer join rbac.role as dr on dr.uuid = g.descendantUuid
|
||||
left outer join rbac.object as dro on dro.uuid = dr.objectuuid
|
||||
left outer join rbac.permission dp on dp.uuid = g.descendantUuid
|
||||
left outer join rbac.object as dpo on dpo.uuid = dp.objectUuid
|
||||
) as x
|
||||
left outer join rbacrole as r on r.uuid = grantedByRoleUuid
|
||||
left outer join rbacuser u on u.uuid = x.ascendantuuid
|
||||
left outer join rbacobject go on go.uuid = r.objectuuid
|
||||
left outer join rbac.role as r on r.uuid = grantedByRoleUuid
|
||||
left outer join rbac.subject u on u.uuid = x.ascendantuuid
|
||||
left outer join rbac.object go on go.uuid = r.objectuuid
|
||||
|
||||
order by x.ascendingIdName, x.descendingIdName;
|
||||
-- @formatter:on
|
||||
@@ -106,116 +106,115 @@ create or replace view rbacgrants_ev as
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-GRANT-RESTRICTED-VIEW:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-views-GRANT-RESTRICTED-VIEW endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
Creates a view to the grants table with row-level limitation
|
||||
based on the direct grants of the current user.
|
||||
*/
|
||||
drop view if exists rbacgrants_rv;
|
||||
create or replace view rbacgrants_rv as
|
||||
-- @formatter:off
|
||||
select o.objectTable || '#' || findIdNameByObjectUuid(o.objectTable, o.uuid) || ':' || r.roletype as grantedByRoleIdName,
|
||||
create or replace view rbac.grants_rv as
|
||||
-- @formatter:off
|
||||
select o.objectTable || '#' || base.findIdNameByObjectUuid(o.objectTable, o.uuid) || ':' || r.roletype as grantedByRoleIdName,
|
||||
g.objectTable || '#' || g.objectIdName || ':' || g.roletype as grantedRoleIdName, g.userName, g.assumed,
|
||||
g.grantedByRoleUuid, g.descendantUuid as grantedRoleUuid, g.ascendantUuid as userUuid,
|
||||
g.grantedByRoleUuid, g.descendantUuid as grantedRoleUuid, g.ascendantUuid as subjectUuid,
|
||||
g.objectTable, g.objectUuid, g.objectIdName, g.roleType as grantedRoleType
|
||||
from (
|
||||
select g.grantedbyroleuuid, g.ascendantuuid, g.descendantuuid, g.assumed,
|
||||
u.name as userName, o.objecttable, r.objectuuid, r.roletype,
|
||||
findIdNameByObjectUuid(o.objectTable, o.uuid) as objectIdName
|
||||
from rbacgrants as g
|
||||
join rbacrole as r on r.uuid = g.descendantUuid
|
||||
join rbacobject o on o.uuid = r.objectuuid
|
||||
left outer join rbacuser u on u.uuid = g.ascendantuuid
|
||||
where isGranted(currentSubjectsUuids(), r.uuid)
|
||||
base.findIdNameByObjectUuid(o.objectTable, o.uuid) as objectIdName
|
||||
from rbac.grants as g
|
||||
join rbac.role as r on r.uuid = g.descendantUuid
|
||||
join rbac.object o on o.uuid = r.objectuuid
|
||||
left outer join rbac.subject u on u.uuid = g.ascendantuuid
|
||||
where rbac.isGranted(rbac.currentSubjectOrAssumedRolesUuids(), r.uuid)
|
||||
) as g
|
||||
join RbacRole as r on r.uuid = grantedByRoleUuid
|
||||
join RbacObject as o on o.uuid = r.objectUuid
|
||||
join rbac.role as r on r.uuid = grantedByRoleUuid
|
||||
join rbac.object as o on o.uuid = r.objectUuid
|
||||
order by grantedRoleIdName;
|
||||
-- @formatter:on
|
||||
grant all privileges on rbacrole_rv to ${HSADMINNG_POSTGRES_RESTRICTED_USERNAME};
|
||||
grant all privileges on rbac.role_rv to ${HSADMINNG_POSTGRES_RESTRICTED_USERNAME};
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-GRANTS-RV-INSERT-TRIGGER:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-views-GRANTS-RV-INSERT-TRIGGER endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
/**
|
||||
Instead of insert trigger function for RbacGrants_RV.
|
||||
Instead of insert trigger function for rbac.grants_rv.
|
||||
*/
|
||||
create or replace function insertRbacGrant()
|
||||
create or replace function rbac.insert_grant_tf()
|
||||
returns trigger
|
||||
language plpgsql as $$
|
||||
declare
|
||||
newGrant RbacGrants_RV;
|
||||
newGrant rbac.grants_rv;
|
||||
begin
|
||||
call grantRoleToUser(assumedRoleUuid(), new.grantedRoleUuid, new.userUuid, new.assumed);
|
||||
call rbac.grantRoleToSubject(rbac.assumedRoleUuid(), new.grantedRoleUuid, new.subjectUuid, new.assumed);
|
||||
select grv.*
|
||||
from RbacGrants_RV grv
|
||||
where grv.userUuid=new.userUuid and grv.grantedRoleUuid=new.grantedRoleUuid
|
||||
from rbac.grants_rv grv
|
||||
where grv.subjectUuid=new.subjectUuid and grv.grantedRoleUuid=new.grantedRoleUuid
|
||||
into newGrant;
|
||||
return newGrant;
|
||||
end; $$;
|
||||
|
||||
/*
|
||||
Creates an instead of insert trigger for the RbacGrants_rv view.
|
||||
Creates an instead of insert trigger for the rbac.grants_rv view.
|
||||
*/
|
||||
create trigger insertRbacGrant_Trigger
|
||||
create trigger insert_grant_tg
|
||||
instead of insert
|
||||
on RbacGrants_rv
|
||||
on rbac.grants_rv
|
||||
for each row
|
||||
execute function insertRbacGrant();
|
||||
execute function rbac.insert_grant_tf();
|
||||
--/
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-GRANTS-RV-DELETE-TRIGGER:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-views-GRANTS-RV-DELETE-TRIGGER endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
/**
|
||||
Instead of delete trigger function for RbacGrants_RV.
|
||||
Instead of delete trigger function for rbac.grants_rv.
|
||||
|
||||
Checks if the current subject (user / assumed role) has the permission to revoke the grant.
|
||||
Checks if the current subject or assumed role have the permission to revoke the grant.
|
||||
*/
|
||||
create or replace function deleteRbacGrant()
|
||||
create or replace function rbac.delete_grant_tf()
|
||||
returns trigger
|
||||
language plpgsql as $$
|
||||
begin
|
||||
call revokeRoleFromUser(old.grantedByRoleUuid, old.grantedRoleUuid, old.userUuid);
|
||||
call rbac.revokeRoleFromSubject(old.grantedByRoleUuid, old.grantedRoleUuid, old.subjectUuid);
|
||||
return old;
|
||||
end; $$;
|
||||
|
||||
/*
|
||||
Creates an instead of delete trigger for the RbacGrants_rv view.
|
||||
Creates an instead of delete trigger for the rbac.grants_rv view.
|
||||
*/
|
||||
create trigger deleteRbacGrant_Trigger
|
||||
create trigger delete_grant_tg
|
||||
instead of delete
|
||||
on RbacGrants_rv
|
||||
on rbac.grants_rv
|
||||
for each row
|
||||
execute function deleteRbacGrant();
|
||||
execute function rbac.delete_grant_tf();
|
||||
--/
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-USER-ENHANCED-VIEW:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-views-USER-ENHANCED-VIEW endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
Creates a view to the users table with additional columns
|
||||
for easier human readability.
|
||||
*/
|
||||
drop view if exists RbacUser_ev;
|
||||
create or replace view RbacUser_ev as
|
||||
drop view if exists rbac.subject_ev;
|
||||
create or replace view rbac.subject_ev as
|
||||
select distinct *
|
||||
-- @formatter:off
|
||||
from (
|
||||
select usersInRolesOfCurrentUser.*
|
||||
from RbacUser as usersInRolesOfCurrentUser
|
||||
join RbacGrants as g on g.ascendantuuid = usersInRolesOfCurrentUser.uuid
|
||||
join rbacrole_ev as r on r.uuid = g.descendantuuid
|
||||
select usersInRolesOfcurrentSubject.*
|
||||
from rbac.subject as usersInRolesOfcurrentSubject
|
||||
join rbac.grants as g on g.ascendantuuid = usersInRolesOfcurrentSubject.uuid
|
||||
join rbac.role_ev as r on r.uuid = g.descendantuuid
|
||||
union
|
||||
select users.*
|
||||
from RbacUser as users
|
||||
from rbac.subject as users
|
||||
) as unordered
|
||||
-- @formatter:on
|
||||
order by unordered.name;
|
||||
@@ -223,53 +222,53 @@ select distinct *
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-USER-RESTRICTED-VIEW:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-views-USER-RESTRICTED-VIEW endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
Creates a view to the users table with row-level limitation
|
||||
based on the grants of the current user or assumed roles.
|
||||
*/
|
||||
drop view if exists RbacUser_rv;
|
||||
create or replace view RbacUser_rv as
|
||||
drop view if exists rbac.subject_rv;
|
||||
create or replace view rbac.subject_rv as
|
||||
select distinct *
|
||||
-- @formatter:off
|
||||
from (
|
||||
select usersInRolesOfCurrentUser.*
|
||||
from RbacUser as usersInRolesOfCurrentUser
|
||||
join RbacGrants as g on g.ascendantuuid = usersInRolesOfCurrentUser.uuid
|
||||
join rbacrole_rv as r on r.uuid = g.descendantuuid
|
||||
select usersInRolesOfcurrentSubject.*
|
||||
from rbac.subject as usersInRolesOfcurrentSubject
|
||||
join rbac.grants as g on g.ascendantuuid = usersInRolesOfcurrentSubject.uuid
|
||||
join rbac.role_rv as r on r.uuid = g.descendantuuid
|
||||
union
|
||||
select users.*
|
||||
from RbacUser as users
|
||||
where cardinality(assumedRoles()) = 0 and
|
||||
(currentUserUuid() = users.uuid or hasGlobalRoleGranted(currentUserUuid()))
|
||||
from rbac.subject as users
|
||||
where cardinality(base.assumedRoles()) = 0 and
|
||||
(rbac.currentSubjectUuid() = users.uuid or rbac.hasGlobalRoleGranted(rbac.currentSubjectUuid()))
|
||||
|
||||
) as unordered
|
||||
-- @formatter:on
|
||||
order by unordered.name;
|
||||
grant all privileges on RbacUser_rv to ${HSADMINNG_POSTGRES_RESTRICTED_USERNAME};
|
||||
grant all privileges on rbac.subject_rv to ${HSADMINNG_POSTGRES_RESTRICTED_USERNAME};
|
||||
--//
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-USER-RV-INSERT-TRIGGER:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-views-USER-RV-INSERT-TRIGGER endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
/**
|
||||
Instead of insert trigger function for RbacUser_rv.
|
||||
Instead of insert trigger function for rbac.subject_rv.
|
||||
*/
|
||||
create or replace function insertRbacUser()
|
||||
create or replace function rbac.insert_subject_tf()
|
||||
returns trigger
|
||||
language plpgsql as $$
|
||||
declare
|
||||
refUuid uuid;
|
||||
newUser RbacUser;
|
||||
newUser rbac.subject;
|
||||
begin
|
||||
insert
|
||||
into RbacReference as r (uuid, type)
|
||||
values( new.uuid, 'RbacUser')
|
||||
into rbac.reference as r (uuid, type)
|
||||
values( new.uuid, 'rbac.subject')
|
||||
returning r.uuid into refUuid;
|
||||
insert
|
||||
into RbacUser (uuid, name)
|
||||
into rbac.subject (uuid, name)
|
||||
values (refUuid, new.name)
|
||||
returning * into newUser;
|
||||
return newUser;
|
||||
@@ -277,84 +276,84 @@ end;
|
||||
$$;
|
||||
|
||||
/*
|
||||
Creates an instead of insert trigger for the RbacUser_rv view.
|
||||
Creates an instead of insert trigger for the rbac.subject_rv view.
|
||||
*/
|
||||
create trigger insertRbacUser_Trigger
|
||||
create trigger insert_subject_tg
|
||||
instead of insert
|
||||
on RbacUser_rv
|
||||
on rbac.subject_rv
|
||||
for each row
|
||||
execute function insertRbacUser();
|
||||
execute function rbac.insert_subject_tf();
|
||||
--//
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-USER-RV-DELETE-TRIGGER:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-views-USER-RV-DELETE-TRIGGER endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
/**
|
||||
Instead of delete trigger function for RbacUser_RV.
|
||||
Instead of delete trigger function for rbac.subject_rv.
|
||||
|
||||
Checks if the current subject (user / assumed role) has the permission to delete the user.
|
||||
*/
|
||||
create or replace function deleteRbacUser()
|
||||
create or replace function rbac.delete_subject_tf()
|
||||
returns trigger
|
||||
language plpgsql as $$
|
||||
begin
|
||||
if currentUserUuid() = old.uuid or hasGlobalRoleGranted(currentUserUuid()) then
|
||||
delete from RbacUser where uuid = old.uuid;
|
||||
if rbac.currentSubjectUuid() = old.uuid or rbac.hasGlobalRoleGranted(rbac.currentSubjectUuid()) then
|
||||
delete from rbac.subject where uuid = old.uuid;
|
||||
return old;
|
||||
end if;
|
||||
raise exception '[403] User % not allowed to delete user uuid %', currentUser(), old.uuid;
|
||||
raise exception '[403] User % not allowed to delete user uuid %', base.currentSubject(), old.uuid;
|
||||
end; $$;
|
||||
|
||||
/*
|
||||
Creates an instead of delete trigger for the RbacUser_rv view.
|
||||
Creates an instead of delete trigger for the rbac.subject_rv view.
|
||||
*/
|
||||
create trigger deleteRbacUser_Trigger
|
||||
create trigger delete_subject_tg
|
||||
instead of delete
|
||||
on RbacUser_rv
|
||||
on rbac.subject_rv
|
||||
for each row
|
||||
execute function deleteRbacUser();
|
||||
execute function rbac.delete_subject_tf();
|
||||
--/
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-OWN-GRANTED-PERMISSIONS-VIEW:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-views-OWN-GRANTED-PERMISSIONS-VIEW endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
Creates a view to all permissions granted to the current user or
|
||||
based on the grants of the current user or assumed roles.
|
||||
*/
|
||||
-- @formatter:off
|
||||
drop view if exists RbacOwnGrantedPermissions_rv;
|
||||
create or replace view RbacOwnGrantedPermissions_rv as
|
||||
drop view if exists rbac.own_granted_permissions_rv;
|
||||
create or replace view rbac.own_granted_permissions_rv as
|
||||
select r.uuid as roleuuid, p.uuid as permissionUuid,
|
||||
(r.objecttable || ':' || r.objectidname || ':' || r.roletype) as roleName, p.op,
|
||||
o.objecttable, r.objectidname, o.uuid as objectuuid
|
||||
from rbacrole_rv r
|
||||
join rbacgrants g on g.ascendantuuid = r.uuid
|
||||
join rbacpermission p on p.uuid = g.descendantuuid
|
||||
join rbacobject o on o.uuid = p.objectuuid;
|
||||
grant all privileges on RbacOwnGrantedPermissions_rv to ${HSADMINNG_POSTGRES_RESTRICTED_USERNAME};
|
||||
from rbac.role_rv r
|
||||
join rbac.grants g on g.ascendantuuid = r.uuid
|
||||
join rbac.permission p on p.uuid = g.descendantuuid
|
||||
join rbac.object o on o.uuid = p.objectuuid;
|
||||
grant all privileges on rbac.own_granted_permissions_rv to ${HSADMINNG_POSTGRES_RESTRICTED_USERNAME};
|
||||
-- @formatter:om
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-GRANTED-PERMISSIONS:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-views-GRANTED-PERMISSIONS endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
Returns all permissions granted to the given user,
|
||||
which are also visible to the current user or assumed roles.
|
||||
*/
|
||||
create or replace function grantedPermissionsRaw(targetUserUuid uuid)
|
||||
returns table(roleUuid uuid, roleName text, permissionUuid uuid, op RbacOp, opTableName varchar(60), objectTable varchar(60), objectIdName varchar, objectUuid uuid)
|
||||
create or replace function rbac.grantedPermissionsRaw(targetSubjectUuid uuid)
|
||||
returns table(roleUuid uuid, roleName text, permissionUuid uuid, op rbac.RbacOp, opTableName varchar(60), objectTable varchar(60), objectIdName varchar, objectUuid uuid)
|
||||
returns null on null input
|
||||
language plpgsql as $$
|
||||
declare
|
||||
currentUserUuid uuid;
|
||||
currentSubjectUuid uuid;
|
||||
begin
|
||||
-- @formatter:off
|
||||
currentUserUuid := currentUserUuid();
|
||||
currentSubjectUuid := rbac.currentSubjectUuid();
|
||||
|
||||
if hasGlobalRoleGranted(targetUserUuid) and not hasGlobalRoleGranted(currentUserUuid) then
|
||||
raise exception '[403] permissions of user "%" are not accessible to user "%"', targetUserUuid, currentUser();
|
||||
if rbac.hasGlobalRoleGranted(targetSubjectUuid) and not rbac.hasGlobalRoleGranted(currentSubjectUuid) then
|
||||
raise exception '[403] permissions of user "%" are not accessible to user "%"', targetSubjectUuid, base.currentSubject();
|
||||
end if;
|
||||
|
||||
return query select
|
||||
@@ -364,29 +363,29 @@ begin
|
||||
xp.permissionObjectTable, xp.permissionObjectIdName, xp.permissionObjectUuid
|
||||
from (select
|
||||
r.uuid as roleUuid, r.roletype, ro.objectTable as roleObjectTable,
|
||||
findIdNameByObjectUuid(ro.objectTable, ro.uuid) as roleObjectIdName,
|
||||
base.findIdNameByObjectUuid(ro.objectTable, ro.uuid) as roleObjectIdName,
|
||||
p.uuid as permissionUuid, p.op, p.opTableName,
|
||||
po.objecttable as permissionObjectTable,
|
||||
findIdNameByObjectUuid(po.objectTable, po.uuid) as permissionObjectIdName,
|
||||
base.findIdNameByObjectUuid(po.objectTable, po.uuid) as permissionObjectIdName,
|
||||
po.uuid as permissionObjectUuid
|
||||
from queryPermissionsGrantedToSubjectId( targetUserUuid) as p
|
||||
join rbacgrants as g on g.descendantUuid = p.uuid
|
||||
join rbacobject as po on po.uuid = p.objectUuid
|
||||
join rbacrole_rv as r on r.uuid = g.ascendantUuid
|
||||
join rbacobject as ro on ro.uuid = r.objectUuid
|
||||
where isGranted(targetUserUuid, r.uuid)
|
||||
from rbac.queryPermissionsGrantedToSubjectId( targetSubjectUuid) as p
|
||||
join rbac.grants as g on g.descendantUuid = p.uuid
|
||||
join rbac.object as po on po.uuid = p.objectUuid
|
||||
join rbac.role_rv as r on r.uuid = g.ascendantUuid
|
||||
join rbac.object as ro on ro.uuid = r.objectUuid
|
||||
where rbac.isGranted(targetSubjectUuid, r.uuid)
|
||||
) xp;
|
||||
-- @formatter:on
|
||||
end; $$;
|
||||
|
||||
create or replace function grantedPermissions(targetUserUuid uuid)
|
||||
returns table(roleUuid uuid, roleName text, permissionUuid uuid, op RbacOp, opTableName varchar(60), objectTable varchar(60), objectIdName varchar, objectUuid uuid)
|
||||
create or replace function rbac.grantedPermissions(targetSubjectUuid uuid)
|
||||
returns table(roleUuid uuid, roleName text, permissionUuid uuid, op rbac.RbacOp, opTableName varchar(60), objectTable varchar(60), objectIdName varchar, objectUuid uuid)
|
||||
returns null on null input
|
||||
language sql as $$
|
||||
select * from grantedPermissionsRaw(targetUserUuid)
|
||||
select * from rbac.grantedPermissionsRaw(targetSubjectUuid)
|
||||
union all
|
||||
select roleUuid, roleName, permissionUuid, 'SELECT'::RbacOp, opTableName, objectTable, objectIdName, objectUuid
|
||||
from grantedPermissionsRaw(targetUserUuid)
|
||||
where op <> 'SELECT'::RbacOp;
|
||||
select roleUuid, roleName, permissionUuid, 'SELECT'::rbac.RbacOp, opTableName, objectTable, objectIdName, objectUuid
|
||||
from rbac.grantedPermissionsRaw(targetSubjectUuid)
|
||||
where op <> 'SELECT'::rbac.RbacOp;
|
||||
$$;
|
||||
--//
|
||||
|
@@ -2,10 +2,10 @@
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-trigger-context-ENTER:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-trigger-context-ENTER endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace procedure enterTriggerForObjectUuid(currentObjectUuid uuid)
|
||||
create or replace procedure rbac.enterTriggerForObjectUuid(currentObjectUuid uuid)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
existingObjectUuid text;
|
||||
@@ -19,13 +19,13 @@ end; $$;
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-trigger-context-CURRENT-ID:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-trigger-context-CURRENT-ID endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
Returns the uuid of the object uuid whose trigger is currently executed as set via `enterTriggerForObjectUuid(...)`.
|
||||
Returns the uuid of the object uuid whose trigger is currently executed as set via `rbac.enterTriggerForObjectUuid(...)`.
|
||||
*/
|
||||
|
||||
create or replace function currentTriggerObjectUuid()
|
||||
create or replace function rbac.currentTriggerObjectUuid()
|
||||
returns uuid
|
||||
stable -- leakproof
|
||||
language plpgsql as $$
|
||||
@@ -44,10 +44,10 @@ end; $$;
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-trigger-context-LEAVE:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-trigger-context-LEAVE endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace procedure leaveTriggerForObjectUuid(currentObjectUuid uuid)
|
||||
create or replace procedure rbac.leaveTriggerForObjectUuid(currentObjectUuid uuid)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
existingObjectUuid uuid;
|
||||
|
@@ -3,62 +3,61 @@
|
||||
|
||||
-- =================================================================
|
||||
-- CREATE ROLE
|
||||
--changeset rbac-role-builder-create-role:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-role-builder-define-role endDelimiter:--//
|
||||
-- -----------------------------------------------------------------
|
||||
|
||||
-- TODO: rename to defineRoleWithGrants because it does not complain if the role already exists
|
||||
create or replace function createRoleWithGrants(
|
||||
roleDescriptor RbacRoleDescriptor,
|
||||
permissions RbacOp[] = array[]::RbacOp[],
|
||||
incomingSuperRoles RbacRoleDescriptor[] = array[]::RbacRoleDescriptor[],
|
||||
outgoingSubRoles RbacRoleDescriptor[] = array[]::RbacRoleDescriptor[],
|
||||
userUuids uuid[] = array[]::uuid[],
|
||||
grantedByRole RbacRoleDescriptor = null
|
||||
create or replace function rbac.defineRoleWithGrants(
|
||||
roleDescriptor rbac.RoleDescriptor,
|
||||
permissions rbac.RbacOp[] = array[]::rbac.RbacOp[],
|
||||
incomingSuperRoles rbac.RoleDescriptor[] = array[]::rbac.RoleDescriptor[],
|
||||
outgoingSubRoles rbac.RoleDescriptor[] = array[]::rbac.RoleDescriptor[],
|
||||
subjectUuids uuid[] = array[]::uuid[],
|
||||
grantedByRole rbac.RoleDescriptor = null
|
||||
)
|
||||
returns uuid
|
||||
called on null input
|
||||
language plpgsql as $$
|
||||
declare
|
||||
roleUuid uuid;
|
||||
permission RbacOp;
|
||||
permission rbac.RbacOp;
|
||||
permissionUuid uuid;
|
||||
subRoleDesc RbacRoleDescriptor;
|
||||
superRoleDesc RbacRoleDescriptor;
|
||||
subRoleDesc rbac.RoleDescriptor;
|
||||
superRoleDesc rbac.RoleDescriptor;
|
||||
subRoleUuid uuid;
|
||||
superRoleUuid uuid;
|
||||
userUuid uuid;
|
||||
subjectUuid uuid;
|
||||
userGrantsByRoleUuid uuid;
|
||||
begin
|
||||
roleUuid := coalesce(findRoleId(roleDescriptor), createRole(roleDescriptor));
|
||||
roleUuid := coalesce(rbac.findRoleId(roleDescriptor), rbac.createRole(roleDescriptor));
|
||||
|
||||
foreach permission in array permissions
|
||||
loop
|
||||
permissionUuid := createPermission(roleDescriptor.objectuuid, permission);
|
||||
call grantPermissionToRole(permissionUuid, roleUuid);
|
||||
permissionUuid := rbac.createPermission(roleDescriptor.objectuuid, permission);
|
||||
call rbac.grantPermissionToRole(permissionUuid, roleUuid);
|
||||
end loop;
|
||||
|
||||
foreach superRoleDesc in array array_remove(incomingSuperRoles, null)
|
||||
loop
|
||||
superRoleUuid := getRoleId(superRoleDesc);
|
||||
call grantRoleToRole(roleUuid, superRoleUuid, superRoleDesc.assumed);
|
||||
superRoleUuid := rbac.getRoleId(superRoleDesc);
|
||||
call rbac.grantRoleToRole(roleUuid, superRoleUuid, superRoleDesc.assumed);
|
||||
end loop;
|
||||
|
||||
foreach subRoleDesc in array array_remove(outgoingSubRoles, null)
|
||||
loop
|
||||
subRoleUuid := getRoleId(subRoleDesc);
|
||||
call grantRoleToRole(subRoleUuid, roleUuid, subRoleDesc.assumed);
|
||||
subRoleUuid := rbac.getRoleId(subRoleDesc);
|
||||
call rbac.grantRoleToRole(subRoleUuid, roleUuid, subRoleDesc.assumed);
|
||||
end loop;
|
||||
|
||||
if cardinality(userUuids) > 0 then
|
||||
if cardinality(subjectUuids) > 0 then
|
||||
-- direct grants to users need a grantedByRole which can revoke the grant
|
||||
if grantedByRole is null then
|
||||
userGrantsByRoleUuid := roleUuid; -- TODO.impl: or do we want to require an explicit userGrantsByRoleUuid?
|
||||
else
|
||||
userGrantsByRoleUuid := getRoleId(grantedByRole);
|
||||
userGrantsByRoleUuid := rbac.getRoleId(grantedByRole);
|
||||
end if;
|
||||
foreach userUuid in array userUuids
|
||||
foreach subjectUuid in array subjectUuids
|
||||
loop
|
||||
call grantRoleToUserUnchecked(userGrantsByRoleUuid, roleUuid, userUuid);
|
||||
call rbac.grantRoleToSubjectUnchecked(userGrantsByRoleUuid, roleUuid, subjectUuid);
|
||||
end loop;
|
||||
end if;
|
||||
|
||||
|
@@ -2,10 +2,10 @@
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-generators-RELATED-OBJECT:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-generators-RELATED-OBJECT endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace procedure generateRelatedRbacObject(targetTable varchar)
|
||||
create or replace procedure rbac.generateRelatedRbacObject(targetTable varchar)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
createInsertTriggerSQL text;
|
||||
@@ -15,16 +15,16 @@ begin
|
||||
create trigger createRbacObjectFor_%s_Trigger
|
||||
before insert on %s
|
||||
for each row
|
||||
execute procedure insertRelatedRbacObject();
|
||||
execute procedure rbac.insert_related_object();
|
||||
$sql$, targetTable, targetTable);
|
||||
execute createInsertTriggerSQL;
|
||||
|
||||
createDeleteTriggerSQL = format($sql$
|
||||
create trigger deleteRbacRulesFor_%s_Trigger
|
||||
create trigger delete_related_rbac_rules_for_%s_tg
|
||||
after delete
|
||||
on %s
|
||||
for each row
|
||||
execute procedure deleteRelatedRbacObject();
|
||||
execute procedure rbac.delete_related_rbac_rules_tf();
|
||||
$sql$, targetTable, targetTable);
|
||||
execute createDeleteTriggerSQL;
|
||||
end; $$;
|
||||
@@ -32,62 +32,62 @@ end; $$;
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-generators-ROLE-DESCRIPTORS:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-generators-ROLE-DESCRIPTORS endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create procedure generateRbacRoleDescriptors(prefix text, targetTable text)
|
||||
create procedure rbac.generateRbacRoleDescriptors(prefix text, targetTable text)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
sql text;
|
||||
begin
|
||||
sql = format($sql$
|
||||
create or replace function %1$sOwner(entity %2$s, assumed boolean = true)
|
||||
returns RbacRoleDescriptor
|
||||
returns rbac.RoleDescriptor
|
||||
language plpgsql
|
||||
strict as $f$
|
||||
begin
|
||||
return roleDescriptor('%2$s', entity.uuid, 'OWNER', assumed);
|
||||
return rbac.roleDescriptorOf('%2$s', entity.uuid, 'OWNER', assumed);
|
||||
end; $f$;
|
||||
|
||||
create or replace function %1$sAdmin(entity %2$s, assumed boolean = true)
|
||||
returns RbacRoleDescriptor
|
||||
returns rbac.RoleDescriptor
|
||||
language plpgsql
|
||||
strict as $f$
|
||||
begin
|
||||
return roleDescriptor('%2$s', entity.uuid, 'ADMIN', assumed);
|
||||
return rbac.roleDescriptorOf('%2$s', entity.uuid, 'ADMIN', assumed);
|
||||
end; $f$;
|
||||
|
||||
create or replace function %1$sAgent(entity %2$s, assumed boolean = true)
|
||||
returns RbacRoleDescriptor
|
||||
returns rbac.RoleDescriptor
|
||||
language plpgsql
|
||||
strict as $f$
|
||||
begin
|
||||
return roleDescriptor('%2$s', entity.uuid, 'AGENT', assumed);
|
||||
return rbac.roleDescriptorOf('%2$s', entity.uuid, 'AGENT', assumed);
|
||||
end; $f$;
|
||||
|
||||
create or replace function %1$sTenant(entity %2$s, assumed boolean = true)
|
||||
returns RbacRoleDescriptor
|
||||
returns rbac.RoleDescriptor
|
||||
language plpgsql
|
||||
strict as $f$
|
||||
begin
|
||||
return roleDescriptor('%2$s', entity.uuid, 'TENANT', assumed);
|
||||
return rbac.roleDescriptorOf('%2$s', entity.uuid, 'TENANT', assumed);
|
||||
end; $f$;
|
||||
|
||||
-- TODO: remove guest role
|
||||
create or replace function %1$sGuest(entity %2$s, assumed boolean = true)
|
||||
returns RbacRoleDescriptor
|
||||
returns rbac.RoleDescriptor
|
||||
language plpgsql
|
||||
strict as $f$
|
||||
begin
|
||||
return roleDescriptor('%2$s', entity.uuid, 'GUEST', assumed);
|
||||
return rbac.roleDescriptorOf('%2$s', entity.uuid, 'GUEST', assumed);
|
||||
end; $f$;
|
||||
|
||||
create or replace function %1$sReferrer(entity %2$s)
|
||||
returns RbacRoleDescriptor
|
||||
returns rbac.RoleDescriptor
|
||||
language plpgsql
|
||||
strict as $f$
|
||||
begin
|
||||
return roleDescriptor('%2$s', entity.uuid, 'REFERRER');
|
||||
return rbac.roleDescriptorOf('%2$s', entity.uuid, 'REFERRER');
|
||||
end; $f$;
|
||||
|
||||
$sql$, prefix, targetTable);
|
||||
@@ -97,10 +97,10 @@ end; $$;
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-generators-IDENTITY-VIEW:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-generators-IDENTITY-VIEW endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace procedure generateRbacIdentityViewFromQuery(targetTable text, sqlQuery text)
|
||||
create or replace procedure rbac.generateRbacIdentityViewFromQuery(targetTable text, sqlQuery text)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
sql text;
|
||||
@@ -140,7 +140,7 @@ begin
|
||||
execute sql;
|
||||
end; $$;
|
||||
|
||||
create or replace procedure generateRbacIdentityViewFromProjection(targetTable text, sqlProjection text)
|
||||
create or replace procedure rbac.generateRbacIdentityViewFromProjection(targetTable text, sqlProjection text)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
sqlQuery text;
|
||||
@@ -148,19 +148,19 @@ begin
|
||||
targettable := lower(targettable);
|
||||
|
||||
sqlQuery = format($sql$
|
||||
select target.uuid, cleanIdentifier(%2$s) as idName
|
||||
select target.uuid, base.cleanIdentifier(%2$s) as idName
|
||||
from %1$s as target;
|
||||
$sql$, targetTable, sqlProjection);
|
||||
call generateRbacIdentityViewFromQuery(targetTable, sqlQuery);
|
||||
call rbac.generateRbacIdentityViewFromQuery(targetTable, sqlQuery);
|
||||
end; $$;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-generators-RESTRICTED-VIEW:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-generators-RESTRICTED-VIEW endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace procedure generateRbacRestrictedView(targetTable text, orderBy text, columnUpdates text = null, columnNames text = '*')
|
||||
create or replace procedure rbac.generateRbacRestrictedView(targetTable text, orderBy text, columnUpdates text = null, columnNames text = '*')
|
||||
language plpgsql as $$
|
||||
declare
|
||||
sql text;
|
||||
@@ -168,7 +168,7 @@ declare
|
||||
begin
|
||||
targetTable := lower(targetTable);
|
||||
if columnNames = '*' then
|
||||
columnNames := columnsNames(targetTable);
|
||||
columnNames := base.tableColumnNames(targetTable);
|
||||
end if;
|
||||
|
||||
/*
|
||||
@@ -179,31 +179,31 @@ begin
|
||||
with accessible_%1$s_uuids as (
|
||||
with recursive
|
||||
recursive_grants as
|
||||
(select distinct rbacgrants.descendantuuid,
|
||||
rbacgrants.ascendantuuid,
|
||||
(select distinct rbac.grants.descendantuuid,
|
||||
rbac.grants.ascendantuuid,
|
||||
1 as level,
|
||||
true
|
||||
from rbacgrants
|
||||
where rbacgrants.assumed
|
||||
and (rbacgrants.ascendantuuid = any (currentsubjectsuuids()))
|
||||
from rbac.grants
|
||||
where rbac.grants.assumed
|
||||
and (rbac.grants.ascendantuuid = any (rbac.currentSubjectOrAssumedRolesUuids()))
|
||||
union all
|
||||
select distinct g.descendantuuid,
|
||||
g.ascendantuuid,
|
||||
grants.level + 1 as level,
|
||||
assertTrue(grants.level < 22, 'too many grant-levels: ' || grants.level)
|
||||
from rbacgrants g
|
||||
base.assertTrue(grants.level < 22, 'too many grant-levels: ' || grants.level)
|
||||
from rbac.grants g
|
||||
join recursive_grants grants on grants.descendantuuid = g.ascendantuuid
|
||||
where g.assumed),
|
||||
grant_count AS (
|
||||
SELECT COUNT(*) AS grant_count FROM recursive_grants
|
||||
),
|
||||
count_check as (select assertTrue((select count(*) as grant_count from recursive_grants) < 400000,
|
||||
count_check as (select base.assertTrue((select count(*) as grant_count from recursive_grants) < 400000,
|
||||
'too many grants for current subjects: ' || (select count(*) as grant_count from recursive_grants))
|
||||
as valid)
|
||||
select distinct perm.objectuuid
|
||||
from recursive_grants
|
||||
join rbacpermission perm on recursive_grants.descendantuuid = perm.uuid
|
||||
join rbacobject obj on obj.uuid = perm.objectuuid
|
||||
join rbac.permission perm on recursive_grants.descendantuuid = perm.uuid
|
||||
join rbac.object obj on obj.uuid = perm.objectuuid
|
||||
join count_check cc on cc.valid
|
||||
where obj.objectTable = '%1$s' -- 'SELECT' permission is included in all other permissions
|
||||
)
|
||||
@@ -256,11 +256,11 @@ begin
|
||||
returns trigger
|
||||
language plpgsql as $f$
|
||||
begin
|
||||
if old.uuid in (select queryAccessibleObjectUuidsOfSubjectIds('DELETE', '%1$s', currentSubjectsUuids())) then
|
||||
if old.uuid in (select rbac.queryAccessibleObjectUuidsOfSubjectIds('DELETE', '%1$s', rbac.currentSubjectOrAssumedRolesUuids())) then
|
||||
delete from %1$s p where p.uuid = old.uuid;
|
||||
return old;
|
||||
end if;
|
||||
raise exception '[403] Subject %% is not allowed to delete %1$s uuid %%', currentSubjectsUuids(), old.uuid;
|
||||
raise exception '[403] Subject %% is not allowed to delete %1$s uuid %%', rbac.currentSubjectOrAssumedRolesUuids(), old.uuid;
|
||||
end; $f$;
|
||||
$sql$, targetTable);
|
||||
execute sql;
|
||||
@@ -287,13 +287,13 @@ begin
|
||||
returns trigger
|
||||
language plpgsql as $f$
|
||||
begin
|
||||
if old.uuid in (select queryAccessibleObjectUuidsOfSubjectIds('UPDATE', '%1$s', currentSubjectsUuids())) then
|
||||
if old.uuid in (select rbac.queryAccessibleObjectUuidsOfSubjectIds('UPDATE', '%1$s', rbac.currentSubjectOrAssumedRolesUuids())) then
|
||||
update %1$s
|
||||
set %2$s
|
||||
where uuid = old.uuid;
|
||||
return old;
|
||||
end if;
|
||||
raise exception '[403] Subject %% is not allowed to update %1$s uuid %%', currentSubjectsUuids(), old.uuid;
|
||||
raise exception '[403] Subject %% is not allowed to update %1$s uuid %%', rbac.currentSubjectOrAssumedRolesUuids(), old.uuid;
|
||||
end; $f$;
|
||||
$sql$, targetTable, columnUpdates);
|
||||
execute sql;
|
||||
|
@@ -1,28 +1,28 @@
|
||||
--liquibase formatted sql
|
||||
|
||||
--changeset rbac-statistics:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-statistics endDelimiter:--//
|
||||
|
||||
/*
|
||||
Creates a view which presents some statistics about the RBAC tables.
|
||||
*/
|
||||
create view RbacStatisticsView as
|
||||
create view rbac.statistics_v 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
|
||||
from rbac.subject
|
||||
union
|
||||
select 2 as no, count(*) as "count", 'roles' as "table"
|
||||
from RbacRole
|
||||
from rbac.role
|
||||
union
|
||||
select 3 as no, count(*) as "count", 'permissions' as "table"
|
||||
from RbacPermission
|
||||
from rbac.permission
|
||||
union
|
||||
select 4 as no, count(*) as "count", 'references' as "table"
|
||||
from RbacReference
|
||||
from rbac.reference
|
||||
union
|
||||
select 5 as no, count(*) as "count", 'grants' as "table"
|
||||
from RbacGrants
|
||||
from rbac.grants
|
||||
union
|
||||
select 6 as no, count(*) as "count", 'objects' as "table"
|
||||
from RbacObject) as totals
|
||||
from rbac.object) as totals
|
||||
order by totals.no;
|
||||
--//
|
||||
|
@@ -1,7 +1,7 @@
|
||||
--liquibase formatted sql
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-global-GLOBAL-OBJECT:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-global-OBJECT endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
The purpose of this table is provide root business objects
|
||||
@@ -11,184 +11,184 @@
|
||||
In production databases, there is only a single row in this table,
|
||||
in test stages, there can be one row for each test data realm.
|
||||
*/
|
||||
create table Global
|
||||
create table rbac.global
|
||||
(
|
||||
uuid uuid primary key references RbacObject (uuid) on delete cascade,
|
||||
uuid uuid primary key references rbac.object (uuid) on delete cascade,
|
||||
name varchar(63) unique
|
||||
);
|
||||
create unique index Global_Singleton on Global ((0));
|
||||
create unique index Global_Singleton on rbac.global ((0));
|
||||
|
||||
grant select on global to ${HSADMINNG_POSTGRES_RESTRICTED_USERNAME};
|
||||
grant select on rbac.global to ${HSADMINNG_POSTGRES_RESTRICTED_USERNAME};
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-global-IS-GLOBAL-ADMIN:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-global-IS-GLOBAL-ADMIN endDelimiter:--//
|
||||
-- ------------------------------------------------------------------
|
||||
|
||||
create or replace function isGlobalAdmin()
|
||||
create or replace function rbac.isGlobalAdmin()
|
||||
returns boolean
|
||||
language plpgsql as $$
|
||||
begin
|
||||
return isGranted(currentSubjectsUuids(), findRoleId(globalAdmin()));
|
||||
return rbac.isGranted(rbac.currentSubjectOrAssumedRolesUuids(), rbac.findRoleId(rbac.globalAdmin()));
|
||||
end; $$;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-global-HAS-GLOBAL-PERMISSION:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-global-HAS-GLOBAL-PERMISSION endDelimiter:--//
|
||||
-- ------------------------------------------------------------------
|
||||
|
||||
create or replace function hasGlobalPermission(op RbacOp)
|
||||
create or replace function rbac.hasGlobalPermission(op rbac.RbacOp)
|
||||
returns boolean
|
||||
language sql as
|
||||
$$
|
||||
-- TODO.perf: this could to be optimized
|
||||
select (select uuid from global) in
|
||||
(select queryAccessibleObjectUuidsOfSubjectIds(op, 'global', currentSubjectsUuids()));
|
||||
select (select uuid from rbac.global) in
|
||||
(select rbac.queryAccessibleObjectUuidsOfSubjectIds(op, 'rbac.global', rbac.currentSubjectOrAssumedRolesUuids()));
|
||||
$$;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-global-GLOBAL-IDENTITY-VIEW:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-global-IDENTITY-VIEW endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
/*
|
||||
Creates a view to the global object table which maps the identifying name to the objectUuid.
|
||||
Creates a view to the rbac.global object table which maps the identifying name to the objectUuid.
|
||||
*/
|
||||
drop view if exists global_iv;
|
||||
create or replace view global_iv as
|
||||
drop view if exists rbac.global_iv;
|
||||
create or replace view rbac.global_iv as
|
||||
select target.uuid, target.name as idName
|
||||
from global as target;
|
||||
grant all privileges on global_iv to ${HSADMINNG_POSTGRES_RESTRICTED_USERNAME};
|
||||
from rbac.global as target;
|
||||
grant all privileges on rbac.global_iv to ${HSADMINNG_POSTGRES_RESTRICTED_USERNAME};
|
||||
|
||||
/*
|
||||
Returns the objectUuid for a given identifying name (in this case the idName).
|
||||
*/
|
||||
create or replace function globalUuidByIdName(idName varchar)
|
||||
create or replace function rbac.globalUuidByIdName(idName varchar)
|
||||
returns uuid
|
||||
language sql
|
||||
strict as $$
|
||||
select uuid from global_iv iv where iv.idName = globalUuidByIdName.idName;
|
||||
select uuid from rbac.global_iv iv where iv.idName = globalUuidByIdName.idName;
|
||||
$$;
|
||||
|
||||
/*
|
||||
Returns the identifying name for a given objectUuid (in this case the idName).
|
||||
*/
|
||||
create or replace function globalIdNameByUuid(uuid uuid)
|
||||
create or replace function rbac.globalIdNameByUuid(uuid uuid)
|
||||
returns varchar
|
||||
language sql
|
||||
strict as $$
|
||||
select idName from global_iv iv where iv.uuid = globalIdNameByUuid.uuid;
|
||||
select idName from rbac.global_iv iv where iv.uuid = globalIdNameByUuid.uuid;
|
||||
$$;
|
||||
--//
|
||||
|
||||
--liquibase formatted sql
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-global-PSEUDO-OBJECT:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-global-PSEUDO-OBJECT endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
/**
|
||||
A single row to be referenced as a global object.
|
||||
A single row to be referenced as a rbac.Global object.
|
||||
*/
|
||||
begin transaction;
|
||||
call defineContext('initializing table "global"', null, null, null);
|
||||
call base.defineContext('initializing table "rbac.global"', null, null, null);
|
||||
insert
|
||||
into RbacObject (objecttable) values ('global');
|
||||
into rbac.object (objecttable) values ('rbac.global');
|
||||
insert
|
||||
into Global (uuid, name) values ((select uuid from RbacObject where objectTable = 'global'), 'global');
|
||||
into rbac.global (uuid, name) values ((select uuid from rbac.object where objectTable = 'rbac.global'), 'global');
|
||||
commit;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-global-ADMIN-ROLE:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-global-ADMIN-ROLE endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
A global administrator role.
|
||||
A rbac.Global administrator role.
|
||||
*/
|
||||
create or replace function globalAdmin(assumed boolean = true)
|
||||
returns RbacRoleDescriptor
|
||||
create or replace function rbac.globalAdmin(assumed boolean = true)
|
||||
returns rbac.RoleDescriptor
|
||||
returns null on null input
|
||||
stable -- leakproof
|
||||
language sql as $$
|
||||
select 'global', (select uuid from RbacObject where objectTable = 'global'), 'ADMIN'::RbacRoleType, assumed;
|
||||
select 'rbac.global', (select uuid from rbac.object where objectTable = 'rbac.global'), 'ADMIN'::rbac.RoleType, assumed;
|
||||
$$;
|
||||
|
||||
begin transaction;
|
||||
call defineContext('creating role:global#global:ADMIN', null, null, null);
|
||||
select createRole(globalAdmin());
|
||||
call base.defineContext('creating role:rbac.global#global:ADMIN', null, null, null);
|
||||
select rbac.createRole(rbac.globalAdmin());
|
||||
commit;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-global-GUEST-ROLE:1 endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-global-GUEST-ROLE endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
A global guest role.
|
||||
A rbac.Global guest role.
|
||||
*/
|
||||
create or replace function globalGuest(assumed boolean = true)
|
||||
returns RbacRoleDescriptor
|
||||
create or replace function rbac.globalglobalGuest(assumed boolean = true)
|
||||
returns rbac.RoleDescriptor
|
||||
returns null on null input
|
||||
stable -- leakproof
|
||||
language sql as $$
|
||||
select 'global', (select uuid from RbacObject where objectTable = 'global'), 'GUEST'::RbacRoleType, assumed;
|
||||
select 'rbac.global', (select uuid from rbac.object where objectTable = 'rbac.global'), 'GUEST'::rbac.RoleType, assumed;
|
||||
$$;
|
||||
|
||||
begin transaction;
|
||||
call defineContext('creating role:global#global:guest', null, null, null);
|
||||
select createRole(globalGuest());
|
||||
call base.defineContext('creating role:rbac.global#global:guest', null, null, null);
|
||||
select rbac.createRole(rbac.globalglobalGuest());
|
||||
commit;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-global-ADMIN-USERS:1 context:dev,tc endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-global-ADMIN-USERS context:dev,tc endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
Create two users and assign both to the administrators role.
|
||||
Create two users and assign both to the administrators' role.
|
||||
*/
|
||||
do language plpgsql $$
|
||||
declare
|
||||
admins uuid ;
|
||||
begin
|
||||
call defineContext('creating fake test-realm admin users', null, null, null);
|
||||
call base.defineContext('creating fake test-realm admin users', null, null, null);
|
||||
|
||||
admins = findRoleId(globalAdmin());
|
||||
call grantRoleToUserUnchecked(admins, admins, createRbacUser('superuser-alex@hostsharing.net'));
|
||||
call grantRoleToUserUnchecked(admins, admins, createRbacUser('superuser-fran@hostsharing.net'));
|
||||
perform createRbacUser('selfregistered-user-drew@hostsharing.org');
|
||||
perform createRbacUser('selfregistered-test-user@hostsharing.org');
|
||||
admins = rbac.findRoleId(rbac.globalAdmin());
|
||||
call rbac.grantRoleToSubjectUnchecked(admins, admins, rbac.create_subject('superuser-alex@hostsharing.net'));
|
||||
call rbac.grantRoleToSubjectUnchecked(admins, admins, rbac.create_subject('superuser-fran@hostsharing.net'));
|
||||
perform rbac.create_subject('selfregistered-user-drew@hostsharing.org');
|
||||
perform rbac.create_subject('selfregistered-test-user@hostsharing.org');
|
||||
end;
|
||||
$$;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-global-TEST:1 context:dev,tc runAlways:true endDelimiter:--//
|
||||
--changeset michael.hoennig:rbac-global-TEST context:dev,tc runAlways:true endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
/*
|
||||
Tests if currentUserUuid() can fetch the user from the session variable.
|
||||
Tests if rbac.currentSubjectUuid() can fetch the user from the session variable.
|
||||
*/
|
||||
|
||||
do language plpgsql $$
|
||||
declare
|
||||
userName varchar;
|
||||
begin
|
||||
call defineContext('testing currentUserUuid', null, 'superuser-fran@hostsharing.net', null);
|
||||
select userName from RbacUser where uuid = currentUserUuid() into userName;
|
||||
call base.defineContext('testing currentSubjectUuid', null, 'superuser-fran@hostsharing.net', null);
|
||||
select userName from rbac.subject where uuid = rbac.currentSubjectUuid() into userName;
|
||||
if userName <> 'superuser-fran@hostsharing.net' then
|
||||
raise exception 'setting or fetching initial currentUser failed, got: %', userName;
|
||||
raise exception 'setting or fetching initial currentSubject failed, got: %', userName;
|
||||
end if;
|
||||
|
||||
call defineContext('testing currentUserUuid', null, 'superuser-alex@hostsharing.net', null);
|
||||
select userName from RbacUser where uuid = currentUserUuid() into userName;
|
||||
call base.defineContext('testing currentSubjectUuid', null, 'superuser-alex@hostsharing.net', null);
|
||||
select userName from rbac.subject where uuid = rbac.currentSubjectUuid() into userName;
|
||||
if userName = 'superuser-alex@hostsharing.net' then
|
||||
raise exception 'currentUser should not change in one transaction, but did change, got: %', userName;
|
||||
raise exception 'currentSubject should not change in one transaction, but did change, got: %', userName;
|
||||
end if;
|
||||
end; $$;
|
||||
--//
|
||||
|
Reference in New Issue
Block a user