Files
zitadel/cmd/setup/63.sql
Livio Spring 0753ed2d6b feat(service ping): add additional resource counts (#10621)
# Which Problems Are Solved

Using the service ping, we want to have some additional insights to how
zitadel is configured. The current resource count report contains
already some amount of configured policies, such as the login_policy.
But we do not know if for example MFA is enforced.

# How the Problems Are Solved

- Added the following counts to the report:
  - service users per organization
  - MFA enforcements (though login policy)
  - Notification policies with password change option enabled
  - SCIM provisioned users (using user metadata)
- Since all of the above are conditional based on at least a column
inside a projection, a new `migration.CountTriggerConditional` has been
added, where a condition (column values) and an option to track updates
on that column should be considered for the count.
- For this to be possible, the following changes had to be made to the
existing sql resources:
- the `resource_name` has been added to unique constraint on the
`projection.resource_counts` table
- triggers have been added / changed to individually track `INSERT`,
`UPDATE`(s) and `DELETE` and be able to handle conditions
- an optional argument has been added to the
`projections.count_resource()` function to allow providing the
information to `UP` or `DOWN` count the resource on an update.

# Additional Changes

None

# Additional Context

- partially solves #10244 (reporting audit log retention limit will be
handled in #10245 directly)
- backport to v4.x

(cherry picked from commit 2dbe21fb30)
2025-09-15 08:30:02 +02:00

58 lines
2.2 KiB
PL/PgSQL

ALTER TABLE projections.resource_counts
DROP CONSTRAINT resource_counts_instance_id_parent_type_parent_id_table_nam_key;
ALTER TABLE projections.resource_counts
ADD CONSTRAINT unique_resource
UNIQUE (instance_id, parent_type, parent_id, table_name, resource_name);
-- count_resource is a trigger function which increases or decreases the count of a resource.
-- When creating the trigger the following required arguments (TG_ARGV) can be passed:
-- 1. The type of the parent
-- 2. The column name of the instance id
-- 3. The column name of the owner id
-- 4. The name of the resource
-- 5. (optional) 'UP' or 'DOWN' to indicate if an UPDATE should count up or down.
CREATE OR REPLACE FUNCTION projections.count_resource()
RETURNS trigger
LANGUAGE 'plpgsql' VOLATILE
AS $$
DECLARE
-- trigger variables
tg_table_name TEXT := TG_TABLE_SCHEMA || '.' || TG_TABLE_NAME;
tg_parent_type TEXT := TG_ARGV[0];
tg_instance_id_column TEXT := TG_ARGV[1];
tg_parent_id_column TEXT := TG_ARGV[2];
tg_resource_name TEXT := TG_ARGV[3];
tg_update_method TEXT := coalesce(TG_ARGV[4], '');
tg_instance_id TEXT;
tg_parent_id TEXT;
select_ids TEXT := format('SELECT ($1).%I, ($1).%I', tg_instance_id_column, tg_parent_id_column);
BEGIN
IF (TG_OP = 'INSERT' OR (TG_OP = 'UPDATE' and tg_update_method = 'UP')) THEN
EXECUTE select_ids INTO tg_instance_id, tg_parent_id USING NEW;
INSERT INTO projections.resource_counts(instance_id, table_name, parent_type, parent_id, resource_name)
VALUES (tg_instance_id, tg_table_name, tg_parent_type, tg_parent_id, tg_resource_name)
ON CONFLICT (instance_id, table_name, parent_type, parent_id, resource_name) DO
UPDATE SET updated_at = now(), amount = projections.resource_counts.amount + 1;
RETURN NEW;
ELSEIF (TG_OP = 'DELETE' OR (TG_OP = 'UPDATE' and tg_update_method = 'DOWN')) THEN
EXECUTE select_ids INTO tg_instance_id, tg_parent_id USING OLD;
UPDATE projections.resource_counts
SET updated_at = now(), amount = amount - 1
WHERE instance_id = tg_instance_id
AND table_name = tg_table_name
AND parent_type = tg_parent_type
AND parent_id = tg_parent_id
AND resource_name = tg_resource_name
AND amount > 0; -- prevent check failure on negative amount.
RETURN OLD;
END IF;
END
$$;