diff --git a/pom.xml b/pom.xml index ba473d75..684bfad9 100644 --- a/pom.xml +++ b/pom.xml @@ -5,7 +5,7 @@ 4.0.0 org.ohdsi circe - 1.11.2-SNAPSHOT + 1.11.3-SNAPSHOT 1.8 1.8 diff --git a/src/main/resources/resources/cohortdefinition/sql/customEraStrategy.sql b/src/main/resources/resources/cohortdefinition/sql/customEraStrategy.sql index c606ec0f..ddb4e6a8 100644 --- a/src/main/resources/resources/cohortdefinition/sql/customEraStrategy.sql +++ b/src/main/resources/resources/cohortdefinition/sql/customEraStrategy.sql @@ -26,38 +26,20 @@ INTO #strategy_ends from @eventTable et JOIN ( - select ENDS.person_id, min(drug_exposure_start_date) as era_start_date, DATEADD(day,@offset, ENDS.era_end_date) as era_end_date - from - ( - select de.person_id, de.drug_exposure_start_date, MIN(e.END_DATE) as era_end_date - FROM #drugTarget DE - JOIN - ( - --cteEndDates - select PERSON_ID, DATEADD(day,-1 * @gapDays,EVENT_DATE) as END_DATE -- unpad the end date by @gapDays - 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 -- this re-numbers the inner UNION so all rows are numbered ordered by the event date - from - ( - -- select the start dates, assigning a row number to each - Select PERSON_ID, DRUG_EXPOSURE_START_DATE AS EVENT_DATE, 0 as EVENT_TYPE, ROW_NUMBER() OVER (PARTITION BY PERSON_ID ORDER BY DRUG_EXPOSURE_START_DATE) as START_ORDINAL - from #drugTarget D - UNION ALL - - -- add the end dates with NULL as the row number, padding the end dates by @gapDays to allow a grace period for overlapping ranges. - select PERSON_ID, DATEADD(day,@gapDays,DRUG_EXPOSURE_END_DATE), 1 as EVENT_TYPE, NULL - FROM #drugTarget D - ) RAWDATA - ) E - WHERE 2 * E.START_ORDINAL - E.OVERALL_ORD = 0 - ) E on DE.PERSON_ID = E.PERSON_ID and E.END_DATE >= DE.DRUG_EXPOSURE_START_DATE - GROUP BY de.person_id, de.drug_exposure_start_date - ) ENDS - GROUP BY ENDS.person_id, ENDS.era_end_date + select person_id, min(start_date) as era_start_date, DATEADD(day,-1 * @gapDays, max(end_date)) as era_end_date + from ( + select person_id, start_date, end_date, sum(is_start) over (partition by person_id order by start_date, is_start desc rows unbounded preceding) group_idx + from ( + select person_id, start_date, end_date, + case when max(end_date) over (partition by person_id order by start_date rows between unbounded preceding and 1 preceding) >= start_date then 0 else 1 end is_start + from ( + select person_id, drug_exposure_start_date as start_date, DATEADD(day,(@gapDays + @offset),DRUG_EXPOSURE_END_DATE) as end_date + FROM #drugTarget + ) DT + ) ST + ) GR + group by person_id, group_idx ) ERAS on ERAS.person_id = et.person_id WHERE et.start_date between ERAS.era_start_date and ERAS.era_end_date; diff --git a/src/main/resources/resources/cohortdefinition/sql/generateCohort.sql b/src/main/resources/resources/cohortdefinition/sql/generateCohort.sql index 436f37bd..c571d56a 100644 --- a/src/main/resources/resources/cohortdefinition/sql/generateCohort.sql +++ b/src/main/resources/resources/cohortdefinition/sql/generateCohort.sql @@ -52,49 +52,21 @@ from ( -- first_ends WHERE F.ordinal = 1 ) FE; -select person_id, min(start_date) as start_date, end_date + +select person_id, min(start_date) as start_date, DATEADD(day,-1 * @eraconstructorpad, max(end_date)) as end_date into #final_cohort -from ( --cteEnds - SELECT - c.person_id - , c.start_date - , MIN(ed.end_date) AS end_date - FROM #cohort_rows c - JOIN ( -- cteEndDates - SELECT - person_id - , DATEADD(day,-1 * @eraconstructorpad, event_date) as end_date - FROM - ( - SELECT - person_id - , event_date - , event_type - , SUM(event_type) OVER (PARTITION BY person_id ORDER BY event_date, event_type ROWS UNBOUNDED PRECEDING) AS interval_status - FROM - ( - SELECT - person_id - , start_date AS event_date - , -1 AS event_type - FROM #cohort_rows - - UNION ALL - - - SELECT - person_id - , DATEADD(day,@eraconstructorpad,end_date) as end_date - , 1 AS event_type - FROM #cohort_rows - ) RAWDATA - ) e - WHERE interval_status = 0 - ) ed ON c.person_id = ed.person_id AND ed.end_date >= c.start_date - GROUP BY c.person_id, c.start_date -) e -group by person_id, end_date -; +from ( + select person_id, start_date, end_date, sum(is_start) over (partition by person_id order by start_date, is_start desc rows unbounded preceding) group_idx + from ( + select person_id, start_date, end_date, + case when max(end_date) over (partition by person_id order by start_date rows between unbounded preceding and 1 preceding) >= start_date then 0 else 1 end is_start + from ( + select person_id, start_date, DATEADD(day,@eraconstructorpad,end_date) as end_date + from #cohort_rows + ) CR + ) ST +) GR +group by person_id, group_idx; DELETE FROM @target_database_schema.@target_cohort_table where @cohort_id_field_name = @target_cohort_id; INSERT INTO @target_database_schema.@target_cohort_table (@cohort_id_field_name, subject_id, cohort_start_date, cohort_end_date)