zitadel/internal/query/instance_by_domain.sql
Tim Möhlmann 8e2c3b671f
fix(query): optimize instance by domain query (#7513)
fix(query): optimize instance by domain query

On zitadel cloud we noticed an increase in database CPU usage and slightly higher response times.
By analyzes we found that the instance by domain query was wrongly joining all instance_feature rows against all instances.
This PR adds an additional CTE to limit the join set to only the features that apply to the found instance.

The query was introduced with https://github.com/zitadel/zitadel/pull/7356 and part of the v2.47 release.

(cherry picked from commit 3af28d29d25b9f396c6129ad8d248df4cc3af8dc)
2024-03-07 11:44:31 +01:00

36 lines
970 B
SQL

with domain as (
select instance_id from projections.instance_domains
where domain = $1
), instance_features as (
select i.*
from domain d
join projections.instance_features2 i on d.instance_id = i.instance_id
), features as (
select instance_id, json_object_agg(
coalesce(i.key, s.key),
coalesce(i.value, s.value)
) features
from domain d
cross join projections.system_features s
full outer join instance_features i using (instance_id, key)
group by instance_id
)
select
i.id,
i.default_org_id,
i.iam_project_id,
i.console_client_id,
i.console_app_id,
i.default_language,
s.enable_iframe_embedding,
s.origins,
s.enable_impersonation,
l.audit_log_retention,
l.block,
f.features
from domain d
join projections.instances i on i.id = d.instance_id
left join projections.security_policies2 s on i.id = s.instance_id
left join projections.limits l on i.id = l.instance_id
left join features f on i.id = f.instance_id;