Skip to content

Commit 7948d99

Browse files
committed
Accommodate OMOP 5.4
Renamed file (5.3) and created new one (5.4) to accommodate OMOP version
1 parent 55e60ca commit 7948d99

File tree

2 files changed

+107
-0
lines changed

2 files changed

+107
-0
lines changed
File renamed without changes.

sql_scripts/4d4_aurum_map_tbl_tmp.sql

+107
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,107 @@
1+
--------------------------------
2+
-- TEMP_DRUG_CONCEPT_MAP
3+
--------------------------------
4+
drop table if exists {SOURCE_SCHEMA}.temp_drug_concept_map CASCADE;
5+
6+
create table if not exists {SOURCE_SCHEMA}.temp_drug_concept_map as
7+
select d.prodcodeid,
8+
d.termfromemis,
9+
d.dmdid,
10+
st1.target_concept_id as dmd_source_concept_id
11+
from {SOURCE_SCHEMA}.productdictionary d
12+
left join {TARGET_SCHEMA}.source_to_source_vocab_map st1 on d.dmdid::varchar = st1.source_code and st1.source_vocabulary_id = 'dm+d';
13+
14+
alter table {SOURCE_SCHEMA}.temp_drug_concept_map add constraint pk_temp_drug_concept_map primary key (prodcodeid);
15+
16+
--------------------------------
17+
-- TEMP_CONCEPT_MAP
18+
--------------------------------
19+
drop table if exists {SOURCE_SCHEMA}.temp_concept_map CASCADE;
20+
21+
create table if not exists {SOURCE_SCHEMA}.temp_concept_map as
22+
with cte1 as (
23+
SELECT source_code, target_concept_id as Read_source_concept_id
24+
FROM {TARGET_SCHEMA}.source_to_source_vocab_map
25+
WHERE source_vocabulary_id = 'Read'
26+
),
27+
cte2 as (
28+
SELECT source_code, target_concept_id as SNOMED_source_concept_id
29+
FROM {TARGET_SCHEMA}.source_to_source_vocab_map
30+
WHERE source_vocabulary_id = 'SNOMED'
31+
)
32+
SELECT m.medcodeid,
33+
m.term,
34+
m.cleansedreadcode,
35+
m.snomedctconceptid,
36+
cte1.Read_source_concept_id,
37+
cte2.SNOMED_source_concept_id
38+
from {SOURCE_SCHEMA}.medicaldictionary m
39+
left join cte1 on m.cleansedreadcode = cte1.source_code
40+
left join cte2 on m.snomedctconceptid = cte2.source_code;
41+
42+
alter table {SOURCE_SCHEMA}.temp_concept_map add constraint pk_temp_concept_map primary key (medcodeid);
43+
44+
--------------------------------
45+
-- TEMP_VISIT_DETAIL
46+
--------------------------------
47+
drop table if exists {SOURCE_SCHEMA}.temp_visit_detail CASCADE;
48+
49+
CREATE TABLE {SOURCE_SCHEMA}.temp_visit_detail
50+
(
51+
visit_detail_id bigint NOT NULL,
52+
visit_detail_source_id bigint NOT NULL,
53+
person_id bigint NOT NULL,
54+
visit_detail_start_date date NOT NULL,
55+
visit_detail_end_date date NOT NULL,
56+
provider_id bigint NULL,
57+
care_site_id bigint NULL,
58+
parent_visit_detail_id bigint NULL,
59+
source_table varchar(20) NULL
60+
);
61+
62+
WITH cte3 as (
63+
select o.obsid as visit_detail_source_id,
64+
o.patid as person_id,
65+
case
66+
when c.consdate is NULL then o.obsdate
67+
else c.consdate
68+
end as visit_detail_start_date,
69+
case
70+
when c.consdate is NULL then o.obsdate
71+
else c.consdate
72+
end as visit_detail_end_date,
73+
c.staffid as provider_id,
74+
o.pracid as care_site_id,
75+
o.parentobsid as parent_visit_detail_id,
76+
'Observation' as source_table
77+
from {SOURCE_SCHEMA}.observation o
78+
left join {SOURCE_SCHEMA}.consultation c on o.consid = c.consid
79+
-- where c.consdate is not null or o.obsdate is not null -- not necessary as obsdate is always not NULL, filtered in check_source_data.sql
80+
),
81+
cte4 as (
82+
select c.consid as visit_detail_source_id,
83+
c.patid as person_id,
84+
c.consdate as visit_detail_start_date,
85+
c.consdate as visit_detail_end_date,
86+
c.staffid as provider_id,
87+
c.pracid as care_site_id,
88+
NULL::bigint as parent_visit_detail_id,
89+
'Consultation' as source_table
90+
from {SOURCE_SCHEMA}.consultation c
91+
where c.consdate is not null
92+
),
93+
cte5 as (
94+
select *
95+
from cte3
96+
UNION
97+
select *
98+
from cte4
99+
)
100+
INSERT INTO {SOURCE_SCHEMA}.temp_visit_detail
101+
SELECT row_number() over (order by visit_detail_source_id) as visit_detail_id, *
102+
FROM cte5;
103+
104+
105+
alter table {SOURCE_SCHEMA}.temp_visit_detail add constraint pk_temp_visit_d primary key (visit_detail_id); --added 31/10/2022
106+
create index idx_temp_visit_det1 on {SOURCE_SCHEMA}.temp_visit_detail (visit_detail_source_id, source_table); --modified 27/10/2022
107+
create index idx_temp_visit_det2 on {SOURCE_SCHEMA}.temp_visit_detail (person_id, visit_detail_start_date, care_site_id);

0 commit comments

Comments
 (0)