feat(permissions): project member permission filter (#9757)

# Which Problems Are Solved

Add the possibility to filter project resources based on project member
roles.

# How the Problems Are Solved

Extend and refactor existing Pl/PgSQL functions to implement the
following:

- Solve O(n) complexity in returned resources IDs by returning a boolean
filter for instance level permissions.
- Individually permitted orgs are returned only if there was no instance
permission
- Individually permitted projects are returned only if there was no
instance permission
- Because of the multiple filter terms, use `INNER JOIN`s instead of
`WHERE` clauses.

# Additional Changes

- system permission function no longer query the organization view and
therefore can be `immutable`, giving big performance benefits for
frequently reused system users. (like our hosted login in Zitadel cloud)
- The permitted org and project functions are now defined as `stable`
because the don't modify on-disk data. This might give a small
performance gain
- The Pl/PgSQL functions are now tested using Go unit tests.

# Additional Context

- Depends on https://github.com/zitadel/zitadel/pull/9677
- Part of https://github.com/zitadel/zitadel/issues/9188
- Closes https://github.com/zitadel/zitadel/issues/9190
This commit is contained in:
Tim Möhlmann
2025-04-22 11:42:59 +03:00
committed by GitHub
parent 618143931b
commit 658ca3606b
18 changed files with 1403 additions and 225 deletions

View File

@@ -1,23 +1,28 @@
DROP FUNCTION IF EXISTS eventstore.check_system_user_perms;
DROP FUNCTION IF EXISTS eventstore.get_system_permissions;
DROP TYPE IF EXISTS eventstore.project_grant;
/*
Function get_system_permissions unpacks an JSON array of system member permissions,
into a table format. Each array entry maps to one row representing a membership which
contained the req_permission.
[
{
"member_type": "IAM",
"aggregate_id": "310716990375453665",
"object_id": "",
"permissions": ["iam.read", "iam.write", "iam.policy.read"]
},
...
]
| member_type | aggregate_id | object_id |
| "IAM" | "310716990375453665" | null |
*/
CREATE OR REPLACE FUNCTION eventstore.get_system_permissions(
permissions_json JSONB
/*
[
{
"member_type": "System",
"aggregate_id": "",
"object_id": "",
"permissions": ["iam.read", "iam.write", "iam.polic.read"]
},
{
"member_type": "IAM",
"aggregate_id": "310716990375453665",
"object_id": "",
"permissions": ["iam.read", "iam.write", "iam.polic.read"]
}
]
*/
, permm TEXT
)
RETURNS TABLE (
@@ -25,7 +30,7 @@ RETURNS TABLE (
aggregate_id TEXT,
object_id TEXT
)
LANGUAGE 'plpgsql'
LANGUAGE 'plpgsql' IMMUTABLE
AS $$
BEGIN
RETURN QUERY
@@ -37,7 +42,73 @@ BEGIN
permission
FROM jsonb_array_elements(permissions_json) AS perm
CROSS JOIN jsonb_array_elements_text(perm->'permissions') AS permission) AS res
WHERE res. permission= permm;
WHERE res.permission = permm;
END;
$$;
/*
Type project_grant is composite identifier using its project and grant IDs.
*/
CREATE TYPE eventstore.project_grant AS (
project_id TEXT -- mapped from a permission's aggregate_id
, grant_id TEXT -- mapped from a permission's object_id
);
/*
Function check_system_user_perms uses system member permissions to establish
on which organization, project or project grant the user has the requested permission.
The permission can also apply to the complete instance when a IAM membership matches
the requested instance ID, or through system membership.
See eventstore.get_system_permissions() on the supported JSON format.
*/
CREATE OR REPLACE FUNCTION eventstore.check_system_user_perms(
system_user_perms JSONB
, req_instance_id TEXT
, perm TEXT
, instance_permitted OUT BOOLEAN
, org_ids OUT TEXT[]
, project_ids OUT TEXT[]
, project_grants OUT eventstore.project_grant[]
)
LANGUAGE 'plpgsql' IMMUTABLE
AS $$
BEGIN
-- make sure no nulls are returned
instance_permitted := FALSE;
org_ids := ARRAY[]::TEXT[];
project_ids := ARRAY[]::TEXT[];
project_grants := ARRAY[]::eventstore.project_grant[];
DECLARE
p RECORD;
BEGIN
FOR p IN SELECT member_type, aggregate_id, object_id
FROM eventstore.get_system_permissions(system_user_perms, perm)
LOOP
CASE p.member_type
WHEN 'System' THEN
instance_permitted := TRUE;
RETURN;
WHEN 'IAM' THEN
IF p.aggregate_id = req_instance_id THEN
instance_permitted := TRUE;
RETURN;
END IF;
WHEN 'Organization' THEN
IF p.aggregate_id != '' THEN
org_ids := array_append(org_ids, p.aggregate_id);
END IF;
WHEN 'Project' THEN
IF p.aggregate_id != '' THEN
project_ids := array_append(project_ids, p.aggregate_id);
END IF;
WHEN 'ProjectGrant' THEN
IF p.aggregate_id != '' THEN
project_grants := array_append(project_grants, ROW(p.aggregate_id, p.object_id)::eventstore.project_grant);
END IF;
END CASE;
END LOOP;
END;
END;
$$;

View File

@@ -1,144 +1,71 @@
DROP FUNCTION IF EXISTS eventstore.check_system_user_perms;
DROP FUNCTION IF EXISTS eventstore.permitted_orgs;
DROP FUNCTION IF EXISTS eventstore.find_roles;
CREATE OR REPLACE FUNCTION eventstore.check_system_user_perms(
system_user_perms JSONB
-- find_roles finds all roles containing the permission
CREATE OR REPLACE FUNCTION eventstore.find_roles(
req_instance_id TEXT
, perm TEXT
, filter_orgs TEXT
, org_ids OUT TEXT[]
, roles OUT TEXT[]
)
LANGUAGE 'plpgsql'
LANGUAGE 'plpgsql' STABLE
AS $$
BEGIN
WITH found_permissions(member_type, aggregate_id, object_id ) AS (
SELECT * FROM eventstore.get_system_permissions(
system_user_perms,
perm)
)
SELECT array_agg(DISTINCT o.org_id) INTO org_ids
FROM eventstore.instance_orgs o, found_permissions
WHERE
CASE WHEN (SELECT TRUE WHERE found_permissions.member_type = 'System' LIMIT 1) THEN
TRUE
WHEN (SELECT TRUE WHERE found_permissions.member_type = 'IAM' LIMIT 1) THEN
-- aggregate_id not present
CASE WHEN (SELECT TRUE WHERE '' = ANY (
(
SELECT array_agg(found_permissions.aggregate_id)
FROM found_permissions
WHERE member_type = 'IAM'
GROUP BY member_type
LIMIT 1
)::TEXT[])) THEN
TRUE
-- aggregate_id is present
ELSE
o.instance_id = ANY (
(
SELECT array_agg(found_permissions.aggregate_id)
FROM found_permissions
WHERE member_type = 'IAM'
GROUP BY member_type
LIMIT 1
)::TEXT[])
END
WHEN (SELECT TRUE WHERE found_permissions.member_type = 'Organization' LIMIT 1) THEN
-- aggregate_id not present
CASE WHEN (SELECT TRUE WHERE '' = ANY (
(
SELECT array_agg(found_permissions.aggregate_id)
FROM found_permissions
WHERE member_type = 'Organization'
GROUP BY member_type
LIMIT 1
)::TEXT[])) THEN
TRUE
-- aggregate_id is present
ELSE
o.org_id = ANY (
(
SELECT array_agg(found_permissions.aggregate_id)
FROM found_permissions
WHERE member_type = 'Organization'
GROUP BY member_type
LIMIT 1
)::TEXT[])
END
END
AND
CASE WHEN filter_orgs != ''
THEN o.org_id IN (filter_orgs)
ELSE TRUE END
LIMIT 1;
SELECT array_agg(rp.role) INTO roles
FROM eventstore.role_permissions rp
WHERE rp.instance_id = req_instance_id
AND rp.permission = perm;
END;
$$;
DROP FUNCTION IF EXISTS eventstore.permitted_orgs;
CREATE OR REPLACE FUNCTION eventstore.permitted_orgs(
instanceId TEXT
, userId TEXT
req_instance_id TEXT
, auth_user_id TEXT
, system_user_perms JSONB
, perm TEXT
, filter_orgs TEXT
, filter_org TEXT
, instance_permitted OUT BOOLEAN
, org_ids OUT TEXT[]
)
LANGUAGE 'plpgsql'
LANGUAGE 'plpgsql' STABLE
AS $$
BEGIN
-- if system user
IF system_user_perms IS NOT NULL THEN
org_ids := eventstore.check_system_user_perms(system_user_perms, perm, filter_orgs);
-- if human/machine user
ELSE
-- if system user
IF system_user_perms IS NOT NULL THEN
SELECT p.instance_permitted, p.org_ids INTO instance_permitted, org_ids
FROM eventstore.check_system_user_perms(system_user_perms, req_instance_id, perm) p;
RETURN;
END IF;
-- if human/machine user
DECLARE
matched_roles TEXT[]; -- roles containing permission
BEGIN
SELECT array_agg(rp.role) INTO matched_roles
FROM eventstore.role_permissions rp
WHERE rp.instance_id = instanceId
AND rp.permission = perm;
-- First try if the permission was granted thru an instance-level role
DECLARE
has_instance_permission bool;
BEGIN
SELECT true INTO has_instance_permission
FROM eventstore.instance_members im
WHERE im.role = ANY(matched_roles)
AND im.instance_id = instanceId
AND im.user_id = userId
LIMIT 1;
matched_roles TEXT[] := eventstore.find_roles(req_instance_id, perm);
BEGIN
-- First try if the permission was granted thru an instance-level role
SELECT true INTO instance_permitted
FROM eventstore.instance_members im
WHERE im.role = ANY(matched_roles)
AND im.instance_id = req_instance_id
AND im.user_id = auth_user_id
LIMIT 1;
IF has_instance_permission THEN
-- Return all organizations or only those in filter_orgs
SELECT array_agg(o.org_id) INTO org_ids
FROM eventstore.instance_orgs o
WHERE o.instance_id = instanceId
AND CASE WHEN filter_orgs != ''
THEN o.org_id IN (filter_orgs)
ELSE TRUE END;
RETURN;
org_ids := ARRAY[]::TEXT[];
IF instance_permitted THEN
RETURN;
END IF;
END;
-- Return the organizations where permission were granted thru org-level roles
SELECT array_agg(sub.org_id) INTO org_ids
FROM (
SELECT DISTINCT om.org_id
FROM eventstore.org_members om
WHERE om.role = ANY(matched_roles)
AND om.instance_id = instanceID
AND om.user_id = userId
) AS sub;
instance_permitted := FALSE;
-- Return the organizations where permission were granted thru org-level roles
SELECT array_agg(sub.org_id) INTO org_ids
FROM (
SELECT DISTINCT om.org_id
FROM eventstore.org_members om
WHERE om.role = ANY(matched_roles)
AND om.instance_id = req_instance_id
AND om.user_id = auth_user_id
AND (filter_org IS NULL OR om.org_id = filter_org)
) AS sub;
END;
END IF;
END;
$$;

View File

@@ -0,0 +1,58 @@
-- recreate the view to include the resource_owner
CREATE OR REPLACE VIEW eventstore.project_members AS
SELECT instance_id, aggregate_id as project_id, object_id as user_id, text_value as role, resource_owner as org_id
FROM eventstore.fields
WHERE aggregate_type = 'project'
AND object_type = 'project_member_role'
AND field_name = 'project_role';
DROP FUNCTION IF EXISTS eventstore.permitted_projects;
CREATE OR REPLACE FUNCTION eventstore.permitted_projects(
req_instance_id TEXT
, auth_user_id TEXT
, system_user_perms JSONB
, perm TEXT
, filter_org TEXT
, instance_permitted OUT BOOLEAN
, org_ids OUT TEXT[]
, project_ids OUT TEXT[]
)
LANGUAGE 'plpgsql' STABLE
AS $$
BEGIN
-- if system user
IF system_user_perms IS NOT NULL THEN
SELECT p.instance_permitted, p.org_ids INTO instance_permitted, org_ids, project_ids
FROM eventstore.check_system_user_perms(system_user_perms, req_instance_id, perm) p;
RETURN;
END IF;
-- if human/machine user
SELECT * FROM eventstore.permitted_orgs(
req_instance_id
, auth_user_id
, system_user_perms
, perm
, filter_org
) INTO instance_permitted, org_ids;
IF instance_permitted THEN
RETURN;
END IF;
DECLARE
matched_roles TEXT[] := eventstore.find_roles(req_instance_id, perm);
BEGIN
-- Get the projects where permission were granted thru project-level roles
SELECT array_agg(sub.project_id) INTO project_ids
FROM (
SELECT DISTINCT pm.project_id
FROM eventstore.project_members pm
WHERE pm.role = ANY(matched_roles)
AND pm.instance_id = req_instance_id
AND pm.user_id = auth_user_id
AND (filter_org IS NULL OR pm.org_id = filter_org)
) AS sub;
END;
END;
$$;