document-potential-rbac-optimizations (#91)

Co-authored-by: Michael Hoennig <michael@hoennig.de>
Reviewed-on: #91
Reviewed-by: Timotheus Pokorra <timotheus.pokorra@hostsharing.net>
This commit is contained in:
Michael Hoennig 2024-09-03 09:37:49 +02:00
parent 0c9931d73a
commit 8b5cf8adc1
2 changed files with 256 additions and 135 deletions

View File

@ -355,6 +355,88 @@ In production, the `SELECT ... FROM hs_office_relation_rv` (No. 2) with about 0.
3. For the production code, we could use raw-entities for referenced entities, here usually RBAC SELECT permission is given anyway. 3. For the production code, we could use raw-entities for referenced entities, here usually RBAC SELECT permission is given anyway.
## The Problematically Huge Join
The origin problem was the expensive RBAC check for many SELECT queries.
This consists of two parts:
1. The recursive CTE query to determine which object's UUIDs are visible for the current subject.
This query itself takes currently about 250ms thus is no problem by itself as long as we only need it once per request.
2. Joining the result from 1. with the result if a business query.
The performance of the business query itself is no problem, for the join see the following explanations.
Superusers can see all objects (currently already over 90.000)
and even high level roles of customers with many hosting assets can see several thousand objects.
This is the one side of that problematic join.
The other side of that problematic is the result of the business query.
For example if a user wants to select all of their e-mail-addresses, that might easily half of the visible objects.
Thus, we would have a join of for example 5.000 x 2.500 rows, which is going to be slow.
As there are currently about 84.000 objects are hosting assets and 33.000 e-mail-addresses in our system,
for a superuser we would even run into an 84.0000 x 33.0000 join.
We found some solution approaches:
1. Getting rid of the `rbacrole` and `rbacpermission` table and only having implicit roles with implicit grants (OWNER->ADMIN->AGENT->TENENT->REFERRER) by comparison of ordered enum values and fixed permission assignments (e.g. OWENER->DELETE, ADMIN->UPDATE etc.). We could also get rid of the table `rbacreferece` if we enter users as business objects.
This should dramatically reduce the size of the table `rbackgrant` as well as the recusion levels.
But since we only apply this query once for each business query, that would only improve performance once we have way more objects in our system, but does not help our current problem.
It's quite some effort to implement even just a prototype, so we did not further explore this idea.
2. Adding the object type to the table `rbacObject` to reduce the size of the result of the recursive CTE query.
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()`.
In the end, we need the object UUIDs, though.
But if we start with the join of `rbacObject` with `rbacPermission`,
we need to forward the object UUIDs through the whole recursion.
This idea was not yet further explored.
### Adding The Object Type To The Table `rbacObject`
This optimization idea came from Michael Hierweck and was promising.
The idea is to reduce the size of the result of the recursive CTE query and maybe even speed up that query itself.
To evaluate this, I added a type column to the `rbacObject` table, initially as an enum hsHostingAssetType. Then I entered the type there for all rows from hs_hosting_asset. This means that 83,886 of 92,545 rows in `rbacobject` have a type set, leaving 8,659 without.
If we do this for other types (we currently have 1,271 relations and 927 booking items), it gets more complicated because they are different enum types. As varchar(16), we could lose performance again due to the higher storage space requirements.
But the performance gained is not particularly high anyway.
See the 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 |
|-----------------------------------------------------|------------------|---------------|
| currently (without type comparision in rbacobject): | ~3.30 - ~3.49 | ~0.23 |
| optimized (with type comparision in rbacobject): | ~2.99 - ~3.08 | ~0.21 |
As you can see, the query is no problem at all for normal customers (in the example, yours truly). With Hostsharing (D-1000000-hsh) it is quite slow.
Luckily this experiment also shows that it's not a big problem, having all hosting assets in the same database table.
Implementing this approach would be a bit difficult anyway, because we would need to transfer the type query parameter into the definition of the restricted view. We have not even the slightest idea how this could be done.
See the related queries in [recursive-cte-experiments-for-accessible-uuids.sql](../sql/recursive-cte-experiments-for-accessible-uuids.sql). They might have changed independently since this document was written, but you can still check out the old version from git.
### Rearranging the Parts of the CTE-Query
I also moved the function call which determines into its own WITH-section, with no improvement.
Experimentally I moved the business condition into the CTE SELECT, also with no improvement.
Such rearrangements seem to be successfully done by the PostgreSQL query optimizer.
## Summary ## Summary
### What we did Achieve? ### What we did Achieve?
@ -363,13 +445,19 @@ In a first step, the total import runtime for office entities was reduced from a
In a second step, we reduced the import of booking- and hosting-assets from about 100min (not counting the required office entities) to 5min. In a second step, we reduced the import of booking- and hosting-assets from about 100min (not counting the required office entities) to 5min.
### What Helped? ### What did not Help?
Rearranging the CTE query by extracting parts into WITH-clauses did not improve the performance.
Surprisingly little performance gain (<10% improvement) came from reducing the result of the CTE query by moving the hosting asset type into RBAC-system and using it in the inner SELECT query instead of in the outer SELECT query of the application side.
### What did Help?
Merging the recursive CTE query to determine the RBAC SELECT-permission, made it more clear which business-queries take the time. Merging the recursive CTE query to determine the RBAC SELECT-permission, made it more clear which business-queries take the time.
Avoiding EAGER-loading where not necessary, reduced the total runtime of the import to about the half. Avoiding EAGER-loading where not necessary, reduced the total runtime of the import to about the half.
The major improvement came from using direct INSERT statements, which then also bypassed the RBAC SELECT permission checks. The major improvement came from using direct INSERT statements, which avoided some SELECT statements unnecessarily generated by the EntityManager and also completely bypassed the RBAC SELECT permission checks.
### What Still Has To Be Done? ### What Still Has To Be Done?

View File

@ -1,36 +1,24 @@
-- just a permanent playground to explore optimization of the central recursive CTE query for RBAC -- just a permanent playground to explore optimization of the central recursive CTE query for RBAC
rollback transaction; select * from hs_statistics_view;
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;
-- ========================================================
-- 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;
rollback transaction; create view hs_hosting_asset_example_gv as
begin transaction; with recursive
SET TRANSACTION READ ONLY; recursive_grants as (
call defineContext('performance testing', null, 'superuser-alex@hostsharing.net', select distinct rbacgrants.descendantuuid,
'hs_booking_project#D-1000000-hshdefaultproject:ADMIN');
-- 'hs_booking_project#D-1000300-mihdefaultproject:ADMIN');
with accessible_hs_hosting_asset_uuids as
(with recursive
recursive_grants as
(select distinct rbacgrants.descendantuuid,
rbacgrants.ascendantuuid, rbacgrants.ascendantuuid,
1 as level, 1 as level,
true true
from rbacgrants from rbacgrants
where rbacgrants.assumed where (rbacgrants.ascendantuuid = any (currentsubjectsuuids()))
and (rbacgrants.ascendantuuid = any (currentsubjectsuuids())) and rbacgrants.assumed
union all union all
select distinct g.descendantuuid, select distinct g.descendantuuid,
g.ascendantuuid, g.ascendantuuid,
@ -38,105 +26,150 @@ with accessible_hs_hosting_asset_uuids as
assertTrue(grants.level < 22, 'too many grant-levels: ' || grants.level) assertTrue(grants.level < 22, 'too many grant-levels: ' || grants.level)
from rbacgrants g from rbacgrants g
join recursive_grants grants on grants.descendantuuid = g.ascendantuuid join recursive_grants grants on grants.descendantuuid = g.ascendantuuid
where g.assumed), where g.assumed
grant_count AS (
SELECT COUNT(*) AS grant_count FROM recursive_grants
), ),
count_check as (select assertTrue((select count(*) as grant_count from recursive_grants) < 300000, grant_count as (
'too many grants for current subjects: ' || (select count(*) as grant_count from recursive_grants)) select count(*) as grant_count from recursive_grants
as valid) ),
select distinct perm.objectuuid 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 from recursive_grants
join rbacpermission perm on recursive_grants.descendantuuid = perm.uuid join rbacpermission perm on recursive_grants.descendantuuid = perm.uuid
join rbacobject obj on obj.uuid = perm.objectuuid join rbacobject obj on obj.uuid = perm.objectuuid
join count_check cc on cc.valid join count_check cc on cc.valid
where obj.objecttable::text = 'hs_hosting_asset'::text) where obj.objecttable::text = 'hs_hosting_asset'::text
select type, -- with/without this type condition
-- count(*) as counter -- and obj.type = 'EMAIL_ADDRESS'::hshostingassettype
target.uuid, and obj.type = 'EMAIL_ADDRESS'::hshostingassettype
-- target.version,
-- target.bookingitemuuid,
-- target.type,
-- target.parentassetuuid,
-- target.assignedtoassetuuid,
target.identifier,
target.caption
-- target.config,
-- target.alarmcontactuuid
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 in ('EMAIL_ADDRESS', 'CLOUD_SERVER', 'MANAGED_SERVER', 'MANAGED_WEBSPACE')
-- and target.type = 'EMAIL_ADDRESS'
-- order by target.identifier;
-- group by type
-- order by counter desc
; ;
commit transaction;
-- -----------------------------------------------------------------------------------------------
-- A query just on the above view, only determining visible objects, no JOIN with business data:
rollback transaction; rollback transaction;
begin transaction; begin transaction;
SET TRANSACTION READ ONLY; CALL defineContext('performance testing', null, 'superuser-alex@hostsharing.net',
call defineContext('performance testing', null, 'superuser-alex@hostsharing.net',
'hs_booking_project#D-1000000-hshdefaultproject:ADMIN'); 'hs_booking_project#D-1000000-hshdefaultproject:ADMIN');
-- 'hs_booking_project#D-1000300-mihdefaultproject:ADMIN'); -- 'hs_booking_project#D-1000300-mihdefaultproject:ADMIN');
SET TRANSACTION READ ONLY;
EXPLAIN ANALYZE select * from hs_hosting_asset_example_gv;
end transaction ;
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 -- 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.
-- Recursive case: Find the next step in the path drop view if exists hs_hosting_asset_example_rv;
select c.ascendantuuid, create view hs_hosting_asset_example_rv as
c.descendantuuid, with accessible_hs_hosting_asset_uuids as (
p.path_so_far || c.ascendantuuid select * from hs_hosting_asset_example_gv
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 target.*
select distinct array_length(path_so_far, 1), from hs_hosting_asset target
path_so_far || descendantuuid as full_path where (target.uuid in (select accessible_hs_hosting_asset_uuids.objectuuid
from path from accessible_hs_hosting_asset_uuids));
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 -- performing several queries on the above view to determine average performance:
where descendantuuid in (
select uuid rollback transaction;
from rbacrole DO language plpgsql $$
where objectuuid in ( DECLARE
select uuid start_time timestamp;
from hs_hosting_asset end_time timestamp;
-- where type = 'DOMAIN_MBOX_SETUP' total_time interval;
-- and identifier = 'example.org|MBOX' 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' where type = 'EMAIL_ADDRESS'
and identifier='test@example.org' and identifier like letter || '%'
)) -- end of the business query example.
)
select * from rbacgrants_ev gev where exists ( select uuid from grants where gev.uuid = grants.uuid ); ) 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);