mirror of
https://github.com/zitadel/zitadel.git
synced 2025-08-12 00:47:33 +00:00
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:
58
cmd/setup/53/03-permitted_projects_func.sql
Normal file
58
cmd/setup/53/03-permitted_projects_func.sql
Normal 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;
|
||||
$$;
|
Reference in New Issue
Block a user