Skip to content

Commit abdfd96

Browse files
committed
refactor/fix check_etl scripts
1 parent 8df2394 commit abdfd96

File tree

11 files changed

+412
-426
lines changed

11 files changed

+412
-426
lines changed

Diff for: etl/StandardizedClinicalDataTables/CONDITION_OCCURRENCE/check_etl.sql

+85-59
Original file line numberDiff line numberDiff line change
@@ -9,143 +9,169 @@
99
-- --------------------------------------------------
1010

1111
BEGIN;
12-
SELECT plan ( 7 );
12+
SELECT plan ( 8 );
1313

1414
SELECT results_eq
1515
(
1616
'
17-
SELECT count(distinct person_id), count(distinct visit_occurrence_id)
17+
SELECT COUNT(distinct person_id), COUNT(distinct visit_occurrence_id)
1818
FROM omop.condition_occurrence
1919
WHERE condition_type_concept_id != 42894222;
2020
'
2121
,
2222
'
23-
SELECT count(distinct subject_id), count(distinct hadm_id) FROM diagnoses_icd where icd9_code is not null;
24-
'
23+
SELECT COUNT(distinct subject_id), COUNT(distinct hadm_id)
24+
FROM diagnoses_icd
25+
WHERE icd9_code IS NOT NULL;
26+
'
2527
,
26-
'Condition_occurrence table -- nb icd'
28+
'CONDITION OCCURRENCE -- check ICD diagnoses row count matches'
2729
);
2830

2931
SELECT results_eq
3032
(
3133
'
32-
WITH tmp as
33-
(SELECT distinct on (visit_occurrence_id) * from omop.condition_occurrence where condition_type_concept_id = 42894222)
34-
SELECT condition_source_value::text, count(1)
35-
FROM tmp
36-
group by condition_source_value order by count(condition_source_value) desc;
34+
WITH tmp as
35+
(
36+
SELECT distinct on (visit_occurrence_id) *
37+
FROM omop.condition_occurrence
38+
WHERE condition_type_concept_id = 42894222
39+
)
40+
SELECT condition_source_value::text, COUNT(1)
41+
FROM tmp
42+
GROUP BY 1
43+
ORDER BY 2, 1;
3744
'
3845
,
3946
'
40-
SELECT diagnosis::text, count(1) from admissions group by diagnosis order by count(1) desc;
41-
'
47+
SELECT diagnosis::text, COUNT(1)
48+
FROM admissions
49+
GROUP BY 1
50+
ORDER BY 2, 1;
51+
'
4252
,
43-
'Condition_occurrence table -- diagnosis in admission same '
53+
'CONDITION OCCURRENCE -- diagnosis in admission same'
4454
);
4555

4656
SELECT results_eq
4757
(
4858
'
49-
with tmp as
50-
(SELECT distinct on (visit_occurrence_id) * from omop.condition_occurrence where condition_type_concept_id = 42894222)
51-
SELECT condition_source_value::text, count(1)
52-
FROM tmp
53-
group by condition_source_value order by count(condition_source_value) desc;
59+
with tmp as
60+
(
61+
SELECT distinct on (visit_occurrence_id) *
62+
FROM omop.condition_occurrence
63+
WHERE condition_type_concept_id = 42894222
64+
)
65+
SELECT condition_source_value::text, COUNT(1)
66+
FROM tmp
67+
GROUP BY 1
68+
ORDER BY 2, 1;
5469
'
5570
,
5671
'
57-
SELECT diagnosis::text, count(1) from admissions group by 1 order by 2 desc
58-
'
72+
SELECT diagnosis::text, COUNT(1)
73+
FROM admissions
74+
GROUP BY 1
75+
ORDER BY 2, 1
76+
'
5977
,
60-
'Condition_occurrence table -- distrib diagnosis the same'
78+
'CONDITION OCCURRENCE -- distrib diagnosis the same'
6179
);
6280

6381
SELECT results_eq
6482
(
6583
'
66-
select 0::integer;
84+
SELECT COUNT(1)::INTEGER
85+
FROM omop.condition_occurrence
86+
WHERE condition_source_concept_id = 0;
6787
'
6888
,
6989
'
70-
SELECT count(1)::integer
71-
FROM omop.condition_occurrence
72-
where condition_source_concept_id = 0;
90+
SELECT 0::INTEGER;
7391
'
7492
,
75-
'Condition_occurrence table -- there is source concept in measurement not described'
93+
'CONDITION OCCURRENCE -- there is source concept in measurement not described'
7694
);
7795

7896
SELECT results_eq
7997
(
8098
'
81-
select 0::integer;
99+
SELECT COUNT(1)::INTEGER
100+
FROM
101+
(
102+
SELECT COUNT(1)::INTEGER
103+
FROM omop.condition_occurrence
104+
GROUP BY condition_occurrence_id
105+
having COUNT(1) > 1
106+
) as t;
82107
'
83108
,
84109
'
85-
select count(1)::integer from (
86-
SELECT count(1)::integer
87-
FROM omop.condition_occurrence
88-
group by condition_occurrence_id
89-
having count(1) > 1) as t;
110+
SELECT 0::INTEGER;
90111
'
91112
,
92-
'Condition_occurrence table -- primary key checker'
113+
'CONDITION OCCURRENCE -- primary key checker'
93114
);
94115

95116
SELECT results_eq
96117
(
97118
'
98-
select 0::integer;
99-
'
100-
,
101-
'
102-
SELECT count(1)::integer
119+
SELECT COUNT(1)::INTEGER
103120
FROM omop.condition_occurrence
104121
LEFT JOIN omop.concept ON condition_concept_id = concept_id
105-
WHERE
106-
condition_concept_id != 0
122+
WHERE condition_concept_id != 0
107123
AND standard_concept != ''S'';
108124
'
109125
,
110-
'Condition_occurrence table -- standard concept checker'
126+
'
127+
SELECT 0::INTEGER;
128+
'
129+
,
130+
'CONDITION OCCURRENCE -- standard concept checker'
111131
);
112132

113133
SELECT results_eq
114134
(
115135
'
116-
select 0::integer;
117-
'
118-
,
119-
'
120136
WITH tmp AS
121137
(
122-
SELECT visit_detail_id, visit_occurrence_id, CASE WHEN condition_end_datetime < condition_start_datetime THEN 1 ELSE 0 END AS abnormal
123-
FROM omop.condition_occurrence
124-
138+
SELECT visit_detail_id, visit_occurrence_id
139+
, CASE
140+
WHEN condition_end_datetime < condition_start_datetime
141+
THEN 1
142+
ELSE 0 END AS abnormal
143+
FROM omop.condition_occurrence
125144
)
126-
SELECT max(abnormal) FROM tmp;
145+
SELECT sum(abnormal)::INTEGER FROM tmp;
146+
'
147+
,
148+
'
149+
SELECT 0::INTEGER;
127150
'
128151
,
129-
'Condition_occurrence table -- start_datetime > end_datetime'
152+
'CONDITION OCCURRENCE -- start_datetime should be > end_datetime'
130153
);
131154

132155
SELECT results_eq
133156
(
134157
'
135-
select 0::integer;
136-
'
137-
,
138-
'
139158
WITH tmp AS
140159
(
141-
SELECT visit_detail_id, visit_occurrence_id, CASE WHEN condition_end_date < condition_start_date THEN 1 ELSE 0 END AS abnormal
142-
FROM omop.condition_occurrence
143-
160+
SELECT visit_detail_id, visit_occurrence_id
161+
, CASE
162+
WHEN condition_end_date < condition_start_date
163+
THEN 1
164+
ELSE 0 END AS abnormal
165+
FROM omop.condition_occurrence
144166
)
145-
SELECT max(abnormal) FROM tmp;
167+
SELECT sum(abnormal)::INTEGER FROM tmp;
168+
'
169+
,
170+
'
171+
SELECT 0::INTEGER;
146172
'
147173
,
148-
'Condition_occurrence table -- start_date > end_date'
174+
'CONDITION OCCURRENCE -- start_date should be > end_date'
149175
);
150176

151177
SELECT * FROM finish();

Diff for: etl/StandardizedClinicalDataTables/DEATH/check_etl.sql

+4-21
Original file line numberDiff line numberDiff line change
@@ -10,36 +10,19 @@
1010

1111
BEGIN;
1212

13-
SELECT plan ( 2 );
13+
SELECT plan ( 1 );
1414

1515
SELECT results_eq
1616
(
17-
'
18-
SELECT count(distinct subject_id) from admissions where hospital_expire_flag = 1;
1917
'
20-
,
21-
'
22-
SELECT count(distinct visit_occurrence_id)
23-
FROM omop.visit_occurrence
24-
WHERE discharge_to_concept_id = 4216643;
25-
'
26-
, 'dead number in hospital'
27-
);
28-
29-
SELECT results_eq
30-
(
31-
'
32-
SELECT count(*) from admissions where hospital_expire_flag = 1;
18+
SELECT count(dod) FROM patients;
3319
'
3420
,
3521
'
36-
SELECT count(distinct visit_occurrence_id)
37-
FROM omop.visit_occurrence
38-
WHERE discharge_to_concept_id = 4216643 or discharge_to_concept_id = 4022058 ; -- dead / organ_donor
22+
SELECT count(death_date) FROM omop.death
3923
'
40-
, 'organ_donor'
24+
, 'number of unique patients who die in the database'
4125
);
4226

43-
4427
SELECT * FROM finish();
4528
ROLLBACK;

Diff for: etl/StandardizedClinicalDataTables/DRUG_EXPOSURE/check_etl.sql

+30-29
Original file line numberDiff line numberDiff line change
@@ -9,74 +9,75 @@
99
-- --------------------------------------------------
1010

1111
BEGIN;
12-
SELECT plan ( 8 );
12+
SELECT plan ( 4 );
1313

1414
-- 1. visit_occurrence_nb
1515
SELECT results_eq
1616
(
1717
'
18-
SELECT count(distinct person_id), count(distinct visit_occurrence_id)
18+
SELECT COUNT(distinct person_id), COUNT(distinct visit_occurrence_id)
1919
FROM omop.drug_exposure
20-
where drug_type_concept_id = 38000177;
20+
WHERE drug_type_concept_id = 38000177;
2121
'
2222
,
2323
'
24-
SELECT count(distinct subject_id), count(distinct hadm_id)
24+
SELECT COUNT(distinct subject_id), COUNT(distinct hadm_id)
2525
FROM prescriptions;
26-
'
27-
,'nb patient with prescription'
26+
'
27+
,'DRUG_EXPOSURE -- check number of patients with prescription matches'
2828
);
2929

3030
-- 2. principaux medicaments de prescripitoin
3131
SELECT results_eq
3232
(
3333
'
34-
SELECT drug::text, count(1)
35-
from prescriptions
36-
group by drug
37-
ORDER by 2,1 desc;
34+
SELECT drug_source_value::text, COUNT(1)
35+
FROM omop.drug_exposure
36+
where drug_type_concept_id = 38000177
37+
GROUP BY 1
38+
ORDER BY 2,1 DESC;
3839
'
3940
,
4041
'
41-
SELECT drug_source_value::text, count(1)
42-
from omop.drug_exposure
43-
where drug_type_concept_id = 38000177
44-
GROUP BY 1 ORDER BY 2,1 desc;
45-
'
46-
,'same drugs for prescrip'
42+
SELECT drug::text, COUNT(1)
43+
FROM prescriptions
44+
GROUP BY 1
45+
ORDER by 2,1 DESC;
46+
'
47+
,'DRUG_EXPOSURE -- check drug_source_value matches source'
4748
);
4849

4950
-- 3. principaux medicaments de prescripitoin
5051
SELECT results_eq
5152
(
5253
'
53-
SELECT count(1)::integer
54-
FROM omop.drug_exposure
55-
where drug_source_concept_id = 0;
54+
SELECT COUNT(1)::integer
55+
FROM omop.drug_exposure
56+
WHERE drug_source_concept_id = 0;
5657
'
5758
,
5859
'
5960
SELECT 0::integer;
60-
'
61-
,'is concept source id full filled'
61+
'
62+
,'DRUG_EXPOSURE -- is concept source id full filled'
6263
);
6364

6465
SELECT results_eq
6566
(
6667
'
67-
select 0::integer;
68+
SELECT COUNT(1)::integer
69+
FROM omop.drug_exposure
70+
LEFT JOIN omop.concept
71+
ON drug_concept_id = concept_id
72+
WHERE drug_concept_id != 0
73+
AND standard_concept != ''S'';
6874
'
6975
,
7076
'
71-
SELECT count(1)::integer
72-
FROM omop.measurement
73-
LEFT JOIN omop.concept ON measurement_concept_id = concept_id
74-
WHERE
75-
measurement_concept_id != 0
76-
AND standard_concept != ''S'';
77+
SELECT 0::INTEGER;
7778
'
7879
,
79-
'Standard concept checker'
80+
'DRUG_EXPOSURE -- Standard concept checker'
8081
);
8182

8283
SELECT * FROM finish();

0 commit comments

Comments
 (0)