structured-liquibase-files (#29)
Co-authored-by: Michael Hoennig <michael@hoennig.de> Reviewed-on: https://dev.hostsharing.net/hostsharing/hs.hsadmin.ng/pulls/29 Reviewed-by: Timotheus Pokorra <timotheus.pokorra@hostsharing.net>
This commit is contained in:
911
src/main/resources/db/changelog/1-rbac/1050-rbac-base.sql
Normal file
911
src/main/resources/db/changelog/1-rbac/1050-rbac-base.sql
Normal file
@@ -0,0 +1,911 @@
|
||||
--liquibase formatted sql
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-REFERENCE:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
|
||||
*/
|
||||
create type ReferenceType as enum ('RbacUser', 'RbacRole', 'RbacPermission');
|
||||
|
||||
create table RbacReference
|
||||
(
|
||||
uuid uuid unique default uuid_generate_v4(),
|
||||
type ReferenceType not null
|
||||
);
|
||||
|
||||
create or replace function assertReferenceType(argument varchar, referenceId uuid, expectedType ReferenceType)
|
||||
returns ReferenceType
|
||||
language plpgsql as $$
|
||||
declare
|
||||
actualType 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);
|
||||
if (actualType <> expectedType) then
|
||||
raise exception '% must reference a %, but got a %', argument, expectedType, actualType;
|
||||
end if;
|
||||
return expectedType;
|
||||
end; $$;
|
||||
--//
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-USER:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
|
||||
*/
|
||||
create table RbacUser
|
||||
(
|
||||
uuid uuid primary key references RbacReference (uuid) on delete cascade,
|
||||
name varchar(63) not null unique
|
||||
);
|
||||
|
||||
call create_journal('RbacUser');
|
||||
|
||||
create or replace function createRbacUser(userName varchar)
|
||||
returns uuid
|
||||
returns null on null input
|
||||
language plpgsql as $$
|
||||
declare
|
||||
objectId uuid;
|
||||
begin
|
||||
insert
|
||||
into RbacReference (type)
|
||||
values ('RbacUser')
|
||||
returning uuid into objectId;
|
||||
insert
|
||||
into RbacUser (uuid, name)
|
||||
values (objectid, userName);
|
||||
return objectId;
|
||||
end;
|
||||
$$;
|
||||
|
||||
create or replace function createRbacUser(refUuid uuid, userName 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')
|
||||
returning r.uuid into refUuid;
|
||||
insert
|
||||
into RbacUser (uuid, name)
|
||||
values (refUuid, userName);
|
||||
return refUuid;
|
||||
end;
|
||||
$$;
|
||||
|
||||
create or replace function findRbacUserId(userName varchar)
|
||||
returns uuid
|
||||
returns null on null input
|
||||
language sql as $$
|
||||
select uuid from RbacUser where name = userName
|
||||
$$;
|
||||
--//
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-OBJECT:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
|
||||
*/
|
||||
create table RbacObject
|
||||
(
|
||||
uuid uuid primary key default uuid_generate_v4(),
|
||||
serialId serial, -- TODO: we might want to remove this once test data deletion works properly
|
||||
objectTable varchar(64) not null,
|
||||
unique (objectTable, uuid)
|
||||
);
|
||||
|
||||
call create_journal('RbacObject');
|
||||
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-GENERATE-RELATED-OBJECT:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
/*
|
||||
Inserts related RbacObject for use in the BEFORE ONSERT TRIGGERs on the business objects.
|
||||
*/
|
||||
create or replace function insertRelatedRbacObject()
|
||||
returns trigger
|
||||
language plpgsql
|
||||
strict as $$
|
||||
declare
|
||||
objectUuid uuid;
|
||||
begin
|
||||
if TG_OP = 'INSERT' then
|
||||
if NEW.uuid is null then
|
||||
insert
|
||||
into RbacObject (objectTable)
|
||||
values (TG_TABLE_NAME)
|
||||
returning uuid into objectUuid;
|
||||
NEW.uuid = objectUuid;
|
||||
else
|
||||
insert
|
||||
into RbacObject (uuid, objectTable)
|
||||
values (NEW.uuid, TG_TABLE_NAME)
|
||||
returning uuid into objectUuid;
|
||||
end if;
|
||||
return NEW;
|
||||
else
|
||||
raise exception 'invalid usage of TRIGGER AFTER INSERT';
|
||||
end if;
|
||||
end; $$;
|
||||
|
||||
/*
|
||||
Deletes related RbacObject for use in the BEFORE DELETE TRIGGERs on the business objects.
|
||||
*/
|
||||
create or replace function deleteRelatedRbacObject()
|
||||
returns trigger
|
||||
language plpgsql
|
||||
strict as $$
|
||||
begin
|
||||
if TG_OP = 'DELETE' then
|
||||
delete from RbacObject where rbacobject.uuid = old.uuid;
|
||||
else
|
||||
raise exception 'invalid usage of TRIGGER BEFORE DELETE';
|
||||
end if;
|
||||
return old;
|
||||
end; $$;
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-ROLE:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
|
||||
*/
|
||||
|
||||
create type RbacRoleType as enum ('OWNER', 'ADMIN', 'AGENT', 'TENANT', 'GUEST', 'REFERRER');
|
||||
|
||||
create table RbacRole
|
||||
(
|
||||
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,
|
||||
unique (objectUuid, roleType)
|
||||
);
|
||||
|
||||
call create_journal('RbacRole');
|
||||
|
||||
create type RbacRoleDescriptor as
|
||||
(
|
||||
objectTable varchar(63), -- for human readability and easier debugging
|
||||
objectUuid uuid,
|
||||
roleType RbacRoleType,
|
||||
assumed boolean
|
||||
);
|
||||
|
||||
create or replace function assumed()
|
||||
returns boolean
|
||||
stable -- leakproof
|
||||
language sql as $$
|
||||
select true;
|
||||
$$;
|
||||
|
||||
create or replace function unassumed()
|
||||
returns boolean
|
||||
stable -- leakproof
|
||||
language sql as $$
|
||||
select false;
|
||||
$$;
|
||||
|
||||
|
||||
create or replace function roleDescriptor(
|
||||
objectTable varchar(63), objectUuid uuid, roleType RbacRoleType,
|
||||
assumed boolean = true) -- just for DSL readability, belongs actually to the grant
|
||||
returns RbacRoleDescriptor
|
||||
returns null on null input
|
||||
stable -- leakproof
|
||||
language sql as $$
|
||||
select objectTable, objectUuid, roleType::RbacRoleType, assumed;
|
||||
$$;
|
||||
|
||||
create or replace function createRole(roleDescriptor RbacRoleDescriptor)
|
||||
returns uuid
|
||||
returns null on null input
|
||||
language plpgsql as $$
|
||||
declare
|
||||
referenceId uuid;
|
||||
begin
|
||||
insert
|
||||
into RbacReference (type)
|
||||
values ('RbacRole')
|
||||
returning uuid into referenceId;
|
||||
insert
|
||||
into RbacRole (uuid, objectUuid, roleType)
|
||||
values (referenceId, roleDescriptor.objectUuid, roleDescriptor.roleType);
|
||||
return referenceId;
|
||||
end;
|
||||
$$;
|
||||
|
||||
|
||||
create or replace procedure deleteRole(roleUUid uuid)
|
||||
language plpgsql as $$
|
||||
begin
|
||||
--raise exception '% deleting role uuid %', currentsubjectsuuids(), roleUUid;
|
||||
delete from RbacRole where uuid = roleUUid;
|
||||
end;
|
||||
$$;
|
||||
|
||||
create or replace function findRoleId(roleIdName varchar)
|
||||
returns uuid
|
||||
returns null on null input
|
||||
language plpgsql as $$
|
||||
declare
|
||||
roleParts text;
|
||||
roleTypeFromRoleIdName RbacRoleType;
|
||||
objectNameFromRoleIdName text;
|
||||
objectTableFromRoleIdName text;
|
||||
objectUuidOfRole uuid;
|
||||
roleUuid uuid;
|
||||
begin
|
||||
-- TODO.refact: extract function toRbacRoleDescriptor(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);
|
||||
|
||||
select uuid
|
||||
from RbacRole
|
||||
where objectUuid = objectUuidOfRole
|
||||
and roleType = roleTypeFromRoleIdName
|
||||
into roleUuid;
|
||||
return roleUuid;
|
||||
end; $$;
|
||||
|
||||
create or replace function findRoleId(roleDescriptor RbacRoleDescriptor)
|
||||
returns uuid
|
||||
returns null on null input
|
||||
language sql as $$
|
||||
select uuid from RbacRole where objectUuid = roleDescriptor.objectUuid and roleType = roleDescriptor.roleType;
|
||||
$$;
|
||||
|
||||
create or replace function getRoleId(roleDescriptor RbacRoleDescriptor)
|
||||
returns uuid
|
||||
language plpgsql as $$
|
||||
declare
|
||||
roleUuid uuid;
|
||||
begin
|
||||
assert roleDescriptor is not null, 'roleDescriptor must not be null';
|
||||
|
||||
roleUuid := findRoleId(roleDescriptor);
|
||||
if (roleUuid is null) then
|
||||
raise exception 'RbacRole "%#%.%" not found', roleDescriptor.objectTable, roleDescriptor.objectUuid, roleDescriptor.roleType;
|
||||
end if;
|
||||
return roleUuid;
|
||||
end;
|
||||
$$;
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-BEFORE-DELETE-ROLE-TRIGGER:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
/*
|
||||
RbacRole BEFORE DELETE TRIGGER function which deletes all related roles.
|
||||
*/
|
||||
create or replace function deleteRbacGrantsOfRbacRole()
|
||||
returns trigger
|
||||
language plpgsql
|
||||
strict as $$
|
||||
begin
|
||||
if TG_OP = 'DELETE' then
|
||||
delete from RbacGrants g where old.uuid in (g.grantedbyroleuuid, g.ascendantuuid, g.descendantuuid);
|
||||
else
|
||||
raise exception 'invalid usage of TRIGGER BEFORE DELETE';
|
||||
end if;
|
||||
return old;
|
||||
end; $$;
|
||||
|
||||
/*
|
||||
Installs the RbacRole BEFORE DELETE TRIGGER.
|
||||
*/
|
||||
create trigger deleteRbacGrantsOfRbacRole_Trigger
|
||||
before delete
|
||||
on RbacRole
|
||||
for each row
|
||||
execute procedure deleteRbacGrantsOfRbacRole();
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-BEFORE-DELETE-OBJECT-TRIGGER:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
/*
|
||||
RbacObject BEFORE DELETE TRIGGER function which deletes all related roles.
|
||||
*/
|
||||
create or replace function deleteRbacRolesOfRbacObject()
|
||||
returns trigger
|
||||
language plpgsql
|
||||
strict as $$
|
||||
begin
|
||||
if TG_OP = 'DELETE' then
|
||||
delete from RbacPermission p where p.objectuuid = old.uuid;
|
||||
delete from RbacRole r where r.objectUuid = old.uuid;
|
||||
else
|
||||
raise exception 'invalid usage of TRIGGER BEFORE DELETE';
|
||||
end if;
|
||||
return old;
|
||||
end; $$;
|
||||
|
||||
/*
|
||||
Installs the RbacRole BEFORE DELETE TRIGGER.
|
||||
*/
|
||||
create trigger deleteRbacRolesOfRbacObject_Trigger
|
||||
before delete
|
||||
on RbacObject
|
||||
for each row
|
||||
execute procedure deleteRbacRolesOfRbacObject();
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-PERMISSION:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
|
||||
*/
|
||||
create domain RbacOp as varchar(67) -- TODO: shorten to 8, once the deprecated values are gone
|
||||
check (
|
||||
VALUE = 'DELETE'
|
||||
or VALUE = 'UPDATE'
|
||||
or VALUE = 'SELECT'
|
||||
or VALUE = 'INSERT'
|
||||
or VALUE = 'ASSUME'
|
||||
-- TODO: all values below are deprecated, use insert with table
|
||||
or VALUE ~ '^add-[a-z]+$'
|
||||
or VALUE ~ '^new-[a-z-]+$'
|
||||
);
|
||||
|
||||
create table RbacPermission
|
||||
(
|
||||
uuid uuid primary key references RbacReference (uuid) on delete cascade,
|
||||
objectUuid uuid not null references RbacObject,
|
||||
op RbacOp not null,
|
||||
opTableName varchar(60)
|
||||
);
|
||||
|
||||
ALTER TABLE RbacPermission
|
||||
ADD CONSTRAINT RbacPermission_uc UNIQUE NULLS NOT DISTINCT (objectUuid, op, opTableName);
|
||||
|
||||
call create_journal('RbacPermission');
|
||||
|
||||
create or replace function createPermission(forObjectUuid uuid, forOp RbacOp, forOpTableName text = null)
|
||||
returns uuid
|
||||
language plpgsql as $$
|
||||
declare
|
||||
permissionUuid uuid;
|
||||
begin
|
||||
if (forObjectUuid is null) then
|
||||
raise exception 'forObjectUuid must not be null';
|
||||
end if;
|
||||
if (forOp = 'INSERT' and forOpTableName is null) then
|
||||
raise exception 'INSERT permissions needs forOpTableName';
|
||||
end if;
|
||||
if (forOp <> 'INSERT' and forOpTableName is not null) then
|
||||
raise exception 'forOpTableName must only be specified for ops: [INSERT]'; -- currently no other
|
||||
end if;
|
||||
|
||||
permissionUuid := (
|
||||
select uuid from RbacPermission
|
||||
where objectUuid = forObjectUuid
|
||||
and op = forOp and opTableName is not distinct from forOpTableName);
|
||||
if (permissionUuid is null) then
|
||||
insert into RbacReference ("type")
|
||||
values ('RbacPermission')
|
||||
returning uuid into permissionUuid;
|
||||
begin
|
||||
insert into RbacPermission (uuid, objectUuid, op, opTableName)
|
||||
values (permissionUuid, forObjectUuid, forOp, forOpTableName);
|
||||
exception
|
||||
when others then
|
||||
raise exception 'insert into RbacPermission (uuid, objectUuid, op, opTableName)
|
||||
values (%, %, %, %);', permissionUuid, forObjectUuid, forOp, forOpTableName;
|
||||
end;
|
||||
end if;
|
||||
return permissionUuid;
|
||||
end; $$;
|
||||
|
||||
-- TODO: deprecated, remove and amend all usages to createPermission
|
||||
create or replace function createPermissions(forObjectUuid uuid, permitOps RbacOp[])
|
||||
returns uuid[]
|
||||
language plpgsql as $$
|
||||
declare
|
||||
refId uuid;
|
||||
permissionIds uuid[] = array []::uuid[];
|
||||
begin
|
||||
if (forObjectUuid is null) then
|
||||
raise exception 'forObjectUuid must not be null';
|
||||
end if;
|
||||
|
||||
for i in array_lower(permitOps, 1)..array_upper(permitOps, 1)
|
||||
loop
|
||||
refId = (select uuid from RbacPermission where objectUuid = forObjectUuid and op = permitOps[i]);
|
||||
if (refId is null) then
|
||||
insert
|
||||
into RbacReference ("type")
|
||||
values ('RbacPermission')
|
||||
returning uuid into refId;
|
||||
insert
|
||||
into RbacPermission (uuid, objectUuid, op)
|
||||
values (refId, forObjectUuid, permitOps[i]);
|
||||
end if;
|
||||
permissionIds = permissionIds || refId;
|
||||
end loop;
|
||||
|
||||
return permissionIds;
|
||||
end;
|
||||
$$;
|
||||
|
||||
create or replace function findEffectivePermissionId(forObjectUuid uuid, forOp RbacOp, forOpTableName text = null)
|
||||
returns uuid
|
||||
returns null on null input
|
||||
stable -- leakproof
|
||||
language sql as $$
|
||||
select uuid
|
||||
from RbacPermission p
|
||||
where p.objectUuid = forObjectUuid
|
||||
and (forOp = 'SELECT' or p.op = forOp) -- all other RbacOp include 'SELECT'
|
||||
and p.opTableName = forOpTableName
|
||||
$$;
|
||||
|
||||
create or replace function findPermissionId(forObjectUuid uuid, forOp RbacOp, forOpTableName text = null)
|
||||
returns uuid
|
||||
returns null on null input
|
||||
stable -- leakproof
|
||||
language sql as $$
|
||||
select uuid
|
||||
from RbacPermission 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)
|
||||
returns uuid
|
||||
stable -- leakproof
|
||||
language plpgsql as $$
|
||||
declare
|
||||
permissionUuid uuid;
|
||||
begin
|
||||
select uuid into permissionUuid
|
||||
from RbacPermission p
|
||||
where p.objectUuid = forObjectUuid
|
||||
and p.op = forOp
|
||||
and forOpTableName is null or p.opTableName = forOpTableName;
|
||||
assert permissionUuid is not null,
|
||||
format('permission %s %s for object UUID %s cannot be found', forOp, forOpTableName, forObjectUuid);
|
||||
return permissionUuid;
|
||||
end; $$;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-duplicate-role-grant-exception:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace procedure 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;
|
||||
raise exception '[400] Duplicate role grant detected: role % (%) already granted to % (%)', subRoleId, subRoleIdName, superRoleId, superRoleIdName;
|
||||
end;
|
||||
$$;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-GRANTS:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
Table to store grants / role- or permission assignments to users or roles.
|
||||
*/
|
||||
create table RbacGrants
|
||||
(
|
||||
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),
|
||||
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);
|
||||
|
||||
call create_journal('RbacGrants');
|
||||
|
||||
create or replace function findGrantees(grantedId uuid)
|
||||
returns setof RbacReference
|
||||
returns null on null input
|
||||
language sql as $$
|
||||
select reference.*
|
||||
from (with recursive grants as (select descendantUuid,
|
||||
ascendantUuid
|
||||
from RbacGrants
|
||||
where descendantUuid = grantedId
|
||||
union all
|
||||
select "grant".descendantUuid,
|
||||
"grant".ascendantUuid
|
||||
from RbacGrants "grant"
|
||||
inner join grants recur on recur.ascendantUuid = "grant".descendantUuid)
|
||||
select ascendantUuid
|
||||
from grants) as grantee
|
||||
join RbacReference reference on reference.uuid = grantee.ascendantUuid;
|
||||
$$;
|
||||
|
||||
create or replace function isGranted(granteeId uuid, grantedId uuid)
|
||||
returns bool
|
||||
returns null on null input
|
||||
language sql as $$
|
||||
select granteeId = grantedId or granteeId in (with recursive grants as (select descendantUuid, ascendantUuid
|
||||
from RbacGrants
|
||||
where descendantUuid = grantedId
|
||||
union all
|
||||
select "grant".descendantUuid, "grant".ascendantUuid
|
||||
from RbacGrants "grant"
|
||||
inner join grants recur on recur.ascendantUuid = "grant".descendantUuid)
|
||||
select ascendantUuid
|
||||
from grants);
|
||||
$$;
|
||||
|
||||
create or replace function isGranted(granteeIds uuid[], grantedId uuid)
|
||||
returns bool
|
||||
returns null on null input
|
||||
language plpgsql as $$
|
||||
declare
|
||||
granteeId uuid;
|
||||
begin
|
||||
-- TODO.perf: needs optimization
|
||||
foreach granteeId in array granteeIds
|
||||
loop
|
||||
if isGranted(granteeId, grantedId) then
|
||||
return true;
|
||||
end if;
|
||||
end loop;
|
||||
return false;
|
||||
end; $$;
|
||||
|
||||
create or replace function isPermissionGrantedToSubject(permissionId uuid, subjectId uuid)
|
||||
returns BOOL
|
||||
stable -- leakproof
|
||||
language sql as $$
|
||||
select exists(
|
||||
select *
|
||||
from RbacUser
|
||||
where uuid in (with recursive grants as (select descendantUuid,
|
||||
ascendantUuid
|
||||
from RbacGrants g
|
||||
where g.descendantUuid = permissionId
|
||||
union all
|
||||
select g.descendantUuid,
|
||||
g.ascendantUuid
|
||||
from RbacGrants g
|
||||
inner join grants recur on recur.ascendantUuid = g.descendantUuid)
|
||||
select ascendantUuid
|
||||
from grants
|
||||
where ascendantUuid = subjectId)
|
||||
);
|
||||
$$;
|
||||
|
||||
create or replace function hasInsertPermission(objectUuid uuid, forOp RbacOp, tableName text )
|
||||
returns BOOL
|
||||
stable -- leakproof
|
||||
language plpgsql as $$
|
||||
declare
|
||||
permissionUuid uuid;
|
||||
begin
|
||||
permissionUuid = findPermissionId(objectUuid, forOp, tableName);
|
||||
return permissionUuid is not null;
|
||||
end;
|
||||
$$;
|
||||
|
||||
create or replace function hasGlobalRoleGranted(userUuid 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'
|
||||
);
|
||||
$$;
|
||||
|
||||
create or replace procedure grantPermissionToRole(permissionUuid uuid, roleUuid uuid)
|
||||
language plpgsql as $$
|
||||
begin
|
||||
perform assertReferenceType('roleId (ascendant)', roleUuid, 'RbacRole');
|
||||
perform assertReferenceType('permissionId (descendant)', permissionUuid, 'RbacPermission');
|
||||
|
||||
insert
|
||||
into RbacGrants (grantedByTriggerOf, ascendantUuid, descendantUuid, assumed)
|
||||
values (currentTriggerObjectUuid(), roleUuid, permissionUuid, true)
|
||||
on conflict do nothing; -- allow granting multiple times
|
||||
end;
|
||||
$$;
|
||||
|
||||
create or replace procedure grantPermissionToRole(permissionUuid uuid, roleDesc RbacRoleDescriptor)
|
||||
language plpgsql as $$
|
||||
begin
|
||||
call grantPermissionToRole(permissionUuid, findRoleId(roleDesc));
|
||||
end;
|
||||
$$;
|
||||
|
||||
-- TODO: deprecated, remove and use grantPermissionToRole(...)
|
||||
create or replace procedure grantPermissionsToRole(roleUuid uuid, permissionIds uuid[])
|
||||
language plpgsql as $$
|
||||
begin
|
||||
if cardinality(permissionIds) = 0 then return; end if;
|
||||
|
||||
for i in array_lower(permissionIds, 1)..array_upper(permissionIds, 1)
|
||||
loop
|
||||
perform assertReferenceType('roleId (ascendant)', roleUuid, 'RbacRole');
|
||||
perform assertReferenceType('permissionId (descendant)', permissionIds[i], 'RbacPermission');
|
||||
|
||||
insert
|
||||
into RbacGrants (grantedByTriggerOf, ascendantUuid, descendantUuid, assumed)
|
||||
values (currentTriggerObjectUuid(), roleUuid, permissionIds[i], true)
|
||||
on conflict do nothing; -- allow granting multiple times
|
||||
end loop;
|
||||
end;
|
||||
$$;
|
||||
|
||||
create or replace procedure grantRoleToRole(subRoleId uuid, superRoleId uuid, doAssume bool = true)
|
||||
language plpgsql as $$
|
||||
begin
|
||||
perform assertReferenceType('superRoleId (ascendant)', superRoleId, 'RbacRole');
|
||||
perform assertReferenceType('subRoleId (descendant)', subRoleId, 'RbacRole');
|
||||
|
||||
if isGranted(subRoleId, superRoleId) then
|
||||
call raiseDuplicateRoleGrantException(subRoleId, superRoleId);
|
||||
end if;
|
||||
|
||||
insert
|
||||
into RbacGrants (grantedByTriggerOf, ascendantuuid, descendantUuid, assumed)
|
||||
values (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)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
superRoleId uuid;
|
||||
subRoleId uuid;
|
||||
begin
|
||||
-- TODO: maybe separate method grantRoleToRoleIfNotNull(...) for NULLABLE references
|
||||
if superRole.objectUuid is null or subRole.objectuuid is null then
|
||||
return;
|
||||
end if;
|
||||
|
||||
superRoleId := findRoleId(superRole);
|
||||
subRoleId := findRoleId(subRole);
|
||||
|
||||
perform assertReferenceType('superRoleId (ascendant)', superRoleId, 'RbacRole');
|
||||
perform assertReferenceType('subRoleId (descendant)', subRoleId, 'RbacRole');
|
||||
|
||||
if isGranted(subRoleId, superRoleId) then
|
||||
call raiseDuplicateRoleGrantException(subRoleId, superRoleId);
|
||||
end if;
|
||||
|
||||
insert
|
||||
into RbacGrants (grantedByTriggerOf, ascendantuuid, descendantUuid, assumed)
|
||||
values (currentTriggerObjectUuid(), superRoleId, subRoleId, doAssume)
|
||||
on conflict do nothing; -- allow granting multiple times
|
||||
end; $$;
|
||||
|
||||
create or replace procedure grantRoleToRoleIfNotNull(subRole RbacRoleDescriptor, superRole RbacRoleDescriptor, doAssume bool = true)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
superRoleId uuid;
|
||||
subRoleId uuid;
|
||||
begin
|
||||
if ( superRoleId is null ) then return; end if;
|
||||
superRoleId := findRoleId(superRole);
|
||||
if ( subRoleId is null ) then return; end if;
|
||||
subRoleId := findRoleId(subRole);
|
||||
|
||||
perform assertReferenceType('superRoleId (ascendant)', superRoleId, 'RbacRole');
|
||||
perform assertReferenceType('subRoleId (descendant)', subRoleId, 'RbacRole');
|
||||
|
||||
if isGranted(subRoleId, superRoleId) then
|
||||
call raiseDuplicateRoleGrantException(subRoleId, superRoleId);
|
||||
end if;
|
||||
|
||||
insert
|
||||
into RbacGrants (grantedByTriggerOf, ascendantuuid, descendantUuid, assumed)
|
||||
values (currentTriggerObjectUuid(), superRoleId, subRoleId, doAssume)
|
||||
on conflict do nothing; -- allow granting multiple times
|
||||
end; $$;
|
||||
|
||||
create or replace procedure revokeRoleFromRole(subRole RbacRoleDescriptor, superRole RbacRoleDescriptor)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
superRoleId uuid;
|
||||
subRoleId uuid;
|
||||
begin
|
||||
superRoleId := findRoleId(superRole);
|
||||
subRoleId := findRoleId(subRole);
|
||||
|
||||
perform assertReferenceType('superRoleId (ascendant)', superRoleId, 'RbacRole');
|
||||
perform assertReferenceType('subRoleId (descendant)', subRoleId, 'RbacRole');
|
||||
|
||||
if (isGranted(superRoleId, subRoleId)) then
|
||||
delete from RbacGrants 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)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
superRoleId uuid;
|
||||
permissionOp text;
|
||||
objectTable text;
|
||||
objectUuid uuid;
|
||||
begin
|
||||
superRoleId := findRoleId(superRole);
|
||||
|
||||
perform assertReferenceType('superRoleId (ascendant)', superRoleId, 'RbacRole');
|
||||
perform assertReferenceType('permission (descendant)', permissionId, 'RbacPermission');
|
||||
|
||||
if (isGranted(superRoleId, permissionId)) then
|
||||
delete from RbacGrants 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
|
||||
where g.uuid=permissionId
|
||||
into permissionOp, objectTable, objectUuid;
|
||||
|
||||
raise exception 'cannot revoke permission % (% on %#% (%) from % (%)) because it is not granted',
|
||||
permissionId, permissionOp, objectTable, objectUuid, permissionId, superRole, superRoleId;
|
||||
end if;
|
||||
end; $$;
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-QUERY-ACCESSIBLE-OBJECT-UUIDS:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
|
||||
*/
|
||||
create or replace function queryAccessibleObjectUuidsOfSubjectIds(
|
||||
requiredOp RbacOp,
|
||||
forObjectTable varchar, -- reduces the result set, but is not really faster when used in restricted view
|
||||
subjectIds uuid[],
|
||||
maxObjects integer = 8000)
|
||||
returns setof uuid
|
||||
returns null on null input
|
||||
language plpgsql as $$
|
||||
declare
|
||||
foundRows bigint;
|
||||
begin
|
||||
return query select distinct perm.objectUuid
|
||||
from (with recursive grants as (select descendantUuid, ascendantUuid, 1 as level
|
||||
from RbacGrants
|
||||
where assumed
|
||||
and ascendantUuid = any (subjectIds)
|
||||
union
|
||||
distinct
|
||||
select "grant".descendantUuid, "grant".ascendantUuid, level + 1 as level
|
||||
from RbacGrants "grant"
|
||||
inner join grants recur on recur.descendantUuid = "grant".ascendantUuid
|
||||
where assumed)
|
||||
select descendantUuid
|
||||
from grants) as granted
|
||||
join RbacPermission perm
|
||||
on granted.descendantUuid = perm.uuid and (requiredOp = 'SELECT' or perm.op = requiredOp)
|
||||
join RbacObject obj on obj.uuid = perm.objectUuid and obj.objectTable = forObjectTable
|
||||
limit maxObjects + 1;
|
||||
|
||||
foundRows = lastRowCount();
|
||||
if foundRows > maxObjects then
|
||||
raise exception '[400] Too many accessible objects, limit is %, found %.', maxObjects, foundRows
|
||||
using
|
||||
errcode = 'P0003',
|
||||
hint = 'Please assume a sub-role and try again.';
|
||||
end if;
|
||||
end;
|
||||
$$;
|
||||
|
||||
--//
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-QUERY-GRANTED-PERMISSIONS:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
Returns all permissions accessible to the given subject UUID (user or role).
|
||||
*/
|
||||
create or replace function queryPermissionsGrantedToSubjectId(subjectId uuid)
|
||||
returns setof RbacPermission
|
||||
strict
|
||||
language sql as $$
|
||||
-- @formatter:off
|
||||
select *
|
||||
from RbacPermission
|
||||
where uuid in (
|
||||
with recursive grants as (
|
||||
select distinct descendantUuid, ascendantUuid
|
||||
from RbacGrants
|
||||
where ascendantUuid = subjectId
|
||||
union all
|
||||
select "grant".descendantUuid, "grant".ascendantUuid
|
||||
from RbacGrants "grant"
|
||||
inner join grants recur on recur.descendantUuid = "grant".ascendantUuid
|
||||
)
|
||||
select descendantUuid
|
||||
from grants
|
||||
);
|
||||
-- @formatter:on
|
||||
$$;
|
||||
--//
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-QUERY-USERS-WITH-PERMISSION-FOR-OBJECT:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
Returns all user UUIDs which have any permission for the given object UUID.
|
||||
*/
|
||||
|
||||
create or replace function queryAllRbacUsersWithPermissionsFor(objectId uuid)
|
||||
returns setof RbacUser
|
||||
returns null on null input
|
||||
language sql as $$
|
||||
select *
|
||||
from RbacUser
|
||||
where uuid in (
|
||||
-- @formatter:off
|
||||
with recursive grants as (
|
||||
select descendantUuid, ascendantUuid
|
||||
from RbacGrants
|
||||
where descendantUuid = objectId
|
||||
union all
|
||||
select "grant".descendantUuid, "grant".ascendantUuid
|
||||
from RbacGrants "grant"
|
||||
inner join grants recur on recur.ascendantUuid = "grant".descendantUuid
|
||||
)
|
||||
-- @formatter:on
|
||||
select ascendantUuid
|
||||
from grants);
|
||||
$$;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-base-PGSQL-ROLES:1 context:dev,tc endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
do $$
|
||||
begin
|
||||
if '${HSADMINNG_POSTGRES_ADMIN_USERNAME}'='admin' then
|
||||
create role admin;
|
||||
grant all privileges on all tables in schema public to admin;
|
||||
end if;
|
||||
|
||||
if '${HSADMINNG_POSTGRES_RESTRICTED_USERNAME}'='restricted' then
|
||||
create role restricted;
|
||||
grant all privileges on all tables in schema public to restricted;
|
||||
end if;
|
||||
end $$;
|
||||
--//
|
126
src/main/resources/db/changelog/1-rbac/1051-rbac-user-grant.sql
Normal file
126
src/main/resources/db/changelog/1-rbac/1051-rbac-user-grant.sql
Normal file
@@ -0,0 +1,126 @@
|
||||
--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, roleUuid uuid, userUuid uuid, doAssume boolean = true)
|
||||
language plpgsql as $$
|
||||
begin
|
||||
perform assertReferenceType('grantingRoleUuid', grantedByRoleUuid, 'RbacRole');
|
||||
perform assertReferenceType('roleId (descendant)', roleUuid, 'RbacRole');
|
||||
perform assertReferenceType('userId (ascendant)', userUuid, 'RbacUser');
|
||||
|
||||
insert
|
||||
into RbacGrants (grantedByRoleUuid, ascendantUuid, descendantUuid, assumed)
|
||||
values (grantedByRoleUuid, userUuid, roleUuid, doAssume);
|
||||
-- TODO.spec: 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; $$;
|
||||
|
||||
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.spec: 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; $$;
|
||||
--//
|
179
src/main/resources/db/changelog/1-rbac/1054-rbac-context.sql
Normal file
179
src/main/resources/db/changelog/1-rbac/1054-rbac-context.sql
Normal file
@@ -0,0 +1,179 @@
|
||||
--liquibase formatted sql
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-context-DETERMINE:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace function determineCurrentUserUuid(currentUser varchar)
|
||||
returns uuid
|
||||
stable -- leakproof
|
||||
language plpgsql as $$
|
||||
declare
|
||||
currentUserUuid uuid;
|
||||
begin
|
||||
if currentUser = '' 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;
|
||||
end if;
|
||||
return currentUserUuid;
|
||||
end; $$;
|
||||
|
||||
create or replace function determineCurrentSubjectsUuids(currentUserUuid uuid, assumedRoles varchar)
|
||||
returns uuid[]
|
||||
stable -- leakproof
|
||||
language plpgsql as $$
|
||||
declare
|
||||
roleName text;
|
||||
roleNameParts text;
|
||||
objectTableToAssume varchar(63);
|
||||
objectNameToAssume varchar(63);
|
||||
objectUuidToAssume uuid;
|
||||
roleTypeToAssume RbacRoleType;
|
||||
roleIdsToAssume uuid[];
|
||||
roleUuidToAssume uuid;
|
||||
begin
|
||||
if currentUserUuid is null then
|
||||
if length(coalesce(assumedRoles, '')) > 0 then
|
||||
raise exception '[403] undefined has no permission to assume role %', assumedRoles;
|
||||
else
|
||||
return array[]::uuid[];
|
||||
end if;
|
||||
end if;
|
||||
if length(coalesce(assumedRoles, '')) = 0 then
|
||||
return array [currentUserUuid];
|
||||
end if;
|
||||
|
||||
foreach roleName in array string_to_array(assumedRoles, ';')
|
||||
loop
|
||||
roleNameParts = overlay(roleName placing '#' from length(roleName) + 1 - strpos(reverse(roleName), ':'));
|
||||
objectTableToAssume = split_part(roleNameParts, '#', 1);
|
||||
objectNameToAssume = split_part(roleNameParts, '#', 2);
|
||||
roleTypeToAssume = split_part(roleNameParts, '#', 3);
|
||||
|
||||
objectUuidToAssume = findObjectUuidByIdName(objectTableToAssume, objectNameToAssume);
|
||||
if objectUuidToAssume is null then
|
||||
raise exception '[401] object % cannot be found in table %', objectNameToAssume, objectTableToAssume;
|
||||
end if;
|
||||
|
||||
select uuid
|
||||
from RbacRole 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();
|
||||
end if;
|
||||
if not isGranted(currentUserUuid, roleUuidToAssume) then
|
||||
raise exception '[403] user % has no permission to assume role %', currentUser(), roleName;
|
||||
end if;
|
||||
roleIdsToAssume := roleIdsToAssume || roleUuidToAssume;
|
||||
end loop;
|
||||
|
||||
return roleIdsToAssume;
|
||||
end; $$;
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-context-CONTEXT-DEFINED:1 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(
|
||||
currentTask varchar,
|
||||
currentRequest varchar,
|
||||
currentUser varchar,
|
||||
assumedRoles varchar
|
||||
)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
currentUserUuid 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.assumedRoles to %L', assumedRoles);
|
||||
execute format('set local hsadminng.currentSubjectsUuids to %L',
|
||||
(select array_to_string(determinecurrentSubjectsUuids(currentUserUuid, assumedRoles), ';')));
|
||||
|
||||
raise notice 'Context defined as: %, %, %, [%]', currentTask, currentRequest, currentUser, assumedRoles;
|
||||
end; $$;
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-context-CURRENT-USER-ID:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
Returns the uuid of the current user as set via `defineContext(...)`.
|
||||
*/
|
||||
|
||||
create or replace function currentUserUuid()
|
||||
returns uuid
|
||||
stable -- leakproof
|
||||
language plpgsql as $$
|
||||
declare
|
||||
currentUserUuid text;
|
||||
currentUserName text;
|
||||
begin
|
||||
begin
|
||||
currentUserUuid := current_setting('hsadminng.currentUserUuid');
|
||||
exception
|
||||
when others then
|
||||
currentUserUuid := 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;
|
||||
else
|
||||
raise exception '[401] currentUserUuid cannot be determined, please call `defineContext(...)` first;"';
|
||||
end if;
|
||||
end if;
|
||||
return currentUserUuid::uuid;
|
||||
end; $$;
|
||||
--//
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-context-CURRENT-SUBJECT-UUIDS:1 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(...)`
|
||||
or empty array, if context is not defined.
|
||||
*/
|
||||
create or replace function currentSubjectsUuids()
|
||||
returns uuid[]
|
||||
stable -- leakproof
|
||||
language plpgsql as $$
|
||||
declare
|
||||
currentSubjectsUuids text;
|
||||
currentUserName text;
|
||||
begin
|
||||
begin
|
||||
currentSubjectsUuids := current_setting('hsadminng.currentSubjectsUuids');
|
||||
exception
|
||||
when others then
|
||||
currentSubjectsUuids := 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;
|
||||
else
|
||||
raise exception '[401] currentSubjectsUuids cannot be determined, please call `defineContext(...)` with a valid user;"';
|
||||
end if;
|
||||
end if;
|
||||
return string_to_array(currentSubjectsUuids, ';');
|
||||
end; $$;
|
||||
--//
|
||||
|
392
src/main/resources/db/changelog/1-rbac/1055-rbac-views.sql
Normal file
392
src/main/resources/db/changelog/1-rbac/1055-rbac-views.sql
Normal file
@@ -0,0 +1,392 @@
|
||||
--liquibase formatted sql
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-ROLE-ENHANCED-VIEW:1 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
|
||||
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
|
||||
) as unordered
|
||||
-- @formatter:on
|
||||
order by roleIdName;
|
||||
--//
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-ROLE-RESTRICTED-VIEW:1 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
|
||||
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)
|
||||
) as unordered
|
||||
-- @formatter:on
|
||||
order by objectTable || '#' || objectIdName || ':' || roleType;
|
||||
grant all privileges on rbacrole_rv to ${HSADMINNG_POSTGRES_RESTRICTED_USERNAME};
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-GRANT-ENHANCED-VIEW:1 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
|
||||
-- @formatter:off
|
||||
select x.grantUuid as uuid,
|
||||
x.grantedByTriggerOf as grantedByTriggerOf,
|
||||
go.objectTable || '#' || findIdNameByObjectUuid(go.objectTable, go.uuid) || ':' || r.roletype as grantedByRoleIdName,
|
||||
x.ascendingIdName as ascendantIdName,
|
||||
x.descendingIdName as descendantIdName,
|
||||
x.grantedByRoleUuid,
|
||||
x.ascendantUuid as ascendantUuid,
|
||||
x.descendantUuid as descendantUuid,
|
||||
x.op as permOp, x.optablename as permOpTableName,
|
||||
x.assumed
|
||||
from (
|
||||
select g.uuid as grantUuid,
|
||||
g.grantedbytriggerof as grantedbytriggerof,
|
||||
g.grantedbyroleuuid, g.ascendantuuid, g.descendantuuid, g.assumed,
|
||||
|
||||
coalesce(
|
||||
'user:' || au.name,
|
||||
'role:' || aro.objectTable || '#' || 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)
|
||||
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
|
||||
end
|
||||
) as descendingIdName,
|
||||
dro.objectTable, dro.uuid,
|
||||
dp.op, dp.optablename
|
||||
from rbacgrants 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 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
|
||||
) 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
|
||||
|
||||
order by x.ascendingIdName, x.descendingIdName;
|
||||
-- @formatter:on
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-GRANT-RESTRICTED-VIEW:1 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,
|
||||
g.objectTable || '#' || g.objectIdName || ':' || g.roletype as grantedRoleIdName, g.userName, g.assumed,
|
||||
g.grantedByRoleUuid, g.descendantUuid as grantedRoleUuid, g.ascendantUuid as userUuid,
|
||||
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)
|
||||
) as g
|
||||
join RbacRole as r on r.uuid = grantedByRoleUuid
|
||||
join RbacObject as o on o.uuid = r.objectUuid
|
||||
order by grantedRoleIdName;
|
||||
-- @formatter:on
|
||||
grant all privileges on rbacrole_rv to ${HSADMINNG_POSTGRES_RESTRICTED_USERNAME};
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-GRANTS-RV-INSERT-TRIGGER:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
/**
|
||||
Instead of insert trigger function for RbacGrants_RV.
|
||||
*/
|
||||
create or replace function insertRbacGrant()
|
||||
returns trigger
|
||||
language plpgsql as $$
|
||||
declare
|
||||
newGrant RbacGrants_RV;
|
||||
begin
|
||||
call grantRoleToUser(assumedRoleUuid(), new.grantedRoleUuid, new.userUuid, new.assumed);
|
||||
select grv.*
|
||||
from RbacGrants_RV grv
|
||||
where grv.userUuid=new.userUuid and grv.grantedRoleUuid=new.grantedRoleUuid
|
||||
into newGrant;
|
||||
return newGrant;
|
||||
end; $$;
|
||||
|
||||
/*
|
||||
Creates an instead of insert trigger for the RbacGrants_rv view.
|
||||
*/
|
||||
create trigger insertRbacGrant_Trigger
|
||||
instead of insert
|
||||
on RbacGrants_rv
|
||||
for each row
|
||||
execute function insertRbacGrant();
|
||||
--/
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-GRANTS-RV-DELETE-TRIGGER:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
/**
|
||||
Instead of delete trigger function for RbacGrants_RV.
|
||||
|
||||
Checks if the current subject (user / assumed role) has the permission to revoke the grant.
|
||||
*/
|
||||
create or replace function deleteRbacGrant()
|
||||
returns trigger
|
||||
language plpgsql as $$
|
||||
begin
|
||||
call revokeRoleFromUser(old.grantedByRoleUuid, old.grantedRoleUuid, old.userUuid);
|
||||
return old;
|
||||
end; $$;
|
||||
|
||||
/*
|
||||
Creates an instead of delete trigger for the RbacGrants_rv view.
|
||||
*/
|
||||
create trigger deleteRbacGrant_Trigger
|
||||
instead of delete
|
||||
on RbacGrants_rv
|
||||
for each row
|
||||
execute function deleteRbacGrant();
|
||||
--/
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-USER-ENHANCED-VIEW:1 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
|
||||
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
|
||||
union
|
||||
select users.*
|
||||
from RbacUser as users
|
||||
) as unordered
|
||||
-- @formatter:on
|
||||
order by unordered.name;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-USER-RESTRICTED-VIEW:1 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
|
||||
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
|
||||
union
|
||||
select users.*
|
||||
from RbacUser as users
|
||||
where cardinality(assumedRoles()) = 0 and
|
||||
(currentUserUuid() = users.uuid or hasGlobalRoleGranted(currentUserUuid()))
|
||||
|
||||
) as unordered
|
||||
-- @formatter:on
|
||||
order by unordered.name;
|
||||
grant all privileges on RbacUser_rv to ${HSADMINNG_POSTGRES_RESTRICTED_USERNAME};
|
||||
--//
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-USER-RV-INSERT-TRIGGER:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
/**
|
||||
Instead of insert trigger function for RbacUser_rv.
|
||||
*/
|
||||
create or replace function insertRbacUser()
|
||||
returns trigger
|
||||
language plpgsql as $$
|
||||
declare
|
||||
refUuid uuid;
|
||||
newUser RbacUser;
|
||||
begin
|
||||
insert
|
||||
into RbacReference as r (uuid, type)
|
||||
values( new.uuid, 'RbacUser')
|
||||
returning r.uuid into refUuid;
|
||||
insert
|
||||
into RbacUser (uuid, name)
|
||||
values (refUuid, new.name)
|
||||
returning * into newUser;
|
||||
return newUser;
|
||||
end;
|
||||
$$;
|
||||
|
||||
/*
|
||||
Creates an instead of insert trigger for the RbacUser_rv view.
|
||||
*/
|
||||
create trigger insertRbacUser_Trigger
|
||||
instead of insert
|
||||
on RbacUser_rv
|
||||
for each row
|
||||
execute function insertRbacUser();
|
||||
--//
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-USER-RV-DELETE-TRIGGER:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
/**
|
||||
Instead of delete trigger function for RbacUser_RV.
|
||||
|
||||
Checks if the current subject (user / assumed role) has the permission to delete the user.
|
||||
*/
|
||||
create or replace function deleteRbacUser()
|
||||
returns trigger
|
||||
language plpgsql as $$
|
||||
begin
|
||||
if currentUserUuid() = old.uuid or hasGlobalRoleGranted(currentUserUuid()) then
|
||||
delete from RbacUser where uuid = old.uuid;
|
||||
return old;
|
||||
end if;
|
||||
raise exception '[403] User % not allowed to delete user uuid %', currentUser(), old.uuid;
|
||||
end; $$;
|
||||
|
||||
/*
|
||||
Creates an instead of delete trigger for the RbacUser_rv view.
|
||||
*/
|
||||
create trigger deleteRbacUser_Trigger
|
||||
instead of delete
|
||||
on RbacUser_rv
|
||||
for each row
|
||||
execute function deleteRbacUser();
|
||||
--/
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-OWN-GRANTED-PERMISSIONS-VIEW:1 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
|
||||
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};
|
||||
-- @formatter:om
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-views-GRANTED-PERMISSIONS:1 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)
|
||||
returns null on null input
|
||||
language plpgsql as $$
|
||||
declare
|
||||
currentUserUuid uuid;
|
||||
begin
|
||||
-- @formatter:off
|
||||
currentUserUuid := currentUserUuid();
|
||||
|
||||
if hasGlobalRoleGranted(targetUserUuid) and not hasGlobalRoleGranted(currentUserUuid) then
|
||||
raise exception '[403] permissions of user "%" are not accessible to user "%"', targetUserUuid, currentUser();
|
||||
end if;
|
||||
|
||||
return query select
|
||||
xp.roleUuid,
|
||||
(xp.roleObjectTable || '#' || xp.roleObjectIdName || ':' || xp.roleType) as roleName,
|
||||
xp.permissionUuid, xp.op, xp.opTableName,
|
||||
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,
|
||||
p.uuid as permissionUuid, p.op, p.opTableName,
|
||||
po.objecttable as permissionObjectTable,
|
||||
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)
|
||||
) 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)
|
||||
returns null on null input
|
||||
language sql as $$
|
||||
select * from grantedPermissionsRaw(targetUserUuid)
|
||||
union all
|
||||
select roleUuid, roleName, permissionUuid, 'SELECT'::RbacOp, opTableName, objectTable, objectIdName, objectUuid
|
||||
from grantedPermissionsRaw(targetUserUuid)
|
||||
where op <> 'SELECT'::RbacOp;
|
||||
$$;
|
||||
--//
|
@@ -0,0 +1,61 @@
|
||||
--liquibase formatted sql
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-trigger-context-ENTER:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace procedure enterTriggerForObjectUuid(currentObjectUuid uuid)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
existingObjectUuid text;
|
||||
begin
|
||||
existingObjectUuid = current_setting('hsadminng.currentObjectUuid', true);
|
||||
if (existingObjectUuid > '' ) then
|
||||
raise exception '[500] currentObjectUuid already defined, already in trigger of "%"', existingObjectUuid;
|
||||
end if;
|
||||
execute format('set local hsadminng.currentObjectUuid to %L', currentObjectUuid);
|
||||
end; $$;
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-trigger-context-CURRENT-ID:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
Returns the uuid of the object uuid whose trigger is currently executed as set via `enterTriggerForObjectUuid(...)`.
|
||||
*/
|
||||
|
||||
create or replace function currentTriggerObjectUuid()
|
||||
returns uuid
|
||||
stable -- leakproof
|
||||
language plpgsql as $$
|
||||
declare
|
||||
currentObjectUuid uuid;
|
||||
begin
|
||||
begin
|
||||
currentObjectUuid = current_setting('hsadminng.currentObjectUuid')::uuid;
|
||||
return currentObjectUuid;
|
||||
exception
|
||||
when others then
|
||||
return null::uuid;
|
||||
end;
|
||||
end; $$;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-trigger-context-LEAVE:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace procedure leaveTriggerForObjectUuid(currentObjectUuid uuid)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
existingObjectUuid uuid;
|
||||
begin
|
||||
existingObjectUuid = current_setting('hsadminng.currentObjectUuid', true);
|
||||
if ( existingObjectUuid <> currentObjectUuid ) then
|
||||
raise exception '[500] currentObjectUuid does not match: "%"', existingObjectUuid;
|
||||
end if;
|
||||
execute format('reset hsadminng.currentObjectUuid');
|
||||
end; $$;
|
||||
|
@@ -0,0 +1,76 @@
|
||||
--liquibase formatted sql
|
||||
|
||||
-- ============================================================================
|
||||
-- PERMISSIONS
|
||||
--changeset rbac-role-builder-to-uuids:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace function toPermissionUuids(forObjectUuid uuid, permitOps RbacOp[])
|
||||
returns uuid[]
|
||||
language plpgsql
|
||||
strict as $$
|
||||
begin
|
||||
return createPermissions(forObjectUuid, permitOps);
|
||||
end; $$;
|
||||
|
||||
|
||||
-- =================================================================
|
||||
-- CREATE ROLE
|
||||
--changeset rbac-role-builder-create-role:1 endDelimiter:--//
|
||||
-- -----------------------------------------------------------------
|
||||
|
||||
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
|
||||
)
|
||||
returns uuid
|
||||
called on null input
|
||||
language plpgsql as $$
|
||||
declare
|
||||
roleUuid uuid;
|
||||
subRoleDesc RbacRoleDescriptor;
|
||||
superRoleDesc RbacRoleDescriptor;
|
||||
subRoleUuid uuid;
|
||||
superRoleUuid uuid;
|
||||
userUuid uuid;
|
||||
userGrantsByRoleUuid uuid;
|
||||
begin
|
||||
roleUuid := createRole(roleDescriptor);
|
||||
|
||||
if cardinality(permissions) > 0 then
|
||||
call grantPermissionsToRole(roleUuid, toPermissionUuids(roleDescriptor.objectuuid, permissions));
|
||||
end if;
|
||||
|
||||
foreach superRoleDesc in array array_remove(incomingSuperRoles, null)
|
||||
loop
|
||||
superRoleUuid := getRoleId(superRoleDesc);
|
||||
call 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);
|
||||
end loop;
|
||||
|
||||
if cardinality(userUuids) > 0 then
|
||||
-- direct grants to users need a grantedByRole which can revoke the grant
|
||||
if grantedByRole is null then
|
||||
userGrantsByRoleUuid := roleUuid; -- TODO: or do we want to require an explicit userGrantsByRoleUuid?
|
||||
else
|
||||
userGrantsByRoleUuid := getRoleId(grantedByRole);
|
||||
end if;
|
||||
foreach userUuid in array userUuids
|
||||
loop
|
||||
call grantRoleToUserUnchecked(userGrantsByRoleUuid, roleUuid, userUuid);
|
||||
end loop;
|
||||
end if;
|
||||
|
||||
return roleUuid;
|
||||
end; $$;
|
||||
--//
|
||||
|
283
src/main/resources/db/changelog/1-rbac/1058-rbac-generators.sql
Normal file
283
src/main/resources/db/changelog/1-rbac/1058-rbac-generators.sql
Normal file
@@ -0,0 +1,283 @@
|
||||
--liquibase formatted sql
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-generators-RELATED-OBJECT:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace procedure generateRelatedRbacObject(targetTable varchar)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
createInsertTriggerSQL text;
|
||||
createDeleteTriggerSQL text;
|
||||
begin
|
||||
createInsertTriggerSQL = format($sql$
|
||||
create trigger createRbacObjectFor_%s_Trigger
|
||||
before insert on %s
|
||||
for each row
|
||||
execute procedure insertRelatedRbacObject();
|
||||
$sql$, targetTable, targetTable);
|
||||
execute createInsertTriggerSQL;
|
||||
|
||||
createDeleteTriggerSQL = format($sql$
|
||||
create trigger deleteRbacRulesFor_%s_Trigger
|
||||
after delete
|
||||
on %s
|
||||
for each row
|
||||
execute procedure deleteRelatedRbacObject();
|
||||
$sql$, targetTable, targetTable);
|
||||
execute createDeleteTriggerSQL;
|
||||
end; $$;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-generators-ROLE-DESCRIPTORS:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create procedure 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
|
||||
language plpgsql
|
||||
strict as $f$
|
||||
begin
|
||||
return roleDescriptor('%2$s', entity.uuid, 'OWNER', assumed);
|
||||
end; $f$;
|
||||
|
||||
create or replace function %1$sAdmin(entity %2$s, assumed boolean = true)
|
||||
returns RbacRoleDescriptor
|
||||
language plpgsql
|
||||
strict as $f$
|
||||
begin
|
||||
return roleDescriptor('%2$s', entity.uuid, 'ADMIN', assumed);
|
||||
end; $f$;
|
||||
|
||||
create or replace function %1$sAgent(entity %2$s, assumed boolean = true)
|
||||
returns RbacRoleDescriptor
|
||||
language plpgsql
|
||||
strict as $f$
|
||||
begin
|
||||
return roleDescriptor('%2$s', entity.uuid, 'AGENT', assumed);
|
||||
end; $f$;
|
||||
|
||||
create or replace function %1$sTenant(entity %2$s, assumed boolean = true)
|
||||
returns RbacRoleDescriptor
|
||||
language plpgsql
|
||||
strict as $f$
|
||||
begin
|
||||
return roleDescriptor('%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
|
||||
language plpgsql
|
||||
strict as $f$
|
||||
begin
|
||||
return roleDescriptor('%2$s', entity.uuid, 'GUEST', assumed);
|
||||
end; $f$;
|
||||
|
||||
create or replace function %1$sReferrer(entity %2$s)
|
||||
returns RbacRoleDescriptor
|
||||
language plpgsql
|
||||
strict as $f$
|
||||
begin
|
||||
return roleDescriptor('%2$s', entity.uuid, 'REFERRER');
|
||||
end; $f$;
|
||||
|
||||
$sql$, prefix, targetTable);
|
||||
execute sql;
|
||||
end; $$;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-generators-IDENTITY-VIEW:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace procedure generateRbacIdentityViewFromQuery(targetTable text, sqlQuery text)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
sql text;
|
||||
begin
|
||||
targettable := lower(targettable);
|
||||
|
||||
-- create a view to the target main table which maps an idName to the objectUuid
|
||||
sql = format($sql$
|
||||
create or replace view %1$s_iv as %2$s;
|
||||
grant all privileges on %1$s_iv to ${HSADMINNG_POSTGRES_RESTRICTED_USERNAME};
|
||||
$sql$, targetTable, sqlQuery);
|
||||
execute sql;
|
||||
|
||||
-- creates a function which maps an idName to the objectUuid
|
||||
sql = format($sql$
|
||||
create or replace function %1$sUuidByIdName(givenIdName varchar)
|
||||
returns uuid
|
||||
language sql
|
||||
strict as $f$
|
||||
select uuid from %1$s_iv iv where iv.idName = givenIdName;
|
||||
$f$;
|
||||
$sql$, targetTable);
|
||||
execute sql;
|
||||
|
||||
-- creates a function which maps an objectUuid to the related idName
|
||||
sql = format($sql$
|
||||
create or replace function %1$sIdNameByUuid(givenUuid uuid)
|
||||
returns varchar
|
||||
language sql
|
||||
strict as $f$
|
||||
select idName from %1$s_iv iv where iv.uuid = givenUuid;
|
||||
$f$;
|
||||
$sql$, targetTable);
|
||||
execute sql;
|
||||
end; $$;
|
||||
|
||||
create or replace procedure generateRbacIdentityViewFromProjection(targetTable text, sqlProjection text)
|
||||
language plpgsql as $$
|
||||
declare
|
||||
sqlQuery text;
|
||||
begin
|
||||
targettable := lower(targettable);
|
||||
|
||||
sqlQuery = format($sql$
|
||||
select target.uuid, cleanIdentifier(%2$s) as idName
|
||||
from %1$s as target;
|
||||
$sql$, targetTable, sqlProjection);
|
||||
call generateRbacIdentityViewFromQuery(targetTable, sqlQuery);
|
||||
end; $$;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-generators-RESTRICTED-VIEW:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
create or replace procedure generateRbacRestrictedView(targetTable text, orderBy text, columnUpdates text = null, columnNames text = '*')
|
||||
language plpgsql as $$
|
||||
declare
|
||||
sql text;
|
||||
newColumns text;
|
||||
begin
|
||||
targetTable := lower(targetTable);
|
||||
if columnNames = '*' then
|
||||
columnNames := columnsNames(targetTable);
|
||||
end if;
|
||||
|
||||
/*
|
||||
Creates a restricted view based on the 'SELECT' permission of the current subject.
|
||||
*/
|
||||
sql := format($sql$
|
||||
set session session authorization default;
|
||||
create view %1$s_rv as
|
||||
with accessibleObjects as (
|
||||
select queryAccessibleObjectUuidsOfSubjectIds('SELECT', '%1$s', currentSubjectsUuids())
|
||||
)
|
||||
select target.*
|
||||
from %1$s as target
|
||||
where target.uuid in (select * from accessibleObjects)
|
||||
order by %2$s;
|
||||
grant all privileges on %1$s_rv to ${HSADMINNG_POSTGRES_RESTRICTED_USERNAME};
|
||||
$sql$, targetTable, orderBy);
|
||||
execute sql;
|
||||
|
||||
/**
|
||||
Instead of insert trigger function for the restricted view.
|
||||
*/
|
||||
newColumns := 'new.' || replace(columnNames, ',', ', new.');
|
||||
sql := format($sql$
|
||||
create or replace function %1$sInsert()
|
||||
returns trigger
|
||||
language plpgsql as $f$
|
||||
declare
|
||||
newTargetRow %1$s;
|
||||
begin
|
||||
insert
|
||||
into %1$s (%2$s)
|
||||
values (%3$s)
|
||||
returning * into newTargetRow;
|
||||
return newTargetRow;
|
||||
end; $f$;
|
||||
$sql$, targetTable, columnNames, newColumns);
|
||||
execute sql;
|
||||
|
||||
/*
|
||||
Creates an instead of insert trigger for the restricted view.
|
||||
*/
|
||||
sql := format($sql$
|
||||
create trigger %1$sInsert_tg
|
||||
instead of insert
|
||||
on %1$s_rv
|
||||
for each row
|
||||
execute function %1$sInsert();
|
||||
$sql$, targetTable);
|
||||
execute sql;
|
||||
|
||||
/**
|
||||
Instead of delete trigger function for the restricted view.
|
||||
*/
|
||||
sql := format($sql$
|
||||
create or replace function %1$sDelete()
|
||||
returns trigger
|
||||
language plpgsql as $f$
|
||||
begin
|
||||
if old.uuid in (select queryAccessibleObjectUuidsOfSubjectIds('DELETE', '%1$s', currentSubjectsUuids())) 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;
|
||||
end; $f$;
|
||||
$sql$, targetTable);
|
||||
execute sql;
|
||||
|
||||
/*
|
||||
Creates an instead of delete trigger for the restricted view.
|
||||
*/
|
||||
sql := format($sql$
|
||||
create trigger %1$sDelete_tg
|
||||
instead of delete
|
||||
on %1$s_rv
|
||||
for each row
|
||||
execute function %1$sDelete();
|
||||
$sql$, targetTable);
|
||||
execute sql;
|
||||
|
||||
/**
|
||||
Instead of update trigger function for the restricted view
|
||||
based on the 'UPDATE' permission of the current subject.
|
||||
*/
|
||||
if columnUpdates is not null then
|
||||
sql := format($sql$
|
||||
create or replace function %1$sUpdate()
|
||||
returns trigger
|
||||
language plpgsql as $f$
|
||||
begin
|
||||
if old.uuid in (select queryAccessibleObjectUuidsOfSubjectIds('UPDATE', '%1$s', currentSubjectsUuids())) 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;
|
||||
end; $f$;
|
||||
$sql$, targetTable, columnUpdates);
|
||||
execute sql;
|
||||
|
||||
/*
|
||||
Creates an instead of delete trigger for the restricted view.
|
||||
*/
|
||||
sql = format($sql$
|
||||
create trigger %1$sUpdate_tg
|
||||
instead of update
|
||||
on %1$s_rv
|
||||
for each row
|
||||
execute function %1$sUpdate();
|
||||
$sql$, targetTable);
|
||||
execute sql;
|
||||
end if;
|
||||
end; $$;
|
||||
--//
|
@@ -0,0 +1,28 @@
|
||||
--liquibase formatted sql
|
||||
|
||||
--changeset rbac-statistics:1 endDelimiter:--//
|
||||
|
||||
/*
|
||||
Creates a view which presents some statistics about the RBAC tables.
|
||||
*/
|
||||
create view RbacStatisticsView as
|
||||
select no, to_char("count", '9 999 999 999') as "count", "table"
|
||||
from (select 1 as no, count(*) as "count", 'login users' as "table"
|
||||
from RbacUser
|
||||
union
|
||||
select 2 as no, count(*) as "count", 'roles' as "table"
|
||||
from RbacRole
|
||||
union
|
||||
select 3 as no, count(*) as "count", 'permissions' as "table"
|
||||
from RbacPermission
|
||||
union
|
||||
select 4 as no, count(*) as "count", 'references' as "table"
|
||||
from RbacReference
|
||||
union
|
||||
select 5 as no, count(*) as "count", 'grants' as "table"
|
||||
from RbacGrants
|
||||
union
|
||||
select 6 as no, count(*) as "count", 'objects' as "table"
|
||||
from RbacObject) as totals
|
||||
order by totals.no;
|
||||
--//
|
194
src/main/resources/db/changelog/1-rbac/1080-rbac-global.sql
Normal file
194
src/main/resources/db/changelog/1-rbac/1080-rbac-global.sql
Normal file
@@ -0,0 +1,194 @@
|
||||
--liquibase formatted sql
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-global-GLOBAL-OBJECT:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
The purpose of this table is provide root business objects
|
||||
which can be referenced from global roles.
|
||||
Without this table, these columns needed to be nullable and
|
||||
many queries would be more complicated.
|
||||
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
|
||||
(
|
||||
uuid uuid primary key references RbacObject (uuid) on delete cascade,
|
||||
name varchar(63) unique
|
||||
);
|
||||
create unique index Global_Singleton on Global ((0));
|
||||
|
||||
grant select on global to ${HSADMINNG_POSTGRES_RESTRICTED_USERNAME};
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-global-IS-GLOBAL-ADMIN:1 endDelimiter:--//
|
||||
-- ------------------------------------------------------------------
|
||||
|
||||
create or replace function isGlobalAdmin()
|
||||
returns boolean
|
||||
language plpgsql as $$
|
||||
begin
|
||||
return isGranted(currentSubjectsUuids(), findRoleId(globalAdmin()));
|
||||
end; $$;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-global-HAS-GLOBAL-PERMISSION:1 endDelimiter:--//
|
||||
-- ------------------------------------------------------------------
|
||||
|
||||
create or replace function hasGlobalPermission(op RbacOp)
|
||||
returns boolean
|
||||
language sql as
|
||||
$$
|
||||
-- TODO.perf: this could to be optimized
|
||||
select (select uuid from global) in
|
||||
(select queryAccessibleObjectUuidsOfSubjectIds(op, 'global', currentSubjectsUuids()));
|
||||
$$;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-global-GLOBAL-IDENTITY-VIEW:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
/*
|
||||
Creates a view to the global object table which maps the identifying name to the objectUuid.
|
||||
*/
|
||||
drop view if exists global_iv;
|
||||
create or replace view 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};
|
||||
|
||||
/*
|
||||
Returns the objectUuid for a given identifying name (in this case the idName).
|
||||
*/
|
||||
create or replace function globalUuidByIdName(idName varchar)
|
||||
returns uuid
|
||||
language sql
|
||||
strict as $$
|
||||
select uuid from 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)
|
||||
returns varchar
|
||||
language sql
|
||||
strict as $$
|
||||
select idName from global_iv iv where iv.uuid = globalIdNameByUuid.uuid;
|
||||
$$;
|
||||
--//
|
||||
|
||||
--liquibase formatted sql
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-global-PSEUDO-OBJECT:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
/**
|
||||
A single row to be referenced as a global object.
|
||||
*/
|
||||
begin transaction;
|
||||
call defineContext('initializing table "global"', null, null, null);
|
||||
insert
|
||||
into RbacObject (objecttable) values ('global');
|
||||
insert
|
||||
into Global (uuid, name) values ((select uuid from RbacObject where objectTable = 'global'), 'global');
|
||||
commit;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-global-ADMIN-ROLE:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
A global administrator role.
|
||||
*/
|
||||
create or replace function globalAdmin(assumed boolean = true)
|
||||
returns RbacRoleDescriptor
|
||||
returns null on null input
|
||||
stable -- leakproof
|
||||
language sql as $$
|
||||
select 'global', (select uuid from RbacObject where objectTable = 'global'), 'ADMIN'::RbacRoleType, assumed;
|
||||
$$;
|
||||
|
||||
begin transaction;
|
||||
call defineContext('creating role:global#global:ADMIN', null, null, null);
|
||||
select createRole(globalAdmin());
|
||||
commit;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-global-GUEST-ROLE:1 endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
A global guest role.
|
||||
*/
|
||||
create or replace function globalGuest(assumed boolean = true)
|
||||
returns RbacRoleDescriptor
|
||||
returns null on null input
|
||||
stable -- leakproof
|
||||
language sql as $$
|
||||
select 'global', (select uuid from RbacObject where objectTable = 'global'), 'GUEST'::RbacRoleType, assumed;
|
||||
$$;
|
||||
|
||||
begin transaction;
|
||||
call defineContext('creating role:global#global:guest', null, null, null);
|
||||
select createRole(globalGuest());
|
||||
commit;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-global-ADMIN-USERS:1 context:dev,tc endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
/*
|
||||
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);
|
||||
|
||||
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');
|
||||
end;
|
||||
$$;
|
||||
--//
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
--changeset rbac-global-TEST:1 context:dev,tc runAlways:true endDelimiter:--//
|
||||
-- ----------------------------------------------------------------------------
|
||||
|
||||
/*
|
||||
Tests if currentUserUuid() 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;
|
||||
if userName <> 'superuser-fran@hostsharing.net' then
|
||||
raise exception 'setting or fetching initial currentUser failed, got: %', userName;
|
||||
end if;
|
||||
|
||||
call defineContext('testing currentUserUuid', null, 'superuser-alex@hostsharing.net', null);
|
||||
select userName from RbacUser where uuid = currentUserUuid() into userName;
|
||||
if userName = 'superuser-alex@hostsharing.net' then
|
||||
raise exception 'currentUser should not change in one transaction, but did change, got: %', userName;
|
||||
end if;
|
||||
end; $$;
|
||||
--//
|
Reference in New Issue
Block a user