-
Notifications
You must be signed in to change notification settings - Fork 2
/
cui2ohdsi_concept_idv2.0.sql
326 lines (322 loc) · 20.8 KB
/
cui2ohdsi_concept_idv2.0.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
####################################################################
### UMLS CUI to OHDSI concept_id mappings V 2.0 ###
### By Juan M. Banda (www.jmbanda.com) ###
### Repository: https://github.com/thepanacealab/OHDSIananke ###
#### USAGE NOTES ###################################################
## These mappings assume that both your OHDSI vocabulary and ###
## UMLS source tables are on the same database ###
## ###
## Result: a table called OHDSI_to_CUICUI2020 in your database ###
## This was developed and tested on PostgreSQL 9.6 ###
####################################################################
DROP TABLE IF EXISTS OHDSI_to_CUI2020_TEMP;
CREATE TABLE OHDSI_to_CUI2020_TEMP AS (
SELECT AAA.CUI, AAA.concept_id, AAA.vocabulary_id FROM (
SELECT DISTINCT ON (AA.CUI) AA.CUI, AA.concept_id, AA.vocabulary_id FROM (
SELECT A.CUI, B.concept_id, B.vocabulary_id FROM MRCONSO as A LEFT JOIN concept as B ON A.CODE=B.concept_code WHERE A.LAT='ENG' AND A.SAB='ATC' AND B.vocabulary_id='ATC'
) AA
UNION
SELECT DISTINCT ON (AA.CUI) AA.CUI, AA.concept_id, AA.vocabulary_id FROM (
SELECT A.CUI, B.concept_id, B.vocabulary_id FROM MRCONSO as A LEFT JOIN concept as B ON A.CODE=B.concept_code WHERE A.LAT='ENG' AND A.SAB='CVX' AND B.vocabulary_id='CVX'
) AA
UNION
SELECT DISTINCT ON (AA.CUI) AA.CUI, AA.concept_id, AA.vocabulary_id FROM (
SELECT A.CUI, B.concept_id, B.vocabulary_id FROM MRCONSO as A LEFT JOIN concept as B ON A.CODE=B.concept_code WHERE A.LAT='ENG' AND A.SAB='RXNORM' AND B.vocabulary_id='RxNorm'
) AA
UNION
SELECT DISTINCT ON (AA.CUI) AA.CUI, AA.concept_id, AA.vocabulary_id FROM (
SELECT A.CUI, B.concept_id, B.vocabulary_id FROM MRCONSO as A LEFT JOIN concept as B ON A.CODE=B.concept_code WHERE A.LAT='ENG' AND A.SAB='CPT' AND B.vocabulary_id='CPT4'
) AA
UNION
SELECT DISTINCT ON (AA.CUI) AA.CUI, AA.concept_id, AA.vocabulary_id FROM (
SELECT A.CUI, B.concept_id, B.vocabulary_id FROM MRCONSO as A LEFT JOIN concept as B ON A.CODE=B.concept_code WHERE A.LAT='ENG' AND A.SAB='HCPCS' AND B.vocabulary_id='HCPCS'
) AA
UNION
SELECT DISTINCT ON (AA.CUI) AA.CUI, AA.concept_id, AA.vocabulary_id FROM (
SELECT A.CUI, B.concept_id, B.vocabulary_id FROM MRCONSO as A LEFT JOIN concept as B ON A.CODE=B.concept_code WHERE A.LAT='ENG' AND A.SAB='ICD10CM' AND B.vocabulary_id='ICD10CM'
) AA
UNION
SELECT DISTINCT ON (AA.CUI) AA.CUI, AA.concept_id, AA.vocabulary_id FROM (
SELECT A.CUI, B.concept_id, B.vocabulary_id FROM MRCONSO as A LEFT JOIN concept as B ON A.CODE=B.concept_code WHERE A.LAT='ENG' AND A.SAB='ICD10' AND B.vocabulary_id='ICD10'
) AA
UNION
SELECT DISTINCT ON (AA.CUI) AA.CUI, AA.concept_id, AA.vocabulary_id FROM (
SELECT A.CUI, B.concept_id, B.vocabulary_id FROM MRCONSO as A LEFT JOIN concept as B ON A.CODE=B.concept_code WHERE A.LAT='ENG' AND A.SAB='MSH' AND B.vocabulary_id='MeSH'
) AA
UNION
SELECT DISTINCT ON (AA.CUI) AA.CUI, AA.concept_id, AA.vocabulary_id FROM (
SELECT A.CUI, B.concept_id, B.vocabulary_id FROM MRCONSO as A LEFT JOIN concept as B ON A.CODE=B.concept_code WHERE A.LAT='ENG' AND A.SAB='NUCCPT' AND B.vocabulary_id='NUCC'
) AA
UNION
SELECT DISTINCT ON (AA.CUI) AA.CUI, AA.concept_id, AA.vocabulary_id FROM (
SELECT A.CUI, B.concept_id, B.vocabulary_id FROM MRCONSO as A LEFT JOIN concept as B ON A.CODE=B.concept_code WHERE A.LAT='ENG' AND A.SAB='VANDF' AND B.vocabulary_id='VA Product'
) AA
UNION
SELECT DISTINCT ON (AA.CUI) AA.CUI, AA.concept_id, AA.vocabulary_id FROM (
SELECT A.CUI, B.concept_id, B.vocabulary_id FROM MRCONSO as A LEFT JOIN concept as B ON A.CODE=B.concept_code WHERE A.LAT='ENG' AND A.SAB='VANDF' AND B.vocabulary_id='VA Class'
) AA
UNION
SELECT DISTINCT ON (AA.CUI) AA.CUI, AA.concept_id, AA.vocabulary_id FROM (
SELECT A.CUI, B.concept_id, B.vocabulary_id FROM MRCONSO as A LEFT JOIN concept as B ON A.CODE=B.concept_code WHERE A.LAT='ENG' AND A.SAB='ICD10PCS' AND B.vocabulary_id='ICD10PCS'
) AA
UNION
SELECT DISTINCT ON (AA.CUI) AA.CUI, AA.concept_id, AA.vocabulary_id FROM (
SELECT A.CUI, B.concept_id, B.vocabulary_id FROM MRCONSO as A LEFT JOIN concept as B ON A.CODE=B.concept_code WHERE A.LAT='ENG' AND A.SAB='ICD9CM' AND B.vocabulary_id='ICD9CM'
) AA
UNION
SELECT DISTINCT ON (AA.CUI) AA.CUI, AA.concept_id, AA.vocabulary_id FROM (
SELECT A.CUI, B.concept_id, B.vocabulary_id FROM MRCONSO as A LEFT JOIN concept as B ON A.CODE=B.concept_code WHERE A.LAT='ENG' AND A.SAB='ICD9CM' AND B.vocabulary_id='ICD9Proc'
) AA
UNION
SELECT DISTINCT ON (AA.CUI) AA.CUI, AA.concept_id, AA.vocabulary_id FROM (
SELECT A.CUI, B.concept_id, B.vocabulary_id FROM MRCONSO as A LEFT JOIN concept as B ON A.CODE=B.concept_code WHERE A.LAT='ENG' AND A.SAB='MDR' AND B.vocabulary_id='MedDRA'
) AA
UNION
SELECT DISTINCT ON (AA.CUI) AA.CUI, AA.concept_id, AA.vocabulary_id FROM (
SELECT A.CUI, B.concept_id, B.vocabulary_id FROM MRCONSO as A LEFT JOIN concept as B ON A.CODE=B.concept_code WHERE A.LAT='ENG' AND A.SAB='HCPCS' AND B.vocabulary_id='HCPCS'
) AA
UNION
SELECT DISTINCT ON (AA.CUI) AA.CUI, AA.concept_id, AA.vocabulary_id FROM (
SELECT A.CUI, B.concept_id, B.vocabulary_id FROM MRCONSO as A LEFT JOIN concept as B ON A.CODE=B.concept_code WHERE A.LAT='ENG' AND A.SAB='NDFRT' AND B.vocabulary_id='NDFRT'
) AA
UNION
SELECT DISTINCT ON (AA.CUI) AA.CUI, AA.concept_id, AA.vocabulary_id FROM (
SELECT A.CUI, B.concept_id, B.vocabulary_id FROM MRCONSO as A LEFT JOIN concept as B ON A.CODE=B.concept_code WHERE A.LAT='ENG' AND A.SAB='SNOMEDCT_US' AND B.vocabulary_id='SNOMED'
) AA
UNION
SELECT DISTINCT ON (AA.CUI) AA.CUI, AA.concept_id, AA.vocabulary_id FROM (
SELECT A.CUI, B.concept_id, B.vocabulary_id FROM MRCONSO as A LEFT JOIN concept as B ON A.CODE=B.concept_code WHERE A.LAT='ENG' AND A.SAB='LNC' AND B.vocabulary_id='LOINC'
) AA
) as AAA
);
CREATE INDEX idxCUI ON OHDSI_to_CUI2020_TEMP (CUI);
CREATE INDEX idxCID ON OHDSI_to_CUI2020_TEMP (concept_id);
CREATE INDEX idxVID ON OHDSI_to_CUI2020_TEMP (vocabulary_id);
##### Improve ATC codes ##########
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI, B.concept_id, 'ATC' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_code FROM (SELECT * FROM concept WHERE vocabulary_id='ATC') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='ATC') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.CODE=B.concept_code AND A.SAB='ATC';
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI, B.concept_id, 'ATC' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_name FROM (SELECT * FROM concept WHERE vocabulary_id='ATC') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='ATC') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.STR=B.concept_name AND A.SAB='ATC';
##### Improve RxNorm codes ##########
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'RxNorm' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_name FROM (SELECT * FROM concept WHERE vocabulary_id='RXNORM') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='RxNorm') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.STR=B.concept_name AND A.SAB='RXNORM' ;
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'RxNorm' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_code FROM (SELECT * FROM concept WHERE vocabulary_id='RXNORM') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='RxNorm') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.CODE=B.concept_code AND A.SAB='RXNORM' ;
######## Improve CPT codes ##########
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'CPT4' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_name FROM (SELECT * FROM concept WHERE vocabulary_id='CPT4') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='CPT') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.STR=B.concept_name AND A.SAB='CPT' ;
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'CPT4' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_code FROM (SELECT * FROM concept WHERE vocabulary_id='CPT4') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='CPT') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.CODE=B.concept_code AND A.SAB='CPT' ;
######## Improve HCPCS codes ##########
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'HCPCS' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_name FROM (SELECT * FROM concept WHERE vocabulary_id='HCPCS') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='HCPCS') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.STR=B.concept_name AND A.SAB='HCPCS' ;
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'HCPCS' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_code FROM (SELECT * FROM concept WHERE vocabulary_id='HCPCS') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='HCPCS') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.CODE=B.concept_code AND A.SAB='HCPCS' ;
######## Improve ICD10CM codes ##########
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'ICD10CM' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_name FROM (SELECT * FROM concept WHERE vocabulary_id='ICD10CM') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='ICD10CM') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.STR=B.concept_name AND A.SAB='ICD10CM' ;
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'ICD10CM' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_code FROM (SELECT * FROM concept WHERE vocabulary_id='ICD10CM') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='ICD10CM') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.CODE=B.concept_code AND A.SAB='ICD10CM' ;
######## Improve ICD10 codes ##########
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'ICD10' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_name FROM (SELECT * FROM concept WHERE vocabulary_id='ICD10') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='ICD10') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.STR=B.concept_name AND A.SAB='ICD10' ;
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'ICD10' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_code FROM (SELECT * FROM concept WHERE vocabulary_id='ICD10') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='ICD10') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.CODE=B.concept_code AND A.SAB='ICD10' ;
######## Improve MSH codes ##########
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'MeSH' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_name FROM (SELECT * FROM concept WHERE vocabulary_id='MeSH') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='MeSH') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.STR=B.concept_name AND A.SAB='MSH' ;
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'MeSH' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_code FROM (SELECT * FROM concept WHERE vocabulary_id='MeSH') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='MeSH') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.CODE=B.concept_code AND A.SAB='MSH' ;
######## Improve NUCC codes ##########
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'NUCC' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_name FROM (SELECT * FROM concept WHERE vocabulary_id='NUCC') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='NUCC') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.STR=B.concept_name AND A.SAB='NUCCPT' ;
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'NUCC' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_code FROM (SELECT * FROM concept WHERE vocabulary_id='NUCC') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='NUCC') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.CODE=B.concept_code AND A.SAB='NUCCPT' ;
######## Improve VA Product codes ##########
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'VA Product' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_name FROM (SELECT * FROM concept WHERE vocabulary_id='VA Product') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='VA Product') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.STR=B.concept_name AND A.SAB='VANDF' ;
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'VA Product' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_code FROM (SELECT * FROM concept WHERE vocabulary_id='VA Product') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='VA Product') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.CODE=B.concept_code AND A.SAB='VANDF' ;
######## Improve VA Class codes ##########
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'VA Class' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_name FROM (SELECT * FROM concept WHERE vocabulary_id='VA Class') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='VA Class') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.STR=B.concept_name AND A.SAB='VANDF' ;
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'VA Class' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_code FROM (SELECT * FROM concept WHERE vocabulary_id='VA Class') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='VA Class') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.CODE=B.concept_code AND A.SAB='VANDF' ;
######## Improve ICD10PCS codes ##########
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'ICD10PCS' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_name FROM (SELECT * FROM concept WHERE vocabulary_id='ICD10PCS') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='ICD10PCS') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.STR=B.concept_name AND A.SAB='ICD10PCS' ;
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'ICD10PCS' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_code FROM (SELECT * FROM concept WHERE vocabulary_id='ICD10PCS') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='ICD10PCS') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.CODE=B.concept_code AND A.SAB='ICD10PCS' ;
######## Improve ICD9CM codes ##########
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'ICD9CM' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_name FROM (SELECT * FROM concept WHERE vocabulary_id='ICD9CM') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='ICD9CM') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.STR=B.concept_name AND A.SAB='ICD9CM' ;
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'ICD9CM' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_code FROM (SELECT * FROM concept WHERE vocabulary_id='ICD9CM') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='ICD9CM') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.CODE=B.concept_code AND A.SAB='ICD9CM' ;
######## Improve ICD9Proc codes ##########
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'ICD9Proc' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_name FROM (SELECT * FROM concept WHERE vocabulary_id='ICD9Proc') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='ICD9Proc') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.STR=B.concept_name AND A.SAB='ICD9CM' ;
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'ICD9Proc' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_code FROM (SELECT * FROM concept WHERE vocabulary_id='ICD9Proc') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='ICD9Proc') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.CODE=B.concept_code AND A.SAB='ICD9CM' ;
######## Improve MeDRA codes ##########
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'MedDRA' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_name FROM (SELECT * FROM concept WHERE vocabulary_id='MedDRA') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='MedDRA') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.STR=B.concept_name AND A.SAB='MDR' ;
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'MedDRA' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_code FROM (SELECT * FROM concept WHERE vocabulary_id='MedDRA') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='MedDRA') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.CODE=B.concept_code AND A.SAB='MDR' ;
######## Improve NDFRT codes ##########
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'NDFRT' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_name FROM (SELECT * FROM concept WHERE vocabulary_id='NDFRT') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='NDFRT') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.STR=B.concept_name AND A.SAB='NDFRT' ;
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'NDFRT' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_code FROM (SELECT * FROM concept WHERE vocabulary_id='NDFRT') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='NDFRT') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.CODE=B.concept_code AND A.SAB='NDFRT' ;
######## Improve SNOMED codes ##########
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'SNOMED' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_name FROM (SELECT * FROM concept WHERE vocabulary_id='SNOMED') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='SNOMED') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.STR=B.concept_name AND A.SAB='SNOMEDCT_US' ;
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'SNOMED' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_code FROM (SELECT * FROM concept WHERE vocabulary_id='SNOMED') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='SNOMED') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.CODE=B.concept_code AND A.SAB='SNOMEDCT_US' ;
######## Improve LOINC codes ##########
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'LOINC' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_name FROM (SELECT * FROM concept WHERE vocabulary_id='LOINC') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='LOINC') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.STR=B.concept_name AND A.SAB='LNC' ;
INSERT INTO OHDSI_to_CUI2020_TEMP
SELECT DISTINCT ON (A.CUI) A.CUI , B.concept_id, 'LOINC' as vocabulary_id FROM MRCONSO as A,
(
SELECT A.concept_id, A.concept_code FROM (SELECT * FROM concept WHERE vocabulary_id='LOINC') as A LEFT JOIN (SELECT * FROM OHDSI_to_CUI2020_TEMP WHERE vocabulary_id='LOINC') as B ON A.concept_id=B.concept_id
WHERE B.CUI IS NULL
) as B WHERE A.CODE=B.concept_code AND A.SAB='LNC' ;
################# Finalize Table ###################
DROP TABLE IF EXISTS OHDSI_to_CUI2020;
CREATE TABLE OHDSI_to_CUI2020 AS ( SELECT CUI,concept_id, vocabulary_id FROM OHDSI_to_CUI2020_TEMP GROUP BY CUI,concept_id, vocabulary_id);
CREATE INDEX idxCUI2 ON OHDSI_to_CUI2020 (CUI);
CREATE INDEX idxCID2 ON OHDSI_to_CUI2020 (concept_id);
CREATE INDEX idxVID2 ON OHDSI_to_CUI2020 (vocabulary_id);
DROP TABLE IF EXISTS OHDSI_to_CUI2020_TEMP;