-
Notifications
You must be signed in to change notification settings - Fork 8
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Merge pull request #109 from OHDSI/katy__refactors
Refactors to improve performance and simplify SQL code
- Loading branch information
Showing
18 changed files
with
219 additions
and
221 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
|
@@ -8,4 +8,6 @@ logs/ | |
data/ | ||
.Rdata | ||
.Rhistory | ||
*.duckdb | ||
*.duckdb | ||
.dbt/ | ||
profiles.yml |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,8 +1,14 @@ | ||
{# This bit of SQL gets reused several times in the OMOP layer #} | ||
SELECT | ||
e.patient_id | ||
p.person_id | ||
, e.patient_id | ||
, e.encounter_id | ||
, vid.visit_occurrence_id_new AS visit_occurrence_id | ||
, pr.provider_id | ||
FROM {{ ref ('stg_synthea__encounters') }} AS e | ||
INNER JOIN {{ ref ('provider') }} AS pr | ||
ON e.provider_id = pr.provider_source_value | ||
INNER JOIN {{ ref ('int__person') }} AS p | ||
ON e.patient_id = p.person_source_value | ||
INNER JOIN {{ ref( 'int__final_visit_ids') }} AS vid | ||
ON e.encounter_id = vid.encounter_id |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,58 @@ | ||
SELECT | ||
p.person_id | ||
, srctostdvm.target_concept_id AS measurement_concept_id | ||
, o.observation_date AS measurement_date | ||
, o.observation_datetime AS measurement_datetime | ||
, {{ dbt.cast("o.observation_datetime", api.Column.translate_type("time")) }} AS measurement_time | ||
, 32827 AS measurement_type_concept_id | ||
, 0 AS operator_concept_id | ||
, CASE | ||
WHEN {{ regexp_like("o.observation_value", "^[-+]?[0-9]+\.?[0-9]*$") }} | ||
THEN {{ dbt.cast("o.observation_value", api.Column.translate_type("decimal")) }} | ||
ELSE {{ dbt.cast("null", api.Column.translate_type("decimal")) }} | ||
END AS value_as_number | ||
, coalesce(srcmap2.target_concept_id, 0) AS value_as_concept_id | ||
, coalesce(srcmap1.target_concept_id, 0) AS unit_concept_id | ||
, {{ dbt.cast("null", api.Column.translate_type("decimal")) }} AS range_low | ||
, {{ dbt.cast("null", api.Column.translate_type("decimal")) }} AS range_high | ||
, epr.provider_id | ||
, epr.visit_occurrence_id | ||
, epr.visit_occurrence_id + 1000000 AS visit_detail_id | ||
, o.observation_code AS measurement_source_value | ||
, coalesce( | ||
srctosrcvm.source_concept_id, 0 | ||
) AS measurement_source_concept_id | ||
, o.observation_units AS unit_source_value | ||
, o.observation_value AS value_source_value | ||
, {{ dbt.cast("null", api.Column.translate_type("integer")) }} AS unit_source_concept_id | ||
, {{ dbt.cast("null", api.Column.translate_type("bigint")) }} AS measurement_event_id | ||
, {{ dbt.cast("null", api.Column.translate_type("integer")) }} AS meas_event_field_concept_id | ||
FROM {{ ref ('stg_synthea__observations') }} AS o | ||
INNER JOIN {{ ref ('int__source_to_standard_vocab_map') }} AS srctostdvm | ||
ON | ||
o.observation_code = srctostdvm.source_code | ||
AND srctostdvm.target_domain_id = 'Measurement' | ||
AND srctostdvm.source_vocabulary_id = 'LOINC' | ||
AND srctostdvm.target_standard_concept = 'S' | ||
AND srctostdvm.target_invalid_reason IS null | ||
LEFT JOIN {{ ref ('int__source_to_standard_vocab_map') }} AS srcmap1 | ||
ON | ||
o.observation_units = srcmap1.source_code | ||
AND srcmap1.target_vocabulary_id = 'UCUM' | ||
AND srcmap1.source_vocabulary_id = 'UCUM' | ||
AND srcmap1.target_standard_concept = 'S' | ||
AND srcmap1.target_invalid_reason IS null | ||
LEFT JOIN {{ ref ('int__source_to_standard_vocab_map') }} AS srcmap2 | ||
ON | ||
o.observation_value = srcmap2.source_code | ||
AND srcmap2.target_domain_id = 'Meas value' | ||
AND srcmap2.target_standard_concept = 'S' | ||
AND srcmap2.target_invalid_reason IS null | ||
LEFT JOIN {{ ref ('int__source_to_source_vocab_map') }} AS srctosrcvm | ||
ON | ||
o.observation_code = srctosrcvm.source_code | ||
AND srctosrcvm.source_vocabulary_id = 'LOINC' | ||
INNER JOIN {{ ref ('int__person') }} AS p | ||
ON o.patient_id = p.person_source_value | ||
LEFT JOIN {{ ref ('int__encounter_provider') }} AS epr | ||
ON o.encounter_id = epr.encounter_id |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,39 @@ | ||
SELECT | ||
p.person_id | ||
, srctostdvm.target_concept_id AS measurement_concept_id | ||
, pr.procedure_start_date AS measurement_date | ||
, pr.procedure_start_datetime AS measurement_datetime | ||
, {{ dbt.cast("pr.procedure_start_datetime", api.Column.translate_type("time")) }} AS measurement_time | ||
, 32827 AS measurement_type_concept_id | ||
, 0 AS operator_concept_id | ||
, {{ dbt.cast("null", api.Column.translate_type("decimal")) }} AS value_as_number | ||
, 0 AS value_as_concept_id | ||
, 0 AS unit_concept_id | ||
, {{ dbt.cast("null", api.Column.translate_type("decimal")) }} AS range_low | ||
, {{ dbt.cast("null", api.Column.translate_type("decimal")) }} AS range_high | ||
, epr.provider_id | ||
, epr.visit_occurrence_id | ||
, epr.visit_occurrence_id + 1000000 AS visit_detail_id | ||
, pr.procedure_code AS measurement_source_value | ||
, srctosrcvm.source_concept_id AS measurement_source_concept_id | ||
, {{ dbt.cast("null", api.Column.translate_type("varchar")) }} AS unit_source_value | ||
, {{ dbt.cast("null", api.Column.translate_type("varchar")) }} AS value_source_value | ||
, {{ dbt.cast("null", api.Column.translate_type("integer")) }} AS unit_source_concept_id | ||
, {{ dbt.cast("null", api.Column.translate_type("bigint")) }} AS measurement_event_id | ||
, {{ dbt.cast("null", api.Column.translate_type("integer")) }} AS meas_event_field_concept_id | ||
FROM {{ ref ('stg_synthea__procedures') }} AS pr | ||
INNER JOIN {{ ref ('int__source_to_standard_vocab_map') }} AS srctostdvm | ||
ON | ||
pr.procedure_code = srctostdvm.source_code | ||
AND srctostdvm.target_domain_id = 'Measurement' | ||
AND srctostdvm.source_vocabulary_id = 'SNOMED' | ||
AND srctostdvm.target_standard_concept = 'S' | ||
AND srctostdvm.target_invalid_reason IS null | ||
INNER JOIN {{ ref ('int__source_to_source_vocab_map') }} AS srctosrcvm | ||
ON | ||
pr.procedure_code = srctosrcvm.source_code | ||
AND srctosrcvm.source_vocabulary_id = 'SNOMED' | ||
INNER JOIN {{ ref ('int__person') }} AS p | ||
ON pr.patient_id = p.person_source_value | ||
LEFT JOIN {{ ref ('int__encounter_provider') }} AS epr | ||
ON pr.encounter_id = epr.encounter_id |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Oops, something went wrong.