Skip to content

Commit 70cbee9

Browse files
authored
Merge pull request #82 from oxford-pharmacoepi/anto_server1
Anto server1
2 parents 6927f69 + 19b7f0c commit 70cbee9

File tree

3 files changed

+62
-27
lines changed

3 files changed

+62
-27
lines changed

sql_scripts/4c_hesapc_map_tbl_simple.sql

+4-3
Original file line numberDiff line numberDiff line change
@@ -115,11 +115,12 @@ DROP SEQUENCE IF EXISTS {TARGET_SCHEMA}.observation_period_seq;
115115
CREATE SEQUENCE {TARGET_SCHEMA}.observation_period_seq;
116116

117117
with cte as (
118-
select t1.patid, MIN(t1.admidate) as min_date, MAX(t1.discharged) as max_date
118+
select t1.patid, LEAST(MIN(t1.admidate), MIN(t2.epistart)) as min_date, GREATEST(MAX(t1.discharged), MAX(t2.epiend)) as max_date --sometimes discharged is null
119119
from {SOURCE_SCHEMA}.hes_hospital as t1
120-
inner join {TARGET_SCHEMA}.person as t2 on t2.person_id = t1.patid
120+
inner join {SOURCE_SCHEMA}.hes_episodes as t2 on t2.patid_id = t1.patid
121+
inner join {TARGET_SCHEMA}.person as t3 on t3.person_id = t1.patid
121122
group by t1.patid
122-
)
123+
)
123124
INSERT INTO {TARGET_SCHEMA}.OBSERVATION_PERIOD
124125
(
125126
observation_period_id,

sql_scripts/4e_hesapc_map_tbl_visit.sql

+46-17
Original file line numberDiff line numberDiff line change
@@ -6,8 +6,8 @@ CREATE SEQUENCE {TARGET_SCHEMA}.sequence_vo INCREMENT 1;
66
SELECT setval('{TARGET_SCHEMA}.sequence_vo', (SELECT max_id from {TARGET_SCHEMA_TO_LINK}._max_ids WHERE lower(tbl_name) = 'visit_occurrence'));
77

88
with cte1 AS (
9-
SELECT person_id
10-
FROM {TARGET_SCHEMA}.person
9+
SELECT person_id, observation_period_start_date, observation_period_end_date
10+
FROM {TARGET_SCHEMA}.observation_period
1111
),
1212
cte2 AS (
1313
SELECT t2.spno, MIN(t2.epistart) AS date_min, MAX(t2.epiend) AS date_max
@@ -17,7 +17,7 @@ cte2 AS (
1717
),
1818
cte3 AS (
1919
SELECT
20-
NEXTVAL('{TARGET_SCHEMA}.sequence_vo') AS visit_occurrence_id,
20+
-- NEXTVAL('{TARGET_SCHEMA}.sequence_vo') AS visit_occurrence_id,
2121
t1.patid AS person_id,
2222
9201 AS visit_concept_id,
2323
COALESCE(t1.admidate, t3.date_min, t1.discharged) AS visit_start_date,
@@ -39,7 +39,7 @@ cte3 AS (
3939
LEFT JOIN cte2 as t3 ON t1.spno = t3.spno
4040
LEFT JOIN {VOCABULARY_SCHEMA}.source_to_standard_vocab_map as t4 on t1.admimeth = t4.source_code and t4.source_vocabulary_id = 'HESAPC_ADMIMETH_STCM'
4141
LEFT JOIN {VOCABULARY_SCHEMA}.source_to_standard_vocab_map as t5 on t1.dismeth::varchar = t5.source_code and t5.source_vocabulary_id = 'HESAPC_DISMETH_STCM'
42-
ORDER BY t1.patid, COALESCE(t1.admidate, t3.date_min, t1.discharged), COALESCE(t1.discharged, t3.date_max, t3.date_min), t1.spno
42+
-- ORDER BY t1.patid, COALESCE(t1.admidate, t3.date_min, t1.discharged), COALESCE(t1.discharged, t3.date_max, t3.date_min), t1.spno
4343
),
4444
cte4 AS (
4545
SELECT visit_occurrence_id,
@@ -58,9 +58,35 @@ cte4 AS (
5858
FROM cte3
5959
),
6060
cte5 AS (
61+
SELECT
62+
NEXTVAL('{TARGET_SCHEMA}.sequence_vo') AS visit_occurrence_id,
63+
t1.person_id,
64+
t1.visit_concept_id,
65+
t2.visit_start_date,
66+
t2.visit_start_datetime,
67+
t2.visit_end_date,
68+
t2.visit_end_datetime,
69+
t1.visit_type_concept_id,
70+
t1.provider_id,
71+
t1.care_site_id,
72+
t1.visit_source_value,
73+
t1.visit_source_concept_id,
74+
t1.admitting_source_value,
75+
t1.admitting_source_concept_id,
76+
t1.discharge_to_source_value,
77+
t1.discharge_to_concept_id,
78+
t1.preceding_visit_occurrence_id
79+
from cte3 as t1
80+
inner join cte4 as t2 on t1.person_id = t2.person_id
81+
inner join cte1 as t3 on t1.person_id = t3.person_id
82+
WHERE t2.visit_start_date >= t3.observation_period_start_date
83+
AND t2.visit_end_date <= t3.observation_period_end_date
84+
ORDER BY t1.person_id, t2.visit_start_date, t2.visit_end_date, t1.visit_source_value
85+
),
86+
cte6 AS (
6187
SELECT t1.person_id, t1.visit_occurrence_id, MAX(t2.visit_occurrence_id) AS preceding_visit_occurrence_id
62-
FROM cte3 AS t1
63-
INNER JOIN cte3 AS t2 ON t1.person_id = t2.person_id
88+
FROM cte5 AS t1
89+
INNER JOIN cte5 AS t2 ON t1.person_id = t2.person_id
6490
WHERE t1.visit_occurrence_id > t2.visit_occurrence_id
6591
GROUP BY t1.person_id, t1.visit_occurrence_id
6692
)
@@ -87,10 +113,10 @@ SELECT
87113
t1.visit_occurrence_id,
88114
t1.person_id,
89115
t1.visit_concept_id,
90-
t2.visit_start_date,
91-
t2.visit_start_datetime,
92-
t2.visit_end_date,
93-
t2.visit_end_datetime,
116+
t1.visit_start_date,
117+
t1.visit_start_datetime,
118+
t1.visit_end_date,
119+
t1.visit_end_datetime,
94120
t1.visit_type_concept_id,
95121
t1.provider_id,
96122
t1.care_site_id,
@@ -100,10 +126,10 @@ SELECT
100126
t1.admitting_source_concept_id,
101127
t1.discharge_to_source_value,
102128
t1.discharge_to_concept_id,
103-
t3.preceding_visit_occurrence_id
104-
FROM cte3 AS t1
105-
INNER JOIN cte4 AS t2 ON t1.visit_occurrence_id = t2.visit_occurrence_id
106-
LEFT JOIN cte5 AS t3 ON t1.visit_occurrence_id = t3.visit_occurrence_id;
129+
t2.preceding_visit_occurrence_id
130+
FROM cte5 AS t1
131+
-- INNER JOIN cte5 AS t2 ON t1.visit_occurrence_id = t2.visit_occurrence_id
132+
LEFT JOIN cte6 AS t2 ON t1.visit_occurrence_id = t2.visit_occurrence_id;
107133

108134
DROP SEQUENCE IF EXISTS {TARGET_SCHEMA}.sequence_vo;
109135

@@ -121,8 +147,8 @@ CREATE SEQUENCE {TARGET_SCHEMA}.sequence_vd INCREMENT 1;
121147
SELECT setval('{TARGET_SCHEMA}.sequence_vd', (SELECT max_id from {TARGET_SCHEMA_TO_LINK}._max_ids WHERE lower(tbl_name) = 'visit_detail'));
122148

123149
with cte1 AS (
124-
SELECT person_id
125-
FROM {TARGET_SCHEMA}.person
150+
SELECT person_id, observation_period_start_date, observation_period_end_date
151+
FROM {TARGET_SCHEMA}.observation_period
126152
),
127153
cte2 AS (
128154
SELECT
@@ -285,6 +311,9 @@ cte8 AS (
285311
t2.visit_occurrence_id
286312
FROM cte7 as t1
287313
INNER JOIN {TARGET_SCHEMA}.visit_occurrence AS t2 ON t2.visit_source_value::bigint = t1.spno and t2.person_id = t1.person_id
314+
INNER JOIN cte1 as t3 ON t1.person_id = t3.person_id
315+
WHERE t1.visit_detail_start_date >= t3.observation_period_start_date
316+
AND t1.visit_detail_start_date <= t3.observation_period_end_date
288317
ORDER BY t1.person_id, t1.visit_detail_start_date, t1.visit_detail_source_value
289318
),
290319
cte9 AS (
@@ -354,4 +383,4 @@ ALTER TABLE {TARGET_SCHEMA}.visit_detail ADD CONSTRAINT xpk_visit_detail PRIMARY
354383
CREATE INDEX idx_visit_detail_person_id ON {TARGET_SCHEMA}.visit_detail (person_id, visit_detail_source_value);
355384
CLUSTER {TARGET_SCHEMA}.visit_detail USING idx_visit_detail_person_id;
356385
CREATE INDEX idx_visit_detail_concept_id ON {TARGET_SCHEMA}.visit_detail (visit_detail_concept_id ASC);
357-
CREATE INDEX idx_visit_detail_occurrence_id ON {TARGET_SCHEMA}.visit_detail (visit_occurrence_id ASC);
386+
CREATE INDEX idx_visit_detail_occurrence_id ON {TARGET_SCHEMA}.visit_detail (visit_occurrence_id ASC);

sql_scripts/4e_hesop_map_tbl_visit.sql

+12-7
Original file line numberDiff line numberDiff line change
@@ -7,8 +7,8 @@ SELECT setval('{TARGET_SCHEMA}.sequence_vo',
77
(SELECT max_id from {TARGET_SCHEMA_TO_LINK}._max_ids WHERE lower(tbl_name) = 'visit_occurrence'));
88

99
with cte1 AS (
10-
SELECT person_id
11-
FROM {TARGET_SCHEMA}.person
10+
SELECT person_id, observation_period_start_date, observation_period_end_date
11+
FROM {TARGET_SCHEMA}.observation_period
1212
),
1313
cte2 AS (
1414
select t1.person_id, t2.attendkey,
@@ -33,7 +33,7 @@ cte4 AS (
3333
t1.apptdate AS visit_end_date,
3434
t1.apptdate AS visit_end_datetime,
3535
32818 AS visit_type_concept_id,
36-
t2.provider_id,
36+
t3.provider_id,
3737
NULL::int AS care_site_id,
3838
t1.attendkey AS visit_source_value,
3939
NULL::int AS visit_source_concept_id,
@@ -42,8 +42,11 @@ cte4 AS (
4242
NULL::varchar AS discharge_to_source_value,
4343
NULL::int AS discharge_to_concept_id
4444
FROM {SOURCE_SCHEMA}.hesop_appointment AS t1
45-
INNER JOIN cte3 as t2 ON t1.patid = t2.person_id AND t1.attendkey = t2.attendkey
45+
INNER JOIN cte1 as t2 ON t1.person_id = t2.person_id
46+
INNER JOIN cte3 as t3 ON t1.patid = t3.person_id AND t1.attendkey = t3.attendkey
4647
WHERE t1.attended = 5 -- 5 = (Seen, having attended on time or, if late, before the relevant care professional was ready to see the patient)
48+
AND t1.apptdate >= t2.observation_period_start_date
49+
AND t1.apptdate <= t2.observation_period_end_date
4750
ORDER BY t1.patid, t1.apptdate, t1.attendkey
4851
),
4952
cte5 AS (
@@ -94,8 +97,8 @@ CREATE SEQUENCE {TARGET_SCHEMA}.sequence_vd INCREMENT 1;
9497
SELECT setval('{TARGET_SCHEMA}.sequence_vd', (SELECT max_id from {TARGET_SCHEMA_TO_LINK}._max_ids WHERE lower(tbl_name) = 'visit_detail'));
9598

9699
with cte1 AS (
97-
SELECT person_id
98-
FROM {TARGET_SCHEMA}.person
100+
SELECT person_id, observation_period_start_date, observation_period_end_date
101+
FROM {TARGET_SCHEMA}.observation_period
99102
),
100103
cte2 AS (
101104
SELECT
@@ -119,6 +122,8 @@ cte2 AS (
119122
FROM {SOURCE_SCHEMA}.hesop_appointment AS t1
120123
INNER JOIN cte1 as t2 ON t1.patid = t2.person_id
121124
WHERE t1.attended = 5 -- 5 = (Seen, having attended on time or, if late, before the relevant care professional was ready to see the patient)
125+
AND t1.apptdate >= t2.observation_period_start_date
126+
AND t1.apptdate <= t2.observation_period_end_date
122127
ORDER BY t1.patid, t1.apptdate, t1.attendkey
123128
),
124129
cte3 AS (
@@ -185,4 +190,4 @@ ALTER TABLE {TARGET_SCHEMA}.visit_detail ADD CONSTRAINT xpk_visit_detail PRIMARY
185190
CREATE INDEX idx_visit_detail_person_id ON {TARGET_SCHEMA}.visit_detail (person_id, visit_detail_source_value);
186191
CLUSTER {TARGET_SCHEMA}.visit_detail USING idx_visit_detail_person_id;
187192
CREATE INDEX idx_visit_detail_concept_id ON {TARGET_SCHEMA}.visit_detail (visit_detail_concept_id ASC);
188-
CREATE INDEX idx_visit_detail_occurrence_id ON {TARGET_SCHEMA}.visit_detail (visit_occurrence_id ASC);
193+
CREATE INDEX idx_visit_detail_occurrence_id ON {TARGET_SCHEMA}.visit_detail (visit_occurrence_id ASC);

0 commit comments

Comments
 (0)