diff --git a/cmd/setup/59.sql b/cmd/setup/59.sql new file mode 100644 index 0000000000..579d6bd963 --- /dev/null +++ b/cmd/setup/59.sql @@ -0,0 +1,33 @@ +-- Add composite indexes to improve introspection endpoint performance +-- These indexes optimize the queries in introspection_client_by_id.sql + +-- Composite index for apps7_api_configs: (instance_id, client_id) +-- This speeds up the WHERE clause in the first part of UNION +CREATE INDEX CONCURRENTLY IF NOT EXISTS apps7_api_configs_instance_client_idx +ON projections.apps7_api_configs (instance_id, client_id); + +-- Composite index for apps7_oidc_configs: (instance_id, client_id) +-- This speeds up the WHERE clause in the second part of UNION +CREATE INDEX CONCURRENTLY IF NOT EXISTS apps7_oidc_configs_instance_client_idx +ON projections.apps7_oidc_configs (instance_id, client_id); + +-- Composite index for apps7: (instance_id, id, state) +-- This speeds up the JOIN condition from config to apps7 +CREATE INDEX CONCURRENTLY IF NOT EXISTS apps7_instance_id_state_idx +ON projections.apps7 (instance_id, id, state); + +-- Composite index for projects4: (instance_id, id, state) +-- This speeds up the JOIN condition from apps7 to projects4 +CREATE INDEX CONCURRENTLY IF NOT EXISTS projects4_instance_id_state_idx +ON projections.projects4 (instance_id, id, state); + +-- Composite index for orgs1: (instance_id, id, org_state) +-- This speeds up the JOIN condition from projects4 to orgs1 +CREATE INDEX CONCURRENTLY IF NOT EXISTS orgs1_instance_id_state_idx +ON projections.orgs1 (instance_id, id, org_state); + +-- Composite index for authn_keys2: (instance_id, identifier, expiration) +-- This speeds up the keys lookup with all filtering conditions +CREATE INDEX CONCURRENTLY IF NOT EXISTS authn_keys2_instance_identifier_expiration_idx +ON projections.authn_keys2 (instance_id, identifier, expiration) +WHERE expiration > current_timestamp; \ No newline at end of file diff --git a/internal/query/introspection_client_by_id.sql b/internal/query/introspection_client_by_id.sql index 1cc6baf9ad..83c57386ff 100644 --- a/internal/query/introspection_client_by_id.sql +++ b/internal/query/introspection_client_by_id.sql @@ -3,24 +3,25 @@ with config as ( from projections.apps7_api_configs where instance_id = $1 and client_id = $2 - union + union all select instance_id, app_id, client_id, client_secret, 'oidc' as app_type from projections.apps7_oidc_configs where instance_id = $1 and client_id = $2 ), keys as ( - select identifier as client_id, json_object_agg(id, encode(public_key, 'base64')) as public_keys + select $2::text as client_id, json_object_agg(id, encode(public_key, 'base64')) as public_keys from projections.authn_keys2 where $3 = true -- when argument is false, don't waste time on trying to query for keys. and instance_id = $1 and identifier = $2 and expiration > current_timestamp - group by identifier ) -select config.app_id, config.client_id, config.client_secret, config.app_type, apps.project_id, apps.resource_owner, p.project_role_assertion, keys.public_keys -from config -join projections.apps7 apps on apps.id = config.app_id and apps.instance_id = config.instance_id and apps.state = 1 -join projections.projects4 p on p.id = apps.project_id and p.instance_id = $1 and p.state = 1 -join projections.orgs1 o on o.id = p.resource_owner and o.instance_id = config.instance_id and o.org_state = 1 -left join keys on keys.client_id = config.client_id; +select c.app_id, c.client_id, c.client_secret, c.app_type, + a.project_id, a.resource_owner, p.project_role_assertion, + k.public_keys +from config c +join projections.apps7 a on a.id = c.app_id and a.instance_id = c.instance_id and a.state = 1 +join projections.projects4 p on p.id = a.project_id and p.instance_id = c.instance_id and p.state = 1 +join projections.orgs1 o on o.id = p.resource_owner and o.instance_id = c.instance_id and o.org_state = 1 +left join keys k on k.client_id = c.client_id and $3 = true;