From 8e2c3b671fa0e932764b5df64c8aad0c4dc8f19f Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Tim=20M=C3=B6hlmann?= Date: Wed, 6 Mar 2024 20:02:16 +0200 Subject: [PATCH] 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) --- internal/query/instance_by_domain.sql | 6 +++++- 1 file changed, 5 insertions(+), 1 deletion(-) diff --git a/internal/query/instance_by_domain.sql b/internal/query/instance_by_domain.sql index ffcf8a2f79..0c914df77b 100644 --- a/internal/query/instance_by_domain.sql +++ b/internal/query/instance_by_domain.sql @@ -1,6 +1,10 @@ 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), @@ -8,7 +12,7 @@ with domain as ( ) features from domain d cross join projections.system_features s - full outer join projections.instance_features2 i using (key, instance_id) + full outer join instance_features i using (instance_id, key) group by instance_id ) select