document-potential-rbac-optimizations #91

Merged
hsh-michaelhoennig merged 6 commits from document-potential-rbac-optimizations into master 2024-09-03 09:37:50 +02:00
2 changed files with 97 additions and 38 deletions
Showing only changes of commit cad8b475f8 - Show all commits

View File

@ -390,6 +390,14 @@ We found some solution approaches:
See chapter below.
3. Inverting the recursion of the CTE-query, combined with the type condition.
Instead of starting the recursion with `currentsubjectsuuids()`,
we could start it with the target table name and row-type,
then recurse down to the `currentsubjectsuuids()`.
This idea was not yet explored.
### Adding The Object Type To The Table `rbacObject`
@ -423,7 +431,7 @@ I also moved the function call which determines into its own WITH-section, with
Experimentally I moved the business condition into the CTE SELECT, also with no improvement.
Such rearrangements seem to be sucessfully done by the PostgreSQL query optimizer.
Such rearrangements seem to be successfully done by the PostgreSQL query optimizer.
## Summary

View File

@ -4,52 +4,80 @@ select * from hs_statistics_view;
-- ========================================================
-- An example for a restricted view (_rv) as generated by our RBAC system:
-- This is the extracted recursive CTE query to determine the visible object UUIDs of a single table
-- (and optionally the hosting-asset-type) as a separate VIEW.
-- In the generated code this is part of the hs_hosting_asset_rv VIEW.
drop view if exists hs_hosting_asset_example_gv;
create view hs_hosting_asset_example_gv as
with recursive
recursive_grants as (
select distinct rbacgrants.descendantuuid,
rbacgrants.ascendantuuid,
1 as level,
true
from rbacgrants
where (rbacgrants.ascendantuuid = any (currentsubjectsuuids()))
and rbacgrants.assumed
union all
select distinct g.descendantuuid,
g.ascendantuuid,
grants.level + 1 as level,
assertTrue(grants.level < 22, 'too many grant-levels: ' || grants.level)
from rbacgrants g
join recursive_grants grants on grants.descendantuuid = g.ascendantuuid
where g.assumed
),
grant_count as (
select count(*) as grant_count from recursive_grants
),
count_check as (
select assertTrue((select grant_count from grant_count) < 600000,
'too many grants for current subjects: ' || (select grant_count from grant_count)) as valid
)
select distinct perm.objectuuid
from recursive_grants
join rbacpermission perm on recursive_grants.descendantuuid = perm.uuid
join rbacobject obj on obj.uuid = perm.objectuuid
join count_check cc on cc.valid
where obj.objecttable::text = 'hs_hosting_asset'::text
-- with/without this type condition
-- and obj.type = 'EMAIL_ADDRESS'::hshostingassettype
and obj.type = 'EMAIL_ADDRESS'::hshostingassettype
;
-- -----------------------------------------------------------------------------------------------
-- A query just on the above view, only determining visible objects, no JOIN with business data:
rollback transaction;
begin transaction;
CALL defineContext('performance testing', null, 'superuser-alex@hostsharing.net',
'hs_booking_project#D-1000000-hshdefaultproject:ADMIN');
-- 'hs_booking_project#D-1000300-mihdefaultproject:ADMIN');
SET TRANSACTION READ ONLY;
EXPLAIN ANALYZE select * from hs_hosting_asset_example_gv;
end transaction ;
-- ========================================================
-- An example for a restricted view (_rv) similar to the one generated by our RBAC system,
-- but using the above separate VIEW to determine the visible objects.
drop view if exists hs_hosting_asset_example_rv;
create view hs_hosting_asset_example_rv as
with accessible_hs_hosting_asset_uuids as (
with recursive
recursive_grants as (
select distinct rbacgrants.descendantuuid,
rbacgrants.ascendantuuid,
1 as level,
true
from rbacgrants
where (rbacgrants.ascendantuuid = any (currentsubjectsuuids()))
and rbacgrants.assumed
union all
select distinct g.descendantuuid,
g.ascendantuuid,
grants.level + 1 as level,
assertTrue(grants.level < 22, 'too many grant-levels: ' || grants.level)
from rbacgrants g
join recursive_grants grants on grants.descendantuuid = g.ascendantuuid
where g.assumed
),
grant_count as (
select count(*) as grant_count from recursive_grants
),
count_check as (
select assertTrue((select grant_count from grant_count) < 600000,
'too many grants for current subjects: ' || (select grant_count from grant_count)) as valid
)
select distinct perm.objectuuid
from recursive_grants
join rbacpermission perm on recursive_grants.descendantuuid = perm.uuid
join rbacobject obj on obj.uuid = perm.objectuuid
join count_check cc on cc.valid
where obj.objecttable::text = 'hs_hosting_asset'::text
and obj.type = 'EMAIL_ADDRESS'::hshostingassettype -- with/without this type condition
select * from hs_hosting_asset_example_gv
)
select target.*
from hs_hosting_asset target
where (target.uuid in (select accessible_hs_hosting_asset_uuids.objectuuid
from accessible_hs_hosting_asset_uuids));
-- end of the example view.
-- -------------------------------------------------------------------------------
-- performing several queries on the above view to determine average performance:
rollback transaction;
DO language plpgsql $$
DECLARE
@ -90,9 +118,32 @@ $$;
-- average seconds per recursive CTE select as role 'hs_hosting_asset:<DEBITOR>defaultproject:ADMIN'
-- joined with business query for all 'EMAIL_ADDRESSES':
-- D-1000000-hsh D-1000300-mih
-- - without type comparision in rbacobject: ~3.30 - ~3.49 ~0.23
-- - with type comparision in rbacobject: ~2.99 - ~3.08 ~0.21
-- - without type comparison in rbacobject: ~3.30 - ~3.49 ~0.23
-- - with type comparison in rbacobject: ~2.99 - ~3.08 ~0.21
-- -------------------------------------------------------------------------------
-- and a single query, so EXPLAIN can be used
rollback transaction;
begin transaction;
CALL defineContext('performance testing', null, 'superuser-alex@hostsharing.net',
'hs_booking_project#D-1000000-hshdefaultproject:ADMIN');
-- 'hs_booking_project#D-1000300-mihdefaultproject:ADMIN');
SET TRANSACTION READ ONLY;
EXPLAIN SELECT * from (
-- An example for a business query based on the view:
select type, uuid, identifier, caption
from hs_hosting_asset_example_rv
where type = 'EMAIL_ADDRESS'
-- and identifier like 'b%'
-- end of the business query example.
) ha;
end transaction;
-- =============================================================================