hs.hsadmin.ng/sql/recursive-cte-experiments-for-accessible-uuids.sql
Michael Hoennig 1eed0e9b21 introduce separate database-schemas base+rbac (#103)
Co-authored-by: Michael Hoennig <michael@hoennig.de>
Co-authored-by: Michael Hönnig <michael@hoennig.de>
Reviewed-on: #103
Reviewed-by: Marc Sandlus <marc.sandlus@hostsharing.net>
2024-09-16 15:36:37 +02:00

176 lines
6.5 KiB
PL/PgSQL

-- just a permanent playground to explore optimization of the central recursive CTE query for RBAC
select * from hs_statistics_v;
-- ========================================================
-- 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 (rbac.currentSubjectOrAssumedRolesUuids()))
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 (
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));
-- -------------------------------------------------------------------------------
-- performing several queries on the above view to determine average performance:
rollback transaction;
DO language plpgsql $$
DECLARE
start_time timestamp;
end_time timestamp;
total_time interval;
letter char(1);
BEGIN
start_time := clock_timestamp();
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;
FOR i IN 0..25 LOOP
letter := chr(i+ascii('a'));
PERFORM count(*) 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 letter || '%'
-- end of the business query example.
) AS timed;
END LOOP;
end_time := clock_timestamp();
total_time := end_time - start_time;
RAISE NOTICE 'average execution time: %', total_time/26;
END;
$$;
-- 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 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;
-- =============================================================================
-- extending the rbacobject table:
alter table rbacobject
-- just for performance testing, we would need a joined enum or a varchar(16) which would make it slow
add column type hshostingassettype;
-- and fill the type column with hs_hosting_asset types:
rollback transaction;
begin transaction;
call defineContext('setting rbacobject.type from hs_hosting_asset.type', null, 'superuser-alex@hostsharing.net');
UPDATE rbacobject
SET type = hs.type
FROM hs_hosting_asset hs
WHERE rbacobject.uuid = hs.uuid;
end transaction;
-- check the result:
select
(select count(*) as "total" from rbacobject),
(select count(*) as "not null" from rbacobject where type is not null),
(select count(*) as "null" from rbacobject where type is null);