Skip to content

Commit

Permalink
Added ICD10 description tiers
Browse files Browse the repository at this point in the history
  • Loading branch information
dogversioning committed Jan 13, 2025
1 parent dbd122d commit 010d5c3
Show file tree
Hide file tree
Showing 17 changed files with 2,890 additions and 53 deletions.
7 changes: 7 additions & 0 deletions .sqlfluff
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
[sqlfluff]
templater = jinja
dialect = athena
sql_file_exts = .sql,.sql.jinja
exclude_rules=
# UMLS uses reserved keywords as column names, tsk tsk
references.keywords
7 changes: 7 additions & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -33,6 +33,13 @@ that concept A is a member of concept B (i.e. is a child, or is explicitly marke
being a tradename/member belonging to the parent concept).
- **mrconso_drugs** a subset of the entity list in mrconso, limited to vocabularies
specifically dealing with drug identifiers (i.e. SNOMED, RxNorm, etc.)
- **mrconso_icd10cm**/**mrrel__icd10cm** are slices of the respective main tables,
only containing records from the ICD10 coding system
- **icd10_(type)** are slices of a given coding system at the relevant level of the
ICD10 hierarchy (category,block,chapter,code)
- **icd10_tree** provides a relation-navigable code hierarchy of the individual levels
in the ICD10 hierarchy


## Licensing details

Expand Down
Binary file modified cumulus_library_umls/.DS_Store
Binary file not shown.
2 changes: 1 addition & 1 deletion cumulus_library_umls/__init__.py
Original file line number Diff line number Diff line change
@@ -1 +1 @@
__version__ = "1.1.0"
__version__ = "2.0.0"
349 changes: 349 additions & 0 deletions cumulus_library_umls/ancilary_tables.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,349 @@
-- A collection of convenience views for UMLS data

-- Selecting only child relationships FROM mrrel
CREATE TABLE IF NOT EXISTS umls__mrrel_is_a AS
SELECT
cui1,
aui1,
stype1,
rel,
cui2,
aui2,
stype2,
rela,
rui,
srui,
sab,
sl,
rg,
dir,
suppress,
cvf
FROM umls__mrrel
WHERE (
rel = 'CHD'
OR rela IN (
'isa',
'tradename_of',
'has_tradename',
'has_basis_of_strength_substance'
)
)
AND rel NOT IN ('RB', 'PAR');

-- Selecting only drug-related concepts FROM mrconso
CREATE TABLE IF NOT EXISTS umls__mrconso_drugs AS
SELECT
cui,
lat,
ts,
lui,
stt,
sui,
ispref,
aui,
saui,
scui,
sdui,
sab,
tty,
code,
str
FROM umls__mrconso
WHERE sab IN (
'ATC',
'CVX',
'DRUGBANK',
'GS',
'MED-RT',
'MMSL',
'MMX',
'MTHCMSFRF',
'MTHSPL',
'NDDF', 'RXNORM', 'SNOMEDCT_US', 'USP', 'VANDF'
);

-- ICD-10CM convenience views

CREATE TABLE IF NOT EXISTS umls__mrconso_icd10cm AS
SELECT
cui,
lat,
ts,
lui,
stt,
sui,
ispref,
aui,
saui,
scui,
sdui,
sab,
tty,
code,
str,
length(code) AS code_len
FROM umls__mrconso
WHERE sab = 'ICD10CM';

CREATE TABLE IF NOT EXISTS umls__mrrel_icd10cm AS
SELECT
cui1,
aui1,
stype1,
rel,
cui2,
aui2,
stype2,
rela,
rui,
srui,
sab,
sl,
rg,
dir,
suppress,
cvf
FROM umls__mrrel
WHERE sab = 'ICD10CM';

-- The following views slice out individual ICD layers.
-- This lines up with how a human might traverse the nomenclature to find
-- a set of codes related to a specific condition.

CREATE TABLE IF NOT EXISTS umls__icd10_chapter AS
SELECT DISTINCT
r.rui,
r.cui1,
r.cui2,
c.tty,
c.code_len,
c.code,
c.str
FROM umls__mrrel_icd10cm AS r,
umls__mrconso_icd10cm AS c
WHERE
c.tty IN ('HT')
AND c.code LIKE '%-%'
AND r.cui1 = 'C2880081'
AND r.cui2 = c.cui
ORDER BY c.code ASC;

CREATE TABLE IF NOT EXISTS umls__icd10_block AS
SELECT DISTINCT
r.rui,
r.cui1,
r.cui2,
c.tty,
c.code_len,
c.code,
c.str
FROM umls__mrrel_icd10cm AS r,
umls__mrconso_icd10cm AS c,
umls__icd10_chapter AS par
WHERE
c.tty IN ('HT')
AND r.rel = 'CHD'
AND c.code LIKE '%-%'
AND r.cui1 = par.cui2
AND r.cui2 = c.cui
ORDER BY c.code ASC;

CREATE TABLE IF NOT EXISTS umls__icd10_category AS
SELECT DISTINCT
r.rui,
r.cui1,
r.cui2,
c.tty,
c.code_len,
c.code,
c.str
FROM umls__mrrel_icd10cm AS r,
umls__mrconso_icd10cm AS c,
umls__icd10_block AS par
WHERE
c.tty IN ('HT', 'PT')
AND c.code_len = 3
AND r.rel = 'CHD'
AND r.cui1 = par.cui2
AND r.cui2 = c.cui
ORDER BY c.code ASC;

CREATE TABLE IF NOT EXISTS umls__icd10_code AS

WITH code_5 AS (
SELECT DISTINCT
r.rui,
r.cui1,
r.cui2,
c.tty,
c.code_len,
c.code,
c.str
FROM umls__mrrel_icd10cm AS r,
umls__mrconso_icd10cm AS c,
umls__icd10_category AS par
WHERE
c.tty IN ('HT', 'PT')
AND c.code LIKE '%.%'
AND (c.code_len = 5 OR c.code LIKE '%.%X%')
AND r.rel = 'CHD'
AND r.cui1 = par.cui2
AND r.cui2 = c.cui
),

code_6 AS (
SELECT DISTINCT
r.rui,
r.cui1,
r.cui2,
c.tty,
c.code_len,
c.code,
c.str
FROM umls__mrrel_icd10cm AS r,
umls__mrconso_icd10cm AS c,
code_5 AS par
WHERE
c.tty IN ('HT', 'PT')
AND c.code LIKE '%.%'
AND (c.code_len = 6 OR c.code LIKE '%.%X%')
AND r.rel = 'CHD'
AND r.cui1 = par.cui2
AND r.cui2 = c.cui
),

code_7 AS (
SELECT DISTINCT
r.rui,
r.cui1,
r.cui2,
c.tty,
c.code_len,
c.code,
c.str
FROM umls__mrrel_icd10cm AS r,
umls__mrconso_icd10cm AS c,
code_6 AS par
WHERE
c.tty IN ('HT', 'PT')
AND c.code LIKE '%.%'
AND (c.code_len = 7 OR c.code LIKE '%.%X%')
AND c.code LIKE '%.%'
AND r.rel = 'CHD'
AND r.cui1 = par.cui2
AND r.cui2 = c.cui
ORDER BY c.code ASC
),

code_8 AS (
SELECT DISTINCT
r.rui,
r.cui1,
r.cui2,
c.tty,
c.code_len,
c.code,
c.str
FROM umls__mrrel_icd10cm AS r,
umls__mrconso_icd10cm AS c,
code_7 AS par
WHERE
c.tty IN ('HT', 'PT')
AND c.code LIKE '%.%'
AND (c.code_len = 8 OR c.code LIKE '%.%X%')
AND c.code LIKE '%.%'
AND r.rel = 'CHD'
AND r.cui1 = par.cui2
AND r.cui2 = c.cui
ORDER BY c.code ASC
)

SELECT
rui,
cui1,
cui2,
tty,
code_len,
code,
str,
5 AS depth
FROM code_5
UNION
SELECT
rui,
cui1,
cui2,
tty,
code_len,
code,
str,
6 AS depth
FROM code_6
UNION
SELECT
rui,
cui1,
cui2,
tty,
code_len,
code,
str,
7 AS depth
FROM code_7
UNION
SELECT
rui,
cui1,
cui2,
tty,
code_len,
code,
str,
8 AS depth
FROM code_8;

CREATE OR REPLACE VIEW umls__icd10_tree AS
SELECT
rui,
cui1,
cui2,
tty,
code_len,
code,
str,
2 AS depth
FROM umls__icd10_chapter
UNION
SELECT
rui,
cui1,
cui2,
tty,
code_len,
code,
str,
3 AS depth
FROM umls__icd10_block
UNION
SELECT
rui,
cui1,
cui2,
tty,
code_len,
code,
str,
4 AS depth
FROM umls__icd10_category
UNION
SELECT
rui,
cui1,
cui2,
tty,
code_len,
code,
str,
depth
FROM umls__icd10_code
3 changes: 2 additions & 1 deletion cumulus_library_umls/manifest.toml
Original file line number Diff line number Diff line change
Expand Up @@ -3,7 +3,8 @@ study_prefix = "umls"
[table_builder_config]
file_names = [
"umls_builder.py",
"static_builder.py"
"static_builder.py",
"ancilary_tables.sql"
]

[advanced_options]
Expand Down
Loading

0 comments on commit 010d5c3

Please sign in to comment.