better formatted SQL and documentation of performance analysis for SELECT

This commit is contained in:
Michael Hoennig 2024-08-22 17:39:54 +02:00
parent 6dd20db238
commit 897ab191c7
2 changed files with 80 additions and 138 deletions

View File

@ -380,13 +380,21 @@ 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 reduce
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.
### Adding The Object Type To The Table `rbacObject`
This optimization idea came from Michael Hierweck.
Its idea is to reduce the size of the result of the recursive CTE query and maybe even speed up that query itself.
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.
@ -403,7 +411,11 @@ joined with business query for all `'EMAIL_ADDRESSES'`:
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.
My optimization, which is not easy to try out, would only improve the part of the recursive CTE query. This is not necessary at the moment, but perhaps if we grow significantly.
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.
## Summary

View File

@ -2,39 +2,11 @@
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:
-- An example for a restricted view (_rv) as generated by our RBAC system:
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
@ -70,27 +42,48 @@ BEGIN
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
select target.*
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'
from accessible_hs_hosting_asset_uuids));
-- end of the example view.
-- -------------------------------------------------------------------------------
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 business query.
) timed;
-- 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;
$$;
@ -103,75 +96,14 @@ $$;
-- =============================================================================
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 );
-- 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');
@ -183,9 +115,7 @@ call defineContext('setting rbacobject.type from hs_hosting_asset.type', null, '
end transaction;
select
(select count(*) from hs_office_relation) as "relation",
(select count(*) from hs_booking_item) as "booking item";
-- check the result:
select
(select count(*) as "total" from rbacobject),