-- just a permanent playground to explore optimization of the central recursive CTE query for RBAC select * from hs_statistics_view; rollback transaction; begin transaction; SET TRANSACTION READ ONLY; call defineContext('performance testing', null, 'superuser-alex@hostsharing.net', 'hs_booking_project#D-1000000-hshdefaultproject:ADMIN'); -- 'hs_booking_project#D-1000300-mihdefaultproject:ADMIN'); select count(type) as counter, type from hs_hosting_asset_rv group by type order by counter desc; commit 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..0 LOOP letter := chr(i+ascii('a')); perform count(*) from ( -- start of VIEW hs_hosting_asset_rv: 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 ) -- end of VIEW hs_hosting_asset_rv. -- start of business query, usually based on a view according to the above CTE query: select type, target.uuid, target.identifier, target.caption from hs_hosting_asset target where (target.uuid in (select accessible_hs_hosting_asset_uuids.objectuuid from accessible_hs_hosting_asset_uuids)) and target.type = 'EMAIL_ADDRESS' and identifier like letter || '%' -- end of business query. ) 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: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 -- ============================================================================= rollback transaction; begin transaction; SET TRANSACTION READ ONLY; call defineContext('performance testing', null, 'superuser-alex@hostsharing.net', 'hs_booking_project#D-1000000-hshdefaultproject:ADMIN'); -- 'hs_booking_project#D-1000300-mihdefaultproject:ADMIN'); with one_path as (with recursive path as ( -- Base case: Start with the row where ascending equals the starting UUID select ascendantuuid, descendantuuid, array [ascendantuuid] as path_so_far from rbacgrants where ascendantuuid = any (currentsubjectsuuids()) union all -- Recursive case: Find the next step in the path select c.ascendantuuid, c.descendantuuid, p.path_so_far || c.ascendantuuid from rbacgrants c inner join path p on c.ascendantuuid = p.descendantuuid where c.ascendantuuid != all (p.path_so_far) -- Prevent cycles ) -- Final selection: Output all paths that reach the target UUID select distinct array_length(path_so_far, 1), path_so_far || descendantuuid as full_path from path join rbacpermission perm on perm.uuid = path.descendantuuid join hs_hosting_asset ha on ha.uuid = perm.objectuuid -- JOIN rbacrole_ev re on re.uuid = any(path_so_far) where ha.identifier = 'vm1068' order by array_length(path_so_far, 1) limit 1 ) select ( SELECT ARRAY_AGG(re.roleidname ORDER BY ord.idx) FROM UNNEST(one_path.full_path) WITH ORDINALITY AS ord(uuid, idx) JOIN rbacrole_ev re ON ord.uuid = re.uuid ) AS name_array from one_path; commit transaction; with grants as ( select uuid from rbacgrants where descendantuuid in ( select uuid from rbacrole where objectuuid in ( select uuid from hs_hosting_asset -- where type = 'DOMAIN_MBOX_SETUP' -- and identifier = 'example.org|MBOX' where type = 'EMAIL_ADDRESS' and identifier='test@example.org' )) ) select * from rbacgrants_ev gev where exists ( select uuid from grants where gev.uuid = grants.uuid ); 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; 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; select (select count(*) from hs_office_relation) as "relation", (select count(*) from hs_booking_item) as "booking item"; 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);