Files
zitadel/internal/query/introspection_client_by_id.sql

28 lines
1.2 KiB
MySQL
Raw Normal View History

with config as (
select instance_id, app_id, client_id, client_secret, 'api' as app_type
from projections.apps7_api_configs
where instance_id = $1
and client_id = $2
perf(oidc): introspection endpoint query optimization (#10392) The `/introspect` endpoint showed poor performance during v4 load testing due to an inefficient database query in `internal/query/introspection_client_by_id.sql`. This PR optimizes the query structure to significantly improve performance. ## Query Optimizations **UNION → UNION ALL**: Changed expensive `UNION` to `UNION ALL` since `client_id` is unique across both API and OIDC config tables, eliminating unnecessary deduplication overhead (30-50% improvement expected). **Simplified Keys CTE**: Optimized the keys lookup logic by using `$2::text as client_id` instead of `identifier as client_id` with `group by`, and added explicit `$3 = true` condition to the LEFT JOIN for better query planning. **Enhanced Readability**: Added consistent table aliases (c, a, p, o, k) for better maintainability. ## Benefits - **Zero-downtime deployment**: Uses existing database indexes, no schema changes required - **Secondary performance gains**: Other similar queries (`oidc_client_by_id.sql`, `userinfo_client_by_id.sql`) will also benefit from the optimizations - **Minimal code changes**: Only 13 lines added, 9 lines removed in the SQL query - **Backward compatible**: Same result set and API behavior The optimized query maintains the same functionality while providing significant performance improvements for the introspection endpoint under high concurrent load. Fixes #10389. <!-- START COPILOT CODING AGENT TIPS --> --- 💬 Share your feedback on Copilot coding agent for the chance to win a $200 gift card! Click [here](https://survey.alchemer.com/s3/8343779/Copilot-Coding-agent) to start the survey. --------- Co-authored-by: copilot-swe-agent[bot] <198982749+Copilot@users.noreply.github.com> Co-authored-by: muhlemmer <5411563+muhlemmer@users.noreply.github.com> Co-authored-by: Tim Möhlmann <tim+github@zitadel.com> (cherry picked from commit a28950661c30157a7c140bcc43887bc9508739eb)
2025-08-20 12:37:00 +00:00
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 (
perf(oidc): introspection endpoint query optimization (#10392) The `/introspect` endpoint showed poor performance during v4 load testing due to an inefficient database query in `internal/query/introspection_client_by_id.sql`. This PR optimizes the query structure to significantly improve performance. ## Query Optimizations **UNION → UNION ALL**: Changed expensive `UNION` to `UNION ALL` since `client_id` is unique across both API and OIDC config tables, eliminating unnecessary deduplication overhead (30-50% improvement expected). **Simplified Keys CTE**: Optimized the keys lookup logic by using `$2::text as client_id` instead of `identifier as client_id` with `group by`, and added explicit `$3 = true` condition to the LEFT JOIN for better query planning. **Enhanced Readability**: Added consistent table aliases (c, a, p, o, k) for better maintainability. ## Benefits - **Zero-downtime deployment**: Uses existing database indexes, no schema changes required - **Secondary performance gains**: Other similar queries (`oidc_client_by_id.sql`, `userinfo_client_by_id.sql`) will also benefit from the optimizations - **Minimal code changes**: Only 13 lines added, 9 lines removed in the SQL query - **Backward compatible**: Same result set and API behavior The optimized query maintains the same functionality while providing significant performance improvements for the introspection endpoint under high concurrent load. Fixes #10389. <!-- START COPILOT CODING AGENT TIPS --> --- 💬 Share your feedback on Copilot coding agent for the chance to win a $200 gift card! Click [here](https://survey.alchemer.com/s3/8343779/Copilot-Coding-agent) to start the survey. --------- Co-authored-by: copilot-swe-agent[bot] <198982749+Copilot@users.noreply.github.com> Co-authored-by: muhlemmer <5411563+muhlemmer@users.noreply.github.com> Co-authored-by: Tim Möhlmann <tim+github@zitadel.com> (cherry picked from commit a28950661c30157a7c140bcc43887bc9508739eb)
2025-08-20 12:37:00 +00:00
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
)
perf(oidc): introspection endpoint query optimization (#10392) The `/introspect` endpoint showed poor performance during v4 load testing due to an inefficient database query in `internal/query/introspection_client_by_id.sql`. This PR optimizes the query structure to significantly improve performance. ## Query Optimizations **UNION → UNION ALL**: Changed expensive `UNION` to `UNION ALL` since `client_id` is unique across both API and OIDC config tables, eliminating unnecessary deduplication overhead (30-50% improvement expected). **Simplified Keys CTE**: Optimized the keys lookup logic by using `$2::text as client_id` instead of `identifier as client_id` with `group by`, and added explicit `$3 = true` condition to the LEFT JOIN for better query planning. **Enhanced Readability**: Added consistent table aliases (c, a, p, o, k) for better maintainability. ## Benefits - **Zero-downtime deployment**: Uses existing database indexes, no schema changes required - **Secondary performance gains**: Other similar queries (`oidc_client_by_id.sql`, `userinfo_client_by_id.sql`) will also benefit from the optimizations - **Minimal code changes**: Only 13 lines added, 9 lines removed in the SQL query - **Backward compatible**: Same result set and API behavior The optimized query maintains the same functionality while providing significant performance improvements for the introspection endpoint under high concurrent load. Fixes #10389. <!-- START COPILOT CODING AGENT TIPS --> --- 💬 Share your feedback on Copilot coding agent for the chance to win a $200 gift card! Click [here](https://survey.alchemer.com/s3/8343779/Copilot-Coding-agent) to start the survey. --------- Co-authored-by: copilot-swe-agent[bot] <198982749+Copilot@users.noreply.github.com> Co-authored-by: muhlemmer <5411563+muhlemmer@users.noreply.github.com> Co-authored-by: Tim Möhlmann <tim+github@zitadel.com> (cherry picked from commit a28950661c30157a7c140bcc43887bc9508739eb)
2025-08-20 12:37:00 +00:00
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;