Skip to content

perf: use materialized CTE for orgUnitMode=SELECTED enrollment queries DHIS2-20921#22982

Draft
teleivo wants to merge 1 commit intomasterfrom
DHIS2-20921-orgunit-selected
Draft

perf: use materialized CTE for orgUnitMode=SELECTED enrollment queries DHIS2-20921#22982
teleivo wants to merge 1 commit intomasterfrom
DHIS2-20921-orgunit-selected

Conversation

@teleivo
Copy link
Contributor

@teleivo teleivo commented Feb 17, 2026

Follow-up to #22979. Fixes the orgUnitMode=SELECTED performance problem for enrollment queries.

The current query starts from the enrollment table (10.9M rows), joins to
trackedentityprogramowner + organisationunit, and filters by org unit ID in WHERE. PostgreSQL
scans all enrollments for the program and checks each one against the program owner -- even when the
selected org unit has zero matches.

This PR replaces the trackedentityprogramowner + organisationunit joins with a materialized CTE
that finds tracked entity IDs via the (programid, organisationunitid) composite index on
trackedentityprogramowner. The CTE result drives the join to enrollment, so PostgreSQL starts
from the small set of tracked entities at the selected org units instead of scanning all enrollments.

The MATERIALIZED keyword is required because without it PostgreSQL flattens the subquery into a
semi-join and still scans all enrollments.

The ownership access control clause (ou.path like ...) is not needed because the mapper validates
that the user has appropriate access (search or capture scope depending on program access level) to
the requested org units before they reach the store.

SQL

-- before (#22979)
select ...
from enrollment e
inner join trackedentity te on ...
inner join trackedentityprogramowner po on po.trackedentityid = e.trackedentityid and po.programid = e.programid
inner join organisationunit ou on ou.organisationunitid = po.organisationunitid
...
where ou.organisationunitid in (:orgUnits) and ou.path like :scopePath
  and e.programid = :programId ...

-- after
with selected_tes as materialized (
  select po.trackedentityid from trackedentityprogramowner po
  where po.programid = :programId and po.organisationunitid in (:selectedOrgUnits)
)
select ...
from enrollment e
inner join trackedentity te on ...
inner join selected_tes on selected_tes.trackedentityid = e.trackedentityid
...
where e.programid = :programId ...

Database Performance

Sierra Leone DB with 10M tracked entities (10.9M enrollments). EXPLAIN ANALYZE, 4 warmup runs.

Request (admin) #22979 This PR
orgUnits=O6uvpzGd5pu&orgUnitMode=SELECTED (district, 0 matches) 8,055ms 72ms
orgUnits=DiszpKrYNg8&orgUnitMode=SELECTED (facility, 8,597 TEs) n/a 273ms
fields=enrollment (no orgUnitMode) 9ms 8ms
orgUnitMode=DESCENDANTS 9ms 9ms

Other org unit modes and queries without org unit filters are unaffected.

@teleivo teleivo force-pushed the DHIS2-20921-orgunit-selected branch from dc3d366 to da49f75 Compare February 18, 2026 10:52
…s DHIS2-20921

When orgUnitMode=SELECTED with a known program, replace the
trackedentityprogramowner + organisationunit joins with a materialized
CTE that finds tracked entity IDs via the (programid, organisationunitid)
composite index. Without materialization, PostgreSQL flattens the
subquery into a semi-join and scans all enrollments instead.

8,005ms -> 72ms for the district-level org unit (0 matches).
273ms for a facility with 8,597 tracked entities.
@teleivo teleivo force-pushed the DHIS2-20921-orgunit-selected branch from da49f75 to 7080583 Compare February 18, 2026 10:53
@sonarqubecloud
Copy link

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment

Labels

None yet

Projects

None yet

Development

Successfully merging this pull request may close these issues.

1 participant

Comments