diff --git a/dhis-2/CTE-README.md b/dhis-2/CTE-README.md new file mode 100644 index 000000000000..bf27e6efb586 --- /dev/null +++ b/dhis-2/CTE-README.md @@ -0,0 +1,257 @@ +# Enrollment CTE refactoring + +## Introduction + +In DHIS2, retrieving Enrollment data often requires additional attributes—counts, last recorded values, or other derived fields—from associated Event tables. +Historically, we used correlated subqueries in the main SELECT list and in the WHERE clause. +However, these correlated subqueries pose two significant problems: + +- **Performance Degradation in PostgreSQL** +Repeated scanning of event tables for each enrollment can be a major bottleneck. +- **Incompatibility with Certain Analytics Engines** +Engines like ClickHouse or Doris do not support queries that reference outer fields in subqueries (e.g., ax.enrollment in a subquery). +This prevents the original correlated subquery approach from working at all in those environments. + +To address both of these issues, we refactored the query to use Common Table Expressions (CTEs). +By computing results upfront in separate CTEs and then joining the results, we eliminate the need for correlated subqueries, +thereby improving performance and ensuring compatibility with more analytics engines. + +## The Original Query (Correlated Subqueries) + +```sql +SELECT + enrollment, + trackedentity, + enrollmentdate, + occurreddate, + storedby, + createdbydisplayname, + lastupdatedbydisplayname, + lastupdated, + ST_AsGeoJSON(enrollmentgeometry), + longitude, + latitude, + ouname, + ounamehierarchy, + oucode, + enrollmentstatus, + ax."ou", + ax."Bpx0589u8y0", + ( + SELECT COUNT((occurreddate IS NOT NULL)) + FROM analytics_event_m3xtlkyblki AS subax + WHERE enrollment = ax.enrollment + AND ps = 'CWaAcQYKVpq' + ) AS "d6Sr0B2NJYv", + ( + SELECT "Qvb7NExMqjZ" + FROM analytics_event_M3xtLkYBlKI + WHERE eventstatus != 'SCHEDULE' + AND enrollment = ax.enrollment + AND ps = 'uvMKOn1oWvd' + ORDER BY occurreddate DESC, created DESC + LIMIT 1 + ) AS "uvMKOn1oWvd.Qvb7NExMqjZ", + ax."coaSpbzZiTB" +FROM analytics_enrollment_m3xtlkyblki AS ax +WHERE + enrollmentdate >= '2021-01-01' + AND enrollmentdate < '2022-01-01' + AND ax."uidlevel1" = 'ImspTQPwCqd' + AND ( + SELECT "fADIatyOu2g" + FROM analytics_event_M3xtLkYBlKI + WHERE eventstatus != 'SCHEDULE' + AND enrollment = ax.enrollment + AND ps = 'uvMKOn1oWvd' + ORDER BY occurreddate DESC, created DESC + LIMIT 1 + ) IS NULL +ORDER BY "lastupdated" DESC NULLS LAST +LIMIT 101 OFFSET 0; +``` + +## The Refactored Query (Using CTEs) + +```sql +WITH pi_d6sr0b2njyv AS ( + SELECT + enrollment, + COUNT((occurreddate IS NOT NULL)) AS value + FROM analytics_event_m3xtlkyblki + WHERE ps = 'CWaAcQYKVpq' + GROUP BY enrollment +), +ps_uvmkon1owvd_uvmkon1owvd_qvb7nexmqjz AS ( + SELECT + enrollment, + "Qvb7NExMqjZ" AS value, + ROW_NUMBER() OVER ( + PARTITION BY enrollment + ORDER BY occurreddate DESC, created DESC + ) AS rn + FROM analytics_event_M3xtLkYBlKI + WHERE eventstatus != 'SCHEDULE' + AND ps = 'uvMKOn1oWvd' +), +uvmkon1owvd_fadiatyou2g AS ( + SELECT + enrollment, + "fADIatyOu2g" AS value + FROM ( + SELECT + enrollment, + "fADIatyOu2g", + ROW_NUMBER() OVER ( + PARTITION BY enrollment + ORDER BY occurreddate DESC, created DESC + ) AS rn + FROM analytics_event_m3xtlkyblki + WHERE eventstatus != 'SCHEDULE' + AND ps = 'uvMKOn1oWvd' + ) ranked + WHERE rn = 1 +) +SELECT + ax.enrollment, + ax.trackedentity, + ax.enrollmentdate, + ax.occurreddate, + ax.storedby, + ax.createdbydisplayname, + ax.lastupdatedbydisplayname, + ax.lastupdated, + ST_AsGeoJSON(enrollmentgeometry), + ax.longitude, + ax.latitude, + ax.ouname, + ax.ounamehierarchy, + ax.oucode, + ax.enrollmentstatus, + ax."ou", + ax."Bpx0589u8y0", + COALESCE(mahfm.value, 0) AS d6Sr0B2NJYv, + rvwqm_0.value AS "uvMKOn1oWvd.Qvb7NExMqjZ", + ax."coaSpbzZiTB" +FROM analytics_enrollment_m3xtlkyblki AS ax +LEFT JOIN pi_d6sr0b2njyv AS mahfm + ON mahfm.enrollment = ax.enrollment +LEFT JOIN ps_uvmkon1owvd_uvmkon1owvd_qvb7nexmqjz AS rvwqm_0 + ON rvwqm_0.enrollment = ax.enrollment + AND rvwqm_0.rn = 1 +LEFT JOIN uvmkon1owvd_fadiatyou2g AS cxylo + ON cxylo.enrollment = ax.enrollment +WHERE + enrollmentdate >= '2021-01-01' + AND enrollmentdate < '2022-01-01' + AND ax."uidlevel1" = 'ImspTQPwCqd' + AND cxylo.value IS NULL +ORDER BY "lastupdated" DESC NULLS LAST +LIMIT 101 OFFSET 0; +``` + +### Explanation of the CTE Approach + +1. `pi_d6sr0b2njyv` + +- Aggregates the count of events per enrollment (`where ps = 'CWaAcQYKVpq'`). +- Eliminates the need for a correlated subquery counting `occurreddate`. + +2. `ps_uvmkon1owvd_uvmkon1owvd_qvb7nexmqjz` + +- Retrieves `Qvb7NExMqjZ` for each enrollment via a window function (`ROW_NUMBER()`) to find the most recent record. +- Eliminates the need for a subquery that grabbed the top 1 event by `occurreddate DESC, created DESC`. + +3. `uvmkon1owvd_fadiatyou2g` + +- Retrieves the latest `"fADIatyOu2g"` value (again using `ROW_NUMBER()`). +- Replaces the subquery used in the original `WHERE` clause to check if `"fADIatyOu2g"` is `NULL`. + +By computing these results in independent CTEs and then joining on enrollment, we avoid referencing ax.enrollment directly in subqueries. +This approach is compatible with additional analytics engines and often provides better performance in PostgreSQL as well. + +### Overall flow + +Below is a high‐level overview of how the **`buildEnrollmentQueryWithCte`** method works and how it refactors the existing logic into a CTE‐based query. + +Inside **`buildEnrollmentQueryWithCte(params)`**, the code proceeds in these key steps: + +1. **Collect CTE Definitions** + - It scans through the **`EventQueryParams`** (especially `params.getItems()`) to identify which columns need special handling. This includes: + - **Program Indicator** items + - **Items bound to a specific Program Stage** (sometimes with offsets, e.g., “nth event” logic) + - For each type of item, we build (or delegate building of) a CTE definition (SQL snippet). These definitions are stored in a **`CteContext`** object. + +2. **Generate CTE Filters** + - Additional filters may be needed for query items that have filters (`item.hasFilter()`). If such items require “latest event” logic or repeated‐stage handling, a separate **filter CTE** is generated. + +3. **Append the CTE Clause** + - We gather all generated CTE definitions from the **`CteContext`** and place them in a `WITH ...` clause at the start of the SQL. + +4. **Construct the Main SELECT** + - We pick the **standard enrollment columns** (e.g., `enrollmentdate`, `trackedentity`, `lastupdated`) plus any columns derived from **CTEs**. + - This step merges basic columns (from the main `analytics_enrollment_*` table) with additional “value” columns pulled out of the CTE definitions. + +5. **FROM and JOIN Logic** + - The **`FROM`** clause references the main enrollment analytics table (e.g. `FROM analytics_enrollment_m3xtlkyblki AS ax`). + - The code appends **LEFT JOIN** statements for each CTE that needs to link to the main table on `enrollment`. + +6. **WHERE Clause** + - The base “where” conditions come from the original logic (`getWhereClause(params)`), covering date ranges, organization units, statuses, etc. + - Additional filters are applied if they relate to columns computed in the CTEs (via `addCteFiltersToWhereClause`). + +7. **Sorting and Paging** + - Finally, an **ORDER BY** (if `params` is sorting on something) is appended. + - A **LIMIT/OFFSET** is added according to the required paging settings. + +When done, the **StringBuilder** contains the fully assembled SQL statement. + +## 3. Key Methods / Helpers + +Within **`buildEnrollmentQueryWithCte`**, you’ll see these helper calls: + +1. **`getCteDefinitions(params)`** + - Identifies all items (e.g., Program Stage columns, Program Indicators) that need a subquery. + - Creates a **CTE definition** for each item, handling “row_number” logic or Program Indicator subqueries. + - Stores definitions in a `CteContext`. + +2. **`generateFilterCTEs(params, cteContext)`** + - Looks for **filters** on items (e.g. `item.hasFilter()`). + - If an item needs a subquery filter (e.g. “the last event’s value must be X”), builds a “filter CTE” specifically for that. + +3. **`appendCteClause(sql, cteContext)`** + - Aggregates all CTE SQL fragments from the context. + - Organizes them in a `WITH cteName AS ( ... )` structure and appends to `sql`. + +4. **`appendSelectClause(sql, params, cteContext)`** + - Builds the `SELECT` part. + - Merges the default columns (e.g., `ax.enrollment`) with columns derived from each CTE definition (e.g. `cteAlias.value AS someColumn`). + +5. **`appendCteJoins(sql, cteContext)`** + - For each CTE, inserts a `LEFT JOIN cteName alias ON cteAlias.enrollment = ax.enrollment`. + - Enables referencing computed values in the main SELECT. + +6. **`appendWhereClause(sql, params, cteContext)`** + - Uses the original `getWhereClause(params)` for base filters. + - Plus merges in any filter conditions from the CTE context (e.g., `cteAlias.value = X`). + +7. **`appendSortingAndPaging(sql, params)`** + - Optionally appends an `ORDER BY ...`. + - Adds `LIMIT x OFFSET y` if relevant. + +## 4. Notable Changes from Pre‐CTE Logic + +1. **Elimination of Correlated Subqueries** + - Previously: + ```sql + SELECT + (SELECT ... FROM analytics_event_xxx WHERE enrollment = ax.enrollment ...) + ``` + repeated for each column. + - Now replaced by a single (or multiple) CTE definitions, joined once. + +2. **Better Handling of Repeatable Stages** + - The offset logic (`createOffset(...)`) and row numbering (`row_number() OVER (...)`) are centralized in specialized CTEs instead of inline subqueries. + +3. **Filter Consolidation** + - Complex filters on “the most recent event for stage X” are turned into “filter CTEs” plus a straightforward check (e.g., `cteAlias.value = 'someFilter'`). diff --git a/dhis-2/dhis-api/src/main/java/org/hisp/dhis/setting/SystemSettings.java b/dhis-2/dhis-api/src/main/java/org/hisp/dhis/setting/SystemSettings.java index 63d79785850c..392e40b41050 100644 --- a/dhis-2/dhis-api/src/main/java/org/hisp/dhis/setting/SystemSettings.java +++ b/dhis-2/dhis-api/src/main/java/org/hisp/dhis/setting/SystemSettings.java @@ -745,4 +745,8 @@ default boolean isHideUnapprovedDataInAnalytics() { // -1 means approval is disabled return getIgnoreAnalyticsApprovalYearThreshold() >= 0; } + + default boolean getUseExperimentalAnalyticsQueryEngine() { + return asBoolean("experimentalAnalyticsSqlEngineEnabled", false); + } } diff --git a/dhis-2/dhis-services/dhis-service-analytics/pom.xml b/dhis-2/dhis-services/dhis-service-analytics/pom.xml index c047a707af10..e306823d4957 100644 --- a/dhis-2/dhis-services/dhis-service-analytics/pom.xml +++ b/dhis-2/dhis-services/dhis-service-analytics/pom.xml @@ -169,7 +169,10 @@ lombok provided - + + com.github.jsqlparser + jsqlparser + diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/common/CteContext.java b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/common/CteContext.java new file mode 100644 index 000000000000..c882de5ea8a6 --- /dev/null +++ b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/common/CteContext.java @@ -0,0 +1,147 @@ +/* + * Copyright (c) 2004-2024, University of Oslo + * All rights reserved. + * + * Redistribution and use in source and binary forms, with or without + * modification, are permitted provided that the following conditions are met: + * Redistributions of source code must retain the above copyright notice, this + * list of conditions and the following disclaimer. + * + * Redistributions in binary form must reproduce the above copyright notice, + * this list of conditions and the following disclaimer in the documentation + * and/or other materials provided with the distribution. + * Neither the name of the HISP project nor the names of its contributors may + * be used to endorse or promote products derived from this software without + * specific prior written permission. + * + * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND + * ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED + * WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE + * DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR + * ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES + * (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; + * LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON + * ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT + * (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS + * SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + */ +package org.hisp.dhis.analytics.common; + +import static org.hisp.dhis.analytics.common.CteUtils.computeKey; + +import java.util.LinkedHashMap; +import java.util.List; +import java.util.Map; +import java.util.Set; +import org.hisp.dhis.common.QueryItem; +import org.hisp.dhis.program.ProgramIndicator; +import org.hisp.dhis.program.ProgramStage; + +public class CteContext { + private final Map cteDefinitions = new LinkedHashMap<>(); + public static final String ENROLLMENT_AGGR_BASE = "enrollment_aggr_base"; + + public CteDefinition getDefinitionByItemUid(String itemUid) { + return cteDefinitions.get(itemUid); + } + + /** + * Adds a CTE definition to the context. + * + * @param programStage The program stage + * @param item The query item + * @param cteDefinition The CTE definition (the SQL query) + * @param offset The calculated offset + * @param isRowContext Whether the CTE is a row context + */ + public void addCte( + ProgramStage programStage, + QueryItem item, + String cteDefinition, + int offset, + boolean isRowContext) { + String key = computeKey(item); + if (cteDefinitions.containsKey(key)) { + cteDefinitions.get(key).getOffsets().add(offset); + } else { + var cteDef = + new CteDefinition( + programStage.getUid(), item.getItemId(), cteDefinition, offset, isRowContext); + cteDefinitions.put(key, cteDef); + } + } + + /** Adds a aggregated base CTE definition to the context. */ + public void addBaseAggregateCte(String cteDefinition, String whereClauses) { + cteDefinitions.put(ENROLLMENT_AGGR_BASE, new CteDefinition(cteDefinition, whereClauses)); + } + + public void addExistsCte(ProgramStage programStage, QueryItem item, String cteDefinition) { + var cteDef = + new CteDefinition(programStage.getUid(), item.getItemId(), cteDefinition, -999, false) + .setExists(true); + cteDefinitions.put(programStage.getUid(), cteDef); + } + + /** + * Adds a CTE definition to the context. + * + * @param programIndicator The program indicator + * @param cteDefinition The CTE definition (the SQL query) + * @param functionRequiresCoalesce Whether the function requires to be "wrapped" in coalesce to + * avoid null values (e.g. avg, sum) + */ + public void addProgramIndicatorCte( + ProgramIndicator programIndicator, String cteDefinition, boolean functionRequiresCoalesce) { + cteDefinitions.put( + programIndicator.getUid(), + new CteDefinition(programIndicator.getUid(), cteDefinition, functionRequiresCoalesce)); + } + + public void addCteFilter(QueryItem item, String ctedefinition) { + String key = computeKey(item); + if (!cteDefinitions.containsKey(key)) { + ProgramStage programStage = item.getProgramStage(); + cteDefinitions.put( + key, + new CteDefinition( + item.getItemId(), + programStage == null ? null : programStage.getUid(), + ctedefinition, + true)); + } + } + + public CteDefinition getBaseAggregatedCte() { + return cteDefinitions.get(ENROLLMENT_AGGR_BASE); + } + + /** + * Returns the CTE definitions as a map. The key is the CTE name and the value is the CTE + * definition (the SQL query). + * + * @return the CTE definitions + */ + public Map getCteDefinitions() { + return cteDefinitions.entrySet().stream() + .collect( + LinkedHashMap::new, + (map, entry) -> map.put(entry.getKey(), entry.getValue().getCteDefinition()), + Map::putAll); + } + + public Set getCteKeys() { + return cteDefinitions.keySet(); + } + + public Set getCteKeys(String... exclude) { + final List toExclude = List.of(exclude); + return cteDefinitions.keySet().stream() + .filter(key -> !toExclude.contains(key)) + .collect(java.util.stream.Collectors.toSet()); + } + + public boolean containsCte(String cteName) { + return cteDefinitions.containsKey(cteName); + } +} diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/common/CteDefinition.java b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/common/CteDefinition.java new file mode 100644 index 000000000000..6444c7578d03 --- /dev/null +++ b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/common/CteDefinition.java @@ -0,0 +1,143 @@ +/* + * Copyright (c) 2004-2025, University of Oslo + * All rights reserved. + * + * Redistribution and use in source and binary forms, with or without + * modification, are permitted provided that the following conditions are met: + * Redistributions of source code must retain the above copyright notice, this + * list of conditions and the following disclaimer. + * + * Redistributions in binary form must reproduce the above copyright notice, + * this list of conditions and the following disclaimer in the documentation + * and/or other materials provided with the distribution. + * Neither the name of the HISP project nor the names of its contributors may + * be used to endorse or promote products derived from this software without + * specific prior written permission. + * + * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND + * ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED + * WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE + * DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR + * ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES + * (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; + * LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON + * ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT + * (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS + * SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + */ +package org.hisp.dhis.analytics.common; + +import java.util.ArrayList; +import java.util.List; +import lombok.Getter; +import org.apache.commons.text.RandomStringGenerator; + +public class CteDefinition { + + // Query item id + @Getter private String itemId; + // The program stage uid + @Getter private final String programStageUid; + // The program indicator uid + @Getter private String programIndicatorUid; + // The CTE definition (the SQL query) + @Getter private final String cteDefinition; + // The calculated offset + @Getter private final List offsets = new ArrayList<>(); + // The alias of the CTE + private final String alias; + // Whether the CTE is a row context + @Getter private boolean rowContext; + // Whether the CTE is a program indicator + @Getter private boolean programIndicator = false; + // Whether the CTE is a filter + @Getter private boolean filter = false; + // Whether the CTE is a exists, used for checking if the enrollment exists + private boolean isExists = false; + + @Getter private boolean aggregationBase = false; + + @Getter private boolean requiresCoalesce = false; + + @Getter private String aggregateWhereClause; + + public CteDefinition setExists(boolean exists) { + this.isExists = exists; + return this; + } + + public String getAlias() { + if (offsets.isEmpty()) { + return alias; + } + return computeAlias(offsets.get(0)); + } + + public String getAlias(int offset) { + return computeAlias(offset); + } + + private String computeAlias(int offset) { + return alias + "_" + offset; + } + + public CteDefinition( + String programStageUid, String queryItemId, String cteDefinition, int offset) { + this.programStageUid = programStageUid; + this.itemId = queryItemId; + this.cteDefinition = cteDefinition; + this.offsets.add(offset); + // one alias per offset + this.alias = new RandomStringGenerator.Builder().withinRange('a', 'z').build().generate(5); + this.rowContext = false; + } + + public CteDefinition( + String programStageUid, + String queryItemId, + String cteDefinition, + int offset, + boolean isRowContext) { + this(programStageUid, queryItemId, cteDefinition, offset); + this.rowContext = isRowContext; + } + + public CteDefinition(String cteDefinition, String aggregateWhereClause) { + this(null, null, cteDefinition, 0, false); + this.rowContext = false; + this.aggregationBase = true; + this.aggregateWhereClause = aggregateWhereClause; + } + + public CteDefinition(String programIndicatorUid, String cteDefinition, boolean requiresCoalesce) { + this.cteDefinition = cteDefinition; + this.programIndicatorUid = programIndicatorUid; + this.programStageUid = null; + // ignore offset + this.alias = new RandomStringGenerator.Builder().withinRange('a', 'z').build().generate(5); + this.rowContext = false; + this.programIndicator = true; + this.requiresCoalesce = requiresCoalesce; + } + + public CteDefinition( + String queryItemId, String programStageUid, String cteDefinition, boolean isFilter) { + this.itemId = queryItemId; + this.cteDefinition = cteDefinition; + this.programIndicatorUid = null; + this.programStageUid = programStageUid; + // ignore offset + this.alias = new RandomStringGenerator.Builder().withinRange('a', 'z').build().generate(5); + this.rowContext = false; + this.programIndicator = false; + this.filter = isFilter; + } + + public boolean isProgramStage() { + return !filter && !programIndicator && !isExists; + } + + public boolean isExists() { + return isExists; + } +} diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/common/CteUtils.java b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/common/CteUtils.java new file mode 100644 index 000000000000..3cb12b3e2c80 --- /dev/null +++ b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/common/CteUtils.java @@ -0,0 +1,50 @@ +/* + * Copyright (c) 2004-2024, University of Oslo + * All rights reserved. + * + * Redistribution and use in source and binary forms, with or without + * modification, are permitted provided that the following conditions are met: + * Redistributions of source code must retain the above copyright notice, this + * list of conditions and the following disclaimer. + * + * Redistributions in binary form must reproduce the above copyright notice, + * this list of conditions and the following disclaimer in the documentation + * and/or other materials provided with the distribution. + * Neither the name of the HISP project nor the names of its contributors may + * be used to endorse or promote products derived from this software without + * specific prior written permission. + * + * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND + * ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED + * WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE + * DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR + * ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES + * (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; + * LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON + * ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT + * (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS + * SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + */ +package org.hisp.dhis.analytics.common; + +import lombok.experimental.UtilityClass; +import org.hisp.dhis.common.QueryItem; + +@UtilityClass +public class CteUtils { + + public static String computeKey(QueryItem queryItem) { + + if (queryItem.hasProgramStage()) { + return "%s_%s".formatted(queryItem.getProgramStage().getUid(), queryItem.getItemId()); + } else if (queryItem.isProgramIndicator()) { + return queryItem.getItemId(); + } + return ""; + } + + public static String getIdentifier(QueryItem queryItem) { + String stage = queryItem.hasProgramStage() ? queryItem.getProgramStage().getUid() : "default"; + return stage + "." + queryItem.getItemId(); + } +} diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/common/InQueryCteFilter.java b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/common/InQueryCteFilter.java new file mode 100644 index 000000000000..2fbbb97e7bd6 --- /dev/null +++ b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/common/InQueryCteFilter.java @@ -0,0 +1,127 @@ +/* + * Copyright (c) 2004-2025, University of Oslo + * All rights reserved. + * + * Redistribution and use in source and binary forms, with or without + * modification, are permitted provided that the following conditions are met: + * Redistributions of source code must retain the above copyright notice, this + * list of conditions and the following disclaimer. + * + * Redistributions in binary form must reproduce the above copyright notice, + * this list of conditions and the following disclaimer in the documentation + * and/or other materials provided with the distribution. + * Neither the name of the HISP project nor the names of its contributors may + * be used to endorse or promote products derived from this software without + * specific prior written permission. + * + * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND + * ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED + * WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE + * DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR + * ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES + * (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; + * LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON + * ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT + * (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS + * SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + */ +package org.hisp.dhis.analytics.common; + +import static org.hisp.dhis.analytics.QueryKey.NV; + +import java.util.List; +import java.util.function.Predicate; +import org.hisp.dhis.common.QueryFilter; + +/** Mimics the logic of @{@link org.hisp.dhis.common.InQueryFilter} to be used in CTEs */ +public class InQueryCteFilter { + + private final String filter; + + private final CteDefinition cteDefinition; + + private final String field; + + private final boolean isText; + + public InQueryCteFilter( + String field, String encodedFilter, boolean isText, CteDefinition cteDefinition) { + this.filter = encodedFilter; + this.field = field; + this.isText = isText; + this.cteDefinition = cteDefinition; + } + + public String getSqlFilter(int offset) { + + List filterItems = QueryFilter.getFilterItems(this.filter); + + StringBuilder condition = new StringBuilder(); + String alias = cteDefinition.getAlias(offset); + if (hasNonMissingValue(filterItems)) { + // TODO GIUSEPPE! + + if (hasMissingValue(filterItems)) { + + // TODO GIUSEPPE! + } + } else { + if (hasMissingValue(filterItems)) { + condition.append("%s.enrollment is not null".formatted(alias)); + condition.append(" and "); + condition.append("%s.%s is null".formatted(alias, field)); + } + } + + return condition.toString(); + } + + /** + * Checks if the filter items contain any non-missing values (values that are not {@link + * org.hisp.dhis.analytics.QueryKey#NV}). Non-missing values represent actual values that should + * be included in the SQL IN clause. This method is used to determine if the generated SQL + * condition needs to include an IN clause. + * + * @param filterItems the list of filter items to check for non-missing values + * @return true if any item in the list is not equal to {@link + * org.hisp.dhis.analytics.QueryKey#NV}, indicating at least one actual value that should be + * included in the SQL IN clause; false if all values are missing + */ + private boolean hasNonMissingValue(List filterItems) { + return anyMatch(filterItems, this::isNotMissingItem); + } + + private boolean isNotMissingItem(String filterItem) { + return !isMissingItem(filterItem); + } + + private boolean isMissingItem(String filterItem) { + return NV.equals(filterItem); + } + + /** + * Checks if any item in the list matches the given predicate. + * + * @param filterItems the list of items to check + * @param predi the predicate to test against + * @return true if any item matches the predicate, false otherwise + */ + private boolean anyMatch(List filterItems, Predicate predi) { + return filterItems.stream().anyMatch(predi); + } + + /** + * Checks if the filter items contain any missing values represented by the special marker {@link + * org.hisp.dhis.analytics.QueryKey#NV}. Missing values indicate that the corresponding database + * field should be treated as NULL in the SQL query. This method is used to determine if the + * generated SQL condition needs to include an IS NULL clause. + * + * @param filterItems the list of filter items to check for missing values + * @return true if any item in the list equals{@link org.hisp.dhis.analytics.QueryKey#NV}, + * indicating a missing value that should be treated as NULL in the SQL query; false otherwise + * @see org.hisp.dhis.analytics.QueryKey#NV + */ + private boolean hasMissingValue(List filterItems) { + return anyMatch(filterItems, this::isMissingItem); + } +} diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/common/ProgramIndicatorSubqueryBuilder.java b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/common/ProgramIndicatorSubqueryBuilder.java index 411757dc52a6..b022ab6a967e 100644 --- a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/common/ProgramIndicatorSubqueryBuilder.java +++ b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/common/ProgramIndicatorSubqueryBuilder.java @@ -101,4 +101,19 @@ String getAggregateClauseForProgramIndicator( AnalyticsType outerSqlEntity, Date earliestStartDate, Date latestDate); + + void contributeCte( + ProgramIndicator programIndicator, + AnalyticsType outerSqlEntity, + Date earliestStartDate, + Date latestDate, + CteContext cteContext); + + void contributeCte( + ProgramIndicator programIndicator, + RelationshipType relationshipType, + AnalyticsType outerSqlEntity, + Date earliestStartDate, + Date latestDate, + CteContext cteContext); } diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/event/data/AbstractJdbcEventAnalyticsManager.java b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/event/data/AbstractJdbcEventAnalyticsManager.java index 47952b35a9d4..fdcbe004bcd9 100644 --- a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/event/data/AbstractJdbcEventAnalyticsManager.java +++ b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/event/data/AbstractJdbcEventAnalyticsManager.java @@ -75,6 +75,7 @@ import java.util.Map; import java.util.Objects; import java.util.Optional; +import java.util.Set; import java.util.UUID; import java.util.stream.Collector; import java.util.stream.Collectors; @@ -91,9 +92,12 @@ import org.hisp.dhis.analytics.EventOutputType; import org.hisp.dhis.analytics.SortOrder; import org.hisp.dhis.analytics.analyze.ExecutionPlanStore; +import org.hisp.dhis.analytics.common.CteContext; +import org.hisp.dhis.analytics.common.CteDefinition; import org.hisp.dhis.analytics.common.ProgramIndicatorSubqueryBuilder; import org.hisp.dhis.analytics.event.EventQueryParams; import org.hisp.dhis.analytics.util.AnalyticsUtils; +import org.hisp.dhis.analytics.util.sql.SqlConditionJoiner; import org.hisp.dhis.common.DimensionType; import org.hisp.dhis.common.DimensionalItemObject; import org.hisp.dhis.common.DimensionalObject; @@ -118,6 +122,7 @@ import org.hisp.dhis.program.AnalyticsType; import org.hisp.dhis.program.ProgramIndicator; import org.hisp.dhis.program.ProgramIndicatorService; +import org.hisp.dhis.setting.SystemSettingsService; import org.hisp.dhis.system.util.MathUtils; import org.springframework.beans.factory.annotation.Qualifier; import org.springframework.jdbc.core.JdbcTemplate; @@ -163,13 +168,15 @@ public abstract class AbstractJdbcEventAnalyticsManager { protected final SqlBuilder sqlBuilder; + protected final SystemSettingsService settingsService; + /** * Returns a SQL paging clause. * * @param params the {@link EventQueryParams}. * @param maxLimit the configurable max limit of records. */ - private String getPagingClause(EventQueryParams params, int maxLimit) { + protected String getPagingClause(EventQueryParams params, int maxLimit) { String sql = ""; if (params.isPaging()) { @@ -191,7 +198,7 @@ private String getPagingClause(EventQueryParams params, int maxLimit) { * * @param params the {@link EventQueryParams}. */ - private String getSortClause(EventQueryParams params) { + protected String getSortClause(EventQueryParams params) { String sql = ""; if (params.isSorting()) { @@ -329,7 +336,7 @@ private List getSelectColumns( * period will not be present in the query, so add it to the select columns and skip it in the * group by columns. */ - private void addDimensionSelectColumns( + protected void addDimensionSelectColumns( List columns, EventQueryParams params, boolean isGroupByClause) { params .getDimensions() @@ -413,7 +420,7 @@ private void addItemSelectColumns( * @param queryItem * @return true when eligible for row context */ - private boolean rowContextAllowedAndNeeded(EventQueryParams params, QueryItem queryItem) { + protected boolean rowContextAllowedAndNeeded(EventQueryParams params, QueryItem queryItem) { return params.getEndpointItem() == ENROLLMENT && params.isRowContext() && queryItem.hasProgramStage() @@ -905,6 +912,7 @@ private String getTableAndColumn( } else if (DimensionType.ORGANISATION_UNIT_GROUP_SET == dimension.getDimensionType()) { return params .getOrgUnitField() + .withSqlBuilder(sqlBuilder) .getOrgUnitGroupSetCol(col, getAnalyticsType(), isGroupByClause); } else { return quoteAlias(col); @@ -944,7 +952,9 @@ protected String getAggregatedEnrollmentsSql(List headers, EventQuer sql += getFromClause(params); - sql += getWhereClause(params); + String whereClause = getWhereClause(params); + String filterWhereClause = getQueryItemsAndFiltersWhereClause(params, new SqlHelper()); + sql += SqlConditionJoiner.joinSqlConditions(whereClause, filterWhereClause); String headerColumns = getHeaderColumns(headers, sql).stream().collect(joining(",")); String orgColumns = getOrgUnitLevelColumns(params).stream().collect(joining(",")); @@ -1079,13 +1089,18 @@ private void addGridDoubleTypeValue( } } + protected String getQueryItemsAndFiltersWhereClause(EventQueryParams params, SqlHelper helper) { + return getQueryItemsAndFiltersWhereClause(params, Set.of(), helper); + } + /** * Returns a SQL where clause string for query items and query item filters. * * @param params the {@link EventQueryParams}. * @param helper the {@link SqlHelper}. */ - protected String getQueryItemsAndFiltersWhereClause(EventQueryParams params, SqlHelper helper) { + protected String getQueryItemsAndFiltersWhereClause( + EventQueryParams params, Set exclude, SqlHelper helper) { if (params.isEnhancedCondition()) { return getItemsSqlForEnhancedConditions(params, helper); } @@ -1096,6 +1111,7 @@ protected String getQueryItemsAndFiltersWhereClause(EventQueryParams params, Sql Map> itemsByRepeatableFlag = Stream.concat(params.getItems().stream(), params.getItemFilters().stream()) .filter(QueryItem::hasFilter) + .filter(queryItem -> !exclude.contains(queryItem)) .collect( groupingBy( queryItem -> @@ -1113,13 +1129,13 @@ protected String getQueryItemsAndFiltersWhereClause(EventQueryParams params, Sql List orConditions = repeatableConditionsByIdentifier.values().stream() .map(sameGroup -> joinSql(sameGroup, OR_JOINER)) - .collect(toList()); + .toList(); // Non-repeatable conditions List andConditions = asSqlCollection(itemsByRepeatableFlag.get(false), params) .map(IdentifiableSql::getSql) - .collect(toList()); + .toList(); if (orConditions.isEmpty() && andConditions.isEmpty()) { return StringUtils.EMPTY; @@ -1173,7 +1189,7 @@ private String joinSql(Stream conditions, Collector sqlConditionByGroup = Stream.concat(params.getItems().stream(), params.getItemFilters().stream()) .filter(QueryItem::hasFilter) @@ -1237,7 +1253,7 @@ private String getIdentifier(QueryItem queryItem) { @Getter @Builder - private static class IdentifiableSql { + public static class IdentifiableSql { private final String identifier; private final String sql; @@ -1250,7 +1266,7 @@ private static class IdentifiableSql { * @param filter the {@link QueryFilter}. * @param params the {@link EventQueryParams}. */ - private String toSql(QueryItem item, QueryFilter filter, EventQueryParams params) { + protected String toSql(QueryItem item, QueryFilter filter, EventQueryParams params) { String field = item.hasAggregationType() ? getSelectSql(filter, item, params) @@ -1393,6 +1409,52 @@ protected String getCoalesce(List fields, String defaultColumnName) { return args.isEmpty() ? defaultColumnName : sql; } + protected List getSelectColumnsWithCTE(EventQueryParams params, CteContext cteContext) { + List columns = new ArrayList<>(); + + // Mirror the logic of addDimensionSelectColumns + addDimensionSelectColumns(columns, params, false); + + // Mirror the logic of addItemSelectColumns but with CTE references + for (QueryItem queryItem : params.getItems()) { + if (queryItem.isProgramIndicator()) { + // For program indicators, use CTE reference + String piUid = queryItem.getItem().getUid(); + CteDefinition cteDef = cteContext.getDefinitionByItemUid(piUid); + // COALESCE(fbyta.value, 0) as CH6wamtY9kK + String col = + cteDef.isRequiresCoalesce() + ? "coalesce(%s.value, 0) as %s".formatted(cteDef.getAlias(), piUid) + : "%s.value as %s".formatted(cteDef.getAlias(), piUid); + columns.add(col); + } else if (ValueType.COORDINATE == queryItem.getValueType()) { + // Handle coordinates + columns.add(getCoordinateColumn(queryItem).asSql()); + } else if (ValueType.ORGANISATION_UNIT == queryItem.getValueType()) { + // Handle org units + if (params.getCoordinateFields().stream() + .anyMatch(f -> queryItem.getItem().getUid().equals(f))) { + columns.add(getCoordinateColumn(queryItem, OU_GEOMETRY_COL_SUFFIX).asSql()); + } else { + columns.add(getOrgUnitQueryItemColumnAndAlias(params, queryItem).asSql()); + } + } else if (queryItem.hasProgramStage()) { + // Handle program stage items with CTE + columns.add(getColumnWithCte(queryItem, "", cteContext)); + } else { + // Handle other types as before + ColumnAndAlias columnAndAlias = getColumnAndAlias(queryItem, false, ""); + columns.add(columnAndAlias.asSql()); + } + } + // remove duplicates + return columns.stream().distinct().toList(); + } + + protected boolean useExperimentalAnalyticsQueryEngine() { + return this.settingsService.getCurrentSettings().getUseExperimentalAnalyticsQueryEngine(); + } + /** * Returns a select SQL clause for the given query. * @@ -1400,6 +1462,8 @@ protected String getCoalesce(List fields, String defaultColumnName) { */ protected abstract String getSelectClause(EventQueryParams params); + protected abstract String getColumnWithCte(QueryItem item, String suffix, CteContext cteContext); + /** * Generates the SQL for the from-clause. Generally this means which analytics table to get data * from. diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/event/data/EnrollmentQueryHelper.java b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/event/data/EnrollmentQueryHelper.java index 7ee323563a9d..de1b9b2e5c71 100644 --- a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/event/data/EnrollmentQueryHelper.java +++ b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/event/data/EnrollmentQueryHelper.java @@ -45,6 +45,7 @@ import org.hisp.dhis.common.DimensionalItemObject; import org.hisp.dhis.common.DimensionalObject; import org.hisp.dhis.common.GridHeader; +import org.hisp.dhis.common.QueryItem; import org.hisp.dhis.organisationunit.OrganisationUnit; import org.hisp.dhis.period.Period; @@ -91,6 +92,37 @@ public static Set getHeaderColumns(List headers, String sql) return headerColumns; } + /** + * Based on the given headers and params, it returns a set of respective database columns. If the + * header contains an column name that references a program stage item, it will be skipped. + * Program Stage items are handled as separate CTE. + * + * @param headers the list of {@link GridHeader}. + * @param params the {@link EventQueryParams}. + * @return the set of database columns. + */ + public static Set getHeaderColumns(List headers, EventQueryParams params) { + Set headerColumns = new LinkedHashSet<>(); + List itemsToSkip = + params.getItems().stream() + .filter(QueryItem::hasProgramStage) + .map(item -> "%s.%s".formatted(item.getProgramStage().getUid(), item.getItemId())) + .toList(); + + for (GridHeader header : headers) { + String headerName = header.getName(); + + if (!headerName.equalsIgnoreCase(COL_VALUE) + && !headerName.equalsIgnoreCase(PERIOD_DIM_ID) + && !headerName.equalsIgnoreCase(ORGUNIT_DIM_ID) + && !itemsToSkip.contains(headerName)) { + headerColumns.add(headerName); + } + } + + return headerColumns; + } + /** * Based on the given params, it returns a set of respective database columns representing org. * unit levels. diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/event/data/JdbcEnrollmentAnalyticsManager.java b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/event/data/JdbcEnrollmentAnalyticsManager.java index da2129f70c2f..8561618a548c 100644 --- a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/event/data/JdbcEnrollmentAnalyticsManager.java +++ b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/event/data/JdbcEnrollmentAnalyticsManager.java @@ -27,35 +27,55 @@ */ package org.hisp.dhis.analytics.event.data; +import static java.util.stream.Collectors.groupingBy; import static java.util.stream.Collectors.joining; import static org.apache.commons.lang3.StringUtils.EMPTY; import static org.hisp.dhis.analytics.AnalyticsConstants.ANALYTICS_TBL_ALIAS; import static org.hisp.dhis.analytics.DataType.BOOLEAN; +import static org.hisp.dhis.analytics.common.CteContext.ENROLLMENT_AGGR_BASE; +import static org.hisp.dhis.analytics.common.CteUtils.computeKey; +import static org.hisp.dhis.analytics.event.data.EnrollmentQueryHelper.getHeaderColumns; import static org.hisp.dhis.analytics.event.data.OrgUnitTableJoiner.joinOrgUnitTables; import static org.hisp.dhis.analytics.util.AnalyticsUtils.withExceptionHandling; import static org.hisp.dhis.common.DataDimensionType.ATTRIBUTE; import static org.hisp.dhis.common.DimensionItemType.DATA_ELEMENT; import static org.hisp.dhis.common.DimensionalObject.ORGUNIT_DIM_ID; import static org.hisp.dhis.common.IdentifiableObjectUtils.getUids; +import static org.hisp.dhis.common.QueryOperator.IN; import static org.hisp.dhis.commons.util.TextUtils.getQuotedCommaDelimitedString; import static org.hisp.dhis.commons.util.TextUtils.removeLastOr; import static org.hisp.dhis.util.DateUtils.toMediumDate; import com.google.common.collect.Sets; +import java.util.ArrayList; import java.util.Arrays; import java.util.Date; import java.util.HashMap; +import java.util.HashSet; import java.util.List; import java.util.Map; import java.util.Optional; +import java.util.Set; +import java.util.stream.Collectors; +import java.util.stream.Stream; import lombok.extern.slf4j.Slf4j; import org.apache.commons.lang3.StringUtils; +import org.apache.commons.text.StringSubstitutor; import org.hisp.dhis.analytics.analyze.ExecutionPlanStore; +import org.hisp.dhis.analytics.common.CteContext; +import org.hisp.dhis.analytics.common.CteDefinition; +import org.hisp.dhis.analytics.common.CteUtils; +import org.hisp.dhis.analytics.common.InQueryCteFilter; import org.hisp.dhis.analytics.common.ProgramIndicatorSubqueryBuilder; import org.hisp.dhis.analytics.event.EnrollmentAnalyticsManager; import org.hisp.dhis.analytics.event.EventQueryParams; import org.hisp.dhis.analytics.table.AbstractJdbcTableManager; import org.hisp.dhis.analytics.table.EnrollmentAnalyticsColumnName; +import org.hisp.dhis.analytics.util.sql.Condition; +import org.hisp.dhis.analytics.util.sql.SelectBuilder; +import org.hisp.dhis.analytics.util.sql.SqlAliasReplacer; +import org.hisp.dhis.analytics.util.sql.SqlColumnParser; +import org.hisp.dhis.analytics.util.sql.SqlWhereClauseExtractor; import org.hisp.dhis.category.CategoryOption; import org.hisp.dhis.common.DimensionItemType; import org.hisp.dhis.common.DimensionType; @@ -63,8 +83,12 @@ import org.hisp.dhis.common.DimensionalObject; import org.hisp.dhis.common.FallbackCoordinateFieldType; import org.hisp.dhis.common.Grid; +import org.hisp.dhis.common.GridHeader; import org.hisp.dhis.common.OrganisationUnitSelectionMode; +import org.hisp.dhis.common.QueryFilter; import org.hisp.dhis.common.QueryItem; +import org.hisp.dhis.common.QueryOperator; +import org.hisp.dhis.common.RequestTypeAware; import org.hisp.dhis.common.ValueStatus; import org.hisp.dhis.common.ValueType; import org.hisp.dhis.commons.collection.ListUtils; @@ -74,7 +98,9 @@ import org.hisp.dhis.event.EventStatus; import org.hisp.dhis.organisationunit.OrganisationUnit; import org.hisp.dhis.program.AnalyticsType; +import org.hisp.dhis.program.ProgramIndicator; import org.hisp.dhis.program.ProgramIndicatorService; +import org.hisp.dhis.setting.SystemSettingsService; import org.hisp.dhis.system.util.ListBuilder; import org.locationtech.jts.util.Assert; import org.springframework.beans.factory.annotation.Qualifier; @@ -113,22 +139,33 @@ public JdbcEnrollmentAnalyticsManager( ProgramIndicatorSubqueryBuilder programIndicatorSubqueryBuilder, EnrollmentTimeFieldSqlRenderer timeFieldSqlRenderer, ExecutionPlanStore executionPlanStore, + SystemSettingsService settingsService, SqlBuilder sqlBuilder) { super( jdbcTemplate, programIndicatorService, programIndicatorSubqueryBuilder, executionPlanStore, - sqlBuilder); + sqlBuilder, + settingsService); this.timeFieldSqlRenderer = timeFieldSqlRenderer; } @Override public void getEnrollments(EventQueryParams params, Grid grid, int maxLimit) { - String sql = - params.isAggregatedEnrollments() - ? getAggregatedEnrollmentsSql(grid.getHeaders(), params) - : getAggregatedEnrollmentsSql(params, maxLimit); + String sql; + if (params.isAggregatedEnrollments()) { + sql = + useExperimentalAnalyticsQueryEngine() + ? buildAggregatedEnrollmentQueryWithCte(grid.getHeaders(), params) + : getAggregatedEnrollmentsSql(grid.getHeaders(), params); + } else { + // getAggregatedEnrollmentsSql + sql = + useExperimentalAnalyticsQueryEngine() + ? buildEnrollmentQueryWithCte(params) + : getAggregatedEnrollmentsSql(params, maxLimit); + } if (params.analyzeOnly()) { withExceptionHandling( @@ -274,6 +311,7 @@ public long getEnrollmentCount(EventQueryParams params) { sql += getFromClause(params); sql += getWhereClause(params); + sql += addFiltersToWhereClause(params); long count = 0; @@ -289,7 +327,7 @@ public long getEnrollmentCount(EventQueryParams params) { withExceptionHandling( () -> jdbcTemplate.queryForObject(finalSqlValue, Long.class), params.isMultipleQueries()) - .orElse(0l); + .orElse(0L); } return count; @@ -411,8 +449,9 @@ protected String getWhereClause(EventQueryParams params) { // --------------------------------------------------------------------- // Query items and filters // --------------------------------------------------------------------- - - sql += getQueryItemsAndFiltersWhereClause(params, hlp); + if (!useExperimentalAnalyticsQueryEngine()) { + sql += getQueryItemsAndFiltersWhereClause(params, hlp); + } // --------------------------------------------------------------------- // Filter expression @@ -476,6 +515,130 @@ protected String getWhereClause(EventQueryParams params) { return sql; } + private String addFiltersToWhereClause(EventQueryParams params) { + return getQueryItemsAndFiltersWhereClause(params, new SqlHelper()); + } + + private String addCteFiltersToWhereClause(EventQueryParams params, CteContext cteContext) { + StringBuilder cteWhereClause = new StringBuilder(); + Set processedItems = new HashSet<>(); // Track processed items + + // Get all filters from the query items and item filters + List filters = + Stream.concat(params.getItems().stream(), params.getItemFilters().stream()) + .filter(QueryItem::hasFilter) + .toList(); + // Iterate over each filter and apply the correct condition + for (QueryItem item : filters) { + String cteName = CteUtils.computeKey(item); + + if (cteContext.containsCte(cteName)) { + processedItems.add(item); // Mark item as processed + CteDefinition cteDef = cteContext.getDefinitionByItemUid(cteName); + for (QueryFilter filter : item.getFilters()) { + if (IN.equals(filter.getOperator())) { + InQueryCteFilter inQueryCteFilter = + new InQueryCteFilter("value", filter.getFilter(), item.isText(), cteDef); + cteWhereClause + .append(" and ") + .append( + inQueryCteFilter.getSqlFilter( + computeRowNumberOffset(item.getProgramStageOffset()))); + } else { + String value = getSqlFilterValue(filter, item); + + cteWhereClause + .append(" and ") + .append(cteDef.getAlias()) + .append(".value ") + .append("NULL".equals(value) ? "is" : filter.getSqlOperator()) + .append(" ") + .append(value); + } + } + } + } + // Add filters for items that are not part of the CTE + String nonCteWhereClause = + getQueryItemsAndFiltersWhereClause(params, processedItems, new SqlHelper()) + .replace("where", ""); + if (nonCteWhereClause.isEmpty()) return cteWhereClause.toString(); + + String currentWhereClause = cteWhereClause.toString().toLowerCase().trim(); + cteWhereClause.append( + currentWhereClause.endsWith("and") ? nonCteWhereClause : " and " + nonCteWhereClause); + + return cteWhereClause.toString(); + } + + private String getSqlFilterValue(QueryFilter filter, QueryItem item) { + if ("NV".equals(filter.getFilter())) { + return "NULL"; // Special case for 'null' filters + } + + // Handle IN operator: wrap the value(s) in parentheses + if (filter.getOperator() == QueryOperator.IN) { + String[] values = filter.getFilter().split(","); // Support multiple values + String quotedValues = + Arrays.stream(values) + .map(value -> item.isNumeric() ? value : sqlBuilder.singleQuote(value)) + .collect(Collectors.joining(", ")); + return "(" + quotedValues + ")"; + } + + // Handle text and numeric values + return item.isNumeric() + ? filter.getSqlBindFilter() + : sqlBuilder.singleQuote(filter.getSqlBindFilter()); + } + + private String buildFilterCteSql(List queryItems, EventQueryParams params) { + return queryItems.stream() + .map( + item -> { + // Determine the correct table: event table or enrollment table + String tableName = + item.hasProgramStage() + ? "analytics_event_" + + item.getProgram() + .getUid() + .toLowerCase() // Event table for program stage + : params.getTableName(); // Enrollment table + + String columnName = quote(item.getItemName()); // Raw column name without alias + String programStageCondition = + item.hasProgramStage() + ? "AND ps = '" + item.getProgramStage().getUid() + "'" + : ""; // Add program stage filter if available + + return """ + select + enrollment, + %s as value + from + (select + enrollment, + %s, + row_number() over ( + partition by enrollment + order by + occurreddate desc, + created desc + ) as rn + from + %s + where + eventstatus != 'SCHEDULE' + %s + ) ranked + where + rn = 1 + """ + .formatted(columnName, columnName, tableName, programStageCondition); + }) + .collect(Collectors.joining("\nUNION ALL\n")); + } + @Override protected String getSelectClause(EventQueryParams params) { List selectCols = @@ -565,6 +728,29 @@ protected ColumnAndAlias getCoordinateColumn(QueryItem item, String suffix) { return ColumnAndAlias.EMPTY; } + @Override + protected String getColumnWithCte(QueryItem item, String suffix, CteContext cteContext) { + List columns = new ArrayList<>(); + + CteDefinition cteDef = cteContext.getDefinitionByItemUid(computeKey(item)); + int programStageOffset = computeRowNumberOffset(item.getProgramStageOffset()); + String alias = getAlias(item).orElse(null); + columns.add("%s.value as %s".formatted(cteDef.getAlias(programStageOffset), quote(alias))); + if (cteDef.isRowContext()) { + // Add additional status and exists columns for row context + columns.add( + "COALESCE(%s.rn = %s, false) as %s" + .formatted( + cteDef.getAlias(programStageOffset), + programStageOffset + 1, + quote(alias + ".exists"))); + columns.add( + "%s.eventstatus as %s" + .formatted(cteDef.getAlias(programStageOffset), quote(alias + ".status"))); + } + return String.join(",\n", columns); + } + /** * Creates a column "selector" for the given item name. The suffix will be appended as part of the * item name. The column selection is based on events analytics tables. @@ -767,4 +953,585 @@ private String createOrderType(int offset) { return ORDER_BY_EXECUTION_DATE.replace(DIRECTION_PLACEHOLDER, "asc"); } } + + // New methods // + + private void handleProgramIndicatorCte( + QueryItem item, CteContext cteContext, EventQueryParams params) { + ProgramIndicator pi = (ProgramIndicator) item.getItem(); + if (item.hasRelationshipType()) { + programIndicatorSubqueryBuilder.contributeCte( + pi, + item.getRelationshipType(), + getAnalyticsType(), + params.getEarliestStartDate(), + params.getLatestEndDate(), + cteContext); + } else { + programIndicatorSubqueryBuilder.contributeCte( + pi, + getAnalyticsType(), + params.getEarliestStartDate(), + params.getLatestEndDate(), + cteContext); + } + } + + /** + * Builds the CTE definitions for the given {@link EventQueryParams}. + * + *

For each {@link QueryItem} in {@code params}, this method: + * + *

    + *
  • Identifies if the item is a {@link ProgramIndicator} and delegates to {@link + * #handleProgramIndicatorCte(QueryItem, CteContext, EventQueryParams)}. + *
  • Identifies if the item has a {@link org.hisp.dhis.program.ProgramStage} and generates the + * appropriate CTE SQL, including any row-context details if the stage is repeatable. + *
  • Adds each resulting CTE (and optional "exists" CTE) to the provided {@link CteContext}. + *
+ * + * @param params the {@link EventQueryParams} describing what data is being queried + * @return a {@link CteContext} instance containing all relevant CTE definitions + */ + private CteContext getCteDefinitions(EventQueryParams params, CteContext cteContext) { + if (cteContext == null) { + cteContext = new CteContext(); + } + + for (QueryItem item : params.getItems()) { + if (item.isProgramIndicator()) { + // Handle any program indicator CTE logic. + handleProgramIndicatorCte(item, cteContext, params); + } else if (item.hasProgramStage()) { + // Build CTE for program-stage-based items (including repeatable logic). + buildProgramStageCte(cteContext, item, params); + } + } + + return cteContext; + } + + private CteContext getCteDefinitions(EventQueryParams params) { + return getCteDefinitions(params, null); + } + + /** + * Constructs the SQL query for the `enrollment_aggr_base` Common Table Expression (CTE). + * + *

The `enrollment_aggr_base` CTE is a foundational component of an analytical query. It + * extracts a filtered subset of enrollment data from the target `analytics_enrollment_*` table + * based on specific criteria. + * + *

This CTE serves as the "base" dataset for subsequent operations in the query, such as + * event-level processing and aggregations. By applying these filters early, the CTE ensures that + * only relevant records are passed to downstream processes, improving query efficiency. + * + *

Purpose

+ * + * The primary purpose of this CTE is to: + * + *
    + *
  • Reduce the size of the dataset by applying restrictive filters. + *
  • Serve as a starting point for analytics queries requiring enrollment-specific data. + *
  • Facilitate joins with event data while minimizing unnecessary computation. + *
+ * + * @param cteContext the {@link CteContext} containing all CTE definitions + * @param params the {@link EventQueryParams} describing the query parameters + * @param headers the {@link GridHeader} list defining the query columns + * @return a {@link List} of column names included in the `enrollment_aggr_base` CTE + */ + private List addBaseAggregationCte( + CteContext cteContext, EventQueryParams params, List headers) { + // create base enrollment context + List columns = new ArrayList<>(); + List rootColumns; + columns.add("enrollment"); + + addDimensionSelectColumns(columns, params, true); + Set headersCols = getHeaderColumns(headers, params); + SelectBuilder sb = new SelectBuilder(); + for (String column : Sets.newHashSet(columns)) { + sb.addColumn(SqlColumnParser.removeTableAlias(column)); + } + for (String column : headersCols) { + sb.addColumnIfNotExist(quote(SqlColumnParser.removeTableAlias(column))); + } + + // return the name of the columns that are part + // of the original params, no need to return also + // the columns that are part of the filters + rootColumns = sb.getColumnNames(); + sb.from(getFromClause(params)); + sb.where( + Condition.and( + Condition.raw(getWhereClause(params)), Condition.raw(addFiltersToWhereClause(params)))); + + // Extract the columns from the where clause + List cols = SqlWhereClauseExtractor.extractWhereColumns(sb.build()); + for (String col : cols) { + sb.addColumnIfNotExist(col); + } + + // Add the base aggregate CTE along with the original where + // condition, that have to be propagated in every other CTE for + // performance reasons + cteContext.addBaseAggregateCte( + sb.build(), SqlAliasReplacer.replaceTableAliases(sb.getWhereClause(), cols)); + + return rootColumns; + } + + /** + * Builds and registers a CTE definition for the given {@link QueryItem} (which must have a {@link + * org.hisp.dhis.program.ProgramStage}). This covers both repeatable and non-repeatable program + * stages, optionally adding row-context CTEs if needed. + * + * @param cteContext the {@link CteContext} to which the new CTE definition(s) will be added + * @param item the {@link QueryItem} containing program-stage details + * @param params the {@link EventQueryParams}, used for checking row-context eligibility, offsets, + * etc. + */ + private void buildProgramStageCte( + CteContext cteContext, QueryItem item, EventQueryParams params) { + // The event table name, e.g. "analytics_event_XYZ". + String eventTableName = ANALYTICS_EVENT + item.getProgram().getUid(); + + // Quoted column name for the item (e.g. "ax"."my_column"). + String colName = quote(item.getItemName()); + + if (params.isAggregatedEnrollments()) { + handleAggregatedEnrollments(cteContext, item, eventTableName, colName); + return; + } + + // Determine if row context is needed (repeatable stage + rowContextAllowed). + boolean hasRowContext = rowContextAllowedAndNeeded(params, item); + + // Build the main CTE SQL. + String cteSql = buildMainCteSql(eventTableName, colName, item, hasRowContext); + + // Register this CTE in the context. + cteContext.addCte( + item.getProgramStage(), + item, + cteSql, + computeRowNumberOffset(item.getProgramStageOffset()), + hasRowContext); + + // If row context is needed, we add an extra "exists" CTE for event checks. + if (hasRowContext) { + addExistsCte(cteContext, item, eventTableName); + } + } + + /** + * Builds the main CTE SQL. + * + * @param eventTableName the event table name + * @param colName the quoted column name for the item + * @param item the {@link QueryItem} containing program-stage details + * @param hasRowContext whether row context is needed + * @return the main CTE SQL + */ + private String buildMainCteSql( + String eventTableName, String colName, QueryItem item, boolean hasRowContext) { + String template = + """ + select + enrollment, + ${colName} as value,${rowContext} + row_number() over ( + partition by enrollment + order by occurreddate desc, created desc + ) as rn + from ${eventTableName} + where eventstatus != 'SCHEDULE' + and ps = '${programStageUid}' + """; + + Map values = new HashMap<>(); + values.put("colName", colName); + values.put("rowContext", hasRowContext ? " eventstatus," : ""); + values.put("eventTableName", eventTableName); + values.put("programStageUid", item.getProgramStage().getUid()); + + return new StringSubstitutor(values).replace(template); + } + + /** + * Handles the case when aggregated enrollments are enabled. + * + * @param cteContext the {@link CteContext} to which the new CTE definition(s) will be added + * @param item the {@link QueryItem} containing program-stage details + * @param params the {@link EventQueryParams}, used for checking row-context eligibility, offsets, + * etc. + * @param eventTableName the event table name + * @param colName the quoted column name for the item + */ + private void handleAggregatedEnrollments( + CteContext cteContext, QueryItem item, String eventTableName, String colName) { + CteDefinition baseAggregatedCte = cteContext.getBaseAggregatedCte(); + assert baseAggregatedCte != null; + + String cteSql = buildAggregatedCteSql(eventTableName, colName, item, baseAggregatedCte); + + cteContext.addCte( + item.getProgramStage(), + item, + cteSql, + computeRowNumberOffset(item.getProgramStageOffset()), + false); + } + + /** + * Builds the aggregated CTE SQL. + * + * @param eventTableName the event table name + * @param colName the quoted column name for the item + * @param item the {@link QueryItem} containing program-stage details + * @param baseAggregatedCte the base aggregated CTE + * @return the aggregated CTE SQL + */ + private String buildAggregatedCteSql( + String eventTableName, String colName, QueryItem item, CteDefinition baseAggregatedCte) { + String template = + """ + select + evt.enrollment, + evt.${colName} as value + from ( + select + evt.enrollment, + evt.${colName}, + row_number() over ( + partition by evt.enrollment + order by occurreddate desc, created desc + ) as rn + from ${eventTableName} evt + join ${enrollmentAggrBase} eb ON eb.enrollment = evt.enrollment + where evt.eventstatus != 'SCHEDULE' + and evt.ps = '${programStageUid}' and ${aggregateWhereClause}) evt + where evt.rn = 1 + """; + + Map values = new HashMap<>(); + values.put("colName", colName); + values.put("eventTableName", eventTableName); + values.put("enrollmentAggrBase", ENROLLMENT_AGGR_BASE); + values.put("programStageUid", item.getProgramStage().getUid()); + values.put( + "aggregateWhereClause", baseAggregatedCte.getAggregateWhereClause().replace("%s", "eb")); + + return new StringSubstitutor(values).replace(template); + } + + /** + * Adds an "exists" CTE for event checks. + * + * @param cteContext the {@link CteContext} to which the new CTE definition(s) will be added + * @param item the {@link QueryItem} containing program-stage details + * @param eventTableName the event table name + */ + private void addExistsCte(CteContext cteContext, QueryItem item, String eventTableName) { + String template = + """ + select distinct + enrollment + from + ${eventTableName} + where + eventstatus != 'SCHEDULE' + and ps = '${programStageUid}' + """; + + Map values = new HashMap<>(); + values.put("eventTableName", eventTableName); + values.put("programStageUid", item.getProgramStage().getUid()); + + String existCte = new StringSubstitutor(values).replace(template); + + cteContext.addExistsCte(item.getProgramStage(), item, existCte); + } + + private void addCteJoins(SelectBuilder builder, CteContext cteContext) { + for (String itemUid : cteContext.getCteKeys()) { + CteDefinition cteDef = cteContext.getDefinitionByItemUid(itemUid); + + // Handle Program Stage CTE (potentially with multiple offsets) + if (cteDef.isProgramStage()) { + for (Integer offset : cteDef.getOffsets()) { + String alias = cteDef.getAlias(offset); + builder.leftJoin( + itemUid, + alias, + tableAlias -> + tableAlias + + ".enrollment = ax.enrollment AND " + + tableAlias + + ".rn = " + + (offset + 1)); + } + } + + // Handle 'Exists' type CTE + if (cteDef.isExists()) { + builder.leftJoin(itemUid, "ee", tableAlias -> tableAlias + ".enrollment = ax.enrollment"); + } + + // Handle Program Indicator CTE + if (cteDef.isProgramIndicator()) { + String alias = cteDef.getAlias(); + builder.leftJoin(itemUid, alias, tableAlias -> tableAlias + ".enrollment = ax.enrollment"); + } + + // Handle Filter CTE + if (cteDef.isFilter()) { + String alias = cteDef.getAlias(); + builder.leftJoin(itemUid, alias, tableAlias -> tableAlias + ".enrollment = ax.enrollment"); + } + } + } + + /** + * Computes a zero-based offset for use with the SQL row_number() function in CTEs that + * partition and order events by date (e.g., most recent first). + * + *

In this context, an {@code offset} of 0 typically means “the most recent event” (row_number + * = 1), a positive offset means “the Nth future event after the most recent” (for example, offset + * = 1 means row_number = 2), and a negative offset means “the Nth older event before the most + * recent”. + * + *

Internally, this method transforms the supplied {@code offset} into a + * zero-based index, suitable for comparing against the row_number output. For + * instance: + * + *

    + *
  • If {@code offset == 0}, returns {@code 0}. + *
  • If {@code offset > 0}, returns {@code offset - 1} (i.e., offset 1 becomes 0-based 0). + *
  • If {@code offset < 0}, returns the absolute value ({@code -offset}). + *
+ * + * @param offset an integer specifying how many positions away from the most recent event + * (row_number = 1) you want to select. A positive offset selects a future row_number, a + * negative offset selects a past row_number, and zero selects the most recent. + * @return an integer representing the zero-based offset to use in a {@code row_number} comparison + */ + private int computeRowNumberOffset(int offset) { + if (offset == 0) { + return 0; + } + + if (offset < 0) { + return (-1 * offset); + } else { + return (offset - 1); + } + } + + private void generateFilterCTEs(EventQueryParams params, CteContext cteContext) { + // Combine items and item filters + List queryItems = + Stream.concat(params.getItems().stream(), params.getItemFilters().stream()) + .filter(QueryItem::hasFilter) + .toList(); + + // Group query items by repeatable and non-repeatable stages + Map> itemsByRepeatableFlag = + queryItems.stream() + .collect( + groupingBy( + queryItem -> + queryItem.hasRepeatableStageParams() + && params.getEndpointItem() + == RequestTypeAware.EndpointItem.ENROLLMENT)); + + // Process repeatable stage filters + itemsByRepeatableFlag.getOrDefault(true, List.of()).stream() + .collect(groupingBy(CteUtils::getIdentifier)) + .forEach( + (identifier, items) -> { + String cteSql = buildFilterCteSql(items, params); + // TODO is this correct? items.get(0) + cteContext.addCteFilter(items.get(0), cteSql); + }); + + // Process non-repeatable stage filters + itemsByRepeatableFlag + .getOrDefault(false, List.of()) + .forEach( + queryItem -> { + if (queryItem.hasProgram() && queryItem.hasProgramStage()) { + String cteSql = buildFilterCteSql(List.of(queryItem), params); + cteContext.addCteFilter(queryItem, cteSql); + } + }); + } + + private String buildAggregatedEnrollmentQueryWithCte( + List headers, EventQueryParams params) { + + CteContext cteContext = new CteContext(); + + // add base aggregation CTE + // and retain the columns from the root query + List rootQueryColumns = addBaseAggregationCte(cteContext, params, headers); + + // Add CTE definitions for program indicators, program stages, etc. + getCteDefinitions(params, cteContext); + + SelectBuilder sb = new SelectBuilder(); + + // add the CTE with clause based on the CTE definitions accumulated so far + addCteClause(sb, cteContext); + + // add select clause + sb.addColumn("count(eb.enrollment) as value"); + + // add the columns from the root CTE query + // excluding the enrollment column + // note that the columns are also added to the group by clause + rootQueryColumns.stream() + .filter(col -> !col.equals("enrollment")) + .peek(sb::groupBy) + .forEach(sb::addColumn); + + // add the columns from the CTE definitions + cteContext + .getCteKeys(ENROLLMENT_AGGR_BASE) + .forEach( + itemUid -> { + CteDefinition cteDef = cteContext.getDefinitionByItemUid(itemUid); + if (cteDef.isProgramStage()) { + String columnAlias = quote(cteDef.getProgramStageUid() + "." + cteDef.getItemId()); + sb.addColumn(cteDef.getAlias() + ".value", "", columnAlias); + sb.groupBy(columnAlias); + } + }); + + // add from + sb.from(ENROLLMENT_AGGR_BASE, "eb"); + + // Add join statements for each CTE definition + for (String itemUid : cteContext.getCteKeys(ENROLLMENT_AGGR_BASE)) { + CteDefinition cteDef = cteContext.getDefinitionByItemUid(itemUid); + sb.leftJoin( + itemUid, cteDef.getAlias(), tableAlias -> tableAlias + ".enrollment = eb.enrollment"); + } + + return sb.build(); + } + + private String buildEnrollmentQueryWithCte(EventQueryParams params) { + + // 1. Create the CTE context (collect all CTE definitions for program indicators, program + // stages, etc.) + CteContext cteContext = getCteDefinitions(params); + + // 2. Generate any additional CTE filters that might be needed + generateFilterCTEs(params, cteContext); + + // 3. Build up the final SQL using dedicated sub-steps + SelectBuilder sb = new SelectBuilder(); + + // 3.1: Append the WITH clause if needed + addCteClause(sb, cteContext); + + // 3.2: Append the SELECT clause, including columns from the CTE context + addSelectClause(sb, params, cteContext); + + // 3.3: Append the FROM clause (the main enrollment analytics table) + addFromClause(sb, params); + + // 3.4: Append LEFT JOINs for each relevant CTE definition + addCteJoins(sb, cteContext); + + // 3.5: Collect and append WHERE conditions (including filters from CTE) + addWhereClause(sb, params, cteContext); + + // 3.6: Append ORDER BY and paging + addSortingAndPaging(sb, params); + + return sb.build(); + } + + /** + * Appends the WITH clause using the CTE definitions from cteContext. If there are no CTE + * definitions, nothing is appended. + */ + private void addCteClause(SelectBuilder sb, CteContext cteContext) { + cteContext.getCteDefinitions().forEach(sb::withCTE); + } + + private boolean columnIsInFormula(String col) { + return col.contains("(") && col.contains(")"); + } + + /** + * Appends the SELECT clause, including both the standard enrollment columns (or aggregated + * columns) and columns derived from the CTE definitions. + */ + private void addSelectClause(SelectBuilder sb, EventQueryParams params, CteContext cteContext) { + + // Append standard columns or aggregated columns + if (params.isAggregatedEnrollments()) { + sb.addColumn("count(eb.enrollment) as value"); + } else { + getStandardColumns() + .forEach( + column -> { + if (columnIsInFormula(column)) { + sb.addColumn(column); + } else { + sb.addColumn(column, "ax"); + } + }); + } + + // Append columns from CTE definitions + getSelectColumnsWithCTE(params, cteContext).forEach(sb::addColumn); + } + + /** Appends the FROM clause, i.e. the main table name and alias. */ + private void addFromClause(SelectBuilder sb, EventQueryParams params) { + sb.from(params.getTableName(), "ax"); + } + + /** + * Collects the WHERE conditions from both the base enrollment table and the CTE-based filters, + * then appends them to the SQL. + */ + private void addWhereClause(SelectBuilder sb, EventQueryParams params, CteContext cteContext) { + Condition baseConditions = Condition.raw(getWhereClause(params)); + Condition cteConditions = Condition.raw(addCteFiltersToWhereClause(params, cteContext)); + sb.where(Condition.and(baseConditions, cteConditions)); + } + + private void addSortingAndPaging(SelectBuilder builder, EventQueryParams params) { + if (params.isSorting()) { + // Assuming getSortFields returns List + builder.orderBy(getSortClause(params)); + } + + // Paging with max limit of 5000 + if (params.isPaging()) { + if (params.isTotalPages()) { + builder.limitWithMax(params.getPageSizeWithDefault(), 5000).offset(params.getOffset()); + } else { + builder + .limitWithMaxPlusOne(params.getPageSizeWithDefault(), 5000) + .offset(params.getOffset()); + } + } else { + builder.limitPlusOne(5000); + } + } + + @Override + protected String getSortClause(EventQueryParams params) { + if (params.isSorting()) { + return super.getSortClause(params); + } + return ""; + } } diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/event/data/JdbcEventAnalyticsManager.java b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/event/data/JdbcEventAnalyticsManager.java index 23da08181fd1..1a2b084a5606 100644 --- a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/event/data/JdbcEventAnalyticsManager.java +++ b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/event/data/JdbcEventAnalyticsManager.java @@ -62,6 +62,7 @@ import org.hisp.dhis.analytics.Rectangle; import org.hisp.dhis.analytics.TimeField; import org.hisp.dhis.analytics.analyze.ExecutionPlanStore; +import org.hisp.dhis.analytics.common.CteContext; import org.hisp.dhis.analytics.common.ProgramIndicatorSubqueryBuilder; import org.hisp.dhis.analytics.event.EventAnalyticsManager; import org.hisp.dhis.analytics.event.EventQueryParams; @@ -85,6 +86,7 @@ import org.hisp.dhis.organisationunit.OrganisationUnit; import org.hisp.dhis.program.AnalyticsType; import org.hisp.dhis.program.ProgramIndicatorService; +import org.hisp.dhis.setting.SystemSettingsService; import org.hisp.dhis.system.util.ListBuilder; import org.postgresql.util.PSQLException; import org.springframework.beans.factory.annotation.Qualifier; @@ -115,13 +117,15 @@ public JdbcEventAnalyticsManager( ProgramIndicatorSubqueryBuilder programIndicatorSubqueryBuilder, EventTimeFieldSqlRenderer timeFieldSqlRenderer, ExecutionPlanStore executionPlanStore, + SystemSettingsService settingsService, SqlBuilder sqlBuilder) { super( jdbcTemplate, programIndicatorService, programIndicatorSubqueryBuilder, executionPlanStore, - sqlBuilder); + sqlBuilder, + settingsService); this.timeFieldSqlRenderer = timeFieldSqlRenderer; } @@ -391,6 +395,12 @@ private String getCoordinateSelectExpression(EventQueryParams params) { return String.format("ST_AsGeoJSON(%s, 6) as geometry", field); } + @Override + protected String getColumnWithCte(QueryItem item, String suffix, CteContext cteContext) { + // TODO: Implement + return ""; + } + /** * Returns a from SQL clause for the given analytics table partition. If the query has a * non-default time field specified, a join with the {@code date period structure} resource table diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/event/data/programindicator/DefaultProgramIndicatorSubqueryBuilder.java b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/event/data/programindicator/DefaultProgramIndicatorSubqueryBuilder.java index 13b83e647c82..bfd2cb060502 100644 --- a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/event/data/programindicator/DefaultProgramIndicatorSubqueryBuilder.java +++ b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/event/data/programindicator/DefaultProgramIndicatorSubqueryBuilder.java @@ -27,7 +27,6 @@ */ package org.hisp.dhis.analytics.event.data.programindicator; -import static org.apache.commons.lang3.StringUtils.isNotBlank; import static org.hisp.dhis.analytics.DataType.BOOLEAN; import static org.hisp.dhis.analytics.DataType.NUMERIC; @@ -38,6 +37,7 @@ import org.hisp.dhis.analytics.AggregationType; import org.hisp.dhis.analytics.AnalyticsTableType; import org.hisp.dhis.analytics.DataType; +import org.hisp.dhis.analytics.common.CteContext; import org.hisp.dhis.analytics.common.ProgramIndicatorSubqueryBuilder; import org.hisp.dhis.analytics.table.model.AnalyticsTable; import org.hisp.dhis.commons.util.TextUtils; @@ -45,6 +45,7 @@ import org.hisp.dhis.program.ProgramIndicator; import org.hisp.dhis.program.ProgramIndicatorService; import org.hisp.dhis.relationship.RelationshipType; +import org.hisp.dhis.setting.SystemSettingsService; import org.springframework.stereotype.Component; @Component @@ -58,6 +59,7 @@ public class DefaultProgramIndicatorSubqueryBuilder implements ProgramIndicatorS private static final String SUBQUERY_TABLE_ALIAS = "subax"; private final ProgramIndicatorService programIndicatorService; + private final SystemSettingsService settingsService; @Override public String getAggregateClauseForProgramIndicator( @@ -77,6 +79,84 @@ public String getAggregateClauseForProgramIndicator( programIndicator, relationshipType, outerSqlEntity, earliestStartDate, latestDate); } + @Override + public void contributeCte( + ProgramIndicator programIndicator, + AnalyticsType outerSqlEntity, + Date earliestStartDate, + Date latestDate, + CteContext cteContext) { + contributeCte( + programIndicator, null, outerSqlEntity, earliestStartDate, latestDate, cteContext); + } + + @Override + public void contributeCte( + ProgramIndicator programIndicator, + RelationshipType relationshipType, + AnalyticsType outerSqlEntity, + Date earliestStartDate, + Date latestDate, + CteContext cteContext) { + + // Define aggregation function + String function = + TextUtils.emptyIfEqual( + programIndicator.getAggregationTypeFallback().getValue(), + AggregationType.CUSTOM.getValue()); + + String filter = ""; + if (programIndicator.hasFilter()) { + + String piResolvedSqlFilter = + getProgramIndicatorSql( + programIndicator.getFilter(), + NUMERIC, + programIndicator, + earliestStartDate, + latestDate) + // FIXME this is a bit of an hack + .replace("subax\\.", ""); + filter = "where " + piResolvedSqlFilter; + } + + String piResolvedSql = + getProgramIndicatorSql( + programIndicator.getExpression(), + NUMERIC, + programIndicator, + earliestStartDate, + latestDate) + // FIXME this is a bit of an hack + .replace("subax\\.", ""); + + String cteSql = + "select enrollment, %s(%s) as value from %s %s group by enrollment" + .formatted(function, piResolvedSql, getTableName(programIndicator), filter); + + // Register the CTE and its column mapping + cteContext.addProgramIndicatorCte(programIndicator, cteSql, requireCoalesce(function)); + } + + /** + * Determine if the aggregation function requires a COALESCE function to handle NULL values. + * + * @param function the aggregation function + * @return true if the function requires a COALESCE function, false otherwise + */ + private boolean requireCoalesce(String function) { + return switch (function.toLowerCase()) { + // removed "avg" from list because it seems that it does not require COALESCE + // even though it is an aggregation function + case "count", "sum", "min", "max" -> true; + default -> false; + }; + } + + private String getTableName(ProgramIndicator programIndicator) { + return "analytics_event_" + programIndicator.getProgram().getUid().toLowerCase(); + } + /** * Generate a subquery based on the result of a Program Indicator and an (optional) Relationship * Type @@ -170,15 +250,15 @@ private String getWhere( SUBQUERY_TABLE_ALIAS, relationshipType, programIndicator.getAnalyticsType()); } else { if (AnalyticsType.ENROLLMENT == outerSqlEntity) { - condition = "enrollment = ax.enrollment"; + condition = useExperimentalAnalyticsQueryEngine() ? "" : "enrollment = ax.enrollment"; } else { if (AnalyticsType.EVENT == programIndicator.getAnalyticsType()) { - condition = "event = ax.event"; + condition = useExperimentalAnalyticsQueryEngine() ? "" : "event = ax.event"; } } } - return isNotBlank(condition) ? " WHERE " + condition : condition; + return !condition.isEmpty() ? " WHERE " + condition : ""; } /** @@ -205,4 +285,8 @@ private String getProgramIndicatorSql( latestDate, SUBQUERY_TABLE_ALIAS); } + + protected boolean useExperimentalAnalyticsQueryEngine() { + return this.settingsService.getCurrentSettings().getUseExperimentalAnalyticsQueryEngine(); + } } diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/Condition.java b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/Condition.java new file mode 100644 index 000000000000..9293d0644f21 --- /dev/null +++ b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/Condition.java @@ -0,0 +1,190 @@ +/* + * Copyright (c) 2004-2025, University of Oslo + * All rights reserved. + * + * Redistribution and use in source and binary forms, with or without + * modification, are permitted provided that the following conditions are met: + * Redistributions of source code must retain the above copyright notice, this + * list of conditions and the following disclaimer. + * + * Redistributions in binary form must reproduce the above copyright notice, + * this list of conditions and the following disclaimer in the documentation + * and/or other materials provided with the distribution. + * Neither the name of the HISP project nor the names of its contributors may + * be used to endorse or promote products derived from this software without + * specific prior written permission. + * + * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND + * ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED + * WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE + * DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR + * ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES + * (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; + * LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON + * ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT + * (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS + * SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + */ +package org.hisp.dhis.analytics.util.sql; + +import java.util.ArrayList; +import java.util.Arrays; +import java.util.Collection; +import java.util.List; +import java.util.stream.Collectors; + +/** + * Represents SQL conditions that can be used in WHERE and HAVING clauses. This interface provides a + * type-safe way to build SQL conditions using composition and various condition types (AND, OR, + * NOT). + */ +public sealed interface Condition + permits Condition.And, + Condition.Not, + Condition.Or, + Condition.Raw, + NotCondition, + SimpleCondition { + /** + * Converts the condition to its SQL string representation. + * + * @return the SQL string representation of the condition + */ + String toSql(); + + /** + * Represents a raw SQL condition string. Automatically removes leading "WHERE" or "AND" keywords. + * + *

Examples: + * + *

{@code
+   * // These will produce the same SQL:
+   * new Raw("active = true")            -> "active = true"
+   * new Raw("WHERE active = true")      -> "active = true"
+   * new Raw("AND active = true")        -> "active = true"
+   *
+   * // Complex conditions are preserved:
+   * new Raw("WHERE age >= 18 AND status IN ('ACTIVE', 'PENDING')")
+   *     -> "age >= 18 AND status IN ('ACTIVE', 'PENDING')"
+   *
+   * // Case insensitive keyword removal:
+   * new Raw("where active = true")      -> "active = true"
+   * new Raw("WHERE active = true")      -> "active = true"
+   * new Raw("And active = true")        -> "active = true"
+   * }
+ */ + record Raw(String sql) implements Condition { + @Override + public String toSql() { + if (sql == null || sql.trim().isEmpty()) { + return ""; + } + + // Remove only the first occurrence of WHERE or AND + String cleaned = sql.trim(); + if (cleaned.toLowerCase().matches("^(where|and)\\b.*")) { + cleaned = cleaned.replaceFirst("(?i)^(where|and)\\s+", ""); + } + + return cleaned.trim(); + } + } + + /** + * Represents multiple conditions combined with AND operator. Empty conditions are filtered out + * from the final SQL. + */ + record And(List conditions) implements Condition { + @Override + public String toSql() { + return conditions.stream() + .map(Condition::toSql) + .filter(s -> !s.isEmpty()) + .collect(Collectors.joining(" and ")); + } + } + + /** + * Represents multiple conditions combined with OR operator. Empty conditions are filtered out and + * each condition is wrapped in parentheses. + */ + record Or(List conditions) implements Condition { + @Override + public String toSql() { + return conditions.stream() + .map(Condition::toSql) + .filter(s -> !s.isEmpty()) + .map(sql -> "(" + sql + ")") + .collect(Collectors.joining(" or ")); + } + } + + /** Represents a negated condition. If the inner condition is empty, returns an empty string. */ + record Not(Condition condition) implements Condition { + @Override + public String toSql() { + String sql = condition.toSql(); + return sql.isEmpty() ? "" : "not (" + sql + ")"; + } + } + + /** + * Creates a condition from a raw SQL string. + * + * @param sql the SQL condition string + * @return a new Raw condition + */ + static Condition raw(String sql) { + return new Raw(sql); + } + + /** + * Combines multiple conditions with AND operator. + * + * @param conditions the conditions to combine + * @return a new And condition containing all provided conditions + */ + static Condition and(Condition... conditions) { + return new And(Arrays.asList(conditions)); + } + + /** + * Combines a collection of conditions with AND operator. + * + * @param conditions the collection of conditions to combine + * @return a new And condition containing all provided conditions + */ + static Condition and(Collection conditions) { + return new And(new ArrayList<>(conditions)); + } + + /** + * Combines multiple conditions with OR operator. + * + * @param conditions the conditions to combine + * @return a new Or condition containing all provided conditions + */ + static Condition or(Condition... conditions) { + return new Or(Arrays.asList(conditions)); + } + + /** + * Combines a collection of conditions with OR operator. + * + * @param conditions the collection of conditions to combine + * @return a new Or condition containing all provided conditions + */ + static Condition or(Collection conditions) { + return new Or(new ArrayList<>(conditions)); + } + + /** + * Creates a negated condition. + * + * @param condition the condition to negate + * @return a new Not condition wrapping the provided condition + */ + static Condition not(Condition condition) { + return new Not(condition); + } +} diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/JoinCondition.java b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/JoinCondition.java new file mode 100644 index 000000000000..5db96fc166b6 --- /dev/null +++ b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/JoinCondition.java @@ -0,0 +1,71 @@ +/* + * Copyright (c) 2004-2025, University of Oslo + * All rights reserved. + * + * Redistribution and use in source and binary forms, with or without + * modification, are permitted provided that the following conditions are met: + * Redistributions of source code must retain the above copyright notice, this + * list of conditions and the following disclaimer. + * + * Redistributions in binary form must reproduce the above copyright notice, + * this list of conditions and the following disclaimer in the documentation + * and/or other materials provided with the distribution. + * Neither the name of the HISP project nor the names of its contributors may + * be used to endorse or promote products derived from this software without + * specific prior written permission. + * + * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND + * ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED + * WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE + * DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR + * ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES + * (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; + * LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON + * ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT + * (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS + * SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + */ +package org.hisp.dhis.analytics.util.sql; + +/** + * Functional interface for building SQL JOIN conditions. The interface takes a table alias and + * returns the corresponding JOIN condition. + * + *

Examples: + * + *

{@code
+ * // Simple join on id
+ * JoinCondition idJoin = alias -> alias + ".user_id = users.id";
+ * // Usage: "LEFT JOIN orders o ON o.user_id = users.id"
+ *
+ * // Join with multiple conditions
+ * JoinCondition activeUserJoin = alias ->
+ *     alias + ".user_id = users.id AND " +
+ *     alias + ".status = 'ACTIVE'";
+ * // Usage: "LEFT JOIN orders o ON o.user_id = users.id AND o.status = 'ACTIVE'"
+ *
+ * // Join with date range
+ * JoinCondition dateRangeJoin = alias ->
+ *     alias + ".start_date <= CURRENT_DATE AND " +
+ *     alias + ".end_date >= CURRENT_DATE";
+ * // Usage: "LEFT JOIN periods p ON p.start_date <= CURRENT_DATE AND p.end_date >= CURRENT_DATE"
+ * }
+ * + *

Typical usage in SelectBuilder: + * + *

{@code
+ * SelectBuilder builder = new SelectBuilder()
+ *     .from("users", "u")
+ *     .leftJoin("orders", "o", alias -> alias + ".user_id = u.id");
+ * }
+ */ +@FunctionalInterface +public interface JoinCondition { + /** + * Builds a JOIN condition string using the provided table alias. + * + * @param alias the alias of the table being joined + * @return the SQL JOIN condition string + */ + String build(String alias); +} diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/NotCondition.java b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/NotCondition.java new file mode 100644 index 000000000000..496c6fa2c8c6 --- /dev/null +++ b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/NotCondition.java @@ -0,0 +1,57 @@ +/* + * Copyright (c) 2004-2025, University of Oslo + * All rights reserved. + * + * Redistribution and use in source and binary forms, with or without + * modification, are permitted provided that the following conditions are met: + * Redistributions of source code must retain the above copyright notice, this + * list of conditions and the following disclaimer. + * + * Redistributions in binary form must reproduce the above copyright notice, + * this list of conditions and the following disclaimer in the documentation + * and/or other materials provided with the distribution. + * Neither the name of the HISP project nor the names of its contributors may + * be used to endorse or promote products derived from this software without + * specific prior written permission. + * + * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND + * ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED + * WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE + * DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR + * ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES + * (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; + * LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON + * ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT + * (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS + * SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + */ +package org.hisp.dhis.analytics.util.sql; + +/** + * Represents a negated SQL condition. Wraps another condition with a NOT operator and parentheses. + * + *

Examples: + * + *

{@code
+ * // Simple negation
+ * new NotCondition(new SimpleCondition("active = true"))
+ *     -> "NOT (active = true)"
+ *
+ * // Negating complex conditions
+ * new NotCondition(Condition.and(
+ *     new SimpleCondition("status = 'ACTIVE'"),
+ *     new SimpleCondition("age >= 18")
+ * ))
+ *     -> "NOT (status = 'ACTIVE' and age >= 18)"
+ *
+ * // Can be created using the factory method
+ * Condition.not(new SimpleCondition("in_stock = true"))
+ *     -> "NOT (in_stock = true)"
+ * }
+ */ +public record NotCondition(Condition condition) implements Condition { + @Override + public String toSql() { + return "NOT (" + condition.toSql() + ")"; + } +} diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/SelectBuilder.java b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/SelectBuilder.java new file mode 100644 index 000000000000..eab082a3d1bb --- /dev/null +++ b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/SelectBuilder.java @@ -0,0 +1,753 @@ +/* + * Copyright (c) 2004-2025, University of Oslo + * All rights reserved. + * + * Redistribution and use in source and binary forms, with or without + * modification, are permitted provided that the following conditions are met: + * Redistributions of source code must retain the above copyright notice, this + * list of conditions and the following disclaimer. + * + * Redistributions in binary form must reproduce the above copyright notice, + * this list of conditions and the following disclaimer in the documentation + * and/or other materials provided with the distribution. + * Neither the name of the HISP project nor the names of its contributors may + * be used to endorse or promote products derived from this software without + * specific prior written permission. + * + * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND + * ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED + * WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE + * DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR + * ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES + * (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; + * LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON + * ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT + * (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS + * SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + */ +package org.hisp.dhis.analytics.util.sql; + +import java.util.ArrayList; +import java.util.Arrays; +import java.util.List; +import java.util.stream.Collectors; + +/** + * A fluent builder for creating SQL SELECT queries. Supports common SQL features including CTEs, + * JOINs, WHERE conditions, GROUP BY, HAVING, ORDER BY, and pagination. + * + *

Example usage: + * + *

{@code
+ * String sql = new SelectBuilder()
+ *     .withCTE("active_users", "SELECT id FROM users WHERE active = true")
+ *     .addColumn("u.name")
+ *     .addColumn("COUNT(o.id)", "order_count")
+ *     .from("users", "u")
+ *     .leftJoin("orders", "o", alias -> alias + ".user_id = u.id")
+ *     .where(Condition.raw("u.id IN (SELECT id FROM active_users)"))
+ *     .groupBy("u.name")
+ *     .having(Condition.raw("COUNT(o.id) > 0"))
+ *     .orderBy("order_count", "DESC", "NULLS LAST")
+ *     .limit(10)
+ *     .build();
+ * }
+ */ +public class SelectBuilder { + /** Maximum limit for pagination to prevent excessive resource usage */ + private static final int DEFAULT_MAX_LIMIT = 5000; + + private final List ctes = new ArrayList<>(); + private final List columns = new ArrayList<>(); + private String fromTable; + private String fromAlias; + private final List joins = new ArrayList<>(); + private Condition whereCondition; + private final List groupByClauses = new ArrayList<>(); + private final List havingConditions = new ArrayList<>(); + private final List orderByClauses = new ArrayList<>(); + private Integer limit; + private Integer offset; + + /** + * Represents a column in the SELECT clause of a SQL query. Handles column expressions with + * optional table prefix and column aliases. + * + *

Examples: + * + *

{@code
+   * // Simple column with table prefix
+   * new Column("name", "u", null)               -> "u.name"
+   *
+   * // Column with table prefix and alias
+   * new Column("first_name", "u", "name")       -> "u.first_name AS name"
+   *
+   * // Aggregate function with alias
+   * new Column("COUNT(*)", null, "total")       -> "COUNT(*) AS total"
+   *
+   * // Expression with alias
+   * new Column("COALESCE(name, 'Unknown')", "u", "display_name")
+   *     -> "u.COALESCE(name, 'Unknown') AS display_name"
+   * }
+ */ + public record Column(String expression, String tablePrefix, String alias) { + /** + * Creates a column with just an expression. + * + * @param expression the column expression + * @return a new Column without prefix or alias + */ + public static Column of(String expression) { + return new Column(expression, null, null); + } + + /** + * Creates a column with an expression and table prefix. + * + * @param expression the column expression + * @param tablePrefix the table prefix/alias + * @return a new Column with prefix + */ + public static Column withPrefix(String expression, String tablePrefix) { + return new Column(expression, tablePrefix, null); + } + + /** + * Creates a column with an expression and alias. + * + * @param expression the column expression + * @param alias the column alias + * @return a new Column with alias + */ + public static Column withAlias(String expression, String alias) { + return new Column(expression, null, alias); + } + + /** + * Converts the column definition to its SQL string representation. + * + * @return the SQL string representation of the column + */ + public String toSql() { + StringBuilder sql = new StringBuilder(); + + // Add table prefix if present + if (tablePrefix != null && !tablePrefix.isEmpty()) { + sql.append(tablePrefix).append("."); + } + + // Add the expression + sql.append(expression); + + // Add alias if present + if (alias != null && !alias.isEmpty()) { + sql.append(" AS ").append(alias); + } + + return sql.toString(); + } + } + + /** + * Represents a Common Table Expression (CTE). CTEs are temporary named result sets that exist for + * the duration of the query. + * + *

Example: + * + *

{@code
+   * new CommonTableExpression("active_users",
+   *     "SELECT id FROM users WHERE status = 'ACTIVE'")
+   *     -> "active_users AS (
+   *         SELECT id FROM users WHERE status = 'ACTIVE'
+   *         )"
+   * }
+ */ + public record CommonTableExpression(String name, String query) { + public String toSql() { + return name + " AS (\n" + query + "\n)"; + } + } + + /** + * Represents a LEFT JOIN clause. Includes the table name, alias, and join condition. + * + *

Example: + * + *

{@code
+   * new Join("orders", "o", "o.user_id = u.id")
+   *     -> "LEFT JOIN orders o ON o.user_id = u.id"
+   * }
+ */ + public record Join(String table, String alias, String condition) { + public String toSql() { + return String.format("LEFT JOIN %s %s ON %s", table, alias, condition); + } + } + + /** + * Represents an ORDER BY clause. Supports direction (ASC/DESC) and NULL handling (NULLS + * FIRST/LAST). + * + *

Examples: + * + *

{@code
+   * new OrderByClause("name", "ASC", null)           -> "name ASC"
+   * new OrderByClause("age", "DESC", "NULLS LAST")   -> "age DESC NULLS LAST"
+   * new OrderByClause("status", null, "NULLS FIRST") -> "status NULLS FIRST"
+   * }
+ */ + public record OrderByClause(String column, String direction, String nullHandling) { + public String toSql() { + StringBuilder sb = new StringBuilder(column); + if (direction != null) { + sb.append(" ").append(direction); + } + if (nullHandling != null) { + sb.append(" ").append(nullHandling); + } + return sb.toString(); + } + } + + /** + * Adds a Common Table Expression (CTE) to the query. + * + * @param name the name of the CTE + * @param query the SELECT query that defines the CTE + * @return this builder instance + *

Example: + *

{@code
+   * builder.withCTE("active_users",
+   *     "SELECT id FROM users WHERE status = 'ACTIVE'")
+   * }
+ */ + public SelectBuilder withCTE(String name, String query) { + ctes.add(new CommonTableExpression(name, query)); + return this; + } + + /** + * Adds a column with table prefix. + * + * @param expression the column expression + * @param tablePrefix the table prefix/alias + * @return this builder instance + */ + public SelectBuilder addColumn(String expression, String tablePrefix) { + columns.add(Column.withPrefix(expression, tablePrefix)); + return this; + } + + public List getColumnNames() { + return columns.stream().map(Column::expression).toList(); + } + + /** + * Adds a column with an alias. + * + * @param expression the column expression + * @param tablePrefix the table prefix/alias + * @param alias the column alias + * @return this builder instance + */ + public SelectBuilder addColumn(String expression, String tablePrefix, String alias) { + columns.add(new Column(expression, tablePrefix, alias)); + return this; + } + + /** + * Adds a simple column without prefix or alias. + * + * @param expression the column expression + * @return this builder instance + */ + public SelectBuilder addColumn(String expression) { + columns.add(Column.of(expression)); + return this; + } + + public SelectBuilder addColumnIfNotExist(String expression) { + String flattenedColumns = + columns.stream().map(Column::expression).collect(Collectors.joining(",")); + + if (!flattenedColumns.contains(unquote(expression))) { + columns.add(Column.of(expression)); + } + return this; + } + + /** + * Sets the FROM clause table without an alias. + * + * @param table the table name + * @return this builder instance + */ + public SelectBuilder from(String table) { + this.fromTable = sanitizeFromClause(table); + return this; + } + + /** + * Sets the FROM clause table with an alias. + * + * @param table the table name + * @param alias the table alias + * @return this builder instance + *

Example: + *

{@code
+   * builder.from("users", "u")
+   * }
+ */ + public SelectBuilder from(String table, String alias) { + this.fromTable = sanitizeFromClause(table); + ; + this.fromAlias = alias; + return this; + } + + /** + * Adds a LEFT JOIN clause to the query. + * + * @param table the table to join + * @param alias the alias for the joined table + * @param condition the join condition builder + * @return this builder instance + *

Example: + *

{@code
+   * builder.leftJoin("orders", "o",
+   *     alias -> alias + ".user_id = u.id")
+   * }
+ */ + public SelectBuilder leftJoin(String table, String alias, JoinCondition condition) { + joins.add(new Join(table, alias, condition.build(alias))); + return this; + } + + /** + * Sets the WHERE clause condition. + * + * @param condition the WHERE condition + * @return this builder instance + *

Example: + *

{@code
+   * builder.where(Condition.and(
+   *     Condition.raw("active = true"),
+   *     Condition.raw("age >= 18")
+   * ))
+   * }
+ */ + public SelectBuilder where(Condition condition) { + this.whereCondition = condition; + return this; + } + + /** + * Adds a HAVING clause condition. Multiple conditions are combined with AND. + * + * @param condition the HAVING condition + * @return this builder instance + *

Example: + *

{@code
+   * builder.having(Condition.raw("COUNT(*) > 0"))
+   * }
+ */ + public SelectBuilder having(Condition condition) { + havingConditions.add(condition); + return this; + } + + /** + * Adds GROUP BY columns. + * + * @param columns the columns to group by + * @return this builder instance + *

Example: + *

{@code
+   * builder.groupBy("department", "status")
+   * }
+ */ + public SelectBuilder groupBy(String... columns) { + groupByClauses.addAll(Arrays.asList(columns)); + return this; + } + + /** + * Adds a GROUP BY column. + * + * @param column the column to group by + * @return this builder instance + */ + public SelectBuilder groupBy(String column) { + groupByClauses.add(column); + return this; + } + + /** + * Adds an ORDER BY clause with direction. + * + * @param column the column to sort by + * @param direction the sort direction ("ASC" or "DESC") + * @return this builder instance + */ + public SelectBuilder orderBy(String column, String direction) { + return orderBy(column, direction, null); + } + + /** + * Adds an ORDER BY clause with direction and NULL handling. + * + * @param column the column to sort by + * @param direction the sort direction ("ASC" or "DESC") + * @param nullHandling the NULL handling ("NULLS FIRST" or "NULLS LAST") + * @return this builder instance + *

Example: + *

{@code
+   * builder.orderBy("last_updated", "DESC", "NULLS LAST")
+   * }
+ */ + public SelectBuilder orderBy(String column, String direction, String nullHandling) { + orderByClauses.add(new OrderByClause(column, direction, nullHandling)); + return this; + } + + /** + * Parses and adds ORDER BY clauses from a raw SQL string. Handles complex expressions including + * CASE statements. + * + * @param rawSortClause the raw ORDER BY clause + * @return this builder instance + *

Example: + *

{@code
+   * builder.orderBy("name ASC, created_at DESC NULLS LAST")
+   * builder.orderBy("CASE WHEN active THEN 1 ELSE 2 END DESC")
+   * }
+ */ + public SelectBuilder orderBy(String rawSortClause) { + if (rawSortClause == null || rawSortClause.trim().isEmpty()) { + return this; + } + + // Remove "order by" prefix if present + String cleaned = rawSortClause.trim().replaceFirst("(?i)^order\\s+by\\s+", ""); + + // Split by commas, but not commas within CASE statements + List parts = splitPreservingCaseStatements(cleaned); + + for (String part : parts) { + String trimmed = part.trim(); + if (!trimmed.isEmpty()) { + // Extract direction and null handling from the end + String[] directionParts = extractDirectionAndNulls(trimmed); + String column = directionParts[0]; + String direction = directionParts[1]; + String nullHandling = directionParts[2]; + + orderByClauses.add(new OrderByClause(column, direction, nullHandling)); + } + } + + return this; + } + + /** + * Adds multiple ORDER BY clauses. + * + * @param clauses the list of ORDER BY clauses + * @return this builder instance + */ + public SelectBuilder orderBy(List clauses) { + orderByClauses.addAll(clauses); + return this; + } + + /** + * Sets the LIMIT clause with a maximum value of {@value DEFAULT_MAX_LIMIT}. + * + * @param limit the maximum number of rows to return + * @return this builder instance + */ + public SelectBuilder limit(int limit) { + this.limit = Math.min(limit, DEFAULT_MAX_LIMIT); + return this; + } + + /** + * Sets the LIMIT clause to the specified value plus one. Useful for detecting if there are more + * rows available. + * + * @param limit the base limit value + * @return this builder instance + */ + public SelectBuilder limitPlusOne(int limit) { + this.limit = limit + 1; + return this; + } + + /** + * Sets the LIMIT clause with a specified maximum value. + * + * @param limit the desired limit + * @param maxLimit the maximum allowed limit + * @return this builder instance + */ + public SelectBuilder limitWithMax(int limit, int maxLimit) { + this.limit = Math.min(limit, maxLimit); + return this; + } + + /** + * Sets the LIMIT clause to the minimum of the specified limit and maxLimit, plus one. + * + * @param limit the desired limit + * @param maxLimit the maximum allowed limit + * @return this builder instance + */ + public SelectBuilder limitWithMaxPlusOne(int limit, int maxLimit) { + this.limit = Math.min(limit, maxLimit) + 1; + return this; + } + + /** + * Sets the OFFSET clause. + * + * @param offset the number of rows to skip + * @return this builder instance + */ + public SelectBuilder offset(int offset) { + this.offset = offset; + return this; + } + + /** + * Builds the SQL query string with all keywords in lowercase. + * + * @return the complete SQL query string + */ + public String build() { + return SqlFormatter.lowercase(buildQuery()); + } + + public String getWhereClause() { + return whereCondition.toSql(); + } + + /** + * Builds the SQL query string with formatting for readability. + * + * @return the formatted SQL query string + */ + public String buildPretty() { + return SqlFormatter.prettyPrint(build()); + } + + private String buildQuery() { + StringBuilder sql = new StringBuilder(); + appendCTEs(sql); + appendSelectClause(sql); + appendFromClause(sql); + appendJoins(sql); + appendWhereClause(sql); + appendGroupByClause(sql); + appendHavingClause(sql); + appendOrderByClause(sql); + appendPagination(sql); + return sql.toString(); + } + + private void appendCTEs(StringBuilder sql) { + if (ctes.isEmpty()) { + return; + } + sql.append("with ") + .append(ctes.stream().map(CommonTableExpression::toSql).collect(Collectors.joining(", "))) + .append(" "); + } + + private void appendSelectClause(StringBuilder sql) { + sql.append("select ") + .append(columns.stream().map(Column::toSql).collect(Collectors.joining(", "))); + } + + private void appendFromClause(StringBuilder sql) { + sql.append(" from ").append(fromTable); + + if (fromAlias != null) { + sql.append(" as ").append(fromAlias); + } + } + + private void appendJoins(StringBuilder sql) { + if (joins.isEmpty()) { + return; + } + sql.append(" ").append(joins.stream().map(Join::toSql).collect(Collectors.joining(" "))); + } + + private void appendWhereClause(StringBuilder sql) { + if (whereCondition != null) { + String whereSql = whereCondition.toSql(); + sql.append(whereSql.isEmpty() ? "" : " where " + whereSql); + } + } + + private void appendGroupByClause(StringBuilder sql) { + if (groupByClauses.isEmpty()) { + return; + } + sql.append(" group by ").append(String.join(", ", groupByClauses)); + } + + private void appendHavingClause(StringBuilder sql) { + if (havingConditions.isEmpty()) { + return; + } + sql.append(" having ") + .append( + havingConditions.stream().map(Condition::toSql).collect(Collectors.joining(" and "))); + } + + private void appendOrderByClause(StringBuilder sql) { + if (orderByClauses.isEmpty()) { + return; + } + sql.append(" order by ") + .append( + orderByClauses.stream().map(OrderByClause::toSql).collect(Collectors.joining(", "))); + } + + private void appendPagination(StringBuilder sql) { + if (limit != null) { + sql.append(" limit ").append(limit); + } + if (offset != null) { + sql.append(" offset ").append(offset); + } + } + + private List splitPreservingCaseStatements(String input) { + List results = new ArrayList<>(); + StringBuilder current = new StringBuilder(); + int depth = 0; + boolean inCase = false; + + for (char c : input.toCharArray()) { + if (c == '(') { + depth++; + } else if (c == ')') { + depth--; + } else if (c == 'C' && current.toString().trim().isEmpty()) { + // Potential start of CASE + inCase = true; + } else if (inCase && current.toString().trim().endsWith("END")) { + // End of CASE statement + inCase = false; + } + + if (c == ',' && depth == 0 && !inCase) { + results.add(current.toString()); + current = new StringBuilder(); + } else { + current.append(c); + } + } + + if (!current.isEmpty()) { + results.add(current.toString()); + } + + return results; + } + + private String[] extractDirectionAndNulls(String expr) { + String column = expr.trim(); + String direction = null; + String nullHandling = null; + + // Extract NULLS FIRST/LAST if present + String[] parts = extractNullHandling(column); + column = parts[0]; + nullHandling = parts[1]; + + // Extract direction if present + parts = extractDirection(column); + column = parts[0]; + direction = parts[1]; + + return new String[] {column, direction, nullHandling}; + } + + private String[] extractNullHandling(String expr) { + String column = expr; + String nullHandling = null; + + String upperExpr = expr.toUpperCase(); + if (upperExpr.endsWith("NULLS LAST") || upperExpr.endsWith("NULLS FIRST")) { + int nullsIndex = upperExpr.lastIndexOf("NULLS"); + nullHandling = expr.substring(nullsIndex).trim(); + column = expr.substring(0, nullsIndex).trim(); + } + + return new String[] {column, nullHandling}; + } + + private String[] extractDirection(String expr) { + String column = expr; + String direction = null; + + int lastSpace = expr.lastIndexOf(' '); + if (lastSpace > 0) { + String lastWord = expr.substring(lastSpace + 1).trim().toUpperCase(); + if (lastWord.equals("ASC") || lastWord.equals("DESC")) { + direction = lastWord; + column = expr.substring(0, lastSpace).trim(); + } + } + + return new String[] {column, direction}; + } + + /** + * Sanitizes the FROM clause by removing any leading or trailing "FROM" keyword. + * + * @param input the input string + * @return the sanitized string + */ + private String sanitizeFromClause(String input) { + if (input == null) { + return null; + } + + // Trim whitespace and remove leading/trailing "FROM" keyword (case-insensitive) + String sanitized = input.trim(); + if (sanitized.toUpperCase().startsWith("FROM ")) { + sanitized = sanitized.substring(5).trim(); + } + if (sanitized.toUpperCase().endsWith(" FROM")) { + sanitized = sanitized.substring(0, sanitized.length() - 5).trim(); + } + + return sanitized; + } + + private static String unquote(String quoted) { + // Handle null or empty + if (quoted == null || quoted.isEmpty()) { + return ""; + } + + // Check minimum length (needs at least 2 chars for quotes) + if (quoted.length() < 2) { + return quoted; + } + + char firstChar = quoted.charAt(0); + char lastChar = quoted.charAt(quoted.length() - 1); + + // Check if quotes match + if ((firstChar == '"' && lastChar == '"') || (firstChar == '`' && lastChar == '`')) { + return quoted.substring(1, quoted.length() - 1); + } + + return quoted; + } +} diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/SimpleCondition.java b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/SimpleCondition.java new file mode 100644 index 000000000000..c8075c78fa6b --- /dev/null +++ b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/SimpleCondition.java @@ -0,0 +1,63 @@ +/* + * Copyright (c) 2004-2025, University of Oslo + * All rights reserved. + * + * Redistribution and use in source and binary forms, with or without + * modification, are permitted provided that the following conditions are met: + * Redistributions of source code must retain the above copyright notice, this + * list of conditions and the following disclaimer. + * + * Redistributions in binary form must reproduce the above copyright notice, + * this list of conditions and the following disclaimer in the documentation + * and/or other materials provided with the distribution. + * Neither the name of the HISP project nor the names of its contributors may + * be used to endorse or promote products derived from this software without + * specific prior written permission. + * + * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND + * ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED + * WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE + * DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR + * ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES + * (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; + * LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON + * ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT + * (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS + * SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + */ +package org.hisp.dhis.analytics.util.sql; + +/** + * Represents a basic SQL condition string without any transformation. Unlike {@link Condition.Raw}, + * this condition does not remove leading WHERE/AND keywords. + * + *

Examples: + * + *

{@code
+ * // Basic conditions
+ * new SimpleCondition("active = true")
+ *     -> "active = true"
+ *
+ * // Comparison operations
+ * new SimpleCondition("age >= 18")
+ *     -> "age >= 18"
+ *
+ * // IN clauses
+ * new SimpleCondition("status IN ('ACTIVE', 'PENDING')")
+ *     -> "status IN ('ACTIVE', 'PENDING')"
+ *
+ * // LIKE patterns
+ * new SimpleCondition("name LIKE 'John%'")
+ *     -> "name LIKE 'John%'"
+ *
+ * // Complex conditions
+ * new SimpleCondition("(age >= 18 AND status = 'ACTIVE')")
+ *     -> "(age >= 18 AND status = 'ACTIVE')"
+ * }
+ */ +public record SimpleCondition(String condition) implements Condition { + @Override + public String toSql() { + return condition; + } +} diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/SqlAliasReplacer.java b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/SqlAliasReplacer.java new file mode 100644 index 000000000000..5069f06cbbec --- /dev/null +++ b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/SqlAliasReplacer.java @@ -0,0 +1,142 @@ +/* + * Copyright (c) 2004-2025, University of Oslo + * All rights reserved. + * + * Redistribution and use in source and binary forms, with or without + * modification, are permitted provided that the following conditions are met: + * Redistributions of source code must retain the above copyright notice, this + * list of conditions and the following disclaimer. + * + * Redistributions in binary form must reproduce the above copyright notice, + * this list of conditions and the following disclaimer in the documentation + * and/or other materials provided with the distribution. + * Neither the name of the HISP project nor the names of its contributors may + * be used to endorse or promote products derived from this software without + * specific prior written permission. + * + * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND + * ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED + * WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE + * DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR + * ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES + * (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; + * LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON + * ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT + * (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS + * SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + */ +package org.hisp.dhis.analytics.util.sql; + +import java.util.List; +import java.util.Set; +import java.util.stream.Collectors; +import lombok.experimental.UtilityClass; +import net.sf.jsqlparser.expression.Expression; +import net.sf.jsqlparser.expression.ExpressionVisitorAdapter; +import net.sf.jsqlparser.expression.Function; +import net.sf.jsqlparser.parser.CCJSqlParserUtil; +import net.sf.jsqlparser.schema.Column; +import net.sf.jsqlparser.schema.Table; +import net.sf.jsqlparser.statement.select.PlainSelect; +import net.sf.jsqlparser.statement.select.SelectExpressionItem; +import net.sf.jsqlparser.statement.select.SubSelect; + +@UtilityClass +public class SqlAliasReplacer { + + public static String replaceTableAliases(String whereClause, List columns) { + if (whereClause == null || columns == null) { + throw new IllegalArgumentException("Where clause and columns list cannot be null"); + } + + if (whereClause.isEmpty() || columns.isEmpty()) { + return whereClause; + } + + try { + Expression expr = CCJSqlParserUtil.parseCondExpression(whereClause); + ColumnReplacementVisitor visitor = new ColumnReplacementVisitor(columns); + expr.accept(visitor); + return expr.toString(); + } catch (Exception e) { + throw new RuntimeException("Error parsing SQL where clause: " + e.getMessage(), e); + } + } + + private static class ColumnReplacementVisitor extends ExpressionVisitorAdapter { + private final Set columns; + private static final Table PLACEHOLDER_TABLE = new Table("%s"); + private boolean inSubQuery = false; + + public ColumnReplacementVisitor(List columns) { + this.columns = + columns.stream() + .map(String::toLowerCase) + .map(this::stripQuotes) + .collect(Collectors.toSet()); + } + + @Override + public void visit(Column column) { + String columnName = column.getColumnName(); + String rawColumnName = stripQuotes(columnName); + + if (columns.contains(rawColumnName.toLowerCase())) { + String quoteType = getQuoteType(columnName); + if (!quoteType.isEmpty()) { + column.setColumnName(quoteType + rawColumnName + quoteType); + } + if (!inSubQuery) { + column.setTable(PLACEHOLDER_TABLE); + } else { + column.setTable(null); + } + } + } + + @Override + public void visit(SubSelect subSelect) { + boolean wasInSubQuery = inSubQuery; + inSubQuery = true; + + if (subSelect.getSelectBody() instanceof PlainSelect) { + PlainSelect plainSelect = (PlainSelect) subSelect.getSelectBody(); + plainSelect + .getSelectItems() + .forEach( + selectItem -> { + if (selectItem instanceof SelectExpressionItem) { + SelectExpressionItem sei = (SelectExpressionItem) selectItem; + Expression expression = sei.getExpression(); + if (expression instanceof Function) { + Function function = (Function) expression; + function.accept(this); + } + } + }); + } + + inSubQuery = wasInSubQuery; + } + + private String stripQuotes(String identifier) { + if (identifier == null) return ""; + + if ((identifier.startsWith("\"") && identifier.endsWith("\"")) + || (identifier.startsWith("`") && identifier.endsWith("`")) + || (identifier.startsWith("'") && identifier.endsWith("'"))) { + return identifier.substring(1, identifier.length() - 1); + } + return identifier; + } + + private String getQuoteType(String identifier) { + if (identifier == null) return ""; + + if (identifier.startsWith("\"")) return "\""; + if (identifier.startsWith("`")) return "`"; + if (identifier.startsWith("'")) return "'"; + return ""; + } + } +} diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/SqlColumnParser.java b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/SqlColumnParser.java new file mode 100644 index 000000000000..b96b9f78b69d --- /dev/null +++ b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/SqlColumnParser.java @@ -0,0 +1,89 @@ +/* + * Copyright (c) 2004-2025, University of Oslo + * All rights reserved. + * + * Redistribution and use in source and binary forms, with or without + * modification, are permitted provided that the following conditions are met: + * Redistributions of source code must retain the above copyright notice, this + * list of conditions and the following disclaimer. + * + * Redistributions in binary form must reproduce the above copyright notice, + * this list of conditions and the following disclaimer in the documentation + * and/or other materials provided with the distribution. + * Neither the name of the HISP project nor the names of its contributors may + * be used to endorse or promote products derived from this software without + * specific prior written permission. + * + * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND + * ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED + * WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE + * DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR + * ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES + * (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; + * LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON + * ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT + * (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS + * SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + */ +package org.hisp.dhis.analytics.util.sql; + +import lombok.experimental.UtilityClass; +import net.sf.jsqlparser.expression.Expression; +import net.sf.jsqlparser.parser.CCJSqlParserUtil; +import net.sf.jsqlparser.schema.Column; + +@UtilityClass +public class SqlColumnParser { + + /** + * Removes table alias from a SQL column reference using JSqlParser. Handles quoted column names + * and complex SQL expressions. + * + * @param columnReference The SQL column reference (e.g., "ax.uidlevel2", "test1.`alfa`") + * @return The column name without the table alias (e.g., "uidlevel2", "alfa") + */ + public static String removeTableAlias(String columnReference) { + if (columnReference == null || columnReference.isEmpty()) { + return columnReference; + } + + try { + // Parse the column reference using JSqlParser + Expression expression = CCJSqlParserUtil.parseExpression(columnReference); + + // Ensure the parsed expression is a Column + if (!(expression instanceof Column column)) { + throw new IllegalArgumentException( + "Input is not a valid SQL column reference: " + columnReference); + } + + // Extract the column name + return unquote(column.getColumnName()); + } catch (Exception e) { + throw new RuntimeException("Error parsing SQL: " + e.getMessage(), e); + } + } + + // FIXME - this method is duplicated in SqlWhereClauseExtractor + private static String unquote(String quoted) { + // Handle null or empty + if (quoted == null || quoted.isEmpty()) { + return ""; + } + + // Check minimum length (needs at least 2 chars for quotes) + if (quoted.length() < 2) { + return quoted; + } + + char firstChar = quoted.charAt(0); + char lastChar = quoted.charAt(quoted.length() - 1); + + // Check if quotes match + if ((firstChar == '"' && lastChar == '"') || (firstChar == '`' && lastChar == '`')) { + return quoted.substring(1, quoted.length() - 1); + } + + return quoted; + } +} diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/SqlConditionJoiner.java b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/SqlConditionJoiner.java new file mode 100644 index 000000000000..af51d0cb1173 --- /dev/null +++ b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/SqlConditionJoiner.java @@ -0,0 +1,62 @@ +/* + * Copyright (c) 2004-2025, University of Oslo + * All rights reserved. + * + * Redistribution and use in source and binary forms, with or without + * modification, are permitted provided that the following conditions are met: + * Redistributions of source code must retain the above copyright notice, this + * list of conditions and the following disclaimer. + * + * Redistributions in binary form must reproduce the above copyright notice, + * this list of conditions and the following disclaimer in the documentation + * and/or other materials provided with the distribution. + * Neither the name of the HISP project nor the names of its contributors may + * be used to endorse or promote products derived from this software without + * specific prior written permission. + * + * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND + * ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED + * WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE + * DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR + * ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES + * (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; + * LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON + * ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT + * (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS + * SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + */ +package org.hisp.dhis.analytics.util.sql; + +public class SqlConditionJoiner { + + public static String joinSqlConditions(String... conditions) { + if (conditions == null || conditions.length == 0) { + return ""; + } + + StringBuilder result = new StringBuilder("where "); + boolean firstCondition = true; + + for (String condition : conditions) { + if (condition == null || condition.trim().isEmpty()) { + continue; + } + + // Remove leading "where" or " where" and trim + String cleanedCondition = condition.trim(); + if (cleanedCondition.toLowerCase().startsWith("where")) { + cleanedCondition = cleanedCondition.substring(5).trim(); + } + + if (!cleanedCondition.isEmpty()) { + if (!firstCondition) { + result.append(" and "); + } + result.append(cleanedCondition); + firstCondition = false; + } + } + + return result.toString(); + } +} diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/SqlFormatter.java b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/SqlFormatter.java new file mode 100644 index 000000000000..fbc595c74001 --- /dev/null +++ b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/SqlFormatter.java @@ -0,0 +1,166 @@ +/* + * Copyright (c) 2004-2025, University of Oslo + * All rights reserved. + * + * Redistribution and use in source and binary forms, with or without + * modification, are permitted provided that the following conditions are met: + * Redistributions of source code must retain the above copyright notice, this + * list of conditions and the following disclaimer. + * + * Redistributions in binary form must reproduce the above copyright notice, + * this list of conditions and the following disclaimer in the documentation + * and/or other materials provided with the distribution. + * Neither the name of the HISP project nor the names of its contributors may + * be used to endorse or promote products derived from this software without + * specific prior written permission. + * + * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND + * ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED + * WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE + * DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR + * ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES + * (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; + * LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON + * ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT + * (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS + * SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + */ +package org.hisp.dhis.analytics.util.sql; + +import java.util.Set; + +public class SqlFormatter { + private static final Set MAIN_CLAUSES = + Set.of( + "with", + "select", + "from", + "left join", + "where", + "group by", + "having", + "order by", + "limit", + "offset"); + + private static final Set SQL_KEYWORDS = + Set.of( + "WITH", + "AS", + "SELECT", + "FROM", + "LEFT JOIN", + "ON", + "WHERE", + "GROUP BY", + "HAVING", + "ORDER BY", + "LIMIT", + "OFFSET", + "AND", + "OR", + "NOT", + "DESC", + "ASC", + "NULLS FIRST", + "NULLS LAST", + "CASE", + "WHEN", + "THEN", + "ELSE", + "END"); + + public static String prettyPrint(String sql) { + // First lowercase all SQL keywords + String formattedSql = lowercase(sql); + + // Add newlines before main clauses + for (String clause : MAIN_CLAUSES) { + formattedSql = formattedSql.replace(" " + clause + " ", "\n" + clause + " "); + } + + // Handle subqueries and CTEs + formattedSql = formatParentheses(formattedSql); + + // Indent lines + String[] lines = formattedSql.split("\n"); + StringBuilder result = new StringBuilder(); + int indent = 0; + + for (String line : lines) { + String trimmedLine = line.trim(); + // Decrease indent if line starts with closing parenthesis + if (trimmedLine.startsWith(")")) { + indent--; + } + // Add indentation + result.append(" ".repeat(Math.max(0, indent))).append(trimmedLine).append("\n"); + // Increase indent if line ends with opening parenthesis + if (trimmedLine.endsWith("(")) { + indent++; + } + } + + return result.toString().trim(); + } + + /** + * Converts SQL keywords to lowercase and formats the SQL string into a single line. Preserves + * single spaces between words and removes extra whitespace. + * + * @param sql the SQL string to format + * @return formatted SQL string in a single line with lowercase keywords + */ + public static String lowercase(String sql) { + String result = sql; + + // Convert keywords to lowercase + for (String keyword : SQL_KEYWORDS) { + // Use word boundaries to only replace complete words + result = result.replaceAll("\\b" + keyword + "\\b", keyword.toLowerCase()); + } + + // Replace all whitespace sequences (including newlines) with a single space + result = result.replaceAll("\\s+", " "); + + return result.trim(); + } + + private static String formatParentheses(String sql) { + StringBuilder result = new StringBuilder(); + int indent = 0; + boolean inString = false; + char[] chars = sql.toCharArray(); + + for (int i = 0; i < chars.length; i++) { + char c = chars[i]; + + // Handle string literals + if (c == '\'') { + inString = !inString; + result.append(c); + continue; + } + + if (!inString) { + if (c == '(') { + // Add newline and indent after opening parenthesis + result.append("(\n").append(" ".repeat(++indent)); + continue; + } else if (c == ')') { + // Add newline and indent before closing parenthesis + result.append("\n").append(" ".repeat(--indent)).append(")"); + continue; + } else if (c == ',') { + // Add newline after comma (for lists of columns, etc.) + result.append(",\n").append(" ".repeat(indent)); + continue; + } + } + + result.append(c); + } + + return result.toString(); + } +} diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/SqlWhereClauseExtractor.java b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/SqlWhereClauseExtractor.java new file mode 100644 index 000000000000..73c27a92b693 --- /dev/null +++ b/dhis-2/dhis-services/dhis-service-analytics/src/main/java/org/hisp/dhis/analytics/util/sql/SqlWhereClauseExtractor.java @@ -0,0 +1,114 @@ +/* + * Copyright (c) 2004-2025, University of Oslo + * All rights reserved. + * + * Redistribution and use in source and binary forms, with or without + * modification, are permitted provided that the following conditions are met: + * Redistributions of source code must retain the above copyright notice, this + * list of conditions and the following disclaimer. + * + * Redistributions in binary form must reproduce the above copyright notice, + * this list of conditions and the following disclaimer in the documentation + * and/or other materials provided with the distribution. + * Neither the name of the HISP project nor the names of its contributors may + * be used to endorse or promote products derived from this software without + * specific prior written permission. + * + * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND + * ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED + * WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE + * DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR + * ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES + * (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; + * LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON + * ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT + * (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS + * SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + */ +package org.hisp.dhis.analytics.util.sql; + +import java.util.ArrayList; +import java.util.HashSet; +import java.util.List; +import java.util.Set; +import net.sf.jsqlparser.expression.BinaryExpression; +import net.sf.jsqlparser.expression.Expression; +import net.sf.jsqlparser.expression.Function; +import net.sf.jsqlparser.expression.Parenthesis; +import net.sf.jsqlparser.expression.operators.relational.Between; +import net.sf.jsqlparser.expression.operators.relational.ExpressionList; +import net.sf.jsqlparser.expression.operators.relational.InExpression; +import net.sf.jsqlparser.expression.operators.relational.IsNullExpression; +import net.sf.jsqlparser.parser.CCJSqlParserUtil; +import net.sf.jsqlparser.statement.Statement; +import net.sf.jsqlparser.statement.select.PlainSelect; +import net.sf.jsqlparser.statement.select.Select; + +public class SqlWhereClauseExtractor { + + // GIUSEPPE/MAIKEL: can we use a different approach to avoid using jsqlparser? + public static List extractWhereColumns(String sql) { + List columns = new ArrayList<>(); + try { + // Parse the SQL string + Statement statement = CCJSqlParserUtil.parse(sql); + if (statement instanceof Select) { + PlainSelect plainSelect = (PlainSelect) ((Select) statement).getSelectBody(); + + // Get the WHERE clause + Expression whereExpression = plainSelect.getWhere(); + + // Extract columns from the WHERE clause + if (whereExpression != null) { + Set columnSet = new HashSet<>(); + extractColumnsFromExpression(whereExpression, columnSet); + columns.addAll(columnSet); + } + } + } catch (Exception e) { + throw new RuntimeException("Error parsing SQL: " + e.getMessage(), e); + } + return columns; + } + + private static void extractColumnsFromExpression(Expression expression, Set columns) { + if (expression instanceof net.sf.jsqlparser.schema.Column column) { + // Add the column name without table alias to the set + String columnName = column.getColumnName(); + // Remove surrounding quotes if present and handle escaped quotes + if (columnName.startsWith("\"") && columnName.endsWith("\"")) { + columnName = + columnName + .substring(1, columnName.length() - 1) + .replace("\"\"", "\""); // Handle escaped quotes + } + columns.add(columnName); + } else if (expression instanceof BinaryExpression binaryExpression) { + // Recursively process left and right expressions + extractColumnsFromExpression(binaryExpression.getLeftExpression(), columns); + extractColumnsFromExpression(binaryExpression.getRightExpression(), columns); + } else if (expression instanceof InExpression inExpression) { + // Process the left expression of an IN clause + extractColumnsFromExpression(inExpression.getLeftExpression(), columns); + } else if (expression instanceof Parenthesis parenthesis) { + // Process the expression inside parentheses + extractColumnsFromExpression(parenthesis.getExpression(), columns); + } else if (expression instanceof IsNullExpression isNullExpression) { + // Process IS NULL expressions + extractColumnsFromExpression(isNullExpression.getLeftExpression(), columns); + } else if (expression instanceof Function function) { + // Process function parameters to extract column names + ExpressionList parameters = function.getParameters(); + if (parameters != null) { + for (Expression parameter : parameters.getExpressions()) { + extractColumnsFromExpression(parameter, columns); + } + } + } else if (expression instanceof Between between) { + // Process BETWEEN expressions + extractColumnsFromExpression(between.getLeftExpression(), columns); + extractColumnsFromExpression(between.getBetweenExpressionStart(), columns); + extractColumnsFromExpression(between.getBetweenExpressionEnd(), columns); + } + } +} diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/event/data/AbstractJdbcEventAnalyticsManagerTest.java b/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/event/data/AbstractJdbcEventAnalyticsManagerTest.java index c78346771352..c74f08b63ce6 100644 --- a/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/event/data/AbstractJdbcEventAnalyticsManagerTest.java +++ b/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/event/data/AbstractJdbcEventAnalyticsManagerTest.java @@ -104,6 +104,7 @@ import org.hisp.dhis.program.Program; import org.hisp.dhis.program.ProgramIndicator; import org.hisp.dhis.program.ProgramIndicatorService; +import org.hisp.dhis.setting.SystemSettingsService; import org.hisp.dhis.system.grid.ListGrid; import org.junit.jupiter.api.BeforeEach; import org.junit.jupiter.api.Test; @@ -129,9 +130,11 @@ class AbstractJdbcEventAnalyticsManagerTest extends EventAnalyticsTest { @Mock private OrganisationUnitService organisationUnitService; + @Mock private SystemSettingsService systemSettingsService; + @Spy private ProgramIndicatorSubqueryBuilder programIndicatorSubqueryBuilder = - new DefaultProgramIndicatorSubqueryBuilder(programIndicatorService); + new DefaultProgramIndicatorSubqueryBuilder(programIndicatorService, systemSettingsService); @Spy private SqlBuilder sqlBuilder = new PostgreSqlBuilder(); diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/event/data/EnrollmentAnalyticsManagerTest.java b/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/event/data/EnrollmentAnalyticsManagerTest.java index a910ce147445..27b7344c906c 100644 --- a/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/event/data/EnrollmentAnalyticsManagerTest.java +++ b/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/event/data/EnrollmentAnalyticsManagerTest.java @@ -76,6 +76,8 @@ import org.hisp.dhis.relationship.RelationshipConstraint; import org.hisp.dhis.relationship.RelationshipEntity; import org.hisp.dhis.relationship.RelationshipType; +import org.hisp.dhis.setting.SystemSettings; +import org.hisp.dhis.setting.SystemSettingsService; import org.hisp.dhis.system.grid.ListGrid; import org.hisp.dhis.test.random.BeanRandomizer; import org.junit.jupiter.api.BeforeEach; @@ -110,10 +112,14 @@ class EnrollmentAnalyticsManagerTest extends EventAnalyticsTest { @Spy private SqlBuilder sqlBuilder = new PostgreSqlBuilder(); + @Mock private SystemSettingsService systemSettingsService; + @Spy private EnrollmentTimeFieldSqlRenderer enrollmentTimeFieldSqlRenderer = new EnrollmentTimeFieldSqlRenderer(sqlBuilder); + @Spy private SystemSettings systemSettings; + @Captor private ArgumentCaptor sql; private String DEFAULT_COLUMNS = @@ -128,9 +134,9 @@ class EnrollmentAnalyticsManagerTest extends EventAnalyticsTest { @BeforeEach public void setUp() { when(jdbcTemplate.queryForRowSet(anyString())).thenReturn(this.rowSet); - + when(systemSettingsService.getCurrentSettings()).thenReturn(systemSettings); DefaultProgramIndicatorSubqueryBuilder programIndicatorSubqueryBuilder = - new DefaultProgramIndicatorSubqueryBuilder(programIndicatorService); + new DefaultProgramIndicatorSubqueryBuilder(programIndicatorService, systemSettingsService); subject = new JdbcEnrollmentAnalyticsManager( @@ -139,6 +145,7 @@ public void setUp() { programIndicatorSubqueryBuilder, enrollmentTimeFieldSqlRenderer, executionPlanStore, + systemSettingsService, sqlBuilder); } diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/event/data/EventAnalyticsManagerTest.java b/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/event/data/EventAnalyticsManagerTest.java index c310aea85254..f09065537227 100644 --- a/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/event/data/EventAnalyticsManagerTest.java +++ b/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/event/data/EventAnalyticsManagerTest.java @@ -86,6 +86,7 @@ import org.hisp.dhis.program.ProgramIndicator; import org.hisp.dhis.program.ProgramIndicatorService; import org.hisp.dhis.program.ProgramType; +import org.hisp.dhis.setting.SystemSettingsService; import org.hisp.dhis.system.grid.ListGrid; import org.junit.jupiter.api.BeforeEach; import org.junit.jupiter.api.Test; @@ -116,6 +117,8 @@ class EventAnalyticsManagerTest extends EventAnalyticsTest { private static final String TABLE_NAME = "analytics_event"; + @Mock private SystemSettingsService systemSettingsService; + private static final String DEFAULT_COLUMNS_WITH_REGISTRATION = "event,ps,occurreddate,storedby," + "createdbydisplayname" @@ -129,7 +132,7 @@ public void setUp() { EventTimeFieldSqlRenderer timeCoordinateSelector = new EventTimeFieldSqlRenderer(sqlBuilder); ProgramIndicatorService programIndicatorService = mock(ProgramIndicatorService.class); DefaultProgramIndicatorSubqueryBuilder programIndicatorSubqueryBuilder = - new DefaultProgramIndicatorSubqueryBuilder(programIndicatorService); + new DefaultProgramIndicatorSubqueryBuilder(programIndicatorService, systemSettingsService); subject = new JdbcEventAnalyticsManager( @@ -138,6 +141,7 @@ public void setUp() { programIndicatorSubqueryBuilder, timeCoordinateSelector, executionPlanStore, + systemSettingsService, sqlBuilder); when(jdbcTemplate.queryForRowSet(anyString())).thenReturn(this.rowSet); diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/event/data/programindicator/ProgramIndicatorSubqueryBuilderTest.java b/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/event/data/programindicator/ProgramIndicatorSubqueryBuilderTest.java index 0b8057d8ec3c..384d20a5731c 100644 --- a/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/event/data/programindicator/ProgramIndicatorSubqueryBuilderTest.java +++ b/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/event/data/programindicator/ProgramIndicatorSubqueryBuilderTest.java @@ -43,18 +43,24 @@ import org.hisp.dhis.program.ProgramIndicatorService; import org.hisp.dhis.relationship.RelationshipEntity; import org.hisp.dhis.relationship.RelationshipType; +import org.hisp.dhis.setting.SystemSettings; +import org.hisp.dhis.setting.SystemSettingsService; import org.hisp.dhis.test.random.BeanRandomizer; import org.junit.jupiter.api.BeforeEach; import org.junit.jupiter.api.Test; import org.junit.jupiter.api.extension.ExtendWith; import org.mockito.InjectMocks; import org.mockito.Mock; +import org.mockito.Spy; import org.mockito.junit.jupiter.MockitoExtension; +import org.mockito.junit.jupiter.MockitoSettings; +import org.mockito.quality.Strictness; /** * @author Luciano Fiandesio */ -@ExtendWith(MockitoExtension.class) +@ExtendWith({MockitoExtension.class}) +@MockitoSettings(strictness = Strictness.LENIENT) class ProgramIndicatorSubqueryBuilderTest { private static final String DUMMY_EXPRESSION = "#{1234567}"; @@ -70,13 +76,18 @@ class ProgramIndicatorSubqueryBuilderTest { @Mock private ProgramIndicatorService programIndicatorService; + @Mock private SystemSettingsService systemSettingsService; + @InjectMocks private DefaultProgramIndicatorSubqueryBuilder subject; + @Spy private SystemSettings systemSettings; + @BeforeEach public void setUp() { program = createProgram('A'); startDate = getDate(2018, 1, 1); endDate = getDate(2018, 6, 30); + when(systemSettingsService.getCurrentSettings()).thenReturn(systemSettings); } @Test diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/table/setting/SqlBuilderSettingsTest.java b/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/table/setting/SqlBuilderSettingsTest.java new file mode 100644 index 000000000000..eecfc05350bd --- /dev/null +++ b/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/table/setting/SqlBuilderSettingsTest.java @@ -0,0 +1,91 @@ +/* + * Copyright (c) 2004-2024, University of Oslo + * All rights reserved. + * + * Redistribution and use in source and binary forms, with or without + * modification, are permitted provided that the following conditions are met: + * Redistributions of source code must retain the above copyright notice, this + * list of conditions and the following disclaimer. + * + * Redistributions in binary form must reproduce the above copyright notice, + * this list of conditions and the following disclaimer in the documentation + * and/or other materials provided with the distribution. + * Neither the name of the HISP project nor the names of its contributors may + * be used to endorse or promote products derived from this software without + * specific prior written permission. + * + * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND + * ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED + * WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE + * DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR + * ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES + * (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; + * LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON + * ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT + * (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS + * SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + */ +package org.hisp.dhis.analytics.table.setting; + +import static org.junit.jupiter.api.Assertions.assertEquals; +import static org.mockito.Mockito.when; + +import java.util.Set; +import org.hisp.dhis.analytics.table.model.Skip; +import org.hisp.dhis.external.conf.ConfigurationKey; +import org.hisp.dhis.external.conf.DhisConfigurationProvider; +import org.hisp.dhis.setting.SystemSettingsService; +import org.junit.jupiter.api.Test; +import org.junit.jupiter.api.extension.ExtendWith; +import org.mockito.InjectMocks; +import org.mockito.Mock; +import org.mockito.junit.jupiter.MockitoExtension; + +@ExtendWith(MockitoExtension.class) +class SqlBuilderSettingsTest { + @Mock private DhisConfigurationProvider config; + + @Mock private SystemSettingsService systemSettings; + + @InjectMocks private AnalyticsTableSettings settings; + + @Test + void testGetSkipIndexDimensionsDefault() { + when(config.getProperty(ConfigurationKey.ANALYTICS_TABLE_SKIP_INDEX)) + .thenReturn(ConfigurationKey.ANALYTICS_TABLE_SKIP_INDEX.getDefaultValue()); + + assertEquals(Set.of(), settings.getSkipIndexDimensions()); + } + + @Test + void testGetSkipIndexDimensions() { + when(config.getProperty(ConfigurationKey.ANALYTICS_TABLE_SKIP_INDEX)) + .thenReturn("kJ7yGrfR413, Hg5tGfr2fas , Ju71jG19Kaq,b5TgfRL9pUq"); + + assertEquals( + Set.of("kJ7yGrfR413", "Hg5tGfr2fas", "Ju71jG19Kaq", "b5TgfRL9pUq"), + settings.getSkipIndexDimensions()); + } + + @Test + void testGetSkipColumnDimensions() { + when(config.getProperty(ConfigurationKey.ANALYTICS_TABLE_SKIP_COLUMN)) + .thenReturn("sixmonthlyapril, financialapril , financialjuly,financialnov"); + + assertEquals( + Set.of("sixmonthlyapril", "financialapril", "financialjuly", "financialnov"), + settings.getSkipColumnDimensions()); + } + + @Test + void testToSet() { + Set expected = Set.of("kJ7yGrfR413", "Hg5tGfr2fas", "Ju71jG19Kaq", "b5TgfRL9pUq"); + assertEquals(expected, settings.toSet("kJ7yGrfR413, Hg5tGfr2fas , Ju71jG19Kaq,b5TgfRL9pUq")); + } + + @Test + void testToSkip() { + assertEquals(Skip.INCLUDE, settings.toSkip(true)); + assertEquals(Skip.SKIP, settings.toSkip(false)); + } +} diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/util/sql/SelectBuilderTest.java b/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/util/sql/SelectBuilderTest.java new file mode 100644 index 000000000000..93d24d2bb4a9 --- /dev/null +++ b/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/util/sql/SelectBuilderTest.java @@ -0,0 +1,863 @@ +/* + * Copyright (c) 2004-2025, University of Oslo + * All rights reserved. + * + * Redistribution and use in source and binary forms, with or without + * modification, are permitted provided that the following conditions are met: + * Redistributions of source code must retain the above copyright notice, this + * list of conditions and the following disclaimer. + * + * Redistributions in binary form must reproduce the above copyright notice, + * this list of conditions and the following disclaimer in the documentation + * and/or other materials provided with the distribution. + * Neither the name of the HISP project nor the names of its contributors may + * be used to endorse or promote products derived from this software without + * specific prior written permission. + * + * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND + * ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED + * WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE + * DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR + * ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES + * (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; + * LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON + * ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT + * (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS + * SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + */ +package org.hisp.dhis.analytics.util.sql; + +import static org.junit.jupiter.api.Assertions.*; + +import org.junit.jupiter.api.DisplayName; +import org.junit.jupiter.api.Nested; +import org.junit.jupiter.api.Test; + +@DisplayName("SelectBuilder") +class SelectBuilderTest { + + @Nested + @DisplayName("Basic SELECT queries") + class BasicSelectQueries { + @Test + @DisplayName("should build simple SELECT query") + void shouldBuildSimpleSelectQuery() { + String sql = new SelectBuilder().addColumn("name").from("users", "u").build(); + + assertEquals("select name from users as u", sql); + } + + @Test + @DisplayName("should build SELECT with multiple columns") + void shouldBuildSelectWithMultipleColumns() { + String sql = + new SelectBuilder() + .addColumn("id") + .addColumn("name") + .addColumn("email", "", "email_address") + .addColumn("count(*)", "", "total") + .from("users", "u") + .build(); + + assertEquals( + "select id, name, email as email_address, count(*) as total from users as u", sql); + } + } + + @Nested + @DisplayName("CTEs") + class CommonTableExpressions { + @Test + @DisplayName("should build query with single CTE") + void shouldBuildQueryWithSingleCTE() { + String sql = + new SelectBuilder() + .withCTE("user_counts", "select user_id, count(*) from events group by user_id") + .addColumn("u.name") + .addColumn("uc.count") + .from("users", "u") + .leftJoin("user_counts", "uc", alias -> alias + ".user_id = u.id") + .build(); + + assertEquals( + "with user_counts as (" + + " select user_id, count(*) from events group by user_id" + + " ) select u.name, uc.count from users as u left join user_counts uc on uc.user_id = u.id", + sql); + } + + @Test + @DisplayName("should build query with multiple CTEs") + void shouldBuildQueryWithMultipleCTEs() { + String sql = + new SelectBuilder() + .withCTE("cte1", "select 1") + .withCTE("cte2", "select 2") + .addColumn("*") + .from("table", "t") + .build(); + + assertEquals("with cte1 as ( select 1 ), cte2 as ( select 2 ) select * from table as t", sql); + } + } + + @Nested + @DisplayName("JOINs") + class Joins { + @Test + @DisplayName("should build query with single JOIN") + void shouldBuildQueryWithSingleJoin() { + String sql = + new SelectBuilder() + .addColumn("u.name") + .addColumn("o.total") + .from("users", "u") + .leftJoin("orders", "o", alias -> alias + ".user_id = u.id") + .build(); + + assertEquals( + "select u.name, o.total from users as u left join orders o on o.user_id = u.id", sql); + } + + @Test + @DisplayName("should build query with multiple JOINs") + void shouldBuildQueryWithMultipleJoins() { + String sql = + new SelectBuilder() + .addColumn("u.name") + .addColumn("o.total") + .addColumn("a.address") + .from("users", "u") + .leftJoin("orders", "o", alias -> alias + ".user_id = u.id") + .leftJoin("addresses", "a", alias -> alias + ".user_id = u.id") + .build(); + + assertEquals( + "select u.name, o.total, a.address from users as u " + + "left join orders o on o.user_id = u.id " + + "left join addresses a on a.user_id = u.id", + sql); + } + } + + @Nested + @DisplayName("WHERE conditions") + class WhereConditions { + @Test + @DisplayName("should build query with simple WHERE") + void shouldBuildQueryWithSimpleWhere() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .where(Condition.raw("active = true")) + .build(); + + assertEquals("select name from users as u where active = true", sql); + } + + @Test + @DisplayName("should build query with AND conditions") + void shouldBuildQueryWithAndConditions() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .where(Condition.and(Condition.raw("active = true"), Condition.raw("age >= 18"))) + .build(); + + assertEquals("select name from users as u where active = true and age >= 18", sql); + } + } + + @Nested + @DisplayName("GROUP BY and HAVING") + class GroupByAndHaving { + @Test + @DisplayName("should build query with GROUP BY") + void shouldBuildQueryWithGroupBy() { + String sql = + new SelectBuilder() + .addColumn("department") + .addColumn("count(*)", "", "total") + .from("employees", "e") + .groupBy("department") + .build(); + + assertEquals( + "select department, count(*) as total from employees as e group by department", sql); + } + + @Test + @DisplayName("should build query with GROUP BY and HAVING") + void shouldBuildQueryWithGroupByAndHaving() { + String sql = + new SelectBuilder() + .addColumn("department") + .addColumn("count(*)", "", "total") + .from("employees", "e") + .groupBy("department") + .having(Condition.raw("count(*) > 10")) + .build(); + + assertEquals( + "select department, count(*) as total from employees as e " + + "group by department having count(*) > 10", + sql); + } + } + + @Nested + @DisplayName("Pagination") + class Pagination { + @Test + @DisplayName("should build query with LIMIT") + void shouldBuildQueryWithLimit() { + String sql = new SelectBuilder().addColumn("name").from("users", "u").limit(10).build(); + + assertEquals("select name from users as u limit 10", sql); + } + + @Test + @DisplayName("should build query with LIMIT and OFFSET") + void shouldBuildQueryWithLimitAndOffset() { + String sql = + new SelectBuilder().addColumn("name").from("users", "u").limit(10).offset(20).build(); + + assertEquals("select name from users as u limit 10 offset 20", sql); + } + + @Test + @DisplayName("should build query with LIMIT plus one") + void shouldBuildQueryWithLimitPlusOne() { + String sql = + new SelectBuilder().addColumn("name").from("users", "u").limitPlusOne(10).build(); + + assertEquals("select name from users as u limit 11", sql); + } + + @Test + @DisplayName("should build query with max LIMIT") + void shouldBuildQueryWithMaxLimit() { + String sql = + new SelectBuilder().addColumn("name").from("users", "u").limitWithMax(100, 50).build(); + + assertEquals("select name from users as u limit 50", sql); + } + } + + @Nested + @DisplayName("SQL keyword case handling") + class SqlKeywordCaseHandling { + @Test + @DisplayName("should lowercase CASE statement keywords") + void shouldLowerCaseCaseStatementKeywords() { + String sql = + new SelectBuilder() + .addColumn("CASE WHEN active THEN 'Active' ELSE 'Inactive' END", "", "status") + .from("users", "u") + .build(); + + assertEquals( + "select case when active then 'Active' else 'Inactive' end as status from users as u", + sql); + } + + @Test + @DisplayName("should handle CASE statement in ORDER BY") + void shouldHandleCaseStatementInOrderBy() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .orderBy("CASE WHEN active THEN 1 ELSE 2 END ASC") + .build(); + + assertEquals( + "select name from users as u order by case when active then 1 else 2 end asc", sql); + } + + @Test + @DisplayName("should handle multiple CASE statements") + void shouldHandleMultipleCaseStatements() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .orderBy( + "CASE WHEN active THEN 1 ELSE 2 END ASC, " + + "CASE WHEN status = 'VIP' THEN 1 ELSE 2 END DESC") + .build(); + + assertEquals( + "select name from users as u order by " + + "case when active then 1 else 2 end asc, " + + "case when status = 'VIP' then 1 else 2 end desc", + sql); + } + + @Test + @DisplayName("should handle CASE statements with multiple WHEN clauses") + void shouldHandleCaseStatementsWithMultipleWhenClauses() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .orderBy( + "CASE " + + "WHEN status = 'ACTIVE' THEN 1 " + + "WHEN status = 'PENDING' THEN 2 " + + "ELSE 3 END DESC") + .build(); + + assertEquals( + "select name from users as u order by case " + + "when status = 'ACTIVE' then 1 " + + "when status = 'PENDING' then 2 " + + "else 3 end desc", + sql); + } + } + + @Nested + @DisplayName("ORDER BY") + class OrderBy { + @Test + @DisplayName("should build query with simple ORDER BY") + void shouldBuildQueryWithSimpleOrderBy() { + String sql = + new SelectBuilder().addColumn("name").from("users", "u").orderBy("name", "asc").build(); + + assertEquals("select name from users as u order by name asc", sql); + } + + @Test + @DisplayName("should build query with ORDER BY and NULL handling") + void shouldBuildQueryWithOrderByAndNullHandling() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .orderBy("name", "desc", "nulls last") + .build(); + + assertEquals("select name from users as u order by name desc nulls last", sql); + } + + @Test + @DisplayName("should parse ORDER BY clause from string") + void shouldParseOrderByClauseFromString() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .orderBy("order by name desc nulls last, created_at asc") + .build(); + + assertEquals( + "select name from users as u order by name desc nulls last, created_at asc", sql); + } + + @Test + @DisplayName("should correctly handle ASC keyword") + void shouldCorrectlyHandleAscKeyword() { + String sql = "SELECT * FROM users ORDER BY name ASC, description DESC"; + String formatted = SqlFormatter.lowercase(sql); + assertEquals("select * from users order by name asc, description desc", formatted); + } + + @Test + @DisplayName("should not affect words containing SQL keywords") + void shouldNotAffectWordsContainingKeywords() { + String sql = "SELECT description, ASCII(name) FROM users"; + String formatted = SqlFormatter.lowercase(sql); + assertEquals("select description, ASCII(name) from users", formatted); + } + + @Test + @DisplayName("should handle keywords at start and end of string") + void shouldHandleKeywordsAtBoundaries() { + String sql = "ASC name DESC"; + String formatted = SqlFormatter.lowercase(sql); + assertEquals("asc name desc", formatted); + } + } + + @Nested + @DisplayName("ORDER BY parsing") + class OrderByParsing { + @Test + @DisplayName("should handle simple direction") + void shouldHandleSimpleDirection() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .orderBy("last_updated DESC") + .build(); + + assertEquals("select name from users as u order by last_updated desc", sql); + } + + @Test + @DisplayName("should handle NULLS LAST without direction") + void shouldHandleNullsLastWithoutDirection() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .orderBy("last_updated NULLS LAST") + .build(); + + assertEquals("select name from users as u order by last_updated nulls last", sql); + } + + @Test + @DisplayName("should handle NULLS FIRST with direction") + void shouldHandleNullsFirstWithDirection() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .orderBy("last_updated DESC NULLS FIRST") + .build(); + + assertEquals("select name from users as u order by last_updated desc nulls first", sql); + } + + @Test + @DisplayName("should handle multiple columns with different combinations") + void shouldHandleMultipleColumnsWithDifferentCombinations() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .orderBy("last_updated DESC NULLS LAST, created_at ASC, name DESC NULLS FIRST") + .build(); + + assertEquals( + "select name from users as u order by last_updated desc nulls last, " + + "created_at asc, name desc nulls first", + sql); + } + + @Test + @DisplayName("should handle column name containing direction words") + void shouldHandleColumnNameContainingDirectionWords() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .orderBy("description_asc DESC") + .build(); + + assertEquals("select name from users as u order by description_asc desc", sql); + } + } + + @Nested + @DisplayName("ORDER BY clause combinations") + class OrderByCombinations { + @Test + @DisplayName("should handle column only") + void shouldHandleColumnOnly() { + String sql = + new SelectBuilder().addColumn("name").from("users", "u").orderBy("last_updated").build(); + + assertEquals("select name from users as u order by last_updated", sql); + } + + @Test + @DisplayName("should handle explicit ASC") + void shouldHandleExplicitAsc() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .orderBy("last_updated ASC") + .build(); + + assertEquals("select name from users as u order by last_updated asc", sql); + } + + @Test + @DisplayName("should handle NULLS LAST without direction") + void shouldHandleNullsLastWithoutDirection() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .orderBy("last_updated NULLS LAST") + .build(); + + assertEquals("select name from users as u order by last_updated nulls last", sql); + } + + @Test + @DisplayName("should handle NULLS FIRST without direction") + void shouldHandleNullsFirstWithoutDirection() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .orderBy("last_updated NULLS FIRST") + .build(); + + assertEquals("select name from users as u order by last_updated nulls first", sql); + } + + @Test + @DisplayName("should handle multiple columns with different specifications") + void shouldHandleMultipleColumnsWithDifferentSpecifications() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .orderBy("status NULLS FIRST, created_at, updated_at DESC NULLS LAST") + .build(); + + assertEquals( + "select name from users as u order by status nulls first, " + + "created_at, updated_at desc nulls last", + sql); + } + } + + @Nested + @DisplayName("ORDER BY raw strings") + class OrderByRawStrings { + @Test + @DisplayName("should handle ORDER BY with single column") + void shouldHandleOrderByWithSingleColumn() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .orderBy("created_at DESC") + .build(); + + assertEquals("select name from users as u order by created_at desc", sql); + } + + @Test + @DisplayName("should handle ORDER BY with multiple columns") + void shouldHandleOrderByWithMultipleColumns() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .orderBy("last_name ASC, first_name DESC") + .build(); + + assertEquals("select name from users as u order by last_name asc, first_name desc", sql); + } + + @Test + @DisplayName("should handle ORDER BY with NULLS handling") + void shouldHandleOrderByWithNullsHandling() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .orderBy("last_updated DESC NULLS LAST") + .build(); + + assertEquals("select name from users as u order by last_updated desc nulls last", sql); + } + + @Test + @DisplayName("should handle ORDER BY with 'order by' prefix") + void shouldHandleOrderByWithPrefix() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .orderBy("ORDER BY created_at DESC") + .build(); + + assertEquals("select name from users as u order by created_at desc", sql); + } + + @Test + @DisplayName("should handle empty ORDER BY") + void shouldHandleEmptyOrderBy() { + String sql = new SelectBuilder().addColumn("name").from("users", "u").orderBy("").build(); + + assertEquals("select name from users as u", sql); + } + + @Test + @DisplayName("should handle null ORDER BY") + void shouldHandleNullOrderBy() { + String sql = + new SelectBuilder().addColumn("name").from("users", "u").orderBy((String) null).build(); + + assertEquals("select name from users as u", sql); + } + + @Test + @DisplayName("should handle multiple ORDER BY calls") + void shouldHandleMultipleOrderByCalls() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .orderBy("last_name ASC") + .orderBy("first_name DESC") + .build(); + + assertEquals("select name from users as u order by last_name asc, first_name desc", sql); + } + + @Test + @DisplayName("should handle complex ORDER BY expression") + void shouldHandleComplexOrderBy() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .orderBy("CASE WHEN active THEN 1 ELSE 2 END ASC, created_at DESC NULLS LAST") + .build(); + + assertEquals( + "select name from users as u order by case when active then 1 else 2 end asc, " + + "created_at desc nulls last", + sql); + } + } + + @Nested + @DisplayName("WHERE raw conditions") + class WhereRawConditions { + @Test + @DisplayName("should handle raw WHERE condition") + void shouldHandleRawWhereCondition() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .where(Condition.raw("WHERE active = true")) + .build(); + + assertEquals("select name from users as u where active = true", sql); + } + + @Test + @DisplayName("should handle raw WHERE with AND") + void shouldHandleRawWhereWithAnd() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .where(Condition.raw("WHERE active = true AND age >= 18")) + .build(); + + assertEquals("select name from users as u where active = true and age >= 18", sql); + } + + @Test + @DisplayName("should clean WHERE prefix from raw condition") + void shouldCleanWherePrefixFromRawCondition() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .where(Condition.raw("WHERE status = 'ACTIVE'")) + .build(); + + assertEquals("select name from users as u where status = 'ACTIVE'", sql); + } + + @Test + @DisplayName("should clean WHERE prefix from raw condition") + void shouldHandleRawWhereConditionWithNestedOr() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .where( + Condition.raw( + "WHERE ps = '12345' AND (status = 'ACTIVE' OR status = 'INACTIVE')")) + .build(); + + assertEquals( + "select name from users as u where ps = '12345' and (status = 'ACTIVE' or status = 'INACTIVE')", + sql); + } + + @Test + @DisplayName("should handle multiple nested conditions with mixed operators") + void shouldHandleMultipleNestedConditions() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .where( + Condition.raw( + "WHERE (ps = '12345' OR ps = '67890') AND (status = 'ACTIVE' OR (status = 'INACTIVE' AND role = 'ADMIN'))")) + .build(); + + assertEquals( + "select name from users as u where (ps = '12345' or ps = '67890') and (status = 'ACTIVE' or (status = 'INACTIVE' and role = 'ADMIN'))", + sql); + } + + @Test + @DisplayName("should handle complex conditions with NOT operator") + void shouldHandleComplexConditionsWithNot() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .where( + Condition.raw( + "WHERE NOT (ps = '12345' AND status = 'ACTIVE') OR (role = 'ADMIN' AND NOT status = 'INACTIVE')")) + .build(); + + assertEquals( + "select name from users as u where not (ps = '12345' and status = 'ACTIVE') or (role = 'ADMIN' and not status = 'INACTIVE')", + sql); + } + + @Test + @DisplayName("should handle conditions with IN and BETWEEN operators") + void shouldHandleInAndBetweenOperators() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .where( + Condition.raw( + "WHERE ps IN ('12345', '67890') AND created_at BETWEEN '2023-01-01' AND '2023-12-31'")) + .build(); + + assertEquals( + "select name from users as u where ps IN ('12345', '67890') and created_at BETWEEN '2023-01-01' and '2023-12-31'", + sql); + } + + @Test + @DisplayName("should handle conditions with LIKE and IS NULL operators") + void shouldHandleLikeAndIsNullOperators() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .where(Condition.raw("WHERE name LIKE '%John%' AND email IS NULL")) + .build(); + + assertEquals("select name from users as u where name LIKE '%John%' and email IS NULL", sql); + } + + @Test + @DisplayName("should handle conditions with subqueries") + void shouldHandleConditionsWithSubqueries() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .where( + Condition.raw( + "WHERE ps = (SELECT ps FROM profiles WHERE user_id = u.id) AND status = 'ACTIVE'")) + .build(); + + assertEquals( + "select name from users as u where ps = (select ps from profiles where user_id = u.id) and status = 'ACTIVE'", + sql); + } + + @Test + @DisplayName("should clean AND prefix from raw condition") + void shouldCleanAndPrefixFromRawCondition() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .where(Condition.raw("AND status = 'ACTIVE'")) + .build(); + + assertEquals("select name from users as u where status = 'ACTIVE'", sql); + } + } + + @Nested + @DisplayName("Mixed raw and structured conditions") + class MixedConditions { + @Test + @DisplayName("should handle mix of raw and structured ORDER BY") + void shouldHandleMixedOrderBy() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .orderBy("last_name ASC") + .orderBy("created_at", "DESC", "NULLS LAST") + .build(); + + assertEquals( + "select name from users as u order by last_name asc, created_at desc nulls last", sql); + } + + @Test + @DisplayName("should handle mix of raw and structured WHERE conditions") + void shouldHandleMixedWhereConditions() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .where(Condition.and(Condition.raw("status = 'ACTIVE'"), Condition.raw("age >= 18"))) + .build(); + + assertEquals("select name from users as u where status = 'ACTIVE' and age >= 18", sql); + } + + @Test + @DisplayName("should handle conditions with CASE statements") + void shouldHandleConditionsWithCaseStatements() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .where( + Condition.raw( + "WHERE CASE WHEN status = 'ACTIVE' THEN ps = '12345' ELSE ps = '67890' END")) + .build(); + + assertEquals( + "select name from users as u where case when status = 'ACTIVE' then ps = '12345' else ps = '67890' end", + sql); + } + + @Test + @DisplayName("should handle conditions with EXISTS operator") + void shouldHandleConditionsWithExists() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .where(Condition.raw("WHERE EXISTS (SELECT 1 FROM profiles WHERE user_id = u.id)")) + .build(); + + assertEquals( + "select name from users as u where EXISTS (select 1 from profiles where user_id = u.id)", + sql); + } + + @Test + @DisplayName("should handle complex parentheses grouping") + void shouldHandleComplexParenthesesGrouping() { + String sql = + new SelectBuilder() + .addColumn("name") + .from("users", "u") + .where( + Condition.raw( + "WHERE (ps = '12345' OR (status = 'ACTIVE' AND role = 'ADMIN')) AND (created_at > '2023-01-01' OR updated_at < '2023-12-31')")) + .build(); + + assertEquals( + "select name from users as u where (ps = '12345' or (status = 'ACTIVE' and role = 'ADMIN')) and (created_at > '2023-01-01' or updated_at < '2023-12-31')", + sql); + } + } +} diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/util/sql/SqlAliasReplacerTest.java b/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/util/sql/SqlAliasReplacerTest.java new file mode 100644 index 000000000000..2af5bf53fcad --- /dev/null +++ b/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/util/sql/SqlAliasReplacerTest.java @@ -0,0 +1,251 @@ +/* + * Copyright (c) 2004-2025, University of Oslo + * All rights reserved. + * + * Redistribution and use in source and binary forms, with or without + * modification, are permitted provided that the following conditions are met: + * Redistributions of source code must retain the above copyright notice, this + * list of conditions and the following disclaimer. + * + * Redistributions in binary form must reproduce the above copyright notice, + * this list of conditions and the following disclaimer in the documentation + * and/or other materials provided with the distribution. + * Neither the name of the HISP project nor the names of its contributors may + * be used to endorse or promote products derived from this software without + * specific prior written permission. + * + * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND + * ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED + * WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE + * DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR + * ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES + * (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; + * LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON + * ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT + * (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS + * SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + */ +package org.hisp.dhis.analytics.util.sql; + +import static org.junit.jupiter.api.Assertions.*; + +import java.util.Arrays; +import java.util.List; +import org.junit.jupiter.api.DisplayName; +import org.junit.jupiter.api.Test; + +class SqlAliasReplacerTest { + + @Test + @DisplayName("Should handle columns without aliases") + void testColumnsWithoutAliases() { + List columns = Arrays.asList("employee", "country"); + String input = "employee = 10 and country = 'IT'"; + String expected = "%s.employee = 10 AND %s.country = 'IT'"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } + + @Test + @DisplayName("Should handle mix of aliased and non-aliased columns") + void testMixedAliasedAndNonAliasedColumns() { + List columns = Arrays.asList("employee", "country", "status"); + String input = "employee = 10 and ax.country = 'IT' and status = 'ACTIVE'"; + String expected = "%s.employee = 10 AND %s.country = 'IT' AND %s.status = 'ACTIVE'"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } + + @Test + @DisplayName("Should handle case insensitive column names") + void testCaseInsensitiveColumns() { + List columns = Arrays.asList("Employee", "COUNTRY"); + String input = "employee = 10 and country = 'IT'"; + String expected = "%s.employee = 10 AND %s.country = 'IT'"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } + + @Test + @DisplayName("Should not modify non-column words") + void testNonColumnWords() { + List columns = Arrays.asList("employee", "country"); + String input = "employee = 10 and country = 'IT' and status = 'ACTIVE'"; + String expected = "%s.employee = 10 AND %s.country = 'IT' AND status = 'ACTIVE'"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } + + @Test + @DisplayName("Should handle complex conditions with functions") + void testComplexConditionsWithFunctions() { + List columns = Arrays.asList("date", "amount"); + String input = "EXTRACT(YEAR FROM date) = 2023 and COALESCE(amount, 0) > 100"; + String expected = "EXTRACT(YEAR FROM %s.date) = 2023 AND COALESCE(%s.amount, 0) > 100"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } + + @Test + @DisplayName("Should handle quoted column names") + void testQuotedColumnNames() { + List columns = Arrays.asList("employee", "country"); + String input = "\"employee\" = 10 and `country` = 'IT'"; + String expected = "%s.\"employee\" = 10 AND %s.`country` = 'IT'"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } + + @Test + @DisplayName("Should handle OR conditions") + void testOrConditions() { + List columns = Arrays.asList("employee", "country", "age"); + String input = "employee = 10 OR ax.country = 'IT' OR age > 25"; + String expected = "%s.employee = 10 OR %s.country = 'IT' OR %s.age > 25"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } + + @Test + @DisplayName("Should handle mixed AND/OR conditions with parentheses") + void testMixedConditionsWithParentheses() { + List columns = Arrays.asList("employee", "country", "age", "salary"); + String input = "(employee = 10 OR ax.country = 'IT') AND (age > 25 OR by.salary >= 50000)"; + String expected = + "(%s.employee = 10 OR %s.country = 'IT') AND (%s.age > 25 OR %s.salary >= 50000)"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } + + @Test + @DisplayName("Should handle various SQL functions") + void testVariousSqlFunctions() { + List columns = Arrays.asList("date", "name", "salary"); + String input = + "UPPER(name) = 'JOHN' AND DATE_TRUNC('month', ax.date) = '2023-01-01' AND ABS(by.salary) > 1000"; + String expected = + "UPPER(%s.name) = 'JOHN' AND DATE_TRUNC('month', %s.date) = '2023-01-01' AND ABS(%s.salary) > 1000"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } + + @Test + @DisplayName("Should handle nested functions") + void testNestedFunctions() { + List columns = Arrays.asList("date", "amount"); + String input = + "ROUND(COALESCE(ax.amount, 0) * 100, 2) > 1000 AND EXTRACT(YEAR FROM DATE_TRUNC('month', date)) = 2023"; + String expected = + "ROUND(COALESCE(%s.amount, 0) * 100, 2) > 1000 AND EXTRACT(YEAR FROM DATE_TRUNC('month', %s.date)) = 2023"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } + + @Test + @DisplayName("Should handle IN conditions") + void testInConditions() { + List columns = Arrays.asList("country", "status"); + String input = "ax.country IN ('US', 'UK', 'IT') AND status IN ('ACTIVE', 'PENDING')"; + String expected = "%s.country IN ('US', 'UK', 'IT') AND %s.status IN ('ACTIVE', 'PENDING')"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } + + @Test + @DisplayName("Should handle BETWEEN conditions") + void testBetweenConditions() { + List columns = Arrays.asList("date", "amount"); + String input = "ax.date BETWEEN '2023-01-01' AND '2023-12-31' AND amount BETWEEN 100 AND 1000"; + String expected = + "%s.date BETWEEN '2023-01-01' AND '2023-12-31' AND %s.amount BETWEEN 100 AND 1000"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } + + @Test + @DisplayName("Should handle NULL comparisons") + void testNullComparisons() { + List columns = Arrays.asList("name", "date"); + String input = "ax.name IS NULL AND date IS NOT NULL"; + String expected = "%s.name IS NULL AND %s.date IS NOT NULL"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } + + @Test + @DisplayName("Should handle LIKE conditions") + void testLikeConditions() { + List columns = Arrays.asList("name", "email"); + String input = "ax.name LIKE 'John%' AND email NOT LIKE '%test%'"; + String expected = "%s.name LIKE 'John%' AND %s.email NOT LIKE '%test%'"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } + + @Test + @DisplayName("Should handle mathematical expressions") + void testMathematicalExpressions() { + List columns = Arrays.asList("price", "quantity", "discount"); + String input = "ax.price * by.quantity * (1 - discount/100) > 1000"; + String expected = "%s.price * %s.quantity * (1 - %s.discount / 100) > 1000"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } + + @Test + @DisplayName("Should handle subqueries in conditions") + void testSubqueries() { + List columns = Arrays.asList("department_id", "salary"); + String input = + "ax.department_id IN (SELECT id FROM departments) AND salary > (SELECT AVG(by.salary) FROM employees)"; + String expected = + "%s.department_id IN (SELECT id FROM departments) AND %s.salary > (SELECT AVG(salary) FROM employees)"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } + + @Test + @DisplayName("Should handle CASE expressions") + void testCaseExpressions() { + List columns = Arrays.asList("status", "amount"); + String input = "CASE WHEN ax.status = 'ACTIVE' THEN by.amount * 1.1 ELSE amount END > 1000"; + String expected = + "CASE WHEN %s.status = 'ACTIVE' THEN %s.amount * 1.1 ELSE %s.amount END > 1000"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } + + @Test + @DisplayName("Should handle special characters in column names") + void testSpecialCharactersInColumnNames() { + List columns = Arrays.asList("first_name", "last_name", "email_address"); + String input = + "ax.\"first_name\" = 'John' AND by.`last_name` = 'Doe' AND \"email_address\" LIKE '%@%'"; + String expected = + "%s.\"first_name\" = 'John' AND %s.`last_name` = 'Doe' AND %s.\"email_address\" LIKE '%@%'"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } + + @Test + @DisplayName("Should handle nested functions in subqueries") + void testNestedFunctionsInSubqueries() { + List columns = Arrays.asList("salary", "bonus"); + String input = "salary > (SELECT MAX(COALESCE(ax.salary + by.bonus, 0)) FROM employees)"; + String expected = "%s.salary > (SELECT MAX(COALESCE(salary + bonus, 0)) FROM employees)"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } + + @Test + @DisplayName("Should handle multiple subqueries with functions") + void testMultipleSubqueriesWithFunctions() { + List columns = Arrays.asList("salary", "age"); + String input = + "ax.salary > (SELECT AVG(by.salary) FROM emp1) AND age < (SELECT MAX(cx.age) FROM emp2)"; + String expected = + "%s.salary > (SELECT AVG(salary) FROM emp1) AND %s.age < (SELECT MAX(age) FROM emp2)"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } + + @Test + @DisplayName("Should handle subqueries with multiple function arguments") + void testSubqueriesWithMultipleFunctionArguments() { + List columns = Arrays.asList("salary", "bonus", "tax"); + String input = "ax.salary > (SELECT SUM(by.salary + cx.bonus - dx.tax) FROM employees)"; + String expected = "%s.salary > (SELECT SUM(salary + bonus - tax) FROM employees)"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } + + @Test + @DisplayName("Should handle subqueries with conditional functions") + void testSubqueriesWithConditionalFunctions() { + List columns = Arrays.asList("salary", "status"); + String input = + "ax.salary > (SELECT AVG(CASE WHEN by.status = 'ACTIVE' THEN cx.salary ELSE 0 END) FROM employees)"; + String expected = + "%s.salary > (SELECT AVG(CASE WHEN status = 'ACTIVE' THEN salary ELSE 0 END) FROM employees)"; + assertEquals(expected, SqlAliasReplacer.replaceTableAliases(input, columns)); + } +} diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/util/sql/SqlColumnParserTest.java b/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/util/sql/SqlColumnParserTest.java new file mode 100644 index 000000000000..e003701d30fd --- /dev/null +++ b/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/util/sql/SqlColumnParserTest.java @@ -0,0 +1,82 @@ +/* + * Copyright (c) 2004-2025, University of Oslo + * All rights reserved. + * + * Redistribution and use in source and binary forms, with or without + * modification, are permitted provided that the following conditions are met: + * Redistributions of source code must retain the above copyright notice, this + * list of conditions and the following disclaimer. + * + * Redistributions in binary form must reproduce the above copyright notice, + * this list of conditions and the following disclaimer in the documentation + * and/or other materials provided with the distribution. + * Neither the name of the HISP project nor the names of its contributors may + * be used to endorse or promote products derived from this software without + * specific prior written permission. + * + * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND + * ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED + * WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE + * DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR + * ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES + * (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; + * LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON + * ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT + * (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS + * SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + */ +package org.hisp.dhis.analytics.util.sql; + +import static org.junit.jupiter.api.Assertions.*; + +import org.junit.jupiter.api.Test; + +class SqlColumnParserTest { + @Test + void testRemoveTableAlias_WithDoubleQuotes() throws Exception { + String result = SqlColumnParser.removeTableAlias("ax.\"uidlevel2\""); + assertEquals("uidlevel2", result); + } + + @Test + void testRemoveTableAlias_WithBackticks() throws Exception { + String result = SqlColumnParser.removeTableAlias("cc.`alfa`"); + assertEquals("alfa", result); + } + + @Test + void testRemoveTableAlias_WithoutQuotes() throws Exception { + String result = SqlColumnParser.removeTableAlias("test1.uidlevel2"); + assertEquals("uidlevel2", result); + } + + @Test + void testRemoveTableAlias_NoAlias() throws Exception { + String result = SqlColumnParser.removeTableAlias("uidlevel2"); + assertEquals("uidlevel2", result); + } + + @Test + void testRemoveTableAlias_EmptyString() throws Exception { + String result = SqlColumnParser.removeTableAlias(""); + assertEquals("", result); + } + + @Test + void testRemoveTableAlias_NullInput() throws Exception { + String result = SqlColumnParser.removeTableAlias(null); + assertNull(result); + } + + @Test + void testRemoveTableAlias_ComplexColumnName() throws Exception { + String result = SqlColumnParser.removeTableAlias("schema.table.\"complex.column.name\""); + assertEquals("complex.column.name", result); + } + + @Test + void testRemoveTableAlias_MultipleDots() throws Exception { + String result = SqlColumnParser.removeTableAlias("schema.table.column"); + assertEquals("column", result); + } +} diff --git a/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/util/sql/SqlWhereClauseExtractorTest.java b/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/util/sql/SqlWhereClauseExtractorTest.java new file mode 100644 index 000000000000..25ec5cc56d7b --- /dev/null +++ b/dhis-2/dhis-services/dhis-service-analytics/src/test/java/org/hisp/dhis/analytics/util/sql/SqlWhereClauseExtractorTest.java @@ -0,0 +1,335 @@ +/* + * Copyright (c) 2004-2025, University of Oslo + * All rights reserved. + * + * Redistribution and use in source and binary forms, with or without + * modification, are permitted provided that the following conditions are met: + * Redistributions of source code must retain the above copyright notice, this + * list of conditions and the following disclaimer. + * + * Redistributions in binary form must reproduce the above copyright notice, + * this list of conditions and the following disclaimer in the documentation + * and/or other materials provided with the distribution. + * Neither the name of the HISP project nor the names of its contributors may + * be used to endorse or promote products derived from this software without + * specific prior written permission. + * + * THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND + * ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED + * WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE + * DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR + * ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES + * (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; + * LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON + * ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT + * (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS + * SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + */ +package org.hisp.dhis.analytics.util.sql; + +import static org.junit.jupiter.api.Assertions.*; + +import java.util.List; +import org.junit.jupiter.api.DisplayName; +import org.junit.jupiter.api.Test; + +class SqlWhereClauseExtractorTest { + + @Test + @DisplayName("Extract single column from simple WHERE clause") + void testExtractWhereColumns_singleColumn() { + String sql = "SELECT * FROM table WHERE column1 = 'value'"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(1, columns.size()); + assertTrue(columns.contains("column1")); + } + + @Test + @DisplayName("Extract multiple columns from WHERE clause with AND") + void testExtractWhereColumns_multipleColumns() { + String sql = "SELECT * FROM table WHERE column1 = 'value' AND column2 = 10"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(2, columns.size()); + assertTrue(columns.contains("column1")); + assertTrue(columns.contains("column2")); + } + + @Test + @DisplayName("Extract column from WHERE clause with IN condition") + void testExtractWhereColumns_inCondition() { + String sql = "SELECT * FROM table WHERE column1 IN (1, 2, 3)"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(1, columns.size()); + assertTrue(columns.contains("column1")); + } + + @Test + @DisplayName("Extract columns from nested parentheses in WHERE clause") + void testExtractWhereColumns_nestedParentheses() { + String sql = "SELECT * FROM table WHERE (column1 = 'value' AND (column2 = 10))"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(2, columns.size()); + assertTrue(columns.contains("column1")); + assertTrue(columns.contains("column2")); + } + + @Test + @DisplayName("Return empty list for SQL without WHERE clause") + void testExtractWhereColumns_noWhereClause() { + String sql = "SELECT * FROM table"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertTrue(columns.isEmpty()); + } + + @Test + @DisplayName("Throw RuntimeException for null SQL input") + void testExtractWhereColumns_nullInput() { + assertThrows( + RuntimeException.class, + () -> { + SqlWhereClauseExtractor.extractWhereColumns(null); + }); + } + + @Test + @DisplayName("Throw RuntimeException for invalid SQL syntax") + void testExtractWhereColumns_invalidSql() { + String sql = "SELECT * FROM WHERE column1"; + assertThrows( + RuntimeException.class, + () -> { + SqlWhereClauseExtractor.extractWhereColumns(sql); + }); + } + + @Test + @DisplayName("Extract column names without table aliases") + void testExtractWhereColumns_withTableAlias() { + String sql = "SELECT * FROM table t WHERE t.column1 = 'value'"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(1, columns.size()); + assertTrue(columns.contains("column1")); + } + + @Test + @DisplayName("Extract columns from complex WHERE clause with multiple conditions") + void testExtractWhereColumns_complexWhere() { + String sql = + "SELECT * FROM table WHERE column1 = 'value' AND " + + "(column2 IN (1,2) OR column3 != 'test')"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(3, columns.size()); + assertTrue(columns.contains("column1")); + assertTrue(columns.contains("column2")); + assertTrue(columns.contains("column3")); + } + + @Test + @DisplayName("Extract column from WHERE clause with LIKE operator") + void testExtractWhereColumns_likeOperator() { + String sql = "SELECT * FROM table WHERE column1 LIKE '%test%'"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(1, columns.size()); + assertTrue(columns.contains("column1")); + } + + @Test + @DisplayName("Extract column from WHERE clause with BETWEEN operator") + void testExtractWhereColumns_betweenOperator() { + String sql = "SELECT * FROM table WHERE column1 BETWEEN 1 AND 10"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(1, columns.size()); + assertTrue(columns.contains("column1")); + } + + @Test + @DisplayName("Extract column from WHERE clause with IS NULL condition") + void testExtractWhereColumns_isNullCondition() { + String sql = "SELECT * FROM table WHERE column1 IS NULL"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(1, columns.size()); + assertTrue(columns.contains("column1")); + } + + @Test + @DisplayName("Throw RuntimeException for empty string SQL") + void testExtractWhereColumns_emptyString() { + assertThrows( + RuntimeException.class, + () -> { + SqlWhereClauseExtractor.extractWhereColumns(""); + }); + } + + @Test + @DisplayName("Extract columns from main query WHERE clause with subquery") + void testExtractWhereColumns_withSubquery() { + String sql = + "SELECT * FROM table WHERE column1 IN (SELECT id FROM other_table WHERE column2 = 'value')"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(1, columns.size()); + assertTrue(columns.contains("column1")); + } + + @Test + @DisplayName("Extract column from WHERE clause with function calls") + void testExtractWhereColumns_withFunctions() { + String sql = "SELECT * FROM table WHERE UPPER(column1) = 'TEST'"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(1, columns.size()); + assertTrue(columns.contains("column1")); + } + + @Test + @DisplayName("Extract column with special characters from WHERE clause") + void testExtractWhereColumns_specialCharacters() { + String sql = "SELECT * FROM table WHERE \"Special Column!\" = 'value'"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(1, columns.size()); + assertTrue(columns.contains("Special Column!")); + } + + @Test + @DisplayName("Preserve case sensitivity in column names") + void testExtractWhereColumns_caseSensitivity() { + String sql = "SELECT * FROM table WHERE COLUMN1 = 'value' AND column1 = 'test'"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(2, columns.size()); + assertTrue(columns.contains("COLUMN1")); + assertTrue(columns.contains("column1")); + } + + @Test + @DisplayName("Remove duplicate columns in WHERE clause") + void testExtractWhereColumns_duplicateColumns() { + String sql = "SELECT * FROM table WHERE column1 > 10 AND column1 < 20"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(1, columns.size()); + assertTrue(columns.contains("column1")); + } + + @Test + @DisplayName("Handle extremely long column names") + void testExtractWhereColumns_longColumnNames() { + String longColumnName = "a".repeat(128); + String sql = "SELECT * FROM table WHERE " + longColumnName + " = 'value'"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(1, columns.size()); + assertTrue(columns.contains(longColumnName)); + } + + @Test + @DisplayName("Handle multiple complex conditions with mixed operators") + void testExtractWhereColumns_complexMixedOperators() { + String sql = + "SELECT * FROM table WHERE " + + "UPPER(column1) LIKE '%TEST%' AND " + + "(column2 BETWEEN 1 AND 10) OR " + + "column3 IS NOT NULL AND " + + "LOWER(column4) IN ('a', 'b', 'c')"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(4, columns.size()); + assertTrue(columns.containsAll(List.of("column1", "column2", "column3", "column4"))); + } + + @Test + @DisplayName("Extract columns from multiple function calls") + void testExtractWhereColumns_multipleFunctions() { + String sql = "SELECT * FROM table WHERE UPPER(column1) = 'TEST' AND LOWER(column2) = 'test'"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(2, columns.size()); + assertTrue(columns.contains("column1")); + assertTrue(columns.contains("column2")); + } + + @Test + @DisplayName("Extract columns from nested function calls") + void testExtractWhereColumns_nestedFunctions() { + String sql = "SELECT * FROM table WHERE UPPER(TRIM(column1)) = 'TEST'"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(1, columns.size()); + assertTrue(columns.contains("column1")); + } + + @Test + @DisplayName("Extract columns from function with multiple parameters") + void testExtractWhereColumns_functionMultipleParams() { + String sql = "SELECT * FROM table WHERE CONCAT(column1, column2) = 'TEST'"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(2, columns.size()); + assertTrue(columns.contains("column1")); + assertTrue(columns.contains("column2")); + } + + @Test + @DisplayName("Extract columns from BETWEEN with column references") + void testExtractWhereColumns_betweenWithColumns() { + String sql = "SELECT * FROM table WHERE column1 BETWEEN column2 AND column3"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(3, columns.size()); + assertTrue(columns.contains("column1")); + assertTrue(columns.contains("column2")); + assertTrue(columns.contains("column3")); + } + + @Test + @DisplayName("Extract columns from multiple BETWEEN conditions") + void testExtractWhereColumns_multipleBetween() { + String sql = + "SELECT * FROM table WHERE column1 BETWEEN 1 AND 10 AND column2 BETWEEN 'A' AND 'Z'"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(2, columns.size()); + assertTrue(columns.contains("column1")); + assertTrue(columns.contains("column2")); + } + + @Test + @DisplayName("Extract columns from BETWEEN with functions") + void testExtractWhereColumns_betweenWithFunctions() { + String sql = "SELECT * FROM table WHERE column1 BETWEEN LOWER(column2) AND UPPER(column3)"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(3, columns.size()); + assertTrue(columns.contains("column1")); + assertTrue(columns.contains("column2")); + assertTrue(columns.contains("column3")); + } + + @Test + @DisplayName("Extract columns with various special characters") + void testExtractWhereColumns_variousSpecialCharacters() { + String sql = + "SELECT * FROM table WHERE " + + "\"Special!@#$%^&*()\" = 'value1' AND " + + "\"Column With Spaces\" = 'value2' AND " + + "\"Mixed_Case-Column\" = 'value3'"; + List columns = SqlWhereClauseExtractor.extractWhereColumns(sql); + + assertEquals(3, columns.size()); + assertTrue(columns.contains("Special!@#$%^&*()")); + assertTrue(columns.contains("Column With Spaces")); + assertTrue(columns.contains("Mixed_Case-Column")); + } +} diff --git a/dhis-2/dhis-services/dhis-service-setting/src/test/java/org/hisp/dhis/setting/SystemSettingsTest.java b/dhis-2/dhis-services/dhis-service-setting/src/test/java/org/hisp/dhis/setting/SystemSettingsTest.java index e630fbe07a28..87447c405042 100644 --- a/dhis-2/dhis-services/dhis-service-setting/src/test/java/org/hisp/dhis/setting/SystemSettingsTest.java +++ b/dhis-2/dhis-services/dhis-service-setting/src/test/java/org/hisp/dhis/setting/SystemSettingsTest.java @@ -93,10 +93,11 @@ void testIsTranslatable() { @Test void testKeysWithDefaults() { Set keys = SystemSettings.keysWithDefaults(); - assertEquals(139, keys.size()); + assertEquals(140, keys.size()); // just check some at random assertTrue(keys.contains("syncSkipSyncForDataChangedBefore")); assertTrue(keys.contains("keyTrackerDashboardLayout")); + assertTrue(keys.contains("experimentalAnalyticsSqlEngineEnabled")); } @Test diff --git a/dhis-2/pom.xml b/dhis-2/pom.xml index c5718fd77333..98a8772478d1 100644 --- a/dhis-2/pom.xml +++ b/dhis-2/pom.xml @@ -1613,7 +1613,11 @@ debezium-connector-postgres ${version.debezium}
- + + com.github.jsqlparser + jsqlparser + 4.6 + org.hamcrest