zitadel/internal/migration/count_trigger.sql
Tim Möhlmann b9c1cdf4ad
feat(projections): resource counters (#9979)
# Which Problems Are Solved

Add the ability to keep track of the current counts of projection
resources. We want to prevent calling `SELECT COUNT(*)` on tables, as
that forces a full scan and sudden spikes of DB resource uses.

# How the Problems Are Solved

- A resource_counts table is added
- Triggers that increment and decrement the counted values on inserts
and deletes
- Triggers that delete all counts of a table when the source table is
TRUNCATEd. This is not in the business logic, but prevents wrong counts
in case someone want to force a re-projection.
- Triggers that delete all counts if the parent resource is deleted
- Script to pre-populate the resource_counts table when a new source
table is added.

The triggers are reusable for any type of resource, in case we choose to
add more in the future.
Counts are aggregated by a given parent. Currently only `instance` and
`organization` are defined as possible parent. This can later be
extended to other types, such as `project`, should the need arise.

I deliberately chose to use `parent_id` to distinguish from the
de-factor `resource_owner` which is usually an organization ID. For
example:

- For users the parent is an organization and the `parent_id` matches
`resource_owner`.
- For organizations the parent is an instance, but the `resource_owner`
is the `org_id`. In this case the `parent_id` is the `instance_id`.
- Applications would have a similar problem, where the parent is a
project, but the `resource_owner` is the `org_id`


# Additional Context

Closes https://github.com/zitadel/zitadel/issues/9957
2025-06-03 14:15:30 +00:00

44 lines
1.1 KiB
SQL

{{ define "count_trigger" -}}
CREATE OR REPLACE TRIGGER count_{{ .Resource }}
AFTER INSERT OR DELETE
ON {{ .Table }}
FOR EACH ROW
EXECUTE FUNCTION projections.count_resource(
'{{ .ParentType }}',
'{{ .InstanceIDColumn }}',
'{{ .ParentIDColumn }}',
'{{ .Resource }}'
);
CREATE OR REPLACE TRIGGER truncate_{{ .Resource }}_counts
AFTER TRUNCATE
ON {{ .Table }}
FOR EACH STATEMENT
EXECUTE FUNCTION projections.delete_table_counts();
-- Prevent inserts and deletes while we populate the counts.
LOCK TABLE {{ .Table }} IN SHARE MODE;
-- Populate the resource counts for the existing data in the table.
INSERT INTO projections.resource_counts(
instance_id,
table_name,
parent_type,
parent_id,
resource_name,
amount
)
SELECT
{{ .InstanceIDColumn }},
'{{ .Table }}',
'{{ .ParentType }}',
{{ .ParentIDColumn }},
'{{ .Resource }}',
COUNT(*) AS amount
FROM {{ .Table }}
GROUP BY ({{ .InstanceIDColumn }}, {{ .ParentIDColumn }})
ON CONFLICT (instance_id, table_name, parent_type, parent_id) DO
UPDATE SET updated_at = now(), amount = EXCLUDED.amount;
{{- end -}}