Skip to content

Conversation

ulferts
Copy link
Contributor

@ulferts ulferts commented Oct 10, 2025

Ticket

https://community.openproject.org/wp/66611

What are you trying to accomplish?

Enable baseline to work flawlessly with the changes to the WP.allowed_to scope.

What approach did you choose and why?

Baseline before worked by manipulating the AR/arel structure to replace references to the model table (e.g. work_packages) by references to the journals (e.g. work_package_journals). With the changes to WorkPackages.allowed_to, the work packages eligible to be filtered are determined beforehand, on the current work packages, based on the current project_id. But when filtering historic data, the project_id might have been a different value. Therefore, the filtering for the allowed work packages has to happen on the data the query is run for, which is stored in the data journals (e.g work_package_journals).

The filtering for allowed work packages happens in a series of CTEs:

                ...
		WITH
			"member_projects" AS (
				(
					(
						SELECT
							"projects"."id",
							"members"."entity_id"
						FROM
							"members"
							INNER JOIN "projects" ON "projects"."active" = TRUE
							AND "members"."project_id" = "projects"."id"
							INNER JOIN "enabled_modules" ON "projects"."id" = "enabled_modules"."project_id"
							AND "enabled_modules"."name" IN ('work_package_tracking')
							AND "projects"."active" = TRUE
							INNER JOIN "member_roles" ON "member_roles"."member_id" = "members"."id"
							INNER JOIN "roles" ON "roles"."id" = "member_roles"."role_id"
							INNER JOIN "role_permissions" ON "roles"."id" = "role_permissions"."role_id"
							AND (
								FALSE
								OR "role_permissions"."permission" = 'view_work_packages'
								AND "enabled_modules"."name" = 'work_package_tracking'
							)
						WHERE
							"members"."user_id" = 86481
							AND (
								"members"."entity_type" IS NULL
								OR "members"."entity_type" = 'WorkPackage'
							)
					)
					UNION ALL
					(
						SELECT
							"projects"."id",
							NULL AS ENTITY_ID
						FROM
							"projects"
							INNER JOIN "enabled_modules" ON "projects"."id" = "enabled_modules"."project_id"
							AND "enabled_modules"."name" IN ('work_package_tracking')
							AND "projects"."active" = TRUE
							INNER JOIN "roles" ON "roles"."builtin" = 1
							AND "projects"."active"
							AND "projects"."public"
							AND NOT (
								EXISTS (
									SELECT
										1
									FROM
										"members"
									WHERE
										"members"."user_id" = 86481
										AND "members"."entity_type" IS NULL
										AND "members"."project_id" = "projects"."id"
								)
							)
							INNER JOIN "role_permissions" ON "roles"."id" = "role_permissions"."role_id"
							AND (
								FALSE
								OR "role_permissions"."permission" = 'view_work_packages'
								AND "enabled_modules"."name" = 'work_package_tracking'
							)
					)
				)
			),
			"entity_member_projects" AS (
				SELECT
					*
				FROM
					MEMBER_PROJECTS
				WHERE
					ENTITY_ID IS NOT NULL
			),
			"project_member_projects" AS (
				SELECT
					*
				FROM
					MEMBER_PROJECTS
				WHERE
					ENTITY_ID IS NULL
			),
			"entity_member_projects_without_duplicates" AS (
				SELECT
					*
				FROM
					ENTITY_MEMBER_PROJECTS
				WHERE
					NOT EXISTS (
						SELECT
							1
						FROM
							PROJECT_MEMBER_PROJECTS
						WHERE
							PROJECT_MEMBER_PROJECTS.ID = ENTITY_MEMBER_PROJECTS.ID
					)
			),
			"allowed_by_projects_and_work_packages" AS (
				SELECT
					*
				FROM
					WORK_PACKAGES
				WHERE
					PROJECT_ID IN (
						SELECT
							ID
						FROM
							MEMBER_PROJECTS
					)
					AND NOT EXISTS (
						SELECT
							1
						FROM
							ENTITY_MEMBER_PROJECTS_WITHOUT_DUPLICATES
						WHERE
							ENTITY_MEMBER_PROJECTS_WITHOUT_DUPLICATES.ID = WORK_PACKAGES.PROJECT_ID
							AND ENTITY_MEMBER_PROJECTS_WITHOUT_DUPLICATES.ENTITY_ID != WORK_PACKAGES.ID
					)
			)

...

Before this PR, the resulting "allowed_by_projects_and_work_packages" was then used to retrieve all work packages by using WorkPackage.from("allowed_by_projects_and_work_packages work_packages". But this fails because of the manipulations done for the historic query.

By switching this to a simple WHERE EXISTS (SELECT 1 from allowed_by_projects_and_work_packages ...) the query itself is valid again but fails to filter on the historic project_id as described above.

Instead of attempting to work this change into the existing structure another approach is taken. What the query understands as work_packages is redefined by placing a CTE under that name at the very top of the CTEs. Doing so will lead to all later CTEs as well as non CTE queries within the statement to understand work_packages as whatever the CTE defines instead of the also existing work_packages table. The redefinition of work_packages is then a join statement on the journals of the timestamp(s) in question:

WITH
			"work_packages" AS (
				SELECT
					JOURNALS.JOURNABLE_ID AS ID,
					JOURNALS.CREATED_AT,
					JOURNALS.UPDATED_AT,
					WORK_PACKAGE_JOURNALS.TYPE_ID,
					WORK_PACKAGE_JOURNALS.PROJECT_ID,
					WORK_PACKAGE_JOURNALS.SUBJECT,
					WORK_PACKAGE_JOURNALS.DESCRIPTION,
					WORK_PACKAGE_JOURNALS.DUE_DATE,
					WORK_PACKAGE_JOURNALS.CATEGORY_ID,
					WORK_PACKAGE_JOURNALS.STATUS_ID,
					WORK_PACKAGE_JOURNALS.ASSIGNED_TO_ID,
					WORK_PACKAGE_JOURNALS.PRIORITY_ID,
					WORK_PACKAGE_JOURNALS.VERSION_ID,
					WORK_PACKAGE_JOURNALS.AUTHOR_ID,
					WORK_PACKAGE_JOURNALS.DONE_RATIO,
					WORK_PACKAGE_JOURNALS.ESTIMATED_HOURS,
					WORK_PACKAGE_JOURNALS.START_DATE,
					WORK_PACKAGE_JOURNALS.PARENT_ID,
					WORK_PACKAGE_JOURNALS.RESPONSIBLE_ID,
					WORK_PACKAGE_JOURNALS.BUDGET_ID,
					WORK_PACKAGE_JOURNALS.STORY_POINTS,
					WORK_PACKAGE_JOURNALS.REMAINING_HOURS,
					WORK_PACKAGE_JOURNALS.DERIVED_ESTIMATED_HOURS,
					WORK_PACKAGE_JOURNALS.SCHEDULE_MANUALLY,
					WORK_PACKAGE_JOURNALS.DURATION,
					WORK_PACKAGE_JOURNALS.IGNORE_NON_WORKING_DAYS,
					WORK_PACKAGE_JOURNALS.DERIVED_REMAINING_HOURS,
					WORK_PACKAGE_JOURNALS.DERIVED_DONE_RATIO,
					WORK_PACKAGE_JOURNALS.PROJECT_PHASE_DEFINITION_ID
				FROM
					JOURNALS
					INNER JOIN WORK_PACKAGE_JOURNALS ON "journals"."data_type" = 'Journal::WorkPackageJournal'
					AND "journals"."data_id" = "work_package_journals"."id"
				AND (
				VALIDITY_PERIOD @> TIMESTAMP WITH TIME ZONE '2025-09-10 12:00:00 UTC'
				OR VALIDITY_PERIOD @> TIMESTAMP WITH TIME ZONE '2025-10-10 11:32:01 UTC'
			    )
			),
			... the rest remains unchanged

Doing so solves the problem while at the same time greatly simplifying the code because the substitution happens at one central place within the SQL.

The only place which still needs to be adapted are WHERE statements on custom values which still need to be rewritten.

Merge checklist

  • Added/updated tests

@ulferts ulferts force-pushed the bug/66611-activerecord-statementinvalid-in-get-api-v3-queries-queriesapi-queries-id-and-get-api-v3-queries-queriesbyprojectapi-projects-id-queries-default branch from 9f78716 to ba49c54 Compare October 10, 2025 15:22
@ulferts ulferts force-pushed the bug/66611-activerecord-statementinvalid-in-get-api-v3-queries-queriesapi-queries-id-and-get-api-v3-queries-queriesbyprojectapi-projects-id-queries-default branch 3 times, most recently from e3c2bdb to f61be08 Compare October 13, 2025 10:09
@ulferts ulferts force-pushed the bug/66611-activerecord-statementinvalid-in-get-api-v3-queries-queriesapi-queries-id-and-get-api-v3-queries-queriesbyprojectapi-projects-id-queries-default branch from f61be08 to 826cb85 Compare October 13, 2025 15:57
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment

Labels

None yet

Development

Successfully merging this pull request may close these issues.

1 participant