2022-09-16 15:25:58 +02:00
|
|
|
--liquibase formatted sql
|
|
|
|
|
|
|
|
|
|
|
|
-- ============================================================================
|
2024-09-16 15:36:37 +02:00
|
|
|
--changeset michael.hoennig:rbac-generators-RELATED-OBJECT endDelimiter:--//
|
2022-09-16 15:25:58 +02:00
|
|
|
-- ----------------------------------------------------------------------------
|
|
|
|
|
2024-09-16 15:36:37 +02:00
|
|
|
create or replace procedure rbac.generateRelatedRbacObject(targetTable varchar)
|
2022-09-16 15:25:58 +02:00
|
|
|
language plpgsql as $$
|
|
|
|
declare
|
2024-09-17 14:21:43 +02:00
|
|
|
targetTableName text;
|
|
|
|
targetSchemaPrefix text;
|
2022-09-16 15:25:58 +02:00
|
|
|
createInsertTriggerSQL text;
|
|
|
|
createDeleteTriggerSQL text;
|
|
|
|
begin
|
2024-09-17 14:21:43 +02:00
|
|
|
if POSITION('.' IN targetTable) > 0 then
|
|
|
|
targetSchemaPrefix := SPLIT_PART(targetTable, '.', 1) || '.';
|
|
|
|
targetTableName := SPLIT_PART(targetTable, '.', 2);
|
|
|
|
else
|
|
|
|
targetSchemaPrefix := '';
|
|
|
|
targetTableName := targetTable;
|
|
|
|
end if;
|
|
|
|
|
|
|
|
if targetSchemaPrefix = '' and targetTableName = 'customer' then
|
|
|
|
raise exception 'missing targetShemaPrefix: %', targetTable;
|
|
|
|
end if;
|
|
|
|
|
2022-09-16 15:25:58 +02:00
|
|
|
createInsertTriggerSQL = format($sql$
|
2024-09-17 14:21:43 +02:00
|
|
|
create trigger createRbacObjectFor_%s_insert_tg_1058_25
|
|
|
|
before insert on %s%s
|
2022-09-16 15:25:58 +02:00
|
|
|
for each row
|
2024-09-16 15:36:37 +02:00
|
|
|
execute procedure rbac.insert_related_object();
|
2024-09-17 14:21:43 +02:00
|
|
|
$sql$, targetTableName, targetSchemaPrefix, targetTableName);
|
2022-09-16 15:25:58 +02:00
|
|
|
execute createInsertTriggerSQL;
|
|
|
|
|
|
|
|
createDeleteTriggerSQL = format($sql$
|
2024-09-17 14:21:43 +02:00
|
|
|
create trigger createRbacObjectFor_%s_delete_tg_1058_35
|
|
|
|
after delete on %s%s
|
2022-09-16 15:25:58 +02:00
|
|
|
for each row
|
2024-09-16 15:36:37 +02:00
|
|
|
execute procedure rbac.delete_related_rbac_rules_tf();
|
2024-09-17 14:21:43 +02:00
|
|
|
$sql$, targetTableName, targetSchemaPrefix, targetTableName);
|
2022-09-16 15:25:58 +02:00
|
|
|
execute createDeleteTriggerSQL;
|
2024-09-17 14:21:43 +02:00
|
|
|
end;
|
|
|
|
$$;
|
2022-09-16 15:25:58 +02:00
|
|
|
--//
|
|
|
|
|
|
|
|
|
|
|
|
-- ============================================================================
|
2024-09-16 15:36:37 +02:00
|
|
|
--changeset michael.hoennig:rbac-generators-ROLE-DESCRIPTORS endDelimiter:--//
|
2022-09-16 15:25:58 +02:00
|
|
|
-- ----------------------------------------------------------------------------
|
|
|
|
|
2024-09-23 10:52:37 +02:00
|
|
|
create procedure rbac.generateRbacRoleDescriptors(targetTable text)
|
2022-09-16 15:25:58 +02:00
|
|
|
language plpgsql as $$
|
|
|
|
declare
|
|
|
|
sql text;
|
|
|
|
begin
|
|
|
|
sql = format($sql$
|
2024-09-23 10:52:37 +02:00
|
|
|
create or replace function %1$s_OWNER(entity %1$s, assumed boolean = true)
|
2024-09-16 15:36:37 +02:00
|
|
|
returns rbac.RoleDescriptor
|
2022-09-16 15:25:58 +02:00
|
|
|
language plpgsql
|
|
|
|
strict as $f$
|
|
|
|
begin
|
2024-09-23 10:52:37 +02:00
|
|
|
return rbac.roleDescriptorOf('%1$s', entity.uuid, 'OWNER', assumed);
|
2022-09-16 15:25:58 +02:00
|
|
|
end; $f$;
|
|
|
|
|
2024-09-23 10:52:37 +02:00
|
|
|
create or replace function %1$s_ADMIN(entity %1$s, assumed boolean = true)
|
2024-09-16 15:36:37 +02:00
|
|
|
returns rbac.RoleDescriptor
|
2022-09-16 15:25:58 +02:00
|
|
|
language plpgsql
|
|
|
|
strict as $f$
|
|
|
|
begin
|
2024-09-23 10:52:37 +02:00
|
|
|
return rbac.roleDescriptorOf('%1$s', entity.uuid, 'ADMIN', assumed);
|
2022-09-16 15:25:58 +02:00
|
|
|
end; $f$;
|
|
|
|
|
2024-09-23 10:52:37 +02:00
|
|
|
create or replace function %1$s_AGENT(entity %1$s, assumed boolean = true)
|
2024-09-16 15:36:37 +02:00
|
|
|
returns rbac.RoleDescriptor
|
2022-10-12 15:48:56 +02:00
|
|
|
language plpgsql
|
|
|
|
strict as $f$
|
|
|
|
begin
|
2024-09-23 10:52:37 +02:00
|
|
|
return rbac.roleDescriptorOf('%1$s', entity.uuid, 'AGENT', assumed);
|
2022-10-12 15:48:56 +02:00
|
|
|
end; $f$;
|
|
|
|
|
2024-09-23 10:52:37 +02:00
|
|
|
create or replace function %1$s_TENANT(entity %1$s, assumed boolean = true)
|
2024-09-16 15:36:37 +02:00
|
|
|
returns rbac.RoleDescriptor
|
2022-09-16 15:25:58 +02:00
|
|
|
language plpgsql
|
|
|
|
strict as $f$
|
|
|
|
begin
|
2024-09-23 10:52:37 +02:00
|
|
|
return rbac.roleDescriptorOf('%1$s', entity.uuid, 'TENANT', assumed);
|
2022-09-16 15:25:58 +02:00
|
|
|
end; $f$;
|
|
|
|
|
2024-03-26 11:25:18 +01:00
|
|
|
-- TODO: remove guest role
|
2024-09-23 10:52:37 +02:00
|
|
|
create or replace function %1$s_GUEST(entity %1$s, assumed boolean = true)
|
2024-09-16 15:36:37 +02:00
|
|
|
returns rbac.RoleDescriptor
|
2022-10-12 15:48:56 +02:00
|
|
|
language plpgsql
|
|
|
|
strict as $f$
|
|
|
|
begin
|
2024-09-23 10:52:37 +02:00
|
|
|
return rbac.roleDescriptorOf('%1$s', entity.uuid, 'GUEST', assumed);
|
2022-10-12 15:48:56 +02:00
|
|
|
end; $f$;
|
|
|
|
|
2024-09-23 10:52:37 +02:00
|
|
|
create or replace function %1$s_REFERRER(entity %1$s)
|
2024-09-16 15:36:37 +02:00
|
|
|
returns rbac.RoleDescriptor
|
2024-03-26 11:25:18 +01:00
|
|
|
language plpgsql
|
|
|
|
strict as $f$
|
|
|
|
begin
|
2024-09-23 10:52:37 +02:00
|
|
|
return rbac.roleDescriptorOf('%1$s', entity.uuid, 'REFERRER');
|
2024-03-26 11:25:18 +01:00
|
|
|
end; $f$;
|
|
|
|
|
2024-09-23 10:52:37 +02:00
|
|
|
$sql$, targetTable);
|
2022-09-16 15:25:58 +02:00
|
|
|
execute sql;
|
|
|
|
end; $$;
|
|
|
|
--//
|
2022-09-16 16:14:39 +02:00
|
|
|
|
|
|
|
|
|
|
|
-- ============================================================================
|
2025-02-17 09:40:58 +01:00
|
|
|
--changeset michael.hoennig:rbac-generators-IDENTITY-VIEW runOnChange:true validCheckSum:ANY endDelimiter:--//
|
2022-09-16 16:14:39 +02:00
|
|
|
-- ----------------------------------------------------------------------------
|
|
|
|
|
2024-09-16 15:36:37 +02:00
|
|
|
create or replace procedure rbac.generateRbacIdentityViewFromQuery(targetTable text, sqlQuery text)
|
2022-09-16 16:14:39 +02:00
|
|
|
language plpgsql as $$
|
|
|
|
declare
|
|
|
|
sql text;
|
|
|
|
begin
|
2022-10-19 07:39:10 +02:00
|
|
|
targettable := lower(targettable);
|
|
|
|
|
2022-09-16 16:14:39 +02:00
|
|
|
-- create a view to the target main table which maps an idName to the objectUuid
|
|
|
|
sql = format($sql$
|
2024-03-11 12:30:43 +01:00
|
|
|
create or replace view %1$s_iv as %2$s;
|
2024-01-23 15:11:23 +01:00
|
|
|
grant all privileges on %1$s_iv to ${HSADMINNG_POSTGRES_RESTRICTED_USERNAME};
|
2024-03-11 12:30:43 +01:00
|
|
|
$sql$, targetTable, sqlQuery);
|
2022-09-16 16:14:39 +02:00
|
|
|
execute sql;
|
|
|
|
|
|
|
|
-- creates a function which maps an idName to the objectUuid
|
|
|
|
sql = format($sql$
|
2024-09-23 10:52:37 +02:00
|
|
|
create or replace function %1$s_uuid_by_id_name(givenIdName varchar)
|
2022-09-16 16:14:39 +02:00
|
|
|
returns uuid
|
2024-06-06 13:46:14 +02:00
|
|
|
language plpgsql as $f$
|
|
|
|
declare
|
|
|
|
singleMatch uuid;
|
|
|
|
begin
|
|
|
|
select uuid into strict singleMatch from %1$s_iv iv where iv.idName = givenIdName;
|
|
|
|
return singleMatch;
|
|
|
|
end; $f$;
|
2022-09-16 16:14:39 +02:00
|
|
|
$sql$, targetTable);
|
|
|
|
execute sql;
|
|
|
|
|
|
|
|
-- creates a function which maps an objectUuid to the related idName
|
|
|
|
sql = format($sql$
|
2024-09-23 10:52:37 +02:00
|
|
|
create or replace function %1$s_id_name_by_uuid(givenUuid uuid)
|
2022-09-16 16:14:39 +02:00
|
|
|
returns varchar
|
|
|
|
language sql
|
|
|
|
strict as $f$
|
|
|
|
select idName from %1$s_iv iv where iv.uuid = givenUuid;
|
|
|
|
$f$;
|
|
|
|
$sql$, targetTable);
|
|
|
|
execute sql;
|
|
|
|
end; $$;
|
2024-03-11 12:30:43 +01:00
|
|
|
|
2024-09-16 15:36:37 +02:00
|
|
|
create or replace procedure rbac.generateRbacIdentityViewFromProjection(targetTable text, sqlProjection text)
|
2024-03-11 12:30:43 +01:00
|
|
|
language plpgsql as $$
|
|
|
|
declare
|
|
|
|
sqlQuery text;
|
|
|
|
begin
|
|
|
|
targettable := lower(targettable);
|
|
|
|
|
|
|
|
sqlQuery = format($sql$
|
2024-09-16 15:36:37 +02:00
|
|
|
select target.uuid, base.cleanIdentifier(%2$s) as idName
|
2024-03-11 12:30:43 +01:00
|
|
|
from %1$s as target;
|
|
|
|
$sql$, targetTable, sqlProjection);
|
2024-09-16 15:36:37 +02:00
|
|
|
call rbac.generateRbacIdentityViewFromQuery(targetTable, sqlQuery);
|
2024-03-11 12:30:43 +01:00
|
|
|
end; $$;
|
2022-09-16 16:14:39 +02:00
|
|
|
--//
|
2022-09-19 20:43:14 +02:00
|
|
|
|
|
|
|
|
|
|
|
-- ============================================================================
|
2025-02-17 09:40:58 +01:00
|
|
|
--changeset michael.hoennig:rbac-generators-RESTRICTED-VIEW runOnChange:true validCheckSum:ANY endDelimiter:--//
|
2022-09-19 20:43:14 +02:00
|
|
|
-- ----------------------------------------------------------------------------
|
|
|
|
|
2024-09-16 15:36:37 +02:00
|
|
|
create or replace procedure rbac.generateRbacRestrictedView(targetTable text, orderBy text, columnUpdates text = null, columnNames text = '*')
|
2022-09-19 20:43:14 +02:00
|
|
|
language plpgsql as $$
|
|
|
|
declare
|
|
|
|
sql text;
|
2024-03-26 11:25:18 +01:00
|
|
|
newColumns text;
|
2022-09-19 20:43:14 +02:00
|
|
|
begin
|
2022-10-19 07:39:10 +02:00
|
|
|
targetTable := lower(targetTable);
|
2024-03-26 11:25:18 +01:00
|
|
|
if columnNames = '*' then
|
2024-09-16 15:36:37 +02:00
|
|
|
columnNames := base.tableColumnNames(targetTable);
|
2024-03-26 11:25:18 +01:00
|
|
|
end if;
|
2022-10-19 07:39:10 +02:00
|
|
|
|
2022-09-19 20:43:14 +02:00
|
|
|
/*
|
2024-03-11 12:30:43 +01:00
|
|
|
Creates a restricted view based on the 'SELECT' permission of the current subject.
|
2022-09-19 20:43:14 +02:00
|
|
|
*/
|
|
|
|
sql := format($sql$
|
2024-07-27 10:18:07 +02:00
|
|
|
create or replace view %1$s_rv as
|
2024-09-17 14:21:43 +02:00
|
|
|
with accessible_uuids as (
|
2024-08-15 10:38:43 +02:00
|
|
|
with recursive
|
|
|
|
recursive_grants as
|
2025-01-02 12:39:18 +01:00
|
|
|
(select distinct rbac.grant.descendantuuid,
|
|
|
|
rbac.grant.ascendantuuid,
|
2024-08-15 10:38:43 +02:00
|
|
|
1 as level,
|
|
|
|
true
|
2025-01-02 12:39:18 +01:00
|
|
|
from rbac.grant
|
|
|
|
where rbac.grant.assumed
|
|
|
|
and (rbac.grant.ascendantuuid = any (rbac.currentSubjectOrAssumedRolesUuids()))
|
2024-08-15 10:38:43 +02:00
|
|
|
union all
|
|
|
|
select distinct g.descendantuuid,
|
|
|
|
g.ascendantuuid,
|
|
|
|
grants.level + 1 as level,
|
2024-09-16 15:36:37 +02:00
|
|
|
base.assertTrue(grants.level < 22, 'too many grant-levels: ' || grants.level)
|
2025-01-02 12:39:18 +01:00
|
|
|
from rbac.grant g
|
2024-08-15 10:38:43 +02:00
|
|
|
join recursive_grants grants on grants.descendantuuid = g.ascendantuuid
|
|
|
|
where g.assumed),
|
|
|
|
grant_count AS (
|
|
|
|
SELECT COUNT(*) AS grant_count FROM recursive_grants
|
|
|
|
),
|
2024-09-16 15:36:37 +02:00
|
|
|
count_check as (select base.assertTrue((select count(*) as grant_count from recursive_grants) < 400000,
|
2024-08-15 10:38:43 +02:00
|
|
|
'too many grants for current subjects: ' || (select count(*) as grant_count from recursive_grants))
|
|
|
|
as valid)
|
|
|
|
select distinct perm.objectuuid
|
|
|
|
from recursive_grants
|
2024-09-16 15:36:37 +02:00
|
|
|
join rbac.permission perm on recursive_grants.descendantuuid = perm.uuid
|
|
|
|
join rbac.object obj on obj.uuid = perm.objectuuid
|
2024-08-15 10:38:43 +02:00
|
|
|
join count_check cc on cc.valid
|
|
|
|
where obj.objectTable = '%1$s' -- 'SELECT' permission is included in all other permissions
|
2022-10-17 12:18:12 +02:00
|
|
|
)
|
|
|
|
select target.*
|
|
|
|
from %1$s as target
|
2024-11-25 10:56:16 +01:00
|
|
|
where rbac.hasGlobalAdminRole() or target.uuid in (select * from accessible_uuids)
|
2022-10-17 12:18:12 +02:00
|
|
|
order by %2$s;
|
2024-07-27 10:18:07 +02:00
|
|
|
|
|
|
|
grant all privileges on %1$s_rv to ${HSADMINNG_POSTGRES_RESTRICTED_USERNAME};
|
2022-09-19 20:43:14 +02:00
|
|
|
$sql$, targetTable, orderBy);
|
|
|
|
execute sql;
|
|
|
|
|
|
|
|
/**
|
|
|
|
Instead of insert trigger function for the restricted view.
|
|
|
|
*/
|
2024-09-17 14:21:43 +02:00
|
|
|
newColumns := 'new.' || replace(columnNames, ', ', ', new.');
|
2022-09-19 20:43:14 +02:00
|
|
|
sql := format($sql$
|
2025-03-03 12:01:33 +01:00
|
|
|
create or replace function %1$s_instead_of_insert_tf()
|
2024-03-26 11:25:18 +01:00
|
|
|
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);
|
2022-09-19 20:43:14 +02:00
|
|
|
execute sql;
|
|
|
|
|
|
|
|
/*
|
|
|
|
Creates an instead of insert trigger for the restricted view.
|
|
|
|
*/
|
|
|
|
sql := format($sql$
|
2025-03-03 12:01:33 +01:00
|
|
|
create or replace trigger instead_of_insert_tg
|
2022-09-19 20:43:14 +02:00
|
|
|
instead of insert
|
|
|
|
on %1$s_rv
|
|
|
|
for each row
|
2024-09-17 14:21:43 +02:00
|
|
|
execute function %1$s_instead_of_insert_tf();
|
2022-09-19 20:43:14 +02:00
|
|
|
$sql$, targetTable);
|
|
|
|
execute sql;
|
|
|
|
|
|
|
|
/**
|
|
|
|
Instead of delete trigger function for the restricted view.
|
|
|
|
*/
|
|
|
|
sql := format($sql$
|
2025-03-03 12:01:33 +01:00
|
|
|
create or replace function %1$s_instead_of_delete_tf()
|
2022-09-19 20:43:14 +02:00
|
|
|
returns trigger
|
|
|
|
language plpgsql as $f$
|
|
|
|
begin
|
2024-09-16 15:36:37 +02:00
|
|
|
if old.uuid in (select rbac.queryAccessibleObjectUuidsOfSubjectIds('DELETE', '%1$s', rbac.currentSubjectOrAssumedRolesUuids())) then
|
2022-09-19 20:43:14 +02:00
|
|
|
delete from %1$s p where p.uuid = old.uuid;
|
|
|
|
return old;
|
|
|
|
end if;
|
2024-09-16 15:36:37 +02:00
|
|
|
raise exception '[403] Subject %% is not allowed to delete %1$s uuid %%', rbac.currentSubjectOrAssumedRolesUuids(), old.uuid;
|
2022-09-19 20:43:14 +02:00
|
|
|
end; $f$;
|
|
|
|
$sql$, targetTable);
|
|
|
|
execute sql;
|
|
|
|
|
|
|
|
/*
|
|
|
|
Creates an instead of delete trigger for the restricted view.
|
|
|
|
*/
|
|
|
|
sql := format($sql$
|
2025-03-03 12:01:33 +01:00
|
|
|
create or replace trigger instead_of_delete_tg
|
2022-09-19 20:43:14 +02:00
|
|
|
instead of delete
|
|
|
|
on %1$s_rv
|
|
|
|
for each row
|
2024-09-17 14:21:43 +02:00
|
|
|
execute function %1$s_instead_of_delete_tf();
|
2022-09-19 20:43:14 +02:00
|
|
|
$sql$, targetTable);
|
|
|
|
execute sql;
|
|
|
|
|
|
|
|
/**
|
|
|
|
Instead of update trigger function for the restricted view
|
2024-03-11 12:30:43 +01:00
|
|
|
based on the 'UPDATE' permission of the current subject.
|
2022-09-19 20:43:14 +02:00
|
|
|
*/
|
2022-10-18 17:29:10 +02:00
|
|
|
if columnUpdates is not null then
|
|
|
|
sql := format($sql$
|
2025-03-03 12:01:33 +01:00
|
|
|
create or replace function %1$s_instead_of_update_tf()
|
2022-10-18 17:29:10 +02:00
|
|
|
returns trigger
|
|
|
|
language plpgsql as $f$
|
|
|
|
begin
|
2024-09-16 15:36:37 +02:00
|
|
|
if old.uuid in (select rbac.queryAccessibleObjectUuidsOfSubjectIds('UPDATE', '%1$s', rbac.currentSubjectOrAssumedRolesUuids())) then
|
2022-10-18 17:29:10 +02:00
|
|
|
update %1$s
|
|
|
|
set %2$s
|
|
|
|
where uuid = old.uuid;
|
|
|
|
return old;
|
|
|
|
end if;
|
2024-09-16 15:36:37 +02:00
|
|
|
raise exception '[403] Subject %% is not allowed to update %1$s uuid %%', rbac.currentSubjectOrAssumedRolesUuids(), old.uuid;
|
2022-10-18 17:29:10 +02:00
|
|
|
end; $f$;
|
|
|
|
$sql$, targetTable, columnUpdates);
|
|
|
|
execute sql;
|
|
|
|
|
|
|
|
/*
|
|
|
|
Creates an instead of delete trigger for the restricted view.
|
|
|
|
*/
|
|
|
|
sql = format($sql$
|
2025-03-03 12:01:33 +01:00
|
|
|
create or replace trigger instead_of_update_tg
|
2022-10-18 17:29:10 +02:00
|
|
|
instead of update
|
|
|
|
on %1$s_rv
|
|
|
|
for each row
|
2024-09-17 14:21:43 +02:00
|
|
|
execute function %1$s_instead_of_update_tf();
|
2022-10-18 17:29:10 +02:00
|
|
|
$sql$, targetTable);
|
|
|
|
execute sql;
|
|
|
|
end if;
|
2022-09-19 20:43:14 +02:00
|
|
|
end; $$;
|
|
|
|
--//
|