From a87a63ccec65f16363ecd6eadd8bfbfea4ffba2d Mon Sep 17 00:00:00 2001 From: Chris Knoll Date: Fri, 23 Sep 2022 10:13:48 -0400 Subject: [PATCH] Remove all CTEs from generateCohortSql. Fixes #172. --- .../CohortExpressionQueryBuilder.java | 5 +- .../cohortdefinition/sql/generateCohort.sql | 120 ++++++++---------- 2 files changed, 55 insertions(+), 70 deletions(-) diff --git a/src/main/java/org/ohdsi/circe/cohortdefinition/CohortExpressionQueryBuilder.java b/src/main/java/org/ohdsi/circe/cohortdefinition/CohortExpressionQueryBuilder.java index 4bf579e7..c6d4ebb9 100644 --- a/src/main/java/org/ohdsi/circe/cohortdefinition/CohortExpressionQueryBuilder.java +++ b/src/main/java/org/ohdsi/circe/cohortdefinition/CohortExpressionQueryBuilder.java @@ -53,7 +53,6 @@ public class CohortExpressionQueryBuilder implements IGetCriteriaSqlDispatcher, private final static String ADDITIONAL_CRITERIA_LEFT_TEMPLATE = StringUtils.replace(ResourceHelper.GetResourceAsString("/resources/cohortdefinition/sql/additionalCriteriaExclude.sql"), "@windowedCriteria", WINDOWED_CRITERIA_TEMPLATE); private final static String GROUP_QUERY_TEMPLATE = ResourceHelper.GetResourceAsString("/resources/cohortdefinition/sql/groupQuery.sql"); - private final static String PRIMARY_CRITERIA_EVENTS_TABLE = "primary_events"; private final static String INCLUSION_RULE_QUERY_TEMPLATE = ResourceHelper.GetResourceAsString("/resources/cohortdefinition/sql/inclusionrule.sql"); private final static String INCLUSION_RULE_TEMP_TABLE_TEMPLATE = ResourceHelper.GetResourceAsString("/resources/cohortdefinition/sql/inclusionRuleTempTable.sql"); private final static String CENSORING_QUERY_TEMPLATE = ResourceHelper.GetResourceAsString("/resources/cohortdefinition/sql/censoringInsert.sql"); @@ -275,7 +274,7 @@ public String buildExpressionQuery(CohortExpression expression, BuildExpressionQ String additionalCriteriaQuery = ""; if (expression.additionalCriteria != null && !expression.additionalCriteria.isEmpty()) { CriteriaGroup acGroup = expression.additionalCriteria; - String acGroupQuery = this.getCriteriaGroupQuery(acGroup, PRIMARY_CRITERIA_EVENTS_TABLE);//acGroup.accept(this); + String acGroupQuery = this.getCriteriaGroupQuery(acGroup, String.format("(%s)", primaryEventsQuery));//acGroup.accept(this); acGroupQuery = StringUtils.replace(acGroupQuery, "@indexId", "" + 0); additionalCriteriaQuery = "\nJOIN (\n" + acGroupQuery + ") AC on AC.person_id = pe.person_id and AC.event_id = pe.event_id\n"; } @@ -386,7 +385,7 @@ public String buildExpressionQuery(CohortExpression expression, BuildExpressionQ resultSql = StringUtils.replace(resultSql, "@generateStats", options.generateStats ? "1" : "0"); if (options.cohortIdFieldName != null) { - resultSql = StringUtils.replaceAll(resultSql, "@cohort_id_field_name", options.cohortIdFieldName.toString()); + resultSql = StringUtils.replaceAll(resultSql, "@cohort_id_field_name", options.cohortIdFieldName); } else { resultSql = StringUtils.replaceAll(resultSql, "@cohort_id_field_name", DEFAULT_COHORT_ID_FIELD_NAME); } diff --git a/src/main/resources/resources/cohortdefinition/sql/generateCohort.sql b/src/main/resources/resources/cohortdefinition/sql/generateCohort.sql index 5cf8b308..707c0ff2 100644 --- a/src/main/resources/resources/cohortdefinition/sql/generateCohort.sql +++ b/src/main/resources/resources/cohortdefinition/sql/generateCohort.sql @@ -1,15 +1,11 @@ @codesetQuery -with primary_events (event_id, person_id, start_date, end_date, op_start_date, op_end_date, visit_occurrence_id) as -( -@primaryEventsQuery -) SELECT event_id, person_id, start_date, end_date, op_start_date, op_end_date, visit_occurrence_id INTO #qualified_events FROM ( select pe.event_id, pe.person_id, pe.start_date, pe.end_date, pe.op_start_date, pe.op_end_date, row_number() over (partition by pe.person_id order by pe.start_date @QualifiedEventSort) as ordinal, cast(pe.visit_occurrence_id as bigint) as visit_occurrence_id - FROM primary_events pe + FROM (@primaryEventsQuery) pe @additionalCriteriaQuery ) QE @QualifiedLimitFilter @@ -19,8 +15,9 @@ FROM @inclusionCohortInserts -with cteIncludedEvents(event_id, person_id, start_date, end_date, op_start_date, op_end_date, ordinal) as -( +select event_id, person_id, start_date, end_date, op_start_date, op_end_date +into #included_events +FROM ( SELECT event_id, person_id, start_date, end_date, op_start_date, op_end_date, row_number() over (partition by person_id order by start_date @IncludedEventSort) as ordinal from ( @@ -33,83 +30,72 @@ with cteIncludedEvents(event_id, person_id, start_date, end_date, op_start_date, -- the matching group with all bits set ( POWER(2,# of inclusion rules) - 1 = inclusion_rule_mask WHERE (MG.inclusion_rule_mask = POWER(cast(2 as bigint),@ruleTotal)-1) } -) -select event_id, person_id, start_date, end_date, op_start_date, op_end_date -into #included_events -FROM cteIncludedEvents Results +) Results @ResultLimitFilter ; @strategy_ends_temp_tables -- generate cohort periods into #final_cohort -with cohort_ends (event_id, person_id, end_date) as -( - -- cohort exit dates - @cohort_end_unions -), -first_ends (person_id, start_date, end_date) as -( +select person_id, start_date, end_date +INTO #cohort_rows +from ( -- first_ends select F.person_id, F.start_date, F.end_date FROM ( - select I.event_id, I.person_id, I.start_date, E.end_date, row_number() over (partition by I.person_id, I.event_id order by E.end_date) as ordinal + select I.event_id, I.person_id, I.start_date, CE.end_date, row_number() over (partition by I.person_id, I.event_id order by CE.end_date) as ordinal from #included_events I - join cohort_ends E on I.event_id = E.event_id and I.person_id = E.person_id and E.end_date >= I.start_date + join ( -- cohort_ends +-- cohort exit dates +@cohort_end_unions + ) CE on I.event_id = CE.event_id and I.person_id = CE.person_id and CE.end_date >= I.start_date ) F WHERE F.ordinal = 1 -) -select person_id, start_date, end_date -INTO #cohort_rows -from first_ends; +) FE; -with cteEndDates (person_id, end_date) AS -- the magic -( - SELECT - person_id - , DATEADD(day,-1 * @eraconstructorpad, event_date) as end_date - FROM - ( - SELECT - person_id - , event_date - , event_type - , MAX(start_ordinal) OVER (PARTITION BY person_id ORDER BY event_date, event_type, start_ordinal ROWS UNBOUNDED PRECEDING) AS start_ordinal - , ROW_NUMBER() OVER (PARTITION BY person_id ORDER BY event_date, event_type, start_ordinal) AS overall_ord - FROM - ( - SELECT - person_id - , start_date AS event_date - , -1 AS event_type - , ROW_NUMBER() OVER (PARTITION BY person_id ORDER BY start_date) AS start_ordinal - FROM #cohort_rows - - UNION ALL - - - SELECT - person_id - , DATEADD(day,@eraconstructorpad,end_date) as end_date - , 1 AS event_type - , NULL - FROM #cohort_rows - ) RAWDATA - ) e - WHERE (2 * e.start_ordinal) - e.overall_ord = 0 -), -cteEnds (person_id, start_date, end_date) AS -( +select person_id, min(start_date) as start_date, end_date +into #final_cohort +from ( --cteEnds SELECT c.person_id , c.start_date - , MIN(e.end_date) AS end_date + , MIN(ed.end_date) AS end_date FROM #cohort_rows c - JOIN cteEndDates e ON c.person_id = e.person_id AND e.end_date >= c.start_date + JOIN ( -- cteEndDates + SELECT + person_id + , DATEADD(day,-1 * @eraconstructorpad, event_date) as end_date + FROM + ( + SELECT + person_id + , event_date + , event_type + , MAX(start_ordinal) OVER (PARTITION BY person_id ORDER BY event_date, event_type, start_ordinal ROWS UNBOUNDED PRECEDING) AS start_ordinal + , ROW_NUMBER() OVER (PARTITION BY person_id ORDER BY event_date, event_type, start_ordinal) AS overall_ord + FROM + ( + SELECT + person_id + , start_date AS event_date + , -1 AS event_type + , ROW_NUMBER() OVER (PARTITION BY person_id ORDER BY start_date) AS start_ordinal + FROM #cohort_rows + + UNION ALL + + + SELECT + person_id + , DATEADD(day,@eraconstructorpad,end_date) as end_date + , 1 AS event_type + , NULL + FROM #cohort_rows + ) RAWDATA + ) e + WHERE (2 * e.start_ordinal) - e.overall_ord = 0 + ) ed ON c.person_id = ed.person_id AND ed.end_date >= c.start_date GROUP BY c.person_id, c.start_date -) -select person_id, min(start_date) as start_date, end_date -into #final_cohort -from cteEnds +) e group by person_id, end_date ;