diff --git a/.github/workflows/psql.yml b/.github/workflows/psql.yml index 4eab8214f..5c6f2d764 100644 --- a/.github/workflows/psql.yml +++ b/.github/workflows/psql.yml @@ -28,6 +28,11 @@ jobs: - name: Check out repository code uses: actions/checkout@v3 + - name: Install Python + uses: actions/setup-python@v5 + with: + python-version: '3.10' + - name: Download demo data uses: ./.github/actions/download-demo @@ -60,7 +65,7 @@ jobs: PGPASSWORD: postgres BUILDCODE_PATH: mimic-iv/buildmimic/postgres - - name: Build mimic-iv concepts + - name: mimic-iv/concepts psql build run: | psql -h $POSTGRES_HOST -U postgres -f postgres-functions.sql psql -h $POSTGRES_HOST -U postgres -f postgres-make-concepts.sql @@ -69,6 +74,16 @@ jobs: POSTGRES_HOST: postgres PGPASSWORD: postgres + - name: mimic_utils - convert mimic-iv concepts to PostgreSQL and rebuild + run: | + pip install . + mimic_utils convert_folder mimic-iv/concepts mimic-iv/concepts_postgres --source_dialect bigquery --destination_dialect postgres + psql -h $POSTGRES_HOST -U postgres -f mimic-iv/concepts_postgres/postgres-make-concepts.sql + working-directory: ./ + env: + POSTGRES_HOST: postgres + PGPASSWORD: postgres + - name: Load ed data into PostgreSQL run: | echo "Loading data into psql." diff --git a/README_mimic_utils.md b/README_mimic_utils.md new file mode 100644 index 000000000..729c3a44d --- /dev/null +++ b/README_mimic_utils.md @@ -0,0 +1,3 @@ +# mimic_utils package + +This package contains utilities for working with the MIMIC datasets. \ No newline at end of file diff --git a/mimic-iii/buildmimic/duckdb/README.md b/mimic-iii/buildmimic/duckdb/README.md index 17787e2ec..15c3e9945 100644 --- a/mimic-iii/buildmimic/duckdb/README.md +++ b/mimic-iii/buildmimic/duckdb/README.md @@ -1,20 +1,51 @@ -# DuckDB +# MIMIC-III in DuckDB -The script in this folder creates the schema for MIMIC-IV and +The scripts in this folder create the schema for MIMIC-III and loads the data into the appropriate tables for [DuckDB](https://duckdb.org/). + DuckDB, like SQLite, is serverless and stores all information in a single file. Unlike SQLite, an OLTP database, DuckDB is an OLAP database, and therefore optimized for analytical queries. -This will result in faster queries for researchers using MIMIC-IV +This will result in faster queries for researchers using MIMIC-III with DuckDB compared to SQLite. To learn more, please read their ["why duckdb"](https://duckdb.org/docs/why_duckdb) page. -The instructions to load MIMIC-III into a DuckDB -only require: -1. DuckDB to be installed and +## Download MIMIC-III files + +[Download](https://physionet.org/content/mimiciii/1.4/) +the CSV files for MIMIC-III by any method you wish. +(These scripts should also work with the much smaller +[demo version](https://physionet.org/content/mimiciii-demo/1.4/#files-panel) +of the dataset.) + +The easiest way to download them is to open a terminal then run: + +``` +wget -r -N -c -np -nH --cut-dirs=1 --user YOURUSERNAME --ask-password https://physionet.org/files/mimiciii/1.4/ +``` + +Replace `YOURUSERNAME` with your physionet username. + +The rest of these intructions assume the CSV files are in the folder structure as follows: + +``` +mimic_data_dir/ + ADMISSIONS.csv.gz + CALLOUT.csv.gz + ... +``` + +By default, the above `wget` downloads the data into `mimiciii/1.4` (as we used `--cut-dirs=1` to remove the base folder). Thus, by default, `mimic_data_dir` is `mimiciii/1.4` (relative to the current folder). The CSV files can be uncompressed (end in `.csv`) or compressed (end in `.csv.gz`). + + +## Shell script method (`import_duckdb.sh`) + +Using this script to load MIMIC-III into a DuckDB +only requires: +1. DuckDB to be installed (the `duckdb` executable must be in your PATH) 2. Your computer to have a POSIX-compliant terminal shell, which is already found by default on any Mac OSX, Linux, or BSD installation. @@ -24,14 +55,6 @@ which you can obtain by either installing [Windows Subsystem for Linux](https://docs.microsoft.com/en-us/windows/wsl/install-win10) or [Cygwin](https://www.cygwin.com/). -## Set-up - -### Quick overview - -1. [Install](https://duckdb.org/docs/installation/) the CLI version of DuckDB -2. [Download](https://physionet.org/content/mimiciii/1.4/) the MIMIC-III files -3. Create DuckDB database and load data - ### Install DuckDB Follow instructions on their website to @@ -41,37 +64,10 @@ the CLI version of DuckDB. You will need to place the `duckdb` binary in a folder on your environment path, e.g. `/usr/local/bin`. -### Download MIMIC-III files - -[Download](https://physionet.org/content/mimiciii/1.4/) -the CSV files for MIMIC-III by any method you wish. - -The intructions assume the CSV files are in the folder structure as follows: - -``` -mimic_data_dir - ADMISSIONS.csv.gz - ... -``` -The CSV files can be uncompressed (end in `.csv`) or compressed (end in `.csv.gz`). +### Create DuckDB database and load data -The easiest way to download them is to open a terminal then run: - -``` -wget -r -N -c -np -nH --cut-dirs=1 --user YOURUSERNAME --ask-password https://physionet.org/files/mimiciii/1.4/ -``` - -Replace `YOURUSERNAME` with your physionet username. - -This will make you `mimic_data_dir` be `mimiciii/1.4`. - -# Create DuckDB database and load data - -The last step requires creating a DuckDB database and -loading the data into it. - -You can do all of this will one shell script, `import_duckdb.sh`, +You can do all of this with one shell script, `import_duckdb.sh`, located in this repository. See the help for it below: @@ -102,6 +98,7 @@ The script will print out progress as it goes. Be patient, this can take minutes to hours to load depending on your computer's configuration. + # Help -Please see the [issues page](https://github.com/MIT-LCP/mimic-iii/issues) to discuss other issues you may be having. +Please see the [issues page](https://github.com/MIT-LCP/mimic-code/issues) to discuss other issues you may be having. diff --git a/mimic-iii/buildmimic/duckdb/duckdb_add_indexes.sql b/mimic-iii/buildmimic/duckdb/duckdb_add_indexes.sql new file mode 100644 index 000000000..6435eb485 --- /dev/null +++ b/mimic-iii/buildmimic/duckdb/duckdb_add_indexes.sql @@ -0,0 +1,553 @@ +-- ---------------------------------------------------------------- +-- +-- This is a script to add the MIMIC-III indexes for DuckDB. +-- +-- ---------------------------------------------------------------- + +-- This is based on the PostgreSQL version but removes the partitioning +-- for the CHARTEVENTS table. + +------------- +-- ADMISSIONS +------------- + +DROP INDEX IF EXISTS ADMISSIONS_idx01; +CREATE INDEX ADMISSIONS_IDX01 + ON ADMISSIONS (SUBJECT_ID); + +DROP INDEX IF EXISTS ADMISSIONS_idx02; +CREATE INDEX ADMISSIONS_IDX02 + ON ADMISSIONS (HADM_ID); + +-- DROP INDEX IF EXISTS ADMISSIONS_idx03; +-- CREATE INDEX ADMISSIONS_IDX03 +-- ON ADMISSIONS (ADMISSION_TYPE); + + +----------- +--CALLOUT-- +----------- + +DROP INDEX IF EXISTS CALLOUT_idx01; +CREATE INDEX CALLOUT_IDX01 + ON CALLOUT (SUBJECT_ID); + +DROP INDEX IF EXISTS CALLOUT_idx02; +CREATE INDEX CALLOUT_IDX02 + ON CALLOUT (HADM_ID); + +-- DROP INDEX IF EXISTS CALLOUT_idx03; +-- CREATE INDEX CALLOUT_IDX03 +-- ON CALLOUT (CALLOUT_SERVICE); + +-- DROP INDEX IF EXISTS CALLOUT_idx04; +-- CREATE INDEX CALLOUT_IDX04 +-- ON CALLOUT (CURR_WARDID, CALLOUT_WARDID, +-- DISCHARGE_WARDID); + +-- DROP INDEX IF EXISTS CALLOUT_idx05; +-- CREATE INDEX CALLOUT_IDX05 +-- ON CALLOUT (CALLOUT_STATUS, +-- CALLOUT_OUTCOME); + +-- DROP INDEX IF EXISTS CALLOUT_idx06; +-- CREATE INDEX CALLOUT_IDX06 +-- ON CALLOUT (CREATETIME, UPDATETIME, +-- ACKNOWLEDGETIME, OUTCOMETIME); + +--------------- +-- CAREGIVERS +--------------- + +-- DROP INDEX IF EXISTS CAREGIVERS_idx01; +-- CREATE INDEX CAREGIVERS_IDX01 +-- ON CAREGIVERS (CGID, LABEL); + +--------------- +-- CHARTEVENTS +--------------- + +DROP INDEX IF EXISTS chartevents_idx01; +CREATE INDEX chartevents_idx01 ON chartevents (itemid); + +--------------- +-- CPTEVENTS +--------------- + +DROP INDEX IF EXISTS CPTEVENTS_idx01; +CREATE INDEX CPTEVENTS_idx01 + ON CPTEVENTS (SUBJECT_ID); + +DROP INDEX IF EXISTS CPTEVENTS_idx02; +CREATE INDEX CPTEVENTS_idx02 + ON CPTEVENTS (CPT_CD); + +----------- +-- D_CPT +----------- + +-- Table is 134 rows - doesn't need an index. + +-------------------- +-- D_ICD_DIAGNOSES +-------------------- + +DROP INDEX IF EXISTS D_ICD_DIAG_idx01; +CREATE INDEX D_ICD_DIAG_idx01 + ON D_ICD_DIAGNOSES (ICD9_CODE); + +DROP INDEX IF EXISTS D_ICD_DIAG_idx02; +CREATE INDEX D_ICD_DIAG_idx02 + ON D_ICD_DIAGNOSES (LONG_TITLE); + +-------------------- +-- D_ICD_PROCEDURES +-------------------- + +DROP INDEX IF EXISTS D_ICD_PROC_idx01; +CREATE INDEX D_ICD_PROC_idx01 + ON D_ICD_PROCEDURES (ICD9_CODE); + +DROP INDEX IF EXISTS D_ICD_PROC_idx02; +CREATE INDEX D_ICD_PROC_idx02 + ON D_ICD_PROCEDURES (LONG_TITLE); + +----------- +-- D_ITEMS +----------- + +DROP INDEX IF EXISTS D_ITEMS_idx01; +CREATE INDEX D_ITEMS_idx01 + ON D_ITEMS (ITEMID); + +DROP INDEX IF EXISTS D_ITEMS_idx02; +CREATE INDEX D_ITEMS_idx02 + ON D_ITEMS (LABEL); + +-- DROP INDEX IF EXISTS D_ITEMS_idx03; +-- CREATE INDEX D_ITEMS_idx03 +-- ON D_ITEMS (CATEGORY); + +--------------- +-- D_LABITEMS +--------------- + +DROP INDEX IF EXISTS D_LABITEMS_idx01; +CREATE INDEX D_LABITEMS_idx01 + ON D_LABITEMS (ITEMID); + +DROP INDEX IF EXISTS D_LABITEMS_idx02; +CREATE INDEX D_LABITEMS_idx02 + ON D_LABITEMS (LABEL); + +DROP INDEX IF EXISTS D_LABITEMS_idx03; +CREATE INDEX D_LABITEMS_idx03 + ON D_LABITEMS (LOINC_CODE); + +------------------- +-- DATETIMEEVENTS +------------------- + +DROP INDEX IF EXISTS DATETIMEEVENTS_idx01; +CREATE INDEX DATETIMEEVENTS_idx01 + ON DATETIMEEVENTS (SUBJECT_ID); + +DROP INDEX IF EXISTS DATETIMEEVENTS_idx02; +CREATE INDEX DATETIMEEVENTS_idx02 + ON DATETIMEEVENTS (ITEMID); + +DROP INDEX IF EXISTS DATETIMEEVENTS_idx03; +CREATE INDEX DATETIMEEVENTS_idx03 + ON DATETIMEEVENTS (ICUSTAY_ID); + +DROP INDEX IF EXISTS DATETIMEEVENTS_idx04; +CREATE INDEX DATETIMEEVENTS_idx04 + ON DATETIMEEVENTS (HADM_ID); + +-- DROP INDEX IF EXISTS DATETIMEEVENTS_idx05; +-- CREATE INDEX DATETIMEEVENTS_idx05 +-- ON DATETIMEEVENTS (VALUE); + +------------------ +-- DIAGNOSES_ICD +------------------ + +DROP INDEX IF EXISTS DIAGNOSES_ICD_idx01; +CREATE INDEX DIAGNOSES_ICD_idx01 + ON DIAGNOSES_ICD (SUBJECT_ID); + +DROP INDEX IF EXISTS DIAGNOSES_ICD_idx02; +CREATE INDEX DIAGNOSES_ICD_idx02 + ON DIAGNOSES_ICD (ICD9_CODE); + +DROP INDEX IF EXISTS DIAGNOSES_ICD_idx03; +CREATE INDEX DIAGNOSES_ICD_idx03 + ON DIAGNOSES_ICD (HADM_ID); + +-------------- +-- DRGCODES +-------------- + +DROP INDEX IF EXISTS DRGCODES_idx01; +CREATE INDEX DRGCODES_idx01 + ON DRGCODES (SUBJECT_ID); + +DROP INDEX IF EXISTS DRGCODES_idx02; +CREATE INDEX DRGCODES_idx02 + ON DRGCODES (DRG_CODE); + +DROP INDEX IF EXISTS DRGCODES_idx03; +CREATE INDEX DRGCODES_idx03 + ON DRGCODES (DESCRIPTION); + +-- HADM_ID + +------------------ +-- ICUSTAYS +------------------ + +DROP INDEX IF EXISTS ICUSTAYS_idx01; +CREATE INDEX ICUSTAYS_idx01 + ON ICUSTAYS (SUBJECT_ID); + +DROP INDEX IF EXISTS ICUSTAYS_idx02; +CREATE INDEX ICUSTAYS_idx02 + ON ICUSTAYS (ICUSTAY_ID); + +-- DROP INDEX IF EXISTS ICUSTAYS_idx03; +-- CREATE INDEX ICUSTAYS_idx03 +-- ON ICUSTAYS (LOS); + +-- DROP INDEX IF EXISTS ICUSTAYS_idx04; +-- CREATE INDEX ICUSTAYS_idx04 +-- ON ICUSTAYS (FIRST_CAREUNIT); + +-- DROP INDEX IF EXISTS ICUSTAYS_idx05; +-- CREATE INDEX ICUSTAYS_idx05 +-- ON ICUSTAYS (LAST_CAREUNIT); + +DROP INDEX IF EXISTS ICUSTAYS_idx06; +CREATE INDEX ICUSTAYS_IDX06 + ON ICUSTAYS (HADM_ID); + +------------- +-- INPUTEVENTS_CV +------------- + +DROP INDEX IF EXISTS INPUTEVENTS_CV_idx01; +CREATE INDEX INPUTEVENTS_CV_idx01 + ON INPUTEVENTS_CV (SUBJECT_ID); + +DROP INDEX IF EXISTS INPUTEVENTS_CV_idx02; +CREATE INDEX INPUTEVENTS_CV_idx02 + ON INPUTEVENTS_CV (HADM_ID); + +DROP INDEX IF EXISTS INPUTEVENTS_CV_idx03; +CREATE INDEX INPUTEVENTS_CV_idx03 + ON INPUTEVENTS_CV (ICUSTAY_ID); + +DROP INDEX IF EXISTS INPUTEVENTS_CV_idx04; +CREATE INDEX INPUTEVENTS_CV_idx04 + ON INPUTEVENTS_CV (CHARTTIME); + +DROP INDEX IF EXISTS INPUTEVENTS_CV_idx05; +CREATE INDEX INPUTEVENTS_CV_idx05 + ON INPUTEVENTS_CV (ITEMID); + +-- DROP INDEX IF EXISTS INPUTEVENTS_CV_idx06; +-- CREATE INDEX INPUTEVENTS_CV_idx06 +-- ON INPUTEVENTS_CV (RATE); + +-- DROP INDEX IF EXISTS INPUTEVENTS_CV_idx07; +-- CREATE INDEX INPUTEVENTS_CV_idx07 +-- ON INPUTEVENTS_CV (AMOUNT); + +-- DROP INDEX IF EXISTS INPUTEVENTS_CV_idx08; +-- CREATE INDEX INPUTEVENTS_CV_idx08 +-- ON INPUTEVENTS_CV (CGID); + +-- DROP INDEX IF EXISTS INPUTEVENTS_CV_idx09; +-- CREATE INDEX INPUTEVENTS_CV_idx09 +-- ON INPUTEVENTS_CV (LINKORDERID, ORDERID); + +------------- +-- INPUTEVENTS_MV +------------- + +DROP INDEX IF EXISTS INPUTEVENTS_MV_idx01; +CREATE INDEX INPUTEVENTS_MV_idx01 + ON INPUTEVENTS_MV (SUBJECT_ID); + +DROP INDEX IF EXISTS INPUTEVENTS_MV_idx02; +CREATE INDEX INPUTEVENTS_MV_idx02 + ON INPUTEVENTS_MV (HADM_ID); + +DROP INDEX IF EXISTS INPUTEVENTS_MV_idx03; +CREATE INDEX INPUTEVENTS_MV_idx03 + ON INPUTEVENTS_MV (ICUSTAY_ID); + +-- DROP INDEX IF EXISTS INPUTEVENTS_MV_idx04; +-- CREATE INDEX INPUTEVENTS_MV_idx04 +-- ON INPUTEVENTS_MV (ENDTIME, STARTTIME); + +DROP INDEX IF EXISTS INPUTEVENTS_MV_idx05; +CREATE INDEX INPUTEVENTS_MV_idx05 + ON INPUTEVENTS_MV (ITEMID); + +-- DROP INDEX IF EXISTS INPUTEVENTS_MV_idx06; +-- CREATE INDEX INPUTEVENTS_MV_idx06 +-- ON INPUTEVENTS_MV (RATE); + +-- DROP INDEX IF EXISTS INPUTEVENTS_MV_idx07; +-- CREATE INDEX INPUTEVENTS_MV_idx07 +-- ON INPUTEVENTS_MV (VOLUME); + +-- DROP INDEX IF EXISTS INPUTEVENTS_MV_idx08; +-- CREATE INDEX INPUTEVENTS_MV_idx08 +-- ON INPUTEVENTS_MV (CGID); + +-- DROP INDEX IF EXISTS INPUTEVENTS_MV_idx09; +-- CREATE INDEX INPUTEVENTS_MV_idx09 +-- ON INPUTEVENTS_MV (LINKORDERID, ORDERID); + +-- DROP INDEX IF EXISTS INPUTEVENTS_MV_idx10; +-- CREATE INDEX INPUTEVENTS_MV_idx10 +-- ON INPUTEVENTS_MV (ORDERCATEGORYDESCRIPTION, +-- ORDERCATEGORYNAME, SECONDARYORDERCATEGORYNAME); + +-- DROP INDEX IF EXISTS INPUTEVENTS_MV_idx11; +-- CREATE INDEX INPUTEVENTS_MV_idx11 +-- ON INPUTEVENTS_MV (ORDERCOMPONENTTYPEDESCRIPTION, +-- ORDERCATEGORYDESCRIPTION); + + +-------------- +-- LABEVENTS +-------------- + +DROP INDEX IF EXISTS LABEVENTS_idx01; +CREATE INDEX LABEVENTS_idx01 + ON LABEVENTS (SUBJECT_ID); + +DROP INDEX IF EXISTS LABEVENTS_idx02; +CREATE INDEX LABEVENTS_idx02 + ON LABEVENTS (HADM_ID); + +DROP INDEX IF EXISTS LABEVENTS_idx03; +CREATE INDEX LABEVENTS_idx03 + ON LABEVENTS (ITEMID); + +-- DROP INDEX IF EXISTS LABEVENTS_idx04; +-- CREATE INDEX LABEVENTS_idx04 +-- ON LABEVENTS (VALUE, VALUENUM); + +---------------------- +-- MICROBIOLOGYEVENTS +---------------------- + +DROP INDEX IF EXISTS MICROBIOLOGYEVENTS_idx01; +CREATE INDEX MICROBIOLOGYEVENTS_idx01 + ON MICROBIOLOGYEVENTS (SUBJECT_ID); + +DROP INDEX IF EXISTS MICROBIOLOGYEVENTS_idx02; +CREATE INDEX MICROBIOLOGYEVENTS_idx02 + ON MICROBIOLOGYEVENTS (HADM_ID); + +-- DROP INDEX IF EXISTS MICROBIOLOGYEVENTS_idx03; +-- CREATE INDEX MICROBIOLOGYEVENTS_idx03 +-- ON MICROBIOLOGYEVENTS (SPEC_ITEMID, +-- ORG_ITEMID, AB_ITEMID); + +--------------- +-- NOTEEVENTS +--------------- + +DROP INDEX IF EXISTS NOTEEVENTS_idx01; +CREATE INDEX NOTEEVENTS_idx01 + ON NOTEEVENTS (SUBJECT_ID); + +DROP INDEX IF EXISTS NOTEEVENTS_idx02; +CREATE INDEX NOTEEVENTS_idx02 + ON NOTEEVENTS (HADM_ID); + +-- DROP INDEX IF EXISTS NOTEEVENTS_idx03; +-- CREATE INDEX NOTEEVENTS_idx03 +-- ON NOTEEVENTS (CGID); + +-- DROP INDEX IF EXISTS NOTEEVENTS_idx04; +-- CREATE INDEX NOTEEVENTS_idx04 +-- ON NOTEEVENTS (RECORD_ID); + +DROP INDEX IF EXISTS NOTEEVENTS_idx05; +CREATE INDEX NOTEEVENTS_idx05 + ON NOTEEVENTS (CATEGORY); + + +--------------- +-- OUTPUTEVENTS +--------------- +DROP INDEX IF EXISTS OUTPUTEVENTS_idx01; +CREATE INDEX OUTPUTEVENTS_idx01 + ON OUTPUTEVENTS (SUBJECT_ID); + + +DROP INDEX IF EXISTS OUTPUTEVENTS_idx02; +CREATE INDEX OUTPUTEVENTS_idx02 + ON OUTPUTEVENTS (ITEMID); + + +DROP INDEX IF EXISTS OUTPUTEVENTS_idx03; +CREATE INDEX OUTPUTEVENTS_idx03 + ON OUTPUTEVENTS (ICUSTAY_ID); + + +DROP INDEX IF EXISTS OUTPUTEVENTS_idx04; +CREATE INDEX OUTPUTEVENTS_idx04 + ON OUTPUTEVENTS (HADM_ID); + +-- Perhaps not useful to index on just value? Index just for popular subset? +-- DROP INDEX IF EXISTS OUTPUTEVENTS_idx05; +-- CREATE INDEX OUTPUTEVENTS_idx05 +-- ON OUTPUTEVENTS (VALUE); + + +------------- +-- PATIENTS +------------- + +-- Note that SUBJECT_ID is already indexed as it is unique + +-- DROP INDEX IF EXISTS PATIENTS_idx01; +-- CREATE INDEX PATIENTS_idx01 +-- ON PATIENTS (EXPIRE_FLAG); + + +------------------ +-- PRESCRIPTIONS +------------------ + +DROP INDEX IF EXISTS PRESCRIPTIONS_idx01; +CREATE INDEX PRESCRIPTIONS_idx01 + ON PRESCRIPTIONS (SUBJECT_ID); + +DROP INDEX IF EXISTS PRESCRIPTIONS_idx02; +CREATE INDEX PRESCRIPTIONS_idx02 + ON PRESCRIPTIONS (ICUSTAY_ID); + +DROP INDEX IF EXISTS PRESCRIPTIONS_idx03; +CREATE INDEX PRESCRIPTIONS_idx03 + ON PRESCRIPTIONS (DRUG_TYPE); + +DROP INDEX IF EXISTS PRESCRIPTIONS_idx04; +CREATE INDEX PRESCRIPTIONS_idx04 + ON PRESCRIPTIONS (DRUG); + +DROP INDEX IF EXISTS PRESCRIPTIONS_idx05; +CREATE INDEX PRESCRIPTIONS_idx05 + ON PRESCRIPTIONS (HADM_ID); + + +--------------------- +-- PROCEDUREEVENTS_MV +--------------------- + +DROP INDEX IF EXISTS PROCEDUREEVENTS_MV_idx01; +CREATE INDEX PROCEDUREEVENTS_MV_idx01 + ON PROCEDUREEVENTS_MV (SUBJECT_ID); + +DROP INDEX IF EXISTS PROCEDUREEVENTS_MV_idx02; +CREATE INDEX PROCEDUREEVENTS_MV_idx02 + ON PROCEDUREEVENTS_MV (HADM_ID); + +DROP INDEX IF EXISTS PROCEDUREEVENTS_MV_idx03; +CREATE INDEX PROCEDUREEVENTS_MV_idx03 + ON PROCEDUREEVENTS_MV (ICUSTAY_ID); + +-- DROP INDEX IF EXISTS PROCEDUREEVENTS_MV_idx04; +-- CREATE INDEX PROCEDUREEVENTS_MV_idx04 +-- ON PROCEDUREEVENTS_MV (ENDTIME, STARTTIME); + +DROP INDEX IF EXISTS PROCEDUREEVENTS_MV_idx05; +CREATE INDEX PROCEDUREEVENTS_MV_idx05 + ON PROCEDUREEVENTS_MV (ITEMID); + +-- DROP INDEX IF EXISTS PROCEDUREEVENTS_MV_idx06; +-- CREATE INDEX PROCEDUREEVENTS_MV_idx06 +-- ON PROCEDUREEVENTS_MV (VALUE); + +-- DROP INDEX IF EXISTS PROCEDUREEVENTS_MV_idx07; +-- CREATE INDEX PROCEDUREEVENTS_MV_idx07 +-- ON PROCEDUREEVENTS_MV (CGID); + +-- DROP INDEX IF EXISTS PROCEDUREEVENTS_MV_idx08; +-- CREATE INDEX PROCEDUREEVENTS_MV_idx08 +-- ON PROCEDUREEVENTS_MV (LINKORDERID, ORDERID); + +-- DROP INDEX IF EXISTS PROCEDUREEVENTS_MV_idx09; +-- CREATE INDEX PROCEDUREEVENTS_MV_idx09 +-- ON PROCEDUREEVENTS_MV (ORDERCATEGORYDESCRIPTION, +-- ORDERCATEGORYNAME, SECONDARYORDERCATEGORYNAME); + +------------------- +-- PROCEDURES_ICD +------------------- + +DROP INDEX IF EXISTS PROCEDURES_ICD_idx01; +CREATE INDEX PROCEDURES_ICD_idx01 + ON PROCEDURES_ICD (SUBJECT_ID); + +DROP INDEX IF EXISTS PROCEDURES_ICD_idx02; +CREATE INDEX PROCEDURES_ICD_idx02 + ON PROCEDURES_ICD (ICD9_CODE); + +DROP INDEX IF EXISTS PROCEDURES_ICD_idx03; +CREATE INDEX PROCEDURES_ICD_idx03 + ON PROCEDURES_ICD (HADM_ID); + + +------------- +-- SERVICES +------------- + +DROP INDEX IF EXISTS SERVICES_idx01; +CREATE INDEX SERVICES_idx01 + ON SERVICES (SUBJECT_ID); + +DROP INDEX IF EXISTS SERVICES_idx02; +CREATE INDEX SERVICES_idx02 + ON SERVICES (HADM_ID); + +-- DROP INDEX IF EXISTS SERVICES_idx03; +-- CREATE INDEX SERVICES_idx03 +-- ON SERVICES (CURR_SERVICE, PREV_SERVICE); + +------------- +-- TRANSFERS +------------- + +DROP INDEX IF EXISTS TRANSFERS_idx01; +CREATE INDEX TRANSFERS_idx01 + ON TRANSFERS (SUBJECT_ID); + +DROP INDEX IF EXISTS TRANSFERS_idx02; +CREATE INDEX TRANSFERS_idx02 + ON TRANSFERS (ICUSTAY_ID); + +DROP INDEX IF EXISTS TRANSFERS_idx03; +CREATE INDEX TRANSFERS_idx03 + ON TRANSFERS (HADM_ID); + +-- DROP INDEX IF EXISTS TRANSFERS_idx04; +-- CREATE INDEX TRANSFERS_idx04 +-- ON TRANSFERS (INTIME, OUTTIME); + +-- DROP INDEX IF EXISTS TRANSFERS_idx05; +-- CREATE INDEX TRANSFERS_idx05 +-- ON TRANSFERS (LOS); + +-------------------------------------- +-- CHARTEVENTS PRIMARY KEY SUBSTITUTE +-------------------------------------- + +-- FIXME: Remove this index when the PK can be re-added... +CREATE UNIQUE INDEX chartevents_rowid_pk ON CHARTEVENTS (ROW_ID); diff --git a/mimic-iii/buildmimic/duckdb/duckdb_add_tables.sql b/mimic-iii/buildmimic/duckdb/duckdb_add_tables.sql new file mode 100644 index 000000000..f4e65fd2b --- /dev/null +++ b/mimic-iii/buildmimic/duckdb/duckdb_add_tables.sql @@ -0,0 +1,490 @@ +DROP TABLE IF EXISTS ADMISSIONS CASCADE; +CREATE TABLE ADMISSIONS +( + ROW_ID INT NOT NULL, + SUBJECT_ID INT NOT NULL, + HADM_ID INT NOT NULL, + ADMITTIME TIMESTAMP NOT NULL, + DISCHTIME TIMESTAMP NOT NULL, + DEATHTIME TIMESTAMP, + ADMISSION_TYPE VARCHAR(50) NOT NULL, + ADMISSION_LOCATION VARCHAR(50) NOT NULL, + DISCHARGE_LOCATION VARCHAR(50) NOT NULL, + INSURANCE VARCHAR(255) NOT NULL, + LANGUAGE VARCHAR(10), + RELIGION VARCHAR(50), + MARITAL_STATUS VARCHAR(50), + ETHNICITY VARCHAR(200) NOT NULL, + EDREGTIME TIMESTAMP, + EDOUTTIME TIMESTAMP, + DIAGNOSIS VARCHAR(255), + HOSPITAL_EXPIRE_FLAG SMALLINT, + HAS_CHARTEVENTS_DATA SMALLINT NOT NULL, + CONSTRAINT adm_rowid_pk PRIMARY KEY (ROW_ID), + CONSTRAINT adm_hadm_unique UNIQUE (HADM_ID) +) ; + +DROP TABLE IF EXISTS CALLOUT CASCADE; +CREATE TABLE CALLOUT +( + ROW_ID INT NOT NULL, + SUBJECT_ID INT NOT NULL, + HADM_ID INT NOT NULL, + SUBMIT_WARDID INT, + SUBMIT_CAREUNIT VARCHAR(15), + CURR_WARDID INT, + CURR_CAREUNIT VARCHAR(15), + CALLOUT_WARDID INT, + CALLOUT_SERVICE VARCHAR(10) NOT NULL, + REQUEST_TELE SMALLINT NOT NULL, + REQUEST_RESP SMALLINT NOT NULL, + REQUEST_CDIFF SMALLINT NOT NULL, + REQUEST_MRSA SMALLINT NOT NULL, + REQUEST_VRE SMALLINT NOT NULL, + CALLOUT_STATUS VARCHAR(20) NOT NULL, + CALLOUT_OUTCOME VARCHAR(20) NOT NULL, + DISCHARGE_WARDID INT, + ACKNOWLEDGE_STATUS VARCHAR(20) NOT NULL, + CREATETIME TIMESTAMP NOT NULL, + UPDATETIME TIMESTAMP NOT NULL, + ACKNOWLEDGETIME TIMESTAMP, + OUTCOMETIME TIMESTAMP NOT NULL, + FIRSTRESERVATIONTIME TIMESTAMP, + CURRENTRESERVATIONTIME TIMESTAMP, + CONSTRAINT callout_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS CAREGIVERS CASCADE; +CREATE TABLE CAREGIVERS +( + ROW_ID INT NOT NULL, + CGID INT NOT NULL, + LABEL VARCHAR(15), + DESCRIPTION VARCHAR(30), + CONSTRAINT cg_rowid_pk PRIMARY KEY (ROW_ID), + CONSTRAINT cg_cgid_unique UNIQUE (CGID) +) ; + +DROP TABLE IF EXISTS chartevents CASCADE; +CREATE TABLE CHARTEVENTS +( + ROW_ID INT NOT NULL, + SUBJECT_ID INT NOT NULL, + HADM_ID INT, + ICUSTAY_ID INT, + ITEMID INT, + CHARTTIME TIMESTAMP, + STORETIME TIMESTAMP, + CGID INT, + VALUE VARCHAR(255), + VALUENUM DOUBLE PRECISION, + VALUEUOM VARCHAR(50), + WARNING INT, + ERROR INT, + RESULTSTATUS VARCHAR(50), + STOPPED VARCHAR(50) + -- Re-add the below when DuckDB > 0.7.1 is released? + -- See https://github.com/duckdb/duckdb/issues/6668#issuecomment-1474880266 + --,CONSTRAINT chartevents_rowid_pk PRIMARY KEY (ROW_ID) +); + +DROP TABLE IF EXISTS CPTEVENTS CASCADE; +CREATE TABLE CPTEVENTS +( + ROW_ID INT NOT NULL, + SUBJECT_ID INT NOT NULL, + HADM_ID INT NOT NULL, + COSTCENTER VARCHAR(10) NOT NULL, + CHARTDATE TIMESTAMP, + CPT_CD VARCHAR(10) NOT NULL, + CPT_NUMBER INT, + CPT_SUFFIX VARCHAR(5), + TICKET_ID_SEQ INT, + SECTIONHEADER VARCHAR(50), + SUBSECTIONHEADER VARCHAR(255), + DESCRIPTION VARCHAR(200), + CONSTRAINT cpt_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS DATETIMEEVENTS CASCADE; +CREATE TABLE DATETIMEEVENTS +( + ROW_ID INT NOT NULL, + SUBJECT_ID INT NOT NULL, + HADM_ID INT, + ICUSTAY_ID INT, + ITEMID INT NOT NULL, + CHARTTIME TIMESTAMP NOT NULL, + STORETIME TIMESTAMP NOT NULL, + CGID INT NOT NULL, + VALUE TIMESTAMP, + VALUEUOM VARCHAR(50) NOT NULL, + WARNING SMALLINT, + ERROR SMALLINT, + RESULTSTATUS VARCHAR(50), + STOPPED VARCHAR(50), + CONSTRAINT datetime_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS DIAGNOSES_ICD CASCADE; +CREATE TABLE DIAGNOSES_ICD +( + ROW_ID INT NOT NULL, + SUBJECT_ID INT NOT NULL, + HADM_ID INT NOT NULL, + SEQ_NUM INT, + ICD9_CODE VARCHAR(10), + CONSTRAINT diagnosesicd_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS DRGCODES CASCADE; +CREATE TABLE DRGCODES +( + ROW_ID INT NOT NULL, + SUBJECT_ID INT NOT NULL, + HADM_ID INT NOT NULL, + DRG_TYPE VARCHAR(20) NOT NULL, + DRG_CODE VARCHAR(20) NOT NULL, + DESCRIPTION VARCHAR(255), + DRG_SEVERITY SMALLINT, + DRG_MORTALITY SMALLINT, + CONSTRAINT drg_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS D_CPT CASCADE; +CREATE TABLE D_CPT +( + ROW_ID INT NOT NULL, + CATEGORY SMALLINT NOT NULL, + SECTIONRANGE VARCHAR(100) NOT NULL, + SECTIONHEADER VARCHAR(50) NOT NULL, + SUBSECTIONRANGE VARCHAR(100) NOT NULL, + SUBSECTIONHEADER VARCHAR(255) NOT NULL, + CODESUFFIX VARCHAR(5), + MINCODEINSUBSECTION INT NOT NULL, + MAXCODEINSUBSECTION INT NOT NULL, + CONSTRAINT dcpt_ssrange_unique UNIQUE (SUBSECTIONRANGE), + CONSTRAINT dcpt_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS D_ICD_DIAGNOSES CASCADE; +CREATE TABLE D_ICD_DIAGNOSES +( + ROW_ID INT NOT NULL, + ICD9_CODE VARCHAR(10) NOT NULL, + SHORT_TITLE VARCHAR(50) NOT NULL, + LONG_TITLE VARCHAR(255) NOT NULL, + CONSTRAINT d_icd_diag_code_unique UNIQUE (ICD9_CODE), + CONSTRAINT d_icd_diag_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS D_ICD_PROCEDURES CASCADE; +CREATE TABLE D_ICD_PROCEDURES +( + ROW_ID INT NOT NULL, + ICD9_CODE VARCHAR(10) NOT NULL, + SHORT_TITLE VARCHAR(50) NOT NULL, + LONG_TITLE VARCHAR(255) NOT NULL, + CONSTRAINT d_icd_proc_code_unique UNIQUE (ICD9_CODE), + CONSTRAINT d_icd_proc_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS D_ITEMS CASCADE; +CREATE TABLE D_ITEMS +( + ROW_ID INT NOT NULL, + ITEMID INT NOT NULL, + LABEL VARCHAR(200), + ABBREVIATION VARCHAR(100), + DBSOURCE VARCHAR(20), + LINKSTO VARCHAR(50), + CATEGORY VARCHAR(100), + UNITNAME VARCHAR(100), + PARAM_TYPE VARCHAR(30), + CONCEPTID INT, + CONSTRAINT ditems_itemid_unique UNIQUE (ITEMID), + CONSTRAINT ditems_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS D_LABITEMS CASCADE; +CREATE TABLE D_LABITEMS +( + ROW_ID INT NOT NULL, + ITEMID INT NOT NULL, + LABEL VARCHAR(100) NOT NULL, + FLUID VARCHAR(100) NOT NULL, + CATEGORY VARCHAR(100) NOT NULL, + LOINC_CODE VARCHAR(100), + CONSTRAINT dlabitems_itemid_unique UNIQUE (ITEMID), + CONSTRAINT dlabitems_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS ICUSTAYS CASCADE; +CREATE TABLE ICUSTAYS +( + ROW_ID INT NOT NULL, + SUBJECT_ID INT NOT NULL, + HADM_ID INT NOT NULL, + ICUSTAY_ID INT NOT NULL, + DBSOURCE VARCHAR(20) NOT NULL, + FIRST_CAREUNIT VARCHAR(20) NOT NULL, + LAST_CAREUNIT VARCHAR(20) NOT NULL, + FIRST_WARDID SMALLINT NOT NULL, + LAST_WARDID SMALLINT NOT NULL, + INTIME TIMESTAMP NOT NULL, + OUTTIME TIMESTAMP, + LOS DOUBLE PRECISION, + CONSTRAINT icustay_icustayid_unique UNIQUE (ICUSTAY_ID), + CONSTRAINT icustay_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS INPUTEVENTS_CV CASCADE; +CREATE TABLE INPUTEVENTS_CV +( + ROW_ID INT NOT NULL, + SUBJECT_ID INT NOT NULL, + HADM_ID INT, + ICUSTAY_ID INT, + CHARTTIME TIMESTAMP, + ITEMID INT, + AMOUNT DOUBLE PRECISION, + AMOUNTUOM VARCHAR(30), + RATE DOUBLE PRECISION, + RATEUOM VARCHAR(30), + STORETIME TIMESTAMP, + CGID INT, + ORDERID INT, + LINKORDERID INT, + STOPPED VARCHAR(30), + NEWBOTTLE INT, + ORIGINALAMOUNT DOUBLE PRECISION, + ORIGINALAMOUNTUOM VARCHAR(30), + ORIGINALROUTE VARCHAR(30), + ORIGINALRATE DOUBLE PRECISION, + ORIGINALRATEUOM VARCHAR(30), + ORIGINALSITE VARCHAR(30), + CONSTRAINT inputevents_cv_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS INPUTEVENTS_MV CASCADE; +CREATE TABLE INPUTEVENTS_MV +( + ROW_ID INT NOT NULL, + SUBJECT_ID INT NOT NULL, + HADM_ID INT, + ICUSTAY_ID INT, + STARTTIME TIMESTAMP, + ENDTIME TIMESTAMP, + ITEMID INT, + AMOUNT DOUBLE PRECISION, + AMOUNTUOM VARCHAR(30), + RATE DOUBLE PRECISION, + RATEUOM VARCHAR(30), + STORETIME TIMESTAMP, + CGID INT, + ORDERID INT, + LINKORDERID INT, + ORDERCATEGORYNAME VARCHAR(100), + SECONDARYORDERCATEGORYNAME VARCHAR(100), + ORDERCOMPONENTTYPEDESCRIPTION VARCHAR(200), + ORDERCATEGORYDESCRIPTION VARCHAR(50), + PATIENTWEIGHT DOUBLE PRECISION, + TOTALAMOUNT DOUBLE PRECISION, + TOTALAMOUNTUOM VARCHAR(50), + ISOPENBAG SMALLINT, + CONTINUEINNEXTDEPT SMALLINT, + CANCELREASON SMALLINT, + STATUSDESCRIPTION VARCHAR(30), + COMMENTS_EDITEDBY VARCHAR(30), + COMMENTS_CANCELEDBY VARCHAR(40), + COMMENTS_DATE TIMESTAMP, + ORIGINALAMOUNT DOUBLE PRECISION, + ORIGINALRATE DOUBLE PRECISION, + CONSTRAINT inputevents_mv_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS LABEVENTS CASCADE; +CREATE TABLE LABEVENTS +( + ROW_ID INT NOT NULL, + SUBJECT_ID INT NOT NULL, + HADM_ID INT, + ITEMID INT NOT NULL, + CHARTTIME TIMESTAMP, + VALUE VARCHAR(200), + VALUENUM DOUBLE PRECISION, + VALUEUOM VARCHAR(20), + FLAG VARCHAR(20), + CONSTRAINT labevents_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS MICROBIOLOGYEVENTS CASCADE; +CREATE TABLE MICROBIOLOGYEVENTS +( + ROW_ID INT NOT NULL, + SUBJECT_ID INT NOT NULL, + HADM_ID INT, + CHARTDATE TIMESTAMP, + CHARTTIME TIMESTAMP, + SPEC_ITEMID INT, + SPEC_TYPE_DESC VARCHAR(100), + ORG_ITEMID INT, + ORG_NAME VARCHAR(100), + ISOLATE_NUM SMALLINT, + AB_ITEMID INT, + AB_NAME VARCHAR(30), + DILUTION_TEXT VARCHAR(10), + DILUTION_COMPARISON VARCHAR(20), + DILUTION_VALUE DOUBLE PRECISION, + INTERPRETATION VARCHAR(5), + CONSTRAINT micro_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS NOTEEVENTS CASCADE; +CREATE TABLE NOTEEVENTS +( + ROW_ID INT NOT NULL, + SUBJECT_ID INT NOT NULL, + HADM_ID INT, + CHARTDATE TIMESTAMP, + CHARTTIME TIMESTAMP, + STORETIME TIMESTAMP, + CATEGORY VARCHAR(50), + DESCRIPTION VARCHAR(255), + CGID INT, + ISERROR CHAR(1), + TEXT TEXT, + CONSTRAINT noteevents_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS OUTPUTEVENTS CASCADE; +CREATE TABLE OUTPUTEVENTS +( + ROW_ID INT NOT NULL, + SUBJECT_ID INT NOT NULL, + HADM_ID INT, + ICUSTAY_ID INT, + CHARTTIME TIMESTAMP, + ITEMID INT, + VALUE DOUBLE PRECISION, + VALUEUOM VARCHAR(30), + STORETIME TIMESTAMP, + CGID INT, + STOPPED VARCHAR(30), + NEWBOTTLE CHAR(1), + ISERROR INT, + CONSTRAINT outputevents_cv_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS PATIENTS CASCADE; +CREATE TABLE PATIENTS +( + ROW_ID INT NOT NULL, + SUBJECT_ID INT NOT NULL, + GENDER VARCHAR(5) NOT NULL, + DOB TIMESTAMP NOT NULL, + DOD TIMESTAMP, + DOD_HOSP TIMESTAMP, + DOD_SSN TIMESTAMP, + EXPIRE_FLAG INT NOT NULL, + CONSTRAINT pat_subid_unique UNIQUE (SUBJECT_ID), + CONSTRAINT pat_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS PRESCRIPTIONS CASCADE; +CREATE TABLE PRESCRIPTIONS +( + ROW_ID INT NOT NULL, + SUBJECT_ID INT NOT NULL, + HADM_ID INT NOT NULL, + ICUSTAY_ID INT, + STARTDATE TIMESTAMP, + ENDDATE TIMESTAMP, + DRUG_TYPE VARCHAR(100) NOT NULL, + DRUG VARCHAR(100) NOT NULL, + DRUG_NAME_POE VARCHAR(100), + DRUG_NAME_GENERIC VARCHAR(100), + FORMULARY_DRUG_CD VARCHAR(120), + GSN VARCHAR(200), + NDC VARCHAR(120), + PROD_STRENGTH VARCHAR(120), + DOSE_VAL_RX VARCHAR(120), + DOSE_UNIT_RX VARCHAR(120), + FORM_VAL_DISP VARCHAR(120), + FORM_UNIT_DISP VARCHAR(120), + ROUTE VARCHAR(120), + CONSTRAINT prescription_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS PROCEDUREEVENTS_MV CASCADE; +CREATE TABLE PROCEDUREEVENTS_MV +( + ROW_ID INT NOT NULL, + SUBJECT_ID INT NOT NULL, + HADM_ID INT NOT NULL, + ICUSTAY_ID INT, + STARTTIME TIMESTAMP, + ENDTIME TIMESTAMP, + ITEMID INT, + VALUE DOUBLE PRECISION, + VALUEUOM VARCHAR(30), + LOCATION VARCHAR(30), + LOCATIONCATEGORY VARCHAR(30), + STORETIME TIMESTAMP, + CGID INT, + ORDERID INT, + LINKORDERID INT, + ORDERCATEGORYNAME VARCHAR(100), + SECONDARYORDERCATEGORYNAME VARCHAR(100), + ORDERCATEGORYDESCRIPTION VARCHAR(50), + ISOPENBAG SMALLINT, + CONTINUEINNEXTDEPT SMALLINT, + CANCELREASON SMALLINT, + STATUSDESCRIPTION VARCHAR(30), + COMMENTS_EDITEDBY VARCHAR(30), + COMMENTS_CANCELEDBY VARCHAR(30), + COMMENTS_DATE TIMESTAMP, + CONSTRAINT procedureevents_mv_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS PROCEDURES_ICD CASCADE; +CREATE TABLE PROCEDURES_ICD +( + ROW_ID INT NOT NULL, + SUBJECT_ID INT NOT NULL, + HADM_ID INT NOT NULL, + SEQ_NUM INT NOT NULL, + ICD9_CODE VARCHAR(10) NOT NULL, + CONSTRAINT proceduresicd_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS SERVICES CASCADE; +CREATE TABLE SERVICES +( + ROW_ID INT NOT NULL, + SUBJECT_ID INT NOT NULL, + HADM_ID INT NOT NULL, + TRANSFERTIME TIMESTAMP NOT NULL, + PREV_SERVICE VARCHAR(20), + CURR_SERVICE VARCHAR(20), + CONSTRAINT services_rowid_pk PRIMARY KEY (ROW_ID) +) ; + +DROP TABLE IF EXISTS TRANSFERS CASCADE; +CREATE TABLE TRANSFERS +( + ROW_ID INT NOT NULL, + SUBJECT_ID INT NOT NULL, + HADM_ID INT NOT NULL, + ICUSTAY_ID INT, + DBSOURCE VARCHAR(20), + EVENTTYPE VARCHAR(20), + PREV_CAREUNIT VARCHAR(20), + CURR_CAREUNIT VARCHAR(20), + PREV_WARDID SMALLINT, + CURR_WARDID SMALLINT, + INTIME TIMESTAMP, + OUTTIME TIMESTAMP, + LOS DOUBLE PRECISION, + CONSTRAINT transfers_rowid_pk PRIMARY KEY (ROW_ID) +) ; diff --git a/mimic-iii/buildmimic/duckdb/duckdb_checks.sql b/mimic-iii/buildmimic/duckdb/duckdb_checks.sql new file mode 100644 index 000000000..2b149ccb7 --- /dev/null +++ b/mimic-iii/buildmimic/duckdb/duckdb_checks.sql @@ -0,0 +1,77 @@ +-- this query runs a few simple checks to make sure the database has loaded in OK +-- These checks are designed for MIMIC-III v1.4 + +-- If running scripts individually, you can set the schema where all tables are created as follows: +-- SET search_path TO mimiciii; + +with expected as +( +select 'admissions' as tbl, 58976 as row_count UNION ALL +select 'callout' as tbl, 34499 as row_count UNION ALL +select 'caregivers' as tbl, 7567 as row_count UNION ALL +select 'chartevents' as tbl, 330712483 as row_count UNION ALL +select 'cptevents' as tbl, 573146 as row_count UNION ALL +select 'd_cpt' as tbl, 134 as row_count UNION ALL +select 'd_icd_diagnoses' as tbl, 14567 as row_count UNION ALL +select 'd_icd_procedures' as tbl, 3882 as row_count UNION ALL +select 'd_items' as tbl, 12487 as row_count UNION ALL +select 'd_labitems' as tbl, 753 as row_count UNION ALL +select 'datetimeevents' as tbl, 4485937 as row_count UNION ALL +select 'diagnoses_icd' as tbl, 651047 as row_count UNION ALL +select 'drgcodes' as tbl, 125557 as row_count UNION ALL +select 'icustays' as tbl, 61532 as row_count UNION ALL +select 'inputevents_cv' as tbl, 17527935 as row_count UNION ALL +select 'inputevents_mv' as tbl, 3618991 as row_count UNION ALL +select 'labevents' as tbl, 27854055 as row_count UNION ALL +select 'microbiologyevents' as tbl, 631726 as row_count UNION ALL +select 'noteevents' as tbl, 2083180 as row_count UNION ALL +select 'outputevents' as tbl, 4349218 as row_count UNION ALL +select 'patients' as tbl, 46520 as row_count UNION ALL +select 'prescriptions' as tbl, 4156450 as row_count UNION ALL +select 'procedureevents_mv' as tbl, 258066 as row_count UNION ALL +select 'procedures_icd' as tbl, 240095 as row_count UNION ALL +select 'services' as tbl, 73343 as row_count UNION ALL +select 'transfers' as tbl, 261897 as row_count +) +, observed as +( + select 'admissions' as tbl, count(*) as row_count from admissions UNION ALL + select 'callout' as tbl, count(*) as row_count from callout UNION ALL + select 'caregivers' as tbl, count(*) as row_count from caregivers UNION ALL + select 'chartevents' as tbl, count(*) as row_count from chartevents UNION ALL + select 'cptevents' as tbl, count(*) as row_count from cptevents UNION ALL + select 'd_cpt' as tbl, count(*) as row_count from d_cpt UNION ALL + select 'd_icd_diagnoses' as tbl, count(*) as row_count from d_icd_diagnoses UNION ALL + select 'd_icd_procedures' as tbl, count(*) as row_count from d_icd_procedures UNION ALL + select 'd_items' as tbl, count(*) as row_count from d_items UNION ALL + select 'd_labitems' as tbl, count(*) as row_count from d_labitems UNION ALL + select 'datetimeevents' as tbl, count(*) as row_count from datetimeevents UNION ALL + select 'diagnoses_icd' as tbl, count(*) as row_count from diagnoses_icd UNION ALL + select 'drgcodes' as tbl, count(*) as row_count from drgcodes UNION ALL + select 'icustays' as tbl, count(*) as row_count from icustays UNION ALL + select 'inputevents_cv' as tbl, count(*) as row_count from inputevents_cv UNION ALL + select 'inputevents_mv' as tbl, count(*) as row_count from inputevents_mv UNION ALL + select 'labevents' as tbl, count(*) as row_count from labevents UNION ALL + select 'microbiologyevents' as tbl, count(*) as row_count from microbiologyevents UNION ALL + select 'noteevents' as tbl, count(*) as row_count from noteevents UNION ALL + select 'outputevents' as tbl, count(*) as row_count from outputevents UNION ALL + select 'patients' as tbl, count(*) as row_count from patients UNION ALL + select 'prescriptions' as tbl, count(*) as row_count from prescriptions UNION ALL + select 'procedureevents_mv' as tbl, count(*) as row_count from procedureevents_mv UNION ALL + select 'procedures_icd' as tbl, count(*) as row_count from procedures_icd UNION ALL + select 'services' as tbl, count(*) as row_count from services UNION ALL + select 'transfers' as tbl, count(*) as row_count from transfers +) +select + exp.tbl + , exp.row_count as expected_count + , obs.row_count as observed_count + , case + when exp.row_count = obs.row_count + then 'PASSED' + else 'FAILED' + end as ROW_COUNT_CHECK +from expected exp +inner join observed obs + on exp.tbl = obs.tbl +order by exp.tbl; diff --git a/mimic-iii/buildmimic/duckdb/import_duckdb.sh b/mimic-iii/buildmimic/duckdb/import_duckdb.sh index 0a70e1e42..96c34cddc 100755 --- a/mimic-iii/buildmimic/duckdb/import_duckdb.sh +++ b/mimic-iii/buildmimic/duckdb/import_duckdb.sh @@ -70,497 +70,7 @@ fi # create tables using DDL from postgres # minor changes: TIMESTAMP(nn) -> TIMESTAMP -try duckdb "$OUTFILE" < --destination_dialect +mimic_utils convert_file mimic-iv/concepts/demographics/age.sql age.sql --destination_dialect duckdb +``` + +To transpile all files in a folder, run: + +```sh +# convert_folder --destination_dialect +mimic_utils convert_folder mimic-iv/concepts mimic-iv/concepts_duckdb --destination_dialect duckdb +``` \ No newline at end of file diff --git a/mimic-iv/buildmimic/duckdb/README.md b/mimic-iv/buildmimic/duckdb/README.md index 3584df9f9..0de5e4ae4 100644 --- a/mimic-iv/buildmimic/duckdb/README.md +++ b/mimic-iv/buildmimic/duckdb/README.md @@ -43,10 +43,11 @@ e.g. `/usr/local/bin`. ### Download MIMIC-IV files -Download the CSV files for [MIMIC-IV v2.0](https://physionet.org/content/mimiciv/2.0/) +Download the CSV files for [MIMIC-IV](https://physionet.org/content/mimiciv/) by any method you wish. +These instructions were tested with MIMIC-IV v2.2. -The intructions assume the CSV files are in the folder structure as follows: +The CSV files should be a folder structure as follows: ``` mimic_data_dir @@ -65,12 +66,12 @@ The CSV files can be uncompressed (end in `.csv`) or compressed (end in `.csv.gz The easiest way to download them is to open a terminal then run: ``` -wget -r -N -c -np --user YOURUSERNAME --ask-password https://physionet.org/files/mimiciv/2.0/ +wget -r -N -c -np --user YOURUSERNAME --ask-password https://physionet.org/files/mimiciv/2.2/ ``` Replace `YOURUSERNAME` with your physionet username. -This will make you `mimic_data_dir` be `physionet.org/files/mimiciv/2.0`. +This will make you `mimic_data_dir` be `physionet.org/files/mimiciv/2.2`. # Create DuckDB database and load data @@ -95,7 +96,7 @@ $ Here's an example invocation that will make the database in the default "mimic4.db": ```sh -$ ./import_duckdb.sh physionet.org/files/mimiciv/2.0 +$ ./import_duckdb.sh physionet.org/files/mimiciv/2.2 <... output of script snipped ...> Successfully finished loading data into mimic4.db. @@ -108,10 +109,8 @@ The script will print out progress as it goes. Be patient, this can take minutes to hours to load depending on your computer's configuration. -On a Fedora 34 workstation with duckdb v 0.2.6 -and a btrfs filesystem with ztsd level 1 compression -it took 16m25s after a fresh reboot -(Hardware: AMD Ryzen 3900X, 32 GB RAM, Samsung 970 Evo NVMe SSD). +* It took 16m25s on a Fedora 34 workstation with duckdb v 0.2.6, a btrfs filesystem with ztsd level 1 compression, AMD Ryzen 3900X, 32 GB RAM, Samsung 970 Evo NVMe SSD. +* It took ~10m on a Mac M1 Max 2021, 32 GB RAM. # Help diff --git a/mimic-iv/concepts/README.md b/mimic-iv/concepts/README.md index 7610be23a..c075a2bbd 100644 --- a/mimic-iv/concepts/README.md +++ b/mimic-iv/concepts/README.md @@ -1,53 +1,77 @@ # MIMIC-IV Concepts -This folder contains scripts to generate useful abstractions of raw MIMIC-IV data ("concepts"). -The scripts are written using the **BigQuery Standard SQL Dialect**. Concepts are categorized into folders if possible, otherwise they remain in the top-level directory. The [postgres](/mimic-iv/concepts/postgres) subfolder contains automatically generated PostgreSQL versions of these scripts; [see below for how these were generated](#postgresql-concepts). Concepts are categorized into folders if possible, otherwise they remain in the top-level directory. - -The concepts are organized into individual SQL scripts, with each script generating a table. The BigQuery `mimiciv_derived` dataset under `physionet-data` contains the concepts pregenerated. Access to this dataset is available to MIMIC-IV approved users: see the [cloud instructions](https://mimic.mit.edu/docs/gettingstarted/cloud/) on how to access MIMIC-IV on BigQuery (which includes the derived concepts). - -* [List of the concept folders and their content](#concept-index) -* [Generating the concept tables on BigQuery](#generating-the-concepts-on-bigquery) -* [Generating the concept tables on PostgreSQL](#generating-the-concepts-on-postgresql) - -## Concept Index - -## Generating the concepts on BigQuery - -Generating the concepts requires the [Google Cloud SDK](https://cloud.google.com/sdk) to be installed. -A shell script, [make_concepts.sh](/mimic-iv/concepts/make_concepts.sh), is provided which iterates over each folder and creates a table with the same name as the concept file. Concept names have been chosen specifically to avoid collisions. - -Generating a single concept can be done by calling the Google Cloud SDK as follows: - -```sh -bq query --use_legacy_sql=False --replace --destination_table=my_bigquery_dataset.age < demographics/age.sql -``` - -In general the concepts may be generated in any order, except for the *first_day_sofa* and *kdigo_stages* tables, which depend on other tables. - -## Generating the concepts on PostgreSQL - -These instructions are used to regenerate the [postgres](/mimic-iv/concepts/postgres) scripts from the BigQuery dialect scripts in the concepts folder. - -* **If you just want to create PostgreSQL concepts for your installation of MIMIC-IV, go to the [postgres](/mimic-iv/concepts/postgres) subfolder** -* If you would like to understand the process better, and possibly improve upon it, read on - -Analogously to [MIMIC-III Concepts](https://github.com/MIT-LCP/mimic-code/tree/master/concepts), the SQL scripts here are written in BigQuery's Standard SQL syntax. The concepts have been carefully written to allow conversion to PostgreSQL, so that only the following changes are necessary to make them compaible with PostgreSQL: - -* create postgres functions which emulate BigQuery functions -* modify SQL scripts for incompatible syntax -* run the modified SQL scripts and direct the output into tables in the PostgreSQL database - -To do this, we have created a (*nix/Mac OS X) compatible shell script which performs regular expression replacements for each script. To simplify the process for users, we output these automatically generated scripts to the [postgres](/mimic-iv/concepts/postgres) folder. -Re-running this shell script can be done as follows: - -1. Open a terminal in the `concepts` folder. -2. Run [convert_bigquery_to_postgres.sh](convert_bigquery_to_postgres.sh). - * e.g. `bash convert_bigquery_to_postgres.sh` - * This file outputs the scripts to the [postgres](/mimic-iv/concepts/postgres) subfolder after applying a few changes. - * This also creates the `postgres_make_concepts.sql` script in the postgres subfolder. - -### Known Problems - -* [convert_bigquery_to_postgres.sh](convert_bigquery_to_postgres.sh) fails for [suspicion_of_infection](sepsis/suspicion_of_infection.sql) due to `, DATETIME_TRUNC(abx.starttime, DAY) AS antibiotic_date`. As a consequence also [sepsis3](sepsis/sepsis3.sql) fails. -* The script runs repeatetly for subfolders `score` and `sepsis` to handle interdependecies between tables. Running the concept scripts in the correct order can be improved. -* The regular expressions in [convert_bigquery_to_postgres.sh](convert_bigquery_to_postgres.sh) depend on the current SQL scripts and might fail when they are changed. +Concepts in this folder: + +├── comorbidity +│ └── charlson.sql +├── demographics +│ ├── age.sql +│ ├── icustay_detail.sql +│ ├── icustay_hourly.sql +│ ├── icustay_times.sql +│ └── weight_durations.sql +├── firstday +│ ├── first_day_bg.sql +│ ├── first_day_bg_art.sql +│ ├── first_day_gcs.sql +│ ├── first_day_height.sql +│ ├── first_day_lab.sql +│ ├── first_day_rrt.sql +│ ├── first_day_sofa.sql +│ ├── first_day_urine_output.sql +│ ├── first_day_vitalsign.sql +│ └── first_day_weight.sql +├── measurement +│ ├── bg.sql +│ ├── blood_differential.sql +│ ├── cardiac_marker.sql +│ ├── chemistry.sql +│ ├── coagulation.sql +│ ├── complete_blood_count.sql +│ ├── creatinine_baseline.sql +│ ├── enzyme.sql +│ ├── gcs.sql +│ ├── height.sql +│ ├── icp.sql +│ ├── inflammation.sql +│ ├── oxygen_delivery.sql +│ ├── rhythm.sql +│ ├── urine_output.sql +│ ├── urine_output_rate.sql +│ ├── ventilator_setting.sql +│ └── vitalsign.sql +├── medication +│ ├── acei.sql +│ ├── antibiotic.sql +│ ├── dobutamine.sql +│ ├── dopamine.sql +│ ├── epinephrine.sql +│ ├── milrinone.sql +│ ├── neuroblock.sql +│ ├── norepinephrine.sql +│ ├── norepinephrine_equivalent_dose.sql +│ ├── nsaid.sql +│ ├── phenylephrine.sql +│ ├── vasoactive_agent.sql +│ └── vasopressin.sql +├── organfailure +│ ├── kdigo_creatinine.sql +│ ├── kdigo_stages.sql +│ ├── kdigo_uo.sql +│ └── meld.sql +├── score +│ ├── apsiii.sql +│ ├── lods.sql +│ ├── oasis.sql +│ ├── sapsii.sql +│ ├── sirs.sql +│ └── sofa.sql +├── sepsis +│ ├── sepsis3.sql +│ └── suspicion_of_infection.sql +└── treatment + ├── code_status.sql + ├── crrt.sql + ├── invasive_line.sql + ├── rrt.sql + └── ventilation.sql \ No newline at end of file diff --git a/mimic-iv/concepts/demographics/icustay_hourly.sql b/mimic-iv/concepts/demographics/icustay_hourly.sql index c51ee4dbc..fbb196d40 100644 --- a/mimic-iv/concepts/demographics/icustay_hourly.sql +++ b/mimic-iv/concepts/demographics/icustay_hourly.sql @@ -12,26 +12,26 @@ WITH all_hours AS ( SELECT it.stay_id - -- ceiling the intime to the nearest hour by adding 59 minutes, - -- then applying truncate by parsing as string - -- string truncate is done to enable compatibility with psql - , PARSE_DATETIME( - '%Y-%m-%d %H:00:00' - , FORMAT_DATETIME( - '%Y-%m-%d %H:00:00' - , DATETIME_ADD(it.intime_hr, INTERVAL '59' MINUTE) - )) AS endtime + -- round the intime up to the nearest hour + , CASE + WHEN DATETIME_TRUNC(it.intime_hr, HOUR) = it.intime_hr + THEN it.intime_hr + ELSE + DATETIME_ADD( + DATETIME_TRUNC(it.intime_hr, HOUR), INTERVAL 1 HOUR + ) + END AS endtime -- create integers for each charttime in hours from admission -- so 0 is admission time, 1 is one hour after admission, etc, -- up to ICU disch -- we allow 24 hours before ICU admission (to grab labs before admit) - , GENERATE_ARRAY(-24, CEIL(DATETIME_DIFF(it.outtime_hr, it.intime_hr, HOUR))) AS hrs -- noqa: L016 + , GENERATE_ARRAY(-24, CAST(CEIL(DATETIME_DIFF(it.outtime_hr, it.intime_hr, HOUR)) AS INTEGER)) AS hrs -- noqa: L016 FROM `physionet-data.mimiciv_derived.icustay_times` it ) SELECT stay_id - , CAST(hr AS INT64) AS hr - , DATETIME_ADD(endtime, INTERVAL CAST(hr AS INT64) HOUR) AS endtime + , CAST(hr_unnested AS INT64) AS hr + , DATETIME_ADD(endtime, INTERVAL CAST(hr_unnested AS INT64) HOUR) AS endtime FROM all_hours -CROSS JOIN UNNEST(all_hours.hrs) AS hr; +CROSS JOIN UNNEST(all_hours.hrs) AS hr_unnested; diff --git a/mimic-iv/concepts/medication/acei.sql b/mimic-iv/concepts/medication/acei.sql index 5be4c109e..4b1c2a195 100644 --- a/mimic-iv/concepts/medication/acei.sql +++ b/mimic-iv/concepts/medication/acei.sql @@ -1,33 +1,33 @@ -WITH acei_drug AS ( - SELECT DISTINCT - drug - , CASE - WHEN UPPER(drug) LIKE '%BENAZEPRIL%' THEN 1 - WHEN UPPER(drug) LIKE '%CAPTOPRIL%' THEN 1 - WHEN UPPER(drug) LIKE '%ENALAPRIL%' THEN 1 - WHEN UPPER(drug) LIKE '%FOSINOPRIL%' THEN 1 - WHEN UPPER(drug) LIKE '%LISINOPRIL%' THEN 1 - WHEN UPPER(drug) LIKE '%MOEXIPRIL%' THEN 1 - WHEN UPPER(drug) LIKE '%PERINDOPRIL%' THEN 1 - WHEN UPPER(drug) LIKE '%QUINAPRIL%' THEN 1 - WHEN UPPER(drug) LIKE '%RAMIPRIL%' THEN 1 - WHEN UPPER(drug) LIKE '%TRANDOLAPRIL%' THEN 1 - ELSE 0 - END AS acei - FROM `physionet-data.mimiciv_hosp.prescriptions` +WITH acei_drug AS ( + SELECT DISTINCT + drug + , CASE + WHEN UPPER(drug) LIKE '%BENAZEPRIL%' THEN 1 + WHEN UPPER(drug) LIKE '%CAPTOPRIL%' THEN 1 + WHEN UPPER(drug) LIKE '%ENALAPRIL%' THEN 1 + WHEN UPPER(drug) LIKE '%FOSINOPRIL%' THEN 1 + WHEN UPPER(drug) LIKE '%LISINOPRIL%' THEN 1 + WHEN UPPER(drug) LIKE '%MOEXIPRIL%' THEN 1 + WHEN UPPER(drug) LIKE '%PERINDOPRIL%' THEN 1 + WHEN UPPER(drug) LIKE '%QUINAPRIL%' THEN 1 + WHEN UPPER(drug) LIKE '%RAMIPRIL%' THEN 1 + WHEN UPPER(drug) LIKE '%TRANDOLAPRIL%' THEN 1 + ELSE 0 + END AS acei + FROM `physionet-data.mimiciv_hosp.prescriptions` ) SELECT - pr.subject_id - , pr.hadm_id - , pr.drug AS acei - , pr.starttime - , pr.stoptime + pr.subject_id + , pr.hadm_id + , pr.drug AS acei + , pr.starttime + , pr.stoptime FROM - `physionet-data.mimiciv_hosp.prescriptions` pr - INNER JOIN acei_drug - ON - pr.drug = acei_drug.drug + `physionet-data.mimiciv_hosp.prescriptions` pr +INNER JOIN acei_drug + ON + pr.drug = acei_drug.drug WHERE - acei_drug.acei = 1 + acei_drug.acei = 1 ; diff --git a/mimic-iv/concepts/medication/nsaid.sql b/mimic-iv/concepts/medication/nsaid.sql index 5069c680e..14f4db2c9 100644 --- a/mimic-iv/concepts/medication/nsaid.sql +++ b/mimic-iv/concepts/medication/nsaid.sql @@ -1,43 +1,43 @@ -WITH nsaid_drug AS ( - SELECT DISTINCT - drug - , CASE - WHEN UPPER(drug) LIKE '%ASPIRIN%' THEN 1 - WHEN UPPER(drug) LIKE '%BROMFENAC%' THEN 1 - WHEN UPPER(drug) LIKE '%CELECOXIB%' THEN 1 - WHEN UPPER(drug) LIKE '%DICLOFENAC%' THEN 1 - WHEN UPPER(drug) LIKE '%DIFLUNISAL%' THEN 1 - WHEN UPPER(drug) LIKE '%ETODOLAC%' THEN 1 - WHEN UPPER(drug) LIKE '%FENOPROFEN%' THEN 1 - WHEN UPPER(drug) LIKE '%FLURBIPROFEN%' THEN 1 - WHEN UPPER(drug) LIKE '%IBUPROFEN%' THEN 1 - WHEN UPPER(drug) LIKE '%INDOMETHACIN%' THEN 1 - WHEN UPPER(drug) LIKE '%KETOPROFEN%' THEN 1 - WHEN UPPER(drug) LIKE '%MEFENAMIC ACID%' THEN 1 - WHEN UPPER(drug) LIKE '%MELOXICAM%' THEN 1 - WHEN UPPER(drug) LIKE '%NABUMETONE%' THEN 1 - WHEN UPPER(drug) LIKE '%NAPROXEN%' THEN 1 - WHEN UPPER(drug) LIKE '%NEPAFENAC%' THEN 1 - WHEN UPPER(drug) LIKE '%OXAPROZIN%' THEN 1 - WHEN UPPER(drug) LIKE '%PIROXICAM%' THEN 1 - WHEN UPPER(drug) LIKE '%SULINDAC%' THEN 1 - WHEN UPPER(drug) LIKE '%TOLMETIN%' THEN 1 - ELSE 0 - END AS nsaid - FROM `physionet-data.mimiciv_hosp.prescriptions` +WITH nsaid_drug AS ( + SELECT DISTINCT + drug + , CASE + WHEN UPPER(drug) LIKE '%ASPIRIN%' THEN 1 + WHEN UPPER(drug) LIKE '%BROMFENAC%' THEN 1 + WHEN UPPER(drug) LIKE '%CELECOXIB%' THEN 1 + WHEN UPPER(drug) LIKE '%DICLOFENAC%' THEN 1 + WHEN UPPER(drug) LIKE '%DIFLUNISAL%' THEN 1 + WHEN UPPER(drug) LIKE '%ETODOLAC%' THEN 1 + WHEN UPPER(drug) LIKE '%FENOPROFEN%' THEN 1 + WHEN UPPER(drug) LIKE '%FLURBIPROFEN%' THEN 1 + WHEN UPPER(drug) LIKE '%IBUPROFEN%' THEN 1 + WHEN UPPER(drug) LIKE '%INDOMETHACIN%' THEN 1 + WHEN UPPER(drug) LIKE '%KETOPROFEN%' THEN 1 + WHEN UPPER(drug) LIKE '%MEFENAMIC ACID%' THEN 1 + WHEN UPPER(drug) LIKE '%MELOXICAM%' THEN 1 + WHEN UPPER(drug) LIKE '%NABUMETONE%' THEN 1 + WHEN UPPER(drug) LIKE '%NAPROXEN%' THEN 1 + WHEN UPPER(drug) LIKE '%NEPAFENAC%' THEN 1 + WHEN UPPER(drug) LIKE '%OXAPROZIN%' THEN 1 + WHEN UPPER(drug) LIKE '%PIROXICAM%' THEN 1 + WHEN UPPER(drug) LIKE '%SULINDAC%' THEN 1 + WHEN UPPER(drug) LIKE '%TOLMETIN%' THEN 1 + ELSE 0 + END AS nsaid + FROM `physionet-data.mimiciv_hosp.prescriptions` ) SELECT - pr.subject_id - , pr.hadm_id - , pr.drug AS nsaid - , pr.starttime - , pr.stoptime + pr.subject_id + , pr.hadm_id + , pr.drug AS nsaid + , pr.starttime + , pr.stoptime FROM - `physionet-data.mimiciv_hosp.prescriptions` pr - INNER JOIN nsaid_drug - ON - pr.drug = nsaid_drug.drug + `physionet-data.mimiciv_hosp.prescriptions` pr +INNER JOIN nsaid_drug + ON + pr.drug = nsaid_drug.drug WHERE - nsaid_drug.nsaid = 1 + nsaid_drug.nsaid = 1 ; diff --git a/mimic-iv/concepts/organfailure/kdigo_uo.sql b/mimic-iv/concepts/organfailure/kdigo_uo.sql index 014e66244..32119dc9b 100644 --- a/mimic-iv/concepts/organfailure/kdigo_uo.sql +++ b/mimic-iv/concepts/organfailure/kdigo_uo.sql @@ -1,6 +1,8 @@ WITH uo_stg1 AS ( SELECT ie.stay_id, uo.charttime - , DATETIME_DIFF(charttime, intime, SECOND) AS seconds_since_admit + , CAST( + DATETIME_DIFF(charttime, intime, SECOND) AS INTEGER + ) AS seconds_since_admit , COALESCE( DATETIME_DIFF(charttime, LAG(charttime) OVER (PARTITION BY ie.stay_id ORDER BY charttime), SECOND) / 3600.0 -- noqa: L016 , 1 diff --git a/mimic-iv/concepts_duckdb/README.md b/mimic-iv/concepts_duckdb/README.md new file mode 100644 index 000000000..5de4cffa8 --- /dev/null +++ b/mimic-iv/concepts_duckdb/README.md @@ -0,0 +1,16 @@ +# duckdb concepts + +This folder has SQL compatible with [DuckDB](https://duckdb.org/). +These concepts were generated automatically from the BigQuery SQL dialect using the [sqlglot](https://sqlglot.com/) package. +If you would like to contribute a correction, do not make it here. Instead, make your correction in the [concepts folder](/mimic-iv/concepts/) using the BigQuery SQL syntax. + +See the [README](/mimic-iv/README.md) in the parent folder for more information. + +## Using these concepts + +The `duckdb.sql` file calls all the concepts in the correct order and outputs them to the `mimiciv_derived` schema. +You should connect to your DuckDB database file and run this file (make sure you are in this folder, as the paths are relative): + +```sh +.read duckdb.sql +``` \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/comorbidity/charlson.sql b/mimic-iv/concepts_duckdb/comorbidity/charlson.sql new file mode 100644 index 000000000..ec8eb90d5 --- /dev/null +++ b/mimic-iv/concepts_duckdb/comorbidity/charlson.sql @@ -0,0 +1,233 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.charlson; CREATE TABLE mimiciv_derived.charlson AS +WITH diag AS ( + SELECT + hadm_id, + CASE WHEN icd_version = 9 THEN icd_code ELSE NULL END AS icd9_code, + CASE WHEN icd_version = 10 THEN icd_code ELSE NULL END AS icd10_code + FROM mimiciv_hosp.diagnoses_icd +), com AS ( + SELECT + ad.hadm_id, + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) IN ('410', '412') + OR SUBSTR(icd10_code, 1, 3) IN ('I21', 'I22') + OR SUBSTR(icd10_code, 1, 4) = 'I252' + THEN 1 + ELSE 0 + END + ) AS myocardial_infarct, + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) = '428' + OR SUBSTR(icd9_code, 1, 5) IN ('39891', '40201', '40211', '40291', '40401', '40403', '40411', '40413', '40491', '40493') + OR SUBSTR(icd9_code, 1, 4) BETWEEN '4254' AND '4259' + OR SUBSTR(icd10_code, 1, 3) IN ('I43', 'I50') + OR SUBSTR(icd10_code, 1, 4) IN ('I099', 'I110', 'I130', 'I132', 'I255', 'I420', 'I425', 'I426', 'I427', 'I428', 'I429', 'P290') + THEN 1 + ELSE 0 + END + ) AS congestive_heart_failure, + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) IN ('440', '441') + OR SUBSTR(icd9_code, 1, 4) IN ('0930', '4373', '4471', '5571', '5579', 'V434') + OR SUBSTR(icd9_code, 1, 4) BETWEEN '4431' AND '4439' + OR SUBSTR(icd10_code, 1, 3) IN ('I70', 'I71') + OR SUBSTR(icd10_code, 1, 4) IN ('I731', 'I738', 'I739', 'I771', 'I790', 'I792', 'K551', 'K558', 'K559', 'Z958', 'Z959') + THEN 1 + ELSE 0 + END + ) AS peripheral_vascular_disease, + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) BETWEEN '430' AND '438' + OR SUBSTR(icd9_code, 1, 5) = '36234' + OR SUBSTR(icd10_code, 1, 3) IN ('G45', 'G46') + OR SUBSTR(icd10_code, 1, 3) BETWEEN 'I60' AND 'I69' + OR SUBSTR(icd10_code, 1, 4) = 'H340' + THEN 1 + ELSE 0 + END + ) AS cerebrovascular_disease, + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) = '290' + OR SUBSTR(icd9_code, 1, 4) IN ('2941', '3312') + OR SUBSTR(icd10_code, 1, 3) IN ('F00', 'F01', 'F02', 'F03', 'G30') + OR SUBSTR(icd10_code, 1, 4) IN ('F051', 'G311') + THEN 1 + ELSE 0 + END + ) AS dementia, + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) BETWEEN '490' AND '505' + OR SUBSTR(icd9_code, 1, 4) IN ('4168', '4169', '5064', '5081', '5088') + OR SUBSTR(icd10_code, 1, 3) BETWEEN 'J40' AND 'J47' + OR SUBSTR(icd10_code, 1, 3) BETWEEN 'J60' AND 'J67' + OR SUBSTR(icd10_code, 1, 4) IN ('I278', 'I279', 'J684', 'J701', 'J703') + THEN 1 + ELSE 0 + END + ) AS chronic_pulmonary_disease, + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) = '725' + OR SUBSTR(icd9_code, 1, 4) IN ('4465', '7100', '7101', '7102', '7103', '7104', '7140', '7141', '7142', '7148') + OR SUBSTR(icd10_code, 1, 3) IN ('M05', 'M06', 'M32', 'M33', 'M34') + OR SUBSTR(icd10_code, 1, 4) IN ('M315', 'M351', 'M353', 'M360') + THEN 1 + ELSE 0 + END + ) AS rheumatic_disease, + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) IN ('531', '532', '533', '534') + OR SUBSTR(icd10_code, 1, 3) IN ('K25', 'K26', 'K27', 'K28') + THEN 1 + ELSE 0 + END + ) AS peptic_ulcer_disease, + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) IN ('570', '571') + OR SUBSTR(icd9_code, 1, 4) IN ('0706', '0709', '5733', '5734', '5738', '5739', 'V427') + OR SUBSTR(icd9_code, 1, 5) IN ('07022', '07023', '07032', '07033', '07044', '07054') + OR SUBSTR(icd10_code, 1, 3) IN ('B18', 'K73', 'K74') + OR SUBSTR(icd10_code, 1, 4) IN ('K700', 'K701', 'K702', 'K703', 'K709', 'K713', 'K714', 'K715', 'K717', 'K760', 'K762', 'K763', 'K764', 'K768', 'K769', 'Z944') + THEN 1 + ELSE 0 + END + ) AS mild_liver_disease, + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 4) IN ('2500', '2501', '2502', '2503', '2508', '2509') + OR SUBSTR(icd10_code, 1, 4) IN ('E100', 'E101', 'E106', 'E108', 'E109', 'E110', 'E111', 'E116', 'E118', 'E119', 'E120', 'E121', 'E126', 'E128', 'E129', 'E130', 'E131', 'E136', 'E138', 'E139', 'E140', 'E141', 'E146', 'E148', 'E149') + THEN 1 + ELSE 0 + END + ) AS diabetes_without_cc, + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 4) IN ('2504', '2505', '2506', '2507') + OR SUBSTR(icd10_code, 1, 4) IN ('E102', 'E103', 'E104', 'E105', 'E107', 'E112', 'E113', 'E114', 'E115', 'E117', 'E122', 'E123', 'E124', 'E125', 'E127', 'E132', 'E133', 'E134', 'E135', 'E137', 'E142', 'E143', 'E144', 'E145', 'E147') + THEN 1 + ELSE 0 + END + ) AS diabetes_with_cc, + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) IN ('342', '343') + OR SUBSTR(icd9_code, 1, 4) IN ('3341', '3440', '3441', '3442', '3443', '3444', '3445', '3446', '3449') + OR SUBSTR(icd10_code, 1, 3) IN ('G81', 'G82') + OR SUBSTR(icd10_code, 1, 4) IN ('G041', 'G114', 'G801', 'G802', 'G830', 'G831', 'G832', 'G833', 'G834', 'G839') + THEN 1 + ELSE 0 + END + ) AS paraplegia, + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) IN ('582', '585', '586', 'V56') + OR SUBSTR(icd9_code, 1, 4) IN ('5880', 'V420', 'V451') + OR SUBSTR(icd9_code, 1, 4) BETWEEN '5830' AND '5837' + OR SUBSTR(icd9_code, 1, 5) IN ('40301', '40311', '40391', '40402', '40403', '40412', '40413', '40492', '40493') + OR SUBSTR(icd10_code, 1, 3) IN ('N18', 'N19') + OR SUBSTR(icd10_code, 1, 4) IN ('I120', 'I131', 'N032', 'N033', 'N034', 'N035', 'N036', 'N037', 'N052', 'N053', 'N054', 'N055', 'N056', 'N057', 'N250', 'Z490', 'Z491', 'Z492', 'Z940', 'Z992') + THEN 1 + ELSE 0 + END + ) AS renal_disease, + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) BETWEEN '140' AND '172' + OR SUBSTR(icd9_code, 1, 4) BETWEEN '1740' AND '1958' + OR SUBSTR(icd9_code, 1, 3) BETWEEN '200' AND '208' + OR SUBSTR(icd9_code, 1, 4) = '2386' + OR SUBSTR(icd10_code, 1, 3) IN ('C43', 'C88') + OR SUBSTR(icd10_code, 1, 3) BETWEEN 'C00' AND 'C26' + OR SUBSTR(icd10_code, 1, 3) BETWEEN 'C30' AND 'C34' + OR SUBSTR(icd10_code, 1, 3) BETWEEN 'C37' AND 'C41' + OR SUBSTR(icd10_code, 1, 3) BETWEEN 'C45' AND 'C58' + OR SUBSTR(icd10_code, 1, 3) BETWEEN 'C60' AND 'C76' + OR SUBSTR(icd10_code, 1, 3) BETWEEN 'C81' AND 'C85' + OR SUBSTR(icd10_code, 1, 3) BETWEEN 'C90' AND 'C97' + THEN 1 + ELSE 0 + END + ) AS malignant_cancer, + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 4) IN ('4560', '4561', '4562') + OR SUBSTR(icd9_code, 1, 4) BETWEEN '5722' AND '5728' + OR SUBSTR(icd10_code, 1, 4) IN ('I850', 'I859', 'I864', 'I982', 'K704', 'K711', 'K721', 'K729', 'K765', 'K766', 'K767') + THEN 1 + ELSE 0 + END + ) AS severe_liver_disease, + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) IN ('196', '197', '198', '199') + OR SUBSTR(icd10_code, 1, 3) IN ('C77', 'C78', 'C79', 'C80') + THEN 1 + ELSE 0 + END + ) AS metastatic_solid_tumor, + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) IN ('042', '043', '044') + OR SUBSTR(icd10_code, 1, 3) IN ('B20', 'B21', 'B22', 'B24') + THEN 1 + ELSE 0 + END + ) AS aids + FROM mimiciv_hosp.admissions AS ad + LEFT JOIN diag + ON ad.hadm_id = diag.hadm_id + GROUP BY + ad.hadm_id +), ag AS ( + SELECT + hadm_id, + age, + CASE + WHEN age <= 50 + THEN 0 + WHEN age <= 60 + THEN 1 + WHEN age <= 70 + THEN 2 + WHEN age <= 80 + THEN 3 + ELSE 4 + END AS age_score + FROM mimiciv_derived.age +) +SELECT + ad.subject_id, + ad.hadm_id, + ag.age_score, + myocardial_infarct, + congestive_heart_failure, + peripheral_vascular_disease, + cerebrovascular_disease, + dementia, + chronic_pulmonary_disease, + rheumatic_disease, + peptic_ulcer_disease, + mild_liver_disease, + diabetes_without_cc, + diabetes_with_cc, + paraplegia, + renal_disease, + malignant_cancer, + severe_liver_disease, + metastatic_solid_tumor, + aids, + age_score + myocardial_infarct + congestive_heart_failure + peripheral_vascular_disease + cerebrovascular_disease + dementia + chronic_pulmonary_disease + rheumatic_disease + peptic_ulcer_disease + GREATEST(mild_liver_disease, 3 * severe_liver_disease) + GREATEST(2 * diabetes_with_cc, diabetes_without_cc) + GREATEST(2 * malignant_cancer, 6 * metastatic_solid_tumor) + 2 * paraplegia + 2 * renal_disease + 6 * aids AS charlson_comorbidity_index +FROM mimiciv_hosp.admissions AS ad +LEFT JOIN com + ON ad.hadm_id = com.hadm_id +LEFT JOIN ag + ON com.hadm_id = ag.hadm_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/demographics/age.sql b/mimic-iv/concepts_duckdb/demographics/age.sql new file mode 100644 index 000000000..665c80bc9 --- /dev/null +++ b/mimic-iv/concepts_duckdb/demographics/age.sql @@ -0,0 +1,12 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.age; CREATE TABLE mimiciv_derived.age AS +SELECT + ad.subject_id, + ad.hadm_id, + ad.admittime, + pa.anchor_age, + pa.anchor_year, + pa.anchor_age + DATE_DIFF('microseconds', MAKE_TIMESTAMP(pa.anchor_year, 1, 1, 0, 0, 0), ad.admittime)/31556908800000.0 AS age +FROM mimiciv_hosp.admissions AS ad +INNER JOIN mimiciv_hosp.patients AS pa + ON ad.subject_id = pa.subject_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/demographics/icustay_detail.sql b/mimic-iv/concepts_duckdb/demographics/icustay_detail.sql new file mode 100644 index 000000000..95f5c8076 --- /dev/null +++ b/mimic-iv/concepts_duckdb/demographics/icustay_detail.sql @@ -0,0 +1,37 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.icustay_detail; CREATE TABLE mimiciv_derived.icustay_detail AS +SELECT + ie.subject_id, + ie.hadm_id, + ie.stay_id, + pat.gender, + pat.dod, + adm.admittime, + adm.dischtime, + DATE_DIFF('microseconds', adm.admittime, adm.dischtime)/86400000000.0 AS los_hospital, + pat.anchor_age + DATE_DIFF('microseconds', MAKE_TIMESTAMP(pat.anchor_year, 1, 1, 0, 0, 0), adm.admittime)/31556908800000.0 AS admission_age, + adm.race, + adm.hospital_expire_flag, + DENSE_RANK() OVER (PARTITION BY adm.subject_id ORDER BY adm.admittime NULLS FIRST) AS hospstay_seq, + CASE + WHEN DENSE_RANK() OVER (PARTITION BY adm.subject_id ORDER BY adm.admittime NULLS FIRST) = 1 + THEN TRUE + ELSE FALSE + END AS first_hosp_stay, + ie.intime AS icu_intime, + ie.outtime AS icu_outtime, + ROUND( + TRY_CAST(DATE_DIFF('microseconds', ie.intime, ie.outtime)/3600000000.0 / 24.0 AS DECIMAL), + 2 + ) AS los_icu, + DENSE_RANK() OVER (PARTITION BY ie.hadm_id ORDER BY ie.intime NULLS FIRST) AS icustay_seq, + CASE + WHEN DENSE_RANK() OVER (PARTITION BY ie.hadm_id ORDER BY ie.intime NULLS FIRST) = 1 + THEN TRUE + ELSE FALSE + END AS first_icu_stay +FROM mimiciv_icu.icustays AS ie +INNER JOIN mimiciv_hosp.admissions AS adm + ON ie.hadm_id = adm.hadm_id +INNER JOIN mimiciv_hosp.patients AS pat + ON ie.subject_id = pat.subject_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/demographics/icustay_hourly.sql b/mimic-iv/concepts_duckdb/demographics/icustay_hourly.sql new file mode 100644 index 000000000..94b7360d1 --- /dev/null +++ b/mimic-iv/concepts_duckdb/demographics/icustay_hourly.sql @@ -0,0 +1,22 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.icustay_hourly; CREATE TABLE mimiciv_derived.icustay_hourly AS +WITH all_hours AS ( + SELECT + it.stay_id, + CASE + WHEN DATE_TRUNC('HOUR', it.intime_hr) = it.intime_hr + THEN it.intime_hr + ELSE DATE_TRUNC('HOUR', it.intime_hr) + INTERVAL '1' HOUR + END AS endtime, + GENERATE_SERIES( + -24, + TRY_CAST(CEIL(DATE_DIFF('microseconds', it.intime_hr, it.outtime_hr)/3600000000.0) AS INT) + ) AS hrs + FROM mimiciv_derived.icustay_times AS it +) +SELECT + stay_id, + TRY_CAST(hr_unnested AS BIGINT) AS hr, + endtime + TRY_CAST(hr_unnested AS BIGINT) * INTERVAL '1' HOUR AS endtime +FROM all_hours +CROSS JOIN UNNEST(all_hours.hrs) AS _t(hr_unnested) \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/demographics/icustay_times.sql b/mimic-iv/concepts_duckdb/demographics/icustay_times.sql new file mode 100644 index 000000000..6f65d9650 --- /dev/null +++ b/mimic-iv/concepts_duckdb/demographics/icustay_times.sql @@ -0,0 +1,22 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.icustay_times; CREATE TABLE mimiciv_derived.icustay_times AS +WITH t1 AS ( + SELECT + ce.stay_id, + MIN(charttime) AS intime_hr, + MAX(charttime) AS outtime_hr + FROM mimiciv_icu.chartevents AS ce + WHERE + ce.itemid = 220045 + GROUP BY + ce.stay_id +) +SELECT + ie.subject_id, + ie.hadm_id, + ie.stay_id, + t1.intime_hr, + t1.outtime_hr +FROM mimiciv_icu.icustays AS ie +LEFT JOIN t1 + ON ie.stay_id = t1.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/demographics/weight_durations.sql b/mimic-iv/concepts_duckdb/demographics/weight_durations.sql new file mode 100644 index 000000000..b30ea0095 --- /dev/null +++ b/mimic-iv/concepts_duckdb/demographics/weight_durations.sql @@ -0,0 +1,95 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.weight_durations; CREATE TABLE mimiciv_derived.weight_durations AS +WITH wt_stg AS ( + SELECT + c.stay_id, + c.charttime, + CASE WHEN c.itemid = 226512 THEN 'admit' ELSE 'daily' END AS weight_type, + c.valuenum AS weight + FROM mimiciv_icu.chartevents AS c + WHERE + NOT c.valuenum IS NULL AND c.itemid IN (226512, 224639) AND c.valuenum > 0 +), wt_stg1 AS ( + SELECT + stay_id, + charttime, + weight_type, + weight, + ROW_NUMBER() OVER (PARTITION BY stay_id, weight_type ORDER BY charttime NULLS FIRST) AS rn + FROM wt_stg + WHERE + NOT weight IS NULL +), wt_stg2 AS ( + SELECT + wt_stg1.stay_id, + ie.intime, + ie.outtime, + wt_stg1.weight_type, + CASE + WHEN wt_stg1.weight_type = 'admit' AND wt_stg1.rn = 1 + THEN ie.intime - INTERVAL '2' HOUR + ELSE wt_stg1.charttime + END AS starttime, + wt_stg1.weight + FROM wt_stg1 + INNER JOIN mimiciv_icu.icustays AS ie + ON ie.stay_id = wt_stg1.stay_id +), wt_stg3 AS ( + SELECT + stay_id, + intime, + outtime, + starttime, + COALESCE( + LEAD(starttime) OVER (PARTITION BY stay_id ORDER BY starttime NULLS FIRST), + outtime + INTERVAL '2' HOUR + ) AS endtime, + weight, + weight_type + FROM wt_stg2 +), wt1 AS ( + SELECT + stay_id, + starttime, + COALESCE( + endtime, + LEAD(starttime) OVER (PARTITION BY stay_id ORDER BY starttime NULLS FIRST), + outtime + INTERVAL '2' HOUR + ) AS endtime, + weight, + weight_type + FROM wt_stg3 +), wt_fix AS ( + SELECT + ie.stay_id, + ie.intime - INTERVAL '2' HOUR AS starttime, + wt.starttime AS endtime, + wt.weight, + wt.weight_type + FROM mimiciv_icu.icustays AS ie + INNER JOIN ( + SELECT + wt1.stay_id, + wt1.starttime, + wt1.weight, + weight_type, + ROW_NUMBER() OVER (PARTITION BY wt1.stay_id ORDER BY wt1.starttime NULLS FIRST) AS rn + FROM wt1 + ) AS wt + ON ie.stay_id = wt.stay_id AND wt.rn = 1 AND ie.intime < wt.starttime +) +SELECT + wt1.stay_id, + wt1.starttime, + wt1.endtime, + wt1.weight, + wt1.weight_type +FROM wt1 +UNION ALL +SELECT + wt_fix.stay_id, + wt_fix.starttime, + wt_fix.endtime, + wt_fix.weight, + wt_fix.weight_type +FROM wt_fix \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/duckdb.sql b/mimic-iv/concepts_duckdb/duckdb.sql new file mode 100644 index 000000000..621cde34f --- /dev/null +++ b/mimic-iv/concepts_duckdb/duckdb.sql @@ -0,0 +1,148 @@ + +-- dependencies +.print 'demographics/icustay_times.sql' +.read demographics/icustay_times.sql +.print 'demographics/icustay_hourly.sql' +.read demographics/icustay_hourly.sql +.print 'demographics/weight_durations.sql' +.read demographics/weight_durations.sql +.print 'measurement/urine_output.sql' +.read measurement/urine_output.sql +.print 'organfailure/kdigo_uo.sql' +.read organfailure/kdigo_uo.sql + +-- demographics +.print 'demographics/age.sql' +.read demographics/age.sql +.print 'demographics/icustay_detail.sql' +.read demographics/icustay_detail.sql + +-- measurement +.print 'measurement/bg.sql' +.read measurement/bg.sql +.print 'measurement/blood_differential.sql' +.read measurement/blood_differential.sql +.print 'measurement/cardiac_marker.sql' +.read measurement/cardiac_marker.sql +.print 'measurement/chemistry.sql' +.read measurement/chemistry.sql +.print 'measurement/coagulation.sql' +.read measurement/coagulation.sql +.print 'measurement/complete_blood_count.sql' +.read measurement/complete_blood_count.sql +.print 'measurement/creatinine_baseline.sql' +.read measurement/creatinine_baseline.sql +.print 'measurement/enzyme.sql' +.read measurement/enzyme.sql +.print 'measurement/gcs.sql' +.read measurement/gcs.sql +.print 'measurement/height.sql' +.read measurement/height.sql +.print 'measurement/icp.sql' +.read measurement/icp.sql +.print 'measurement/inflammation.sql' +.read measurement/inflammation.sql +.print 'measurement/oxygen_delivery.sql' +.read measurement/oxygen_delivery.sql +.print 'measurement/rhythm.sql' +.read measurement/rhythm.sql +.print 'measurement/urine_output_rate.sql' +.read measurement/urine_output_rate.sql +.print 'measurement/ventilator_setting.sql' +.read measurement/ventilator_setting.sql +.print 'measurement/vitalsign.sql' +.read measurement/vitalsign.sql + +-- comorbidity +.print 'comorbidity/charlson.sql' +.read comorbidity/charlson.sql + +-- medication +.print 'medication/acei.sql' +.read medication/acei.sql +.print 'medication/antibiotic.sql' +.read medication/antibiotic.sql +.print 'medication/dobutamine.sql' +.read medication/dobutamine.sql +.print 'medication/dopamine.sql' +.read medication/dopamine.sql +.print 'medication/epinephrine.sql' +.read medication/epinephrine.sql +.print 'medication/milrinone.sql' +.read medication/milrinone.sql +.print 'medication/neuroblock.sql' +.read medication/neuroblock.sql +.print 'medication/norepinephrine.sql' +.read medication/norepinephrine.sql +.print 'medication/nsaid.sql' +.read medication/nsaid.sql +.print 'medication/phenylephrine.sql' +.read medication/phenylephrine.sql +.print 'medication/vasopressin.sql' +.read medication/vasopressin.sql + +-- treatment +.print 'treatment/crrt.sql' +.read treatment/crrt.sql +.print 'treatment/invasive_line.sql' +.read treatment/invasive_line.sql +.print 'treatment/rrt.sql' +.read treatment/rrt.sql +.print 'treatment/ventilation.sql' +.read treatment/ventilation.sql + +-- firstday +.print 'firstday/first_day_bg.sql' +.read firstday/first_day_bg.sql +.print 'firstday/first_day_bg_art.sql' +.read firstday/first_day_bg_art.sql +.print 'firstday/first_day_gcs.sql' +.read firstday/first_day_gcs.sql +.print 'firstday/first_day_height.sql' +.read firstday/first_day_height.sql +.print 'firstday/first_day_lab.sql' +.read firstday/first_day_lab.sql +.print 'firstday/first_day_rrt.sql' +.read firstday/first_day_rrt.sql +.print 'firstday/first_day_urine_output.sql' +.read firstday/first_day_urine_output.sql +.print 'firstday/first_day_vitalsign.sql' +.read firstday/first_day_vitalsign.sql +.print 'firstday/first_day_weight.sql' +.read firstday/first_day_weight.sql + +-- organfailure +.print 'organfailure/kdigo_creatinine.sql' +.read organfailure/kdigo_creatinine.sql +.print 'organfailure/meld.sql' +.read organfailure/meld.sql + +-- score +.print 'score/apsiii.sql' +.read score/apsiii.sql +.print 'score/lods.sql' +.read score/lods.sql +.print 'score/oasis.sql' +.read score/oasis.sql +.print 'score/sapsii.sql' +.read score/sapsii.sql +.print 'score/sirs.sql' +.read score/sirs.sql +.print 'score/sofa.sql' +.read score/sofa.sql + +-- sepsis +.print 'sepsis/suspicion_of_infection.sql' +.read sepsis/suspicion_of_infection.sql + +-- final tables which were dependent on one or more prior tables +.print 'organfailure/kdigo_stages.sql' +.read organfailure/kdigo_stages.sql +.print 'firstday/first_day_sofa.sql' +.read firstday/first_day_sofa.sql +.print 'sepsis/sepsis3.sql' +.read sepsis/sepsis3.sql +.print 'medication/vasoactive_agent.sql' +.read medication/vasoactive_agent.sql +.print 'medication/norepinephrine_equivalent_dose.sql' +.read medication/norepinephrine_equivalent_dose.sql diff --git a/mimic-iv/concepts_duckdb/firstday/first_day_bg.sql b/mimic-iv/concepts_duckdb/firstday/first_day_bg.sql new file mode 100644 index 000000000..c1b289ad9 --- /dev/null +++ b/mimic-iv/concepts_duckdb/firstday/first_day_bg.sql @@ -0,0 +1,55 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.first_day_bg; CREATE TABLE mimiciv_derived.first_day_bg AS +SELECT + ie.subject_id, + ie.stay_id, + MIN(lactate) AS lactate_min, + MAX(lactate) AS lactate_max, + MIN(ph) AS ph_min, + MAX(ph) AS ph_max, + MIN(so2) AS so2_min, + MAX(so2) AS so2_max, + MIN(po2) AS po2_min, + MAX(po2) AS po2_max, + MIN(pco2) AS pco2_min, + MAX(pco2) AS pco2_max, + MIN(aado2) AS aado2_min, + MAX(aado2) AS aado2_max, + MIN(aado2_calc) AS aado2_calc_min, + MAX(aado2_calc) AS aado2_calc_max, + MIN(pao2fio2ratio) AS pao2fio2ratio_min, + MAX(pao2fio2ratio) AS pao2fio2ratio_max, + MIN(baseexcess) AS baseexcess_min, + MAX(baseexcess) AS baseexcess_max, + MIN(bicarbonate) AS bicarbonate_min, + MAX(bicarbonate) AS bicarbonate_max, + MIN(totalco2) AS totalco2_min, + MAX(totalco2) AS totalco2_max, + MIN(hematocrit) AS hematocrit_min, + MAX(hematocrit) AS hematocrit_max, + MIN(hemoglobin) AS hemoglobin_min, + MAX(hemoglobin) AS hemoglobin_max, + MIN(carboxyhemoglobin) AS carboxyhemoglobin_min, + MAX(carboxyhemoglobin) AS carboxyhemoglobin_max, + MIN(methemoglobin) AS methemoglobin_min, + MAX(methemoglobin) AS methemoglobin_max, + MIN(temperature) AS temperature_min, + MAX(temperature) AS temperature_max, + MIN(chloride) AS chloride_min, + MAX(chloride) AS chloride_max, + MIN(calcium) AS calcium_min, + MAX(calcium) AS calcium_max, + MIN(glucose) AS glucose_min, + MAX(glucose) AS glucose_max, + MIN(potassium) AS potassium_min, + MAX(potassium) AS potassium_max, + MIN(sodium) AS sodium_min, + MAX(sodium) AS sodium_max +FROM mimiciv_icu.icustays AS ie +LEFT JOIN mimiciv_derived.bg AS bg + ON ie.subject_id = bg.subject_id + AND bg.charttime >= ie.intime - INTERVAL '6' HOUR + AND bg.charttime <= ie.intime + INTERVAL '1' DAY +GROUP BY + ie.subject_id, + ie.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/firstday/first_day_bg_art.sql b/mimic-iv/concepts_duckdb/firstday/first_day_bg_art.sql new file mode 100644 index 000000000..9e9195d8c --- /dev/null +++ b/mimic-iv/concepts_duckdb/firstday/first_day_bg_art.sql @@ -0,0 +1,56 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.first_day_bg_art; CREATE TABLE mimiciv_derived.first_day_bg_art AS +SELECT + ie.subject_id, + ie.stay_id, + MIN(lactate) AS lactate_min, + MAX(lactate) AS lactate_max, + MIN(ph) AS ph_min, + MAX(ph) AS ph_max, + MIN(so2) AS so2_min, + MAX(so2) AS so2_max, + MIN(po2) AS po2_min, + MAX(po2) AS po2_max, + MIN(pco2) AS pco2_min, + MAX(pco2) AS pco2_max, + MIN(aado2) AS aado2_min, + MAX(aado2) AS aado2_max, + MIN(aado2_calc) AS aado2_calc_min, + MAX(aado2_calc) AS aado2_calc_max, + MIN(pao2fio2ratio) AS pao2fio2ratio_min, + MAX(pao2fio2ratio) AS pao2fio2ratio_max, + MIN(baseexcess) AS baseexcess_min, + MAX(baseexcess) AS baseexcess_max, + MIN(bicarbonate) AS bicarbonate_min, + MAX(bicarbonate) AS bicarbonate_max, + MIN(totalco2) AS totalco2_min, + MAX(totalco2) AS totalco2_max, + MIN(hematocrit) AS hematocrit_min, + MAX(hematocrit) AS hematocrit_max, + MIN(hemoglobin) AS hemoglobin_min, + MAX(hemoglobin) AS hemoglobin_max, + MIN(carboxyhemoglobin) AS carboxyhemoglobin_min, + MAX(carboxyhemoglobin) AS carboxyhemoglobin_max, + MIN(methemoglobin) AS methemoglobin_min, + MAX(methemoglobin) AS methemoglobin_max, + MIN(temperature) AS temperature_min, + MAX(temperature) AS temperature_max, + MIN(chloride) AS chloride_min, + MAX(chloride) AS chloride_max, + MIN(calcium) AS calcium_min, + MAX(calcium) AS calcium_max, + MIN(glucose) AS glucose_min, + MAX(glucose) AS glucose_max, + MIN(potassium) AS potassium_min, + MAX(potassium) AS potassium_max, + MIN(sodium) AS sodium_min, + MAX(sodium) AS sodium_max +FROM mimiciv_icu.icustays AS ie +LEFT JOIN mimiciv_derived.bg AS bg + ON ie.subject_id = bg.subject_id + AND bg.specimen = 'ART.' + AND bg.charttime >= ie.intime - INTERVAL '6' HOUR + AND bg.charttime <= ie.intime + INTERVAL '1' DAY +GROUP BY + ie.subject_id, + ie.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/firstday/first_day_gcs.sql b/mimic-iv/concepts_duckdb/firstday/first_day_gcs.sql new file mode 100644 index 000000000..d11e2f9a8 --- /dev/null +++ b/mimic-iv/concepts_duckdb/firstday/first_day_gcs.sql @@ -0,0 +1,29 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.first_day_gcs; CREATE TABLE mimiciv_derived.first_day_gcs AS +WITH gcs_final AS ( + SELECT + ie.subject_id, + ie.stay_id, + g.gcs, + g.gcs_motor, + g.gcs_verbal, + g.gcs_eyes, + g.gcs_unable, + ROW_NUMBER() OVER (PARTITION BY g.stay_id ORDER BY g.gcs NULLS FIRST) AS gcs_seq + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.gcs AS g + ON ie.stay_id = g.stay_id + AND g.charttime >= ie.intime - INTERVAL '6' HOUR + AND g.charttime <= ie.intime + INTERVAL '1' DAY +) +SELECT + ie.subject_id, + ie.stay_id, + gcs AS gcs_min, + gcs_motor, + gcs_verbal, + gcs_eyes, + gcs_unable +FROM mimiciv_icu.icustays AS ie +LEFT JOIN gcs_final AS gs + ON ie.stay_id = gs.stay_id AND gs.gcs_seq = 1 \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/firstday/first_day_height.sql b/mimic-iv/concepts_duckdb/firstday/first_day_height.sql new file mode 100644 index 000000000..3aa1f9abe --- /dev/null +++ b/mimic-iv/concepts_duckdb/firstday/first_day_height.sql @@ -0,0 +1,14 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.first_day_height; CREATE TABLE mimiciv_derived.first_day_height AS +SELECT + ie.subject_id, + ie.stay_id, + ROUND(TRY_CAST(AVG(height) AS DECIMAL), 2) AS height +FROM mimiciv_icu.icustays AS ie +LEFT JOIN mimiciv_derived.height AS ht + ON ie.stay_id = ht.stay_id + AND ht.charttime >= ie.intime - INTERVAL '6' HOUR + AND ht.charttime <= ie.intime + INTERVAL '1' DAY +GROUP BY + ie.subject_id, + ie.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/firstday/first_day_lab.sql b/mimic-iv/concepts_duckdb/firstday/first_day_lab.sql new file mode 100644 index 000000000..9ab088fd1 --- /dev/null +++ b/mimic-iv/concepts_duckdb/firstday/first_day_lab.sql @@ -0,0 +1,239 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.first_day_lab; CREATE TABLE mimiciv_derived.first_day_lab AS +WITH cbc AS ( + SELECT + ie.stay_id, + MIN(hematocrit) AS hematocrit_min, + MAX(hematocrit) AS hematocrit_max, + MIN(hemoglobin) AS hemoglobin_min, + MAX(hemoglobin) AS hemoglobin_max, + MIN(platelet) AS platelets_min, + MAX(platelet) AS platelets_max, + MIN(wbc) AS wbc_min, + MAX(wbc) AS wbc_max + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.complete_blood_count AS le + ON le.subject_id = ie.subject_id + AND le.charttime >= ie.intime - INTERVAL '6' HOUR + AND le.charttime <= ie.intime + INTERVAL '1' DAY + GROUP BY + ie.stay_id +), chem AS ( + SELECT + ie.stay_id, + MIN(albumin) AS albumin_min, + MAX(albumin) AS albumin_max, + MIN(globulin) AS globulin_min, + MAX(globulin) AS globulin_max, + MIN(total_protein) AS total_protein_min, + MAX(total_protein) AS total_protein_max, + MIN(aniongap) AS aniongap_min, + MAX(aniongap) AS aniongap_max, + MIN(bicarbonate) AS bicarbonate_min, + MAX(bicarbonate) AS bicarbonate_max, + MIN(bun) AS bun_min, + MAX(bun) AS bun_max, + MIN(calcium) AS calcium_min, + MAX(calcium) AS calcium_max, + MIN(chloride) AS chloride_min, + MAX(chloride) AS chloride_max, + MIN(creatinine) AS creatinine_min, + MAX(creatinine) AS creatinine_max, + MIN(glucose) AS glucose_min, + MAX(glucose) AS glucose_max, + MIN(sodium) AS sodium_min, + MAX(sodium) AS sodium_max, + MIN(potassium) AS potassium_min, + MAX(potassium) AS potassium_max + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.chemistry AS le + ON le.subject_id = ie.subject_id + AND le.charttime >= ie.intime - INTERVAL '6' HOUR + AND le.charttime <= ie.intime + INTERVAL '1' DAY + GROUP BY + ie.stay_id +), diff AS ( + SELECT + ie.stay_id, + MIN(basophils_abs) AS abs_basophils_min, + MAX(basophils_abs) AS abs_basophils_max, + MIN(eosinophils_abs) AS abs_eosinophils_min, + MAX(eosinophils_abs) AS abs_eosinophils_max, + MIN(lymphocytes_abs) AS abs_lymphocytes_min, + MAX(lymphocytes_abs) AS abs_lymphocytes_max, + MIN(monocytes_abs) AS abs_monocytes_min, + MAX(monocytes_abs) AS abs_monocytes_max, + MIN(neutrophils_abs) AS abs_neutrophils_min, + MAX(neutrophils_abs) AS abs_neutrophils_max, + MIN(atypical_lymphocytes) AS atyps_min, + MAX(atypical_lymphocytes) AS atyps_max, + MIN(bands) AS bands_min, + MAX(bands) AS bands_max, + MIN(immature_granulocytes) AS imm_granulocytes_min, + MAX(immature_granulocytes) AS imm_granulocytes_max, + MIN(metamyelocytes) AS metas_min, + MAX(metamyelocytes) AS metas_max, + MIN(nrbc) AS nrbc_min, + MAX(nrbc) AS nrbc_max + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.blood_differential AS le + ON le.subject_id = ie.subject_id + AND le.charttime >= ie.intime - INTERVAL '6' HOUR + AND le.charttime <= ie.intime + INTERVAL '1' DAY + GROUP BY + ie.stay_id +), coag AS ( + SELECT + ie.stay_id, + MIN(d_dimer) AS d_dimer_min, + MAX(d_dimer) AS d_dimer_max, + MIN(fibrinogen) AS fibrinogen_min, + MAX(fibrinogen) AS fibrinogen_max, + MIN(thrombin) AS thrombin_min, + MAX(thrombin) AS thrombin_max, + MIN(inr) AS inr_min, + MAX(inr) AS inr_max, + MIN(pt) AS pt_min, + MAX(pt) AS pt_max, + MIN(ptt) AS ptt_min, + MAX(ptt) AS ptt_max + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.coagulation AS le + ON le.subject_id = ie.subject_id + AND le.charttime >= ie.intime - INTERVAL '6' HOUR + AND le.charttime <= ie.intime + INTERVAL '1' DAY + GROUP BY + ie.stay_id +), enz AS ( + SELECT + ie.stay_id, + MIN(alt) AS alt_min, + MAX(alt) AS alt_max, + MIN(alp) AS alp_min, + MAX(alp) AS alp_max, + MIN(ast) AS ast_min, + MAX(ast) AS ast_max, + MIN(amylase) AS amylase_min, + MAX(amylase) AS amylase_max, + MIN(bilirubin_total) AS bilirubin_total_min, + MAX(bilirubin_total) AS bilirubin_total_max, + MIN(bilirubin_direct) AS bilirubin_direct_min, + MAX(bilirubin_direct) AS bilirubin_direct_max, + MIN(bilirubin_indirect) AS bilirubin_indirect_min, + MAX(bilirubin_indirect) AS bilirubin_indirect_max, + MIN(ck_cpk) AS ck_cpk_min, + MAX(ck_cpk) AS ck_cpk_max, + MIN(ck_mb) AS ck_mb_min, + MAX(ck_mb) AS ck_mb_max, + MIN(ggt) AS ggt_min, + MAX(ggt) AS ggt_max, + MIN(ld_ldh) AS ld_ldh_min, + MAX(ld_ldh) AS ld_ldh_max + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.enzyme AS le + ON le.subject_id = ie.subject_id + AND le.charttime >= ie.intime - INTERVAL '6' HOUR + AND le.charttime <= ie.intime + INTERVAL '1' DAY + GROUP BY + ie.stay_id +) +SELECT + ie.subject_id, + ie.stay_id, + hematocrit_min, + hematocrit_max, + hemoglobin_min, + hemoglobin_max, + platelets_min, + platelets_max, + wbc_min, + wbc_max, + albumin_min, + albumin_max, + globulin_min, + globulin_max, + total_protein_min, + total_protein_max, + aniongap_min, + aniongap_max, + bicarbonate_min, + bicarbonate_max, + bun_min, + bun_max, + calcium_min, + calcium_max, + chloride_min, + chloride_max, + creatinine_min, + creatinine_max, + glucose_min, + glucose_max, + sodium_min, + sodium_max, + potassium_min, + potassium_max, + abs_basophils_min, + abs_basophils_max, + abs_eosinophils_min, + abs_eosinophils_max, + abs_lymphocytes_min, + abs_lymphocytes_max, + abs_monocytes_min, + abs_monocytes_max, + abs_neutrophils_min, + abs_neutrophils_max, + atyps_min, + atyps_max, + bands_min, + bands_max, + imm_granulocytes_min, + imm_granulocytes_max, + metas_min, + metas_max, + nrbc_min, + nrbc_max, + d_dimer_min, + d_dimer_max, + fibrinogen_min, + fibrinogen_max, + thrombin_min, + thrombin_max, + inr_min, + inr_max, + pt_min, + pt_max, + ptt_min, + ptt_max, + alt_min, + alt_max, + alp_min, + alp_max, + ast_min, + ast_max, + amylase_min, + amylase_max, + bilirubin_total_min, + bilirubin_total_max, + bilirubin_direct_min, + bilirubin_direct_max, + bilirubin_indirect_min, + bilirubin_indirect_max, + ck_cpk_min, + ck_cpk_max, + ck_mb_min, + ck_mb_max, + ggt_min, + ggt_max, + ld_ldh_min, + ld_ldh_max +FROM mimiciv_icu.icustays AS ie +LEFT JOIN cbc + ON ie.stay_id = cbc.stay_id +LEFT JOIN chem + ON ie.stay_id = chem.stay_id +LEFT JOIN diff + ON ie.stay_id = diff.stay_id +LEFT JOIN coag + ON ie.stay_id = coag.stay_id +LEFT JOIN enz + ON ie.stay_id = enz.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/firstday/first_day_rrt.sql b/mimic-iv/concepts_duckdb/firstday/first_day_rrt.sql new file mode 100644 index 000000000..acdda7503 --- /dev/null +++ b/mimic-iv/concepts_duckdb/firstday/first_day_rrt.sql @@ -0,0 +1,16 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.first_day_rrt; CREATE TABLE mimiciv_derived.first_day_rrt AS +SELECT + ie.subject_id, + ie.stay_id, + MAX(dialysis_present) AS dialysis_present, + MAX(dialysis_active) AS dialysis_active, + GROUP_CONCAT(DISTINCT dialysis_type, ', ') AS dialysis_type +FROM mimiciv_icu.icustays AS ie +LEFT JOIN mimiciv_derived.rrt AS rrt + ON ie.stay_id = rrt.stay_id + AND rrt.charttime >= ie.intime - INTERVAL '6' HOUR + AND rrt.charttime <= ie.intime + INTERVAL '1' DAY +GROUP BY + ie.subject_id, + ie.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/firstday/first_day_sofa.sql b/mimic-iv/concepts_duckdb/firstday/first_day_sofa.sql new file mode 100644 index 000000000..cd03364fd --- /dev/null +++ b/mimic-iv/concepts_duckdb/firstday/first_day_sofa.sql @@ -0,0 +1,221 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.first_day_sofa; CREATE TABLE mimiciv_derived.first_day_sofa AS +WITH vaso_stg AS ( + SELECT + ie.stay_id, + 'norepinephrine' AS treatment, + vaso_rate AS rate + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_derived.norepinephrine AS mv + ON ie.stay_id = mv.stay_id + AND mv.starttime >= ie.intime - INTERVAL '6' HOUR + AND mv.starttime <= ie.intime + INTERVAL '1' DAY + UNION ALL + SELECT + ie.stay_id, + 'epinephrine' AS treatment, + vaso_rate AS rate + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_derived.epinephrine AS mv + ON ie.stay_id = mv.stay_id + AND mv.starttime >= ie.intime - INTERVAL '6' HOUR + AND mv.starttime <= ie.intime + INTERVAL '1' DAY + UNION ALL + SELECT + ie.stay_id, + 'dobutamine' AS treatment, + vaso_rate AS rate + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_derived.dobutamine AS mv + ON ie.stay_id = mv.stay_id + AND mv.starttime >= ie.intime - INTERVAL '6' HOUR + AND mv.starttime <= ie.intime + INTERVAL '1' DAY + UNION ALL + SELECT + ie.stay_id, + 'dopamine' AS treatment, + vaso_rate AS rate + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_derived.dopamine AS mv + ON ie.stay_id = mv.stay_id + AND mv.starttime >= ie.intime - INTERVAL '6' HOUR + AND mv.starttime <= ie.intime + INTERVAL '1' DAY +), vaso_mv AS ( + SELECT + ie.stay_id, + MAX(CASE WHEN treatment = 'norepinephrine' THEN rate ELSE NULL END) AS rate_norepinephrine, + MAX(CASE WHEN treatment = 'epinephrine' THEN rate ELSE NULL END) AS rate_epinephrine, + MAX(CASE WHEN treatment = 'dopamine' THEN rate ELSE NULL END) AS rate_dopamine, + MAX(CASE WHEN treatment = 'dobutamine' THEN rate ELSE NULL END) AS rate_dobutamine + FROM mimiciv_icu.icustays AS ie + LEFT JOIN vaso_stg AS v + ON ie.stay_id = v.stay_id + GROUP BY + ie.stay_id +), pafi1 AS ( + SELECT + ie.stay_id, + bg.charttime, + bg.pao2fio2ratio, + CASE WHEN NOT vd.stay_id IS NULL THEN 1 ELSE 0 END AS isvent + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.bg AS bg + ON ie.subject_id = bg.subject_id + AND bg.charttime >= ie.intime - INTERVAL '6' HOUR + AND bg.charttime <= ie.intime + INTERVAL '1' DAY + LEFT JOIN mimiciv_derived.ventilation AS vd + ON ie.stay_id = vd.stay_id + AND bg.charttime >= vd.starttime + AND bg.charttime <= vd.endtime + AND vd.ventilation_status = 'InvasiveVent' +), pafi2 AS ( + SELECT + stay_id, + MIN(CASE WHEN isvent = 0 THEN pao2fio2ratio ELSE NULL END) AS pao2fio2_novent_min, + MIN(CASE WHEN isvent = 1 THEN pao2fio2ratio ELSE NULL END) AS pao2fio2_vent_min + FROM pafi1 + GROUP BY + stay_id +), scorecomp AS ( + SELECT + ie.stay_id, + v.mbp_min, + mv.rate_norepinephrine, + mv.rate_epinephrine, + mv.rate_dopamine, + mv.rate_dobutamine, + l.creatinine_max, + l.bilirubin_total_max AS bilirubin_max, + l.platelets_min AS platelet_min, + pf.pao2fio2_novent_min, + pf.pao2fio2_vent_min, + uo.urineoutput, + gcs.gcs_min + FROM mimiciv_icu.icustays AS ie + LEFT JOIN vaso_mv AS mv + ON ie.stay_id = mv.stay_id + LEFT JOIN pafi2 AS pf + ON ie.stay_id = pf.stay_id + LEFT JOIN mimiciv_derived.first_day_vitalsign AS v + ON ie.stay_id = v.stay_id + LEFT JOIN mimiciv_derived.first_day_lab AS l + ON ie.stay_id = l.stay_id + LEFT JOIN mimiciv_derived.first_day_urine_output AS uo + ON ie.stay_id = uo.stay_id + LEFT JOIN mimiciv_derived.first_day_gcs AS gcs + ON ie.stay_id = gcs.stay_id +), scorecalc AS ( + SELECT + stay_id, + CASE + WHEN pao2fio2_vent_min < 100 + THEN 4 + WHEN pao2fio2_vent_min < 200 + THEN 3 + WHEN pao2fio2_novent_min < 300 + THEN 2 + WHEN pao2fio2_novent_min < 400 + THEN 1 + WHEN COALESCE(pao2fio2_vent_min, pao2fio2_novent_min) IS NULL + THEN NULL + ELSE 0 + END AS respiration, + CASE + WHEN platelet_min < 20 + THEN 4 + WHEN platelet_min < 50 + THEN 3 + WHEN platelet_min < 100 + THEN 2 + WHEN platelet_min < 150 + THEN 1 + WHEN platelet_min IS NULL + THEN NULL + ELSE 0 + END AS coagulation, + CASE + WHEN bilirubin_max >= 12.0 + THEN 4 + WHEN bilirubin_max >= 6.0 + THEN 3 + WHEN bilirubin_max >= 2.0 + THEN 2 + WHEN bilirubin_max >= 1.2 + THEN 1 + WHEN bilirubin_max IS NULL + THEN NULL + ELSE 0 + END AS liver, + CASE + WHEN rate_dopamine > 15 OR rate_epinephrine > 0.1 OR rate_norepinephrine > 0.1 + THEN 4 + WHEN rate_dopamine > 5 OR rate_epinephrine <= 0.1 OR rate_norepinephrine <= 0.1 + THEN 3 + WHEN rate_dopamine > 0 OR rate_dobutamine > 0 + THEN 2 + WHEN mbp_min < 70 + THEN 1 + WHEN COALESCE(mbp_min, rate_dopamine, rate_dobutamine, rate_epinephrine, rate_norepinephrine) IS NULL + THEN NULL + ELSE 0 + END AS cardiovascular, + CASE + WHEN ( + gcs_min >= 13 AND gcs_min <= 14 + ) + THEN 1 + WHEN ( + gcs_min >= 10 AND gcs_min <= 12 + ) + THEN 2 + WHEN ( + gcs_min >= 6 AND gcs_min <= 9 + ) + THEN 3 + WHEN gcs_min < 6 + THEN 4 + WHEN gcs_min IS NULL + THEN NULL + ELSE 0 + END AS cns, + CASE + WHEN ( + creatinine_max >= 5.0 + ) + THEN 4 + WHEN urineoutput < 200 + THEN 4 + WHEN ( + creatinine_max >= 3.5 AND creatinine_max < 5.0 + ) + THEN 3 + WHEN urineoutput < 500 + THEN 3 + WHEN ( + creatinine_max >= 2.0 AND creatinine_max < 3.5 + ) + THEN 2 + WHEN ( + creatinine_max >= 1.2 AND creatinine_max < 2.0 + ) + THEN 1 + WHEN COALESCE(urineoutput, creatinine_max) IS NULL + THEN NULL + ELSE 0 + END AS renal + FROM scorecomp +) +SELECT + ie.subject_id, + ie.hadm_id, + ie.stay_id, + COALESCE(respiration, 0) + COALESCE(coagulation, 0) + COALESCE(liver, 0) + COALESCE(cardiovascular, 0) + COALESCE(cns, 0) + COALESCE(renal, 0) AS sofa, + respiration, + coagulation, + liver, + cardiovascular, + cns, + renal +FROM mimiciv_icu.icustays AS ie +LEFT JOIN scorecalc AS s + ON ie.stay_id = s.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/firstday/first_day_urine_output.sql b/mimic-iv/concepts_duckdb/firstday/first_day_urine_output.sql new file mode 100644 index 000000000..e53efb78d --- /dev/null +++ b/mimic-iv/concepts_duckdb/firstday/first_day_urine_output.sql @@ -0,0 +1,14 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.first_day_urine_output; CREATE TABLE mimiciv_derived.first_day_urine_output AS +SELECT + ie.subject_id, + ie.stay_id, + SUM(urineoutput) AS urineoutput +FROM mimiciv_icu.icustays AS ie +LEFT JOIN mimiciv_derived.urine_output AS uo + ON ie.stay_id = uo.stay_id + AND uo.charttime >= ie.intime + AND uo.charttime <= ie.intime + INTERVAL '1' DAY +GROUP BY + ie.subject_id, + ie.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/firstday/first_day_vitalsign.sql b/mimic-iv/concepts_duckdb/firstday/first_day_vitalsign.sql new file mode 100644 index 000000000..2ea9c9fe9 --- /dev/null +++ b/mimic-iv/concepts_duckdb/firstday/first_day_vitalsign.sql @@ -0,0 +1,37 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.first_day_vitalsign; CREATE TABLE mimiciv_derived.first_day_vitalsign AS +SELECT + ie.subject_id, + ie.stay_id, + MIN(heart_rate) AS heart_rate_min, + MAX(heart_rate) AS heart_rate_max, + AVG(heart_rate) AS heart_rate_mean, + MIN(sbp) AS sbp_min, + MAX(sbp) AS sbp_max, + AVG(sbp) AS sbp_mean, + MIN(dbp) AS dbp_min, + MAX(dbp) AS dbp_max, + AVG(dbp) AS dbp_mean, + MIN(mbp) AS mbp_min, + MAX(mbp) AS mbp_max, + AVG(mbp) AS mbp_mean, + MIN(resp_rate) AS resp_rate_min, + MAX(resp_rate) AS resp_rate_max, + AVG(resp_rate) AS resp_rate_mean, + MIN(temperature) AS temperature_min, + MAX(temperature) AS temperature_max, + AVG(temperature) AS temperature_mean, + MIN(spo2) AS spo2_min, + MAX(spo2) AS spo2_max, + AVG(spo2) AS spo2_mean, + MIN(glucose) AS glucose_min, + MAX(glucose) AS glucose_max, + AVG(glucose) AS glucose_mean +FROM mimiciv_icu.icustays AS ie +LEFT JOIN mimiciv_derived.vitalsign AS ce + ON ie.stay_id = ce.stay_id + AND ce.charttime >= ie.intime - INTERVAL '6' HOUR + AND ce.charttime <= ie.intime + INTERVAL '1' DAY +GROUP BY + ie.subject_id, + ie.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/firstday/first_day_weight.sql b/mimic-iv/concepts_duckdb/firstday/first_day_weight.sql new file mode 100644 index 000000000..2889860c5 --- /dev/null +++ b/mimic-iv/concepts_duckdb/firstday/first_day_weight.sql @@ -0,0 +1,15 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.first_day_weight; CREATE TABLE mimiciv_derived.first_day_weight AS +SELECT + ie.subject_id, + ie.stay_id, + AVG(CASE WHEN weight_type = 'admit' THEN ce.weight ELSE NULL END) AS weight_admit, + AVG(ce.weight) AS weight, + MIN(ce.weight) AS weight_min, + MAX(ce.weight) AS weight_max +FROM mimiciv_icu.icustays AS ie +LEFT JOIN mimiciv_derived.weight_durations AS ce + ON ie.stay_id = ce.stay_id AND ce.starttime <= ie.intime + INTERVAL '1' DAY +GROUP BY + ie.subject_id, + ie.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/measurement/bg.sql b/mimic-iv/concepts_duckdb/measurement/bg.sql new file mode 100644 index 000000000..a090d1923 --- /dev/null +++ b/mimic-iv/concepts_duckdb/measurement/bg.sql @@ -0,0 +1,167 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.bg; CREATE TABLE mimiciv_derived.bg AS +WITH bg AS ( + SELECT + MAX(subject_id) AS subject_id, + MAX(hadm_id) AS hadm_id, + MAX(charttime) AS charttime, + MAX(storetime) AS storetime, + le.specimen_id, + MAX(CASE WHEN itemid = 52033 THEN value ELSE NULL END) AS specimen, + MAX(CASE WHEN itemid = 50801 THEN valuenum ELSE NULL END) AS aado2, + MAX(CASE WHEN itemid = 50802 THEN valuenum ELSE NULL END) AS baseexcess, + MAX(CASE WHEN itemid = 50803 THEN valuenum ELSE NULL END) AS bicarbonate, + MAX(CASE WHEN itemid = 50804 THEN valuenum ELSE NULL END) AS totalco2, + MAX(CASE WHEN itemid = 50805 THEN valuenum ELSE NULL END) AS carboxyhemoglobin, + MAX(CASE WHEN itemid = 50806 THEN valuenum ELSE NULL END) AS chloride, + MAX(CASE WHEN itemid = 50808 THEN valuenum ELSE NULL END) AS calcium, + MAX(CASE WHEN itemid = 50809 AND valuenum <= 10000 THEN valuenum ELSE NULL END) AS glucose, + MAX(CASE WHEN itemid = 50810 AND valuenum <= 100 THEN valuenum ELSE NULL END) AS hematocrit, + MAX(CASE WHEN itemid = 50811 THEN valuenum ELSE NULL END) AS hemoglobin, + MAX(CASE WHEN itemid = 50813 AND valuenum <= 10000 THEN valuenum ELSE NULL END) AS lactate, + MAX(CASE WHEN itemid = 50814 THEN valuenum ELSE NULL END) AS methemoglobin, + MAX(CASE WHEN itemid = 50815 THEN valuenum ELSE NULL END) AS o2flow, + MAX( + CASE + WHEN itemid = 50816 + THEN CASE + WHEN valuenum > 20 AND valuenum <= 100 + THEN valuenum + WHEN valuenum > 0.2 AND valuenum <= 1.0 + THEN valuenum * 100.0 + ELSE NULL + END + ELSE NULL + END + ) AS fio2, + MAX(CASE WHEN itemid = 50817 AND valuenum <= 100 THEN valuenum ELSE NULL END) AS so2, + MAX(CASE WHEN itemid = 50818 THEN valuenum ELSE NULL END) AS pco2, + MAX(CASE WHEN itemid = 50819 THEN valuenum ELSE NULL END) AS peep, + MAX(CASE WHEN itemid = 50820 THEN valuenum ELSE NULL END) AS ph, + MAX(CASE WHEN itemid = 50821 THEN valuenum ELSE NULL END) AS po2, + MAX(CASE WHEN itemid = 50822 THEN valuenum ELSE NULL END) AS potassium, + MAX(CASE WHEN itemid = 50823 THEN valuenum ELSE NULL END) AS requiredo2, + MAX(CASE WHEN itemid = 50824 THEN valuenum ELSE NULL END) AS sodium, + MAX(CASE WHEN itemid = 50825 THEN valuenum ELSE NULL END) AS temperature, + MAX(CASE WHEN itemid = 50807 THEN value ELSE NULL END) AS comments + FROM mimiciv_hosp.labevents AS le + WHERE + le.itemid IN (52033, 50801, 50802, 50803, 50804, 50805, 50806, 50807, 50808, 50809, 50810, 50811, 50813, 50814, 50815, 50816, 50817, 50818, 50819, 50820, 50821, 50822, 50823, 50824, 50825) + GROUP BY + le.specimen_id +), stg_spo2 AS ( + SELECT + subject_id, + charttime, + AVG(valuenum) AS spo2 + FROM mimiciv_icu.chartevents + WHERE + itemid = 220277 AND valuenum > 0 AND valuenum <= 100 + GROUP BY + subject_id, + charttime +), stg_fio2 AS ( + SELECT + subject_id, + charttime, + MAX( + CASE + WHEN valuenum > 0.2 AND valuenum <= 1 + THEN valuenum * 100 + WHEN valuenum > 1 AND valuenum < 20 + THEN NULL + WHEN valuenum >= 20 AND valuenum <= 100 + THEN valuenum + ELSE NULL + END + ) AS fio2_chartevents + FROM mimiciv_icu.chartevents + WHERE + itemid = 223835 AND valuenum > 0 AND valuenum <= 100 + GROUP BY + subject_id, + charttime +), stg2 AS ( + SELECT + bg.*, + ROW_NUMBER() OVER (PARTITION BY bg.subject_id, bg.charttime ORDER BY s1.charttime DESC) AS lastrowspo2, + s1.spo2 + FROM bg + LEFT JOIN stg_spo2 AS s1 + ON bg.subject_id = s1.subject_id + AND s1.charttime BETWEEN bg.charttime - INTERVAL '2' HOUR AND bg.charttime + WHERE + NOT bg.po2 IS NULL +), stg3 AS ( + SELECT + bg.*, + ROW_NUMBER() OVER (PARTITION BY bg.subject_id, bg.charttime ORDER BY s2.charttime DESC) AS lastrowfio2, + s2.fio2_chartevents + FROM stg2 AS bg + LEFT JOIN stg_fio2 AS s2 + ON bg.subject_id = s2.subject_id + AND s2.charttime >= bg.charttime - INTERVAL '4' HOUR + AND s2.charttime <= bg.charttime + AND s2.fio2_chartevents > 0 + WHERE + bg.lastrowspo2 = 1 +) +SELECT + stg3.subject_id, + stg3.hadm_id, + stg3.charttime, + specimen, + so2, + po2, + pco2, + fio2_chartevents, + fio2, + aado2, + CASE + WHEN po2 IS NULL OR pco2 IS NULL + THEN NULL + WHEN NOT fio2 IS NULL + THEN ( + fio2 / 100 + ) * ( + 760 - 47 + ) - ( + pco2 / 0.8 + ) - po2 + WHEN NOT fio2_chartevents IS NULL + THEN ( + fio2_chartevents / 100 + ) * ( + 760 - 47 + ) - ( + pco2 / 0.8 + ) - po2 + ELSE NULL + END AS aado2_calc, + CASE + WHEN po2 IS NULL + THEN NULL + WHEN NOT fio2 IS NULL + THEN 100 * po2 / fio2 + WHEN NOT fio2_chartevents IS NULL + THEN 100 * po2 / fio2_chartevents + ELSE NULL + END AS pao2fio2ratio, + ph, + baseexcess, + bicarbonate, + totalco2, + hematocrit, + hemoglobin, + carboxyhemoglobin, + methemoglobin, + chloride, + calcium, + temperature, + potassium, + sodium, + lactate, + glucose +FROM stg3 +WHERE + lastrowfio2 = 1 \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/measurement/blood_differential.sql b/mimic-iv/concepts_duckdb/measurement/blood_differential.sql new file mode 100644 index 000000000..6ef051e08 --- /dev/null +++ b/mimic-iv/concepts_duckdb/measurement/blood_differential.sql @@ -0,0 +1,126 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.blood_differential; CREATE TABLE mimiciv_derived.blood_differential AS +WITH blood_diff AS ( + SELECT + MAX(subject_id) AS subject_id, + MAX(hadm_id) AS hadm_id, + MAX(charttime) AS charttime, + le.specimen_id, + MAX(CASE WHEN itemid IN (51300, 51301, 51755) THEN valuenum ELSE NULL END) AS wbc, + MAX(CASE WHEN itemid = 52069 THEN valuenum ELSE NULL END) AS basophils_abs, + MAX( + CASE + WHEN itemid = 52073 + THEN valuenum + WHEN itemid = 51199 + THEN valuenum / 1000.0 + ELSE NULL + END + ) AS eosinophils_abs, + MAX( + CASE + WHEN itemid = 51133 + THEN valuenum + WHEN itemid = 52769 + THEN valuenum / 1000.0 + ELSE NULL + END + ) AS lymphocytes_abs, + MAX( + CASE + WHEN itemid = 52074 + THEN valuenum + WHEN itemid = 51253 + THEN valuenum / 1000.0 + ELSE NULL + END + ) AS monocytes_abs, + MAX(CASE WHEN itemid = 52075 THEN valuenum ELSE NULL END) AS neutrophils_abs, + MAX(CASE WHEN itemid = 51218 THEN valuenum / 1000.0 ELSE NULL END) AS granulocytes_abs, + MAX(CASE WHEN itemid = 51146 THEN valuenum ELSE NULL END) AS basophils, + MAX(CASE WHEN itemid = 51200 THEN valuenum ELSE NULL END) AS eosinophils, + MAX(CASE WHEN itemid IN (51244, 51245) THEN valuenum ELSE NULL END) AS lymphocytes, + MAX(CASE WHEN itemid = 51254 THEN valuenum ELSE NULL END) AS monocytes, + MAX(CASE WHEN itemid = 51256 THEN valuenum ELSE NULL END) AS neutrophils, + MAX(CASE WHEN itemid = 51143 THEN valuenum ELSE NULL END) AS atypical_lymphocytes, + MAX(CASE WHEN itemid = 51144 THEN valuenum ELSE NULL END) AS bands, + MAX(CASE WHEN itemid = 52135 THEN valuenum ELSE NULL END) AS immature_granulocytes, + MAX(CASE WHEN itemid = 51251 THEN valuenum ELSE NULL END) AS metamyelocytes, + MAX(CASE WHEN itemid = 51257 THEN valuenum ELSE NULL END) AS nrbc, + CASE + WHEN MAX(CASE WHEN itemid IN (51300, 51301, 51755) THEN valuenum ELSE NULL END) > 0 + AND SUM( + CASE + WHEN itemid IN (51146, 51200, 51244, 51245, 51254, 51256) + THEN valuenum + ELSE NULL + END + ) > 0 + THEN 1 + ELSE 0 + END AS impute_abs + FROM mimiciv_hosp.labevents AS le + WHERE + le.itemid IN (51146, 52069, 51199, 51200, 52073, 51244, 51245, 51133, 52769, 51253, 51254, 52074, 51256, 52075, 51143, 51144, 51218, 52135, 51251, 51257, 51300, 51301, 51755) + AND NOT valuenum IS NULL + AND valuenum >= 0 + GROUP BY + le.specimen_id +) +SELECT + subject_id, + hadm_id, + charttime, + specimen_id, + wbc, + ROUND( + TRY_CAST(CASE + WHEN basophils_abs IS NULL AND NOT basophils IS NULL AND impute_abs = 1 + THEN basophils * wbc / 100 + ELSE basophils_abs + END AS DECIMAL), + 4 + ) AS basophils_abs, + ROUND( + TRY_CAST(CASE + WHEN eosinophils_abs IS NULL AND NOT eosinophils IS NULL AND impute_abs = 1 + THEN eosinophils * wbc / 100 + ELSE eosinophils_abs + END AS DECIMAL), + 4 + ) AS eosinophils_abs, + ROUND( + TRY_CAST(CASE + WHEN lymphocytes_abs IS NULL AND NOT lymphocytes IS NULL AND impute_abs = 1 + THEN lymphocytes * wbc / 100 + ELSE lymphocytes_abs + END AS DECIMAL), + 4 + ) AS lymphocytes_abs, + ROUND( + TRY_CAST(CASE + WHEN monocytes_abs IS NULL AND NOT monocytes IS NULL AND impute_abs = 1 + THEN monocytes * wbc / 100 + ELSE monocytes_abs + END AS DECIMAL), + 4 + ) AS monocytes_abs, + ROUND( + TRY_CAST(CASE + WHEN neutrophils_abs IS NULL AND NOT neutrophils IS NULL AND impute_abs = 1 + THEN neutrophils * wbc / 100 + ELSE neutrophils_abs + END AS DECIMAL), + 4 + ) AS neutrophils_abs, + basophils, + eosinophils, + lymphocytes, + monocytes, + neutrophils, + atypical_lymphocytes, + bands, + immature_granulocytes, + metamyelocytes, + nrbc +FROM blood_diff \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/measurement/cardiac_marker.sql b/mimic-iv/concepts_duckdb/measurement/cardiac_marker.sql new file mode 100644 index 000000000..5f2a64ab7 --- /dev/null +++ b/mimic-iv/concepts_duckdb/measurement/cardiac_marker.sql @@ -0,0 +1,15 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.cardiac_marker; CREATE TABLE mimiciv_derived.cardiac_marker AS +SELECT + MAX(subject_id) AS subject_id, + MAX(hadm_id) AS hadm_id, + MAX(charttime) AS charttime, + le.specimen_id, + MAX(CASE WHEN itemid = 51003 THEN value ELSE NULL END) AS troponin_t, + MAX(CASE WHEN itemid = 50911 THEN valuenum ELSE NULL END) AS ck_mb, + MAX(CASE WHEN itemid = 50963 THEN valuenum ELSE NULL END) AS ntprobnp +FROM mimiciv_hosp.labevents AS le +WHERE + le.itemid IN (51003, 50911, 50963) AND NOT valuenum IS NULL +GROUP BY + le.specimen_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/measurement/chemistry.sql b/mimic-iv/concepts_duckdb/measurement/chemistry.sql new file mode 100644 index 000000000..45d639055 --- /dev/null +++ b/mimic-iv/concepts_duckdb/measurement/chemistry.sql @@ -0,0 +1,28 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.chemistry; CREATE TABLE mimiciv_derived.chemistry AS +SELECT + MAX(subject_id) AS subject_id, + MAX(hadm_id) AS hadm_id, + MAX(charttime) AS charttime, + le.specimen_id, + MAX(CASE WHEN itemid = 50862 AND valuenum <= 10 THEN valuenum ELSE NULL END) AS albumin, + MAX(CASE WHEN itemid = 50930 AND valuenum <= 10 THEN valuenum ELSE NULL END) AS globulin, + MAX(CASE WHEN itemid = 50976 AND valuenum <= 20 THEN valuenum ELSE NULL END) AS total_protein, + MAX(CASE WHEN itemid = 50868 AND valuenum <= 10000 THEN valuenum ELSE NULL END) AS aniongap, + MAX(CASE WHEN itemid = 50882 AND valuenum <= 10000 THEN valuenum ELSE NULL END) AS bicarbonate, + MAX(CASE WHEN itemid = 51006 AND valuenum <= 300 THEN valuenum ELSE NULL END) AS bun, + MAX(CASE WHEN itemid = 50893 AND valuenum <= 10000 THEN valuenum ELSE NULL END) AS calcium, + MAX(CASE WHEN itemid = 50902 AND valuenum <= 10000 THEN valuenum ELSE NULL END) AS chloride, + MAX(CASE WHEN itemid = 50912 AND valuenum <= 150 THEN valuenum ELSE NULL END) AS creatinine, + MAX(CASE WHEN itemid = 50931 AND valuenum <= 10000 THEN valuenum ELSE NULL END) AS glucose, + MAX(CASE WHEN itemid = 50983 AND valuenum <= 200 THEN valuenum ELSE NULL END) AS sodium, + MAX(CASE WHEN itemid = 50971 AND valuenum <= 30 THEN valuenum ELSE NULL END) AS potassium +FROM mimiciv_hosp.labevents AS le +WHERE + le.itemid IN (50862, 50930, 50976, 50868, 50882, 50893, 50912, 50902, 50931, 50971, 50983, 51006) + AND NOT valuenum IS NULL + AND ( + valuenum > 0 OR itemid = 50868 + ) +GROUP BY + le.specimen_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/measurement/coagulation.sql b/mimic-iv/concepts_duckdb/measurement/coagulation.sql new file mode 100644 index 000000000..69d00552c --- /dev/null +++ b/mimic-iv/concepts_duckdb/measurement/coagulation.sql @@ -0,0 +1,18 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.coagulation; CREATE TABLE mimiciv_derived.coagulation AS +SELECT + MAX(subject_id) AS subject_id, + MAX(hadm_id) AS hadm_id, + MAX(charttime) AS charttime, + le.specimen_id, + MAX(CASE WHEN itemid = 51196 THEN valuenum ELSE NULL END) AS d_dimer, + MAX(CASE WHEN itemid = 51214 THEN valuenum ELSE NULL END) AS fibrinogen, + MAX(CASE WHEN itemid = 51297 THEN valuenum ELSE NULL END) AS thrombin, + MAX(CASE WHEN itemid = 51237 THEN valuenum ELSE NULL END) AS inr, + MAX(CASE WHEN itemid = 51274 THEN valuenum ELSE NULL END) AS pt, + MAX(CASE WHEN itemid = 51275 THEN valuenum ELSE NULL END) AS ptt +FROM mimiciv_hosp.labevents AS le +WHERE + le.itemid IN (51196, 51214, 51297, 51237, 51274, 51275) AND NOT valuenum IS NULL +GROUP BY + le.specimen_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/measurement/complete_blood_count.sql b/mimic-iv/concepts_duckdb/measurement/complete_blood_count.sql new file mode 100644 index 000000000..6dfabe267 --- /dev/null +++ b/mimic-iv/concepts_duckdb/measurement/complete_blood_count.sql @@ -0,0 +1,24 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.complete_blood_count; CREATE TABLE mimiciv_derived.complete_blood_count AS +SELECT + MAX(subject_id) AS subject_id, + MAX(hadm_id) AS hadm_id, + MAX(charttime) AS charttime, + le.specimen_id, + MAX(CASE WHEN itemid = 51221 THEN valuenum ELSE NULL END) AS hematocrit, + MAX(CASE WHEN itemid = 51222 THEN valuenum ELSE NULL END) AS hemoglobin, + MAX(CASE WHEN itemid = 51248 THEN valuenum ELSE NULL END) AS mch, + MAX(CASE WHEN itemid = 51249 THEN valuenum ELSE NULL END) AS mchc, + MAX(CASE WHEN itemid = 51250 THEN valuenum ELSE NULL END) AS mcv, + MAX(CASE WHEN itemid = 51265 THEN valuenum ELSE NULL END) AS platelet, + MAX(CASE WHEN itemid = 51279 THEN valuenum ELSE NULL END) AS rbc, + MAX(CASE WHEN itemid = 51277 THEN valuenum ELSE NULL END) AS rdw, + MAX(CASE WHEN itemid = 52159 THEN valuenum ELSE NULL END) AS rdwsd, + MAX(CASE WHEN itemid = 51301 THEN valuenum ELSE NULL END) AS wbc +FROM mimiciv_hosp.labevents AS le +WHERE + le.itemid IN (51221, 51222, 51248, 51249, 51250, 51265, 51279, 51277, 52159, 51301) + AND NOT valuenum IS NULL + AND valuenum > 0 +GROUP BY + le.specimen_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/measurement/creatinine_baseline.sql b/mimic-iv/concepts_duckdb/measurement/creatinine_baseline.sql new file mode 100644 index 000000000..bcfa1a852 --- /dev/null +++ b/mimic-iv/concepts_duckdb/measurement/creatinine_baseline.sql @@ -0,0 +1,59 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.creatinine_baseline; CREATE TABLE mimiciv_derived.creatinine_baseline AS +WITH p AS ( + SELECT + ag.subject_id, + ag.hadm_id, + ag.age, + p.gender, + CASE + WHEN p.gender = 'F' + THEN POWER(75.0 / 186.0 / POWER(ag.age, -0.203) / 0.742, -1 / 1.154) + ELSE POWER(75.0 / 186.0 / POWER(ag.age, -0.203), -1 / 1.154) + END AS mdrd_est + FROM mimiciv_derived.age AS ag + LEFT JOIN mimiciv_hosp.patients AS p + ON ag.subject_id = p.subject_id + WHERE + ag.age >= 18 +), lab AS ( + SELECT + hadm_id, + MIN(creatinine) AS scr_min + FROM mimiciv_derived.chemistry + GROUP BY + hadm_id +), ckd AS ( + SELECT + hadm_id, + MAX(1) AS ckd_flag + FROM mimiciv_hosp.diagnoses_icd + WHERE + ( + SUBSTR(icd_code, 1, 3) = '585' AND icd_version = 9 + ) + OR ( + SUBSTR(icd_code, 1, 3) = 'N18' AND icd_version = 10 + ) + GROUP BY + hadm_id +) +SELECT + p.hadm_id, + p.gender, + p.age, + lab.scr_min, + COALESCE(ckd.ckd_flag, 0) AS ckd, + p.mdrd_est, + CASE + WHEN lab.scr_min <= 1.1 + THEN scr_min + WHEN ckd.ckd_flag = 1 + THEN scr_min + ELSE mdrd_est + END AS scr_baseline +FROM p +LEFT JOIN lab + ON p.hadm_id = lab.hadm_id +LEFT JOIN ckd + ON p.hadm_id = ckd.hadm_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/measurement/enzyme.sql b/mimic-iv/concepts_duckdb/measurement/enzyme.sql new file mode 100644 index 000000000..df62ba35b --- /dev/null +++ b/mimic-iv/concepts_duckdb/measurement/enzyme.sql @@ -0,0 +1,25 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.enzyme; CREATE TABLE mimiciv_derived.enzyme AS +SELECT + MAX(subject_id) AS subject_id, + MAX(hadm_id) AS hadm_id, + MAX(charttime) AS charttime, + le.specimen_id, + MAX(CASE WHEN itemid = 50861 THEN valuenum ELSE NULL END) AS alt, + MAX(CASE WHEN itemid = 50863 THEN valuenum ELSE NULL END) AS alp, + MAX(CASE WHEN itemid = 50878 THEN valuenum ELSE NULL END) AS ast, + MAX(CASE WHEN itemid = 50867 THEN valuenum ELSE NULL END) AS amylase, + MAX(CASE WHEN itemid = 50885 THEN valuenum ELSE NULL END) AS bilirubin_total, + MAX(CASE WHEN itemid = 50883 THEN valuenum ELSE NULL END) AS bilirubin_direct, + MAX(CASE WHEN itemid = 50884 THEN valuenum ELSE NULL END) AS bilirubin_indirect, + MAX(CASE WHEN itemid = 50910 THEN valuenum ELSE NULL END) AS ck_cpk, + MAX(CASE WHEN itemid = 50911 THEN valuenum ELSE NULL END) AS ck_mb, + MAX(CASE WHEN itemid = 50927 THEN valuenum ELSE NULL END) AS ggt, + MAX(CASE WHEN itemid = 50954 THEN valuenum ELSE NULL END) AS ld_ldh +FROM mimiciv_hosp.labevents AS le +WHERE + le.itemid IN (50861, 50863, 50878, 50867, 50885, 50884, 50883, 50910, 50911, 50927, 50954) + AND NOT valuenum IS NULL + AND valuenum > 0 +GROUP BY + le.specimen_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/measurement/gcs.sql b/mimic-iv/concepts_duckdb/measurement/gcs.sql new file mode 100644 index 000000000..f25e8d147 --- /dev/null +++ b/mimic-iv/concepts_duckdb/measurement/gcs.sql @@ -0,0 +1,70 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.gcs; CREATE TABLE mimiciv_derived.gcs AS +WITH base AS ( + SELECT + subject_id, + ce.stay_id, + ce.charttime, + MAX(CASE WHEN ce.itemid = 223901 THEN ce.valuenum ELSE NULL END) AS gcsmotor, + MAX( + CASE + WHEN ce.itemid = 223900 AND ce.value = 'No Response-ETT' + THEN 0 + WHEN ce.itemid = 223900 + THEN ce.valuenum + ELSE NULL + END + ) AS gcsverbal, + MAX(CASE WHEN ce.itemid = 220739 THEN ce.valuenum ELSE NULL END) AS gcseyes, + MAX(CASE WHEN ce.itemid = 223900 AND ce.value = 'No Response-ETT' THEN 1 ELSE 0 END) AS endotrachflag, + ROW_NUMBER() OVER (PARTITION BY ce.stay_id ORDER BY ce.charttime ASC NULLS FIRST) AS rn + FROM mimiciv_icu.chartevents AS ce + WHERE + ce.itemid IN (223900, 223901, 220739) + GROUP BY + ce.subject_id, + ce.stay_id, + ce.charttime +), gcs AS ( + SELECT + b.*, + b2.gcsverbal AS gcsverbalprev, + b2.gcsmotor AS gcsmotorprev, + b2.gcseyes AS gcseyesprev, + CASE + WHEN b.gcsverbal = 0 + THEN 15 + WHEN b.gcsverbal IS NULL AND b2.gcsverbal = 0 + THEN 15 + WHEN b2.gcsverbal = 0 + THEN COALESCE(b.gcsmotor, 6) + COALESCE(b.gcsverbal, 5) + COALESCE(b.gcseyes, 4) + ELSE COALESCE(b.gcsmotor, COALESCE(b2.gcsmotor, 6)) + COALESCE(b.gcsverbal, COALESCE(b2.gcsverbal, 5)) + COALESCE(b.gcseyes, COALESCE(b2.gcseyes, 4)) + END AS gcs + FROM base AS b + LEFT JOIN base AS b2 + ON b.stay_id = b2.stay_id + AND b.rn = b2.rn + 1 + AND b2.charttime > b.charttime - INTERVAL '6' HOUR +), gcs_stg AS ( + SELECT + subject_id, + gs.stay_id, + gs.charttime, + gcs, + COALESCE(gcsmotor, gcsmotorprev) AS gcsmotor, + COALESCE(gcsverbal, gcsverbalprev) AS gcsverbal, + COALESCE(gcseyes, gcseyesprev) AS gcseyes, + CASE WHEN COALESCE(gcsmotor, gcsmotorprev) IS NULL THEN 0 ELSE 1 END + CASE WHEN COALESCE(gcsverbal, gcsverbalprev) IS NULL THEN 0 ELSE 1 END + CASE WHEN COALESCE(gcseyes, gcseyesprev) IS NULL THEN 0 ELSE 1 END AS components_measured, + endotrachflag + FROM gcs AS gs +) +SELECT + gs.subject_id, + gs.stay_id, + gs.charttime, + gcs AS gcs, + gcsmotor AS gcs_motor, + gcsverbal AS gcs_verbal, + gcseyes AS gcs_eyes, + endotrachflag AS gcs_unable +FROM gcs_stg AS gs \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/measurement/height.sql b/mimic-iv/concepts_duckdb/measurement/height.sql new file mode 100644 index 000000000..3afa74234 --- /dev/null +++ b/mimic-iv/concepts_duckdb/measurement/height.sql @@ -0,0 +1,39 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.height; CREATE TABLE mimiciv_derived.height AS +WITH ht_in AS ( + SELECT + c.subject_id, + c.stay_id, + c.charttime, + ROUND(TRY_CAST(c.valuenum * 2.54 AS DECIMAL), 2) AS height, + c.valuenum AS height_orig + FROM mimiciv_icu.chartevents AS c + WHERE + NOT c.valuenum IS NULL AND c.itemid = 226707 +), ht_cm AS ( + SELECT + c.subject_id, + c.stay_id, + c.charttime, + ROUND(TRY_CAST(c.valuenum AS DECIMAL), 2) AS height + FROM mimiciv_icu.chartevents AS c + WHERE + NOT c.valuenum IS NULL AND c.itemid = 226730 +), ht_stg0 AS ( + SELECT + COALESCE(h1.subject_id, h1.subject_id) AS subject_id, + COALESCE(h1.stay_id, h1.stay_id) AS stay_id, + COALESCE(h1.charttime, h1.charttime) AS charttime, + COALESCE(h1.height, h2.height) AS height + FROM ht_cm AS h1 + FULL OUTER JOIN ht_in AS h2 + ON h1.subject_id = h2.subject_id AND h1.charttime = h2.charttime +) +SELECT + subject_id, + stay_id, + charttime, + height +FROM ht_stg0 +WHERE + NOT height IS NULL AND height > 120 AND height < 230 \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/measurement/icp.sql b/mimic-iv/concepts_duckdb/measurement/icp.sql new file mode 100644 index 000000000..0c50080b9 --- /dev/null +++ b/mimic-iv/concepts_duckdb/measurement/icp.sql @@ -0,0 +1,22 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.icp; CREATE TABLE mimiciv_derived.icp AS +WITH ce AS ( + SELECT + ce.subject_id, + ce.stay_id, + ce.charttime, + CASE WHEN valuenum > 0 AND valuenum < 100 THEN valuenum ELSE NULL END AS icp + FROM mimiciv_icu.chartevents AS ce + WHERE + ce.itemid IN (220765, 227989) +) +SELECT + ce.subject_id, + ce.stay_id, + ce.charttime, + MAX(icp) AS icp +FROM ce +GROUP BY + ce.subject_id, + ce.stay_id, + ce.charttime \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/measurement/inflammation.sql b/mimic-iv/concepts_duckdb/measurement/inflammation.sql new file mode 100644 index 000000000..6557801ce --- /dev/null +++ b/mimic-iv/concepts_duckdb/measurement/inflammation.sql @@ -0,0 +1,13 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.inflammation; CREATE TABLE mimiciv_derived.inflammation AS +SELECT + MAX(subject_id) AS subject_id, + MAX(hadm_id) AS hadm_id, + MAX(charttime) AS charttime, + le.specimen_id, + MAX(CASE WHEN itemid = 50889 THEN valuenum ELSE NULL END) AS crp +FROM mimiciv_hosp.labevents AS le +WHERE + le.itemid IN (50889) AND NOT valuenum IS NULL AND valuenum > 0 +GROUP BY + le.specimen_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/measurement/oxygen_delivery.sql b/mimic-iv/concepts_duckdb/measurement/oxygen_delivery.sql new file mode 100644 index 000000000..e3a5b955f --- /dev/null +++ b/mimic-iv/concepts_duckdb/measurement/oxygen_delivery.sql @@ -0,0 +1,67 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.oxygen_delivery; CREATE TABLE mimiciv_derived.oxygen_delivery AS +WITH ce_stg1 AS ( + SELECT + ce.subject_id, + ce.stay_id, + ce.charttime, + CASE WHEN itemid IN (223834, 227582) THEN 223834 ELSE itemid END AS itemid, + value, + valuenum, + valueuom, + storetime + FROM mimiciv_icu.chartevents AS ce + WHERE + NOT ce.value IS NULL AND ce.itemid IN (223834, 227582, 227287) +), ce_stg2 AS ( + SELECT + ce.subject_id, + ce.stay_id, + ce.charttime, + itemid, + value, + valuenum, + valueuom, + ROW_NUMBER() OVER (PARTITION BY subject_id, charttime, itemid ORDER BY storetime DESC) AS rn + FROM ce_stg1 AS ce +), o2 AS ( + SELECT + subject_id, + stay_id, + charttime, + itemid, + value AS o2_device, + ROW_NUMBER() OVER (PARTITION BY subject_id, charttime, itemid ORDER BY value NULLS FIRST) AS rn + FROM mimiciv_icu.chartevents + WHERE + itemid = 226732 +), stg AS ( + SELECT + COALESCE(ce.subject_id, o2.subject_id) AS subject_id, + COALESCE(ce.stay_id, o2.stay_id) AS stay_id, + COALESCE(ce.charttime, o2.charttime) AS charttime, + COALESCE(ce.itemid, o2.itemid) AS itemid, + ce.value, + ce.valuenum, + o2.o2_device, + o2.rn + FROM ce_stg2 AS ce + FULL OUTER JOIN o2 + ON ce.subject_id = o2.subject_id AND ce.charttime = o2.charttime + WHERE + ce.rn = 1 +) +SELECT + subject_id, + MAX(stay_id) AS stay_id, + charttime, + MAX(CASE WHEN itemid = 223834 THEN valuenum ELSE NULL END) AS o2_flow, + MAX(CASE WHEN itemid = 227287 THEN valuenum ELSE NULL END) AS o2_flow_additional, + MAX(CASE WHEN rn = 1 THEN o2_device ELSE NULL END) AS o2_delivery_device_1, + MAX(CASE WHEN rn = 2 THEN o2_device ELSE NULL END) AS o2_delivery_device_2, + MAX(CASE WHEN rn = 3 THEN o2_device ELSE NULL END) AS o2_delivery_device_3, + MAX(CASE WHEN rn = 4 THEN o2_device ELSE NULL END) AS o2_delivery_device_4 +FROM stg +GROUP BY + subject_id, + charttime \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/measurement/rhythm.sql b/mimic-iv/concepts_duckdb/measurement/rhythm.sql new file mode 100644 index 000000000..9a570a977 --- /dev/null +++ b/mimic-iv/concepts_duckdb/measurement/rhythm.sql @@ -0,0 +1,16 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.rhythm; CREATE TABLE mimiciv_derived.rhythm AS +SELECT + ce.subject_id, + ce.charttime, + MAX(CASE WHEN itemid = 220048 THEN value ELSE NULL END) AS heart_rhythm, + MAX(CASE WHEN itemid = 224650 THEN value ELSE NULL END) AS ectopy_type, + MAX(CASE WHEN itemid = 224651 THEN value ELSE NULL END) AS ectopy_frequency, + MAX(CASE WHEN itemid = 226479 THEN value ELSE NULL END) AS ectopy_type_secondary, + MAX(CASE WHEN itemid = 226480 THEN value ELSE NULL END) AS ectopy_frequency_secondary +FROM mimiciv_icu.chartevents AS ce +WHERE + NOT ce.stay_id IS NULL AND ce.itemid IN (220048, 224650, 224651, 226479, 226480) +GROUP BY + ce.subject_id, + ce.charttime \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/measurement/urine_output.sql b/mimic-iv/concepts_duckdb/measurement/urine_output.sql new file mode 100644 index 000000000..20b8403eb --- /dev/null +++ b/mimic-iv/concepts_duckdb/measurement/urine_output.sql @@ -0,0 +1,19 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.urine_output; CREATE TABLE mimiciv_derived.urine_output AS +WITH uo AS ( + SELECT + oe.stay_id, + oe.charttime, + CASE WHEN oe.itemid = 227488 AND oe.value > 0 THEN -1 * oe.value ELSE oe.value END AS urineoutput + FROM mimiciv_icu.outputevents AS oe + WHERE + itemid IN (226559, 226560, 226561, 226584, 226563, 226564, 226565, 226567, 226557, 226558, 227488, 227489) +) +SELECT + stay_id, + charttime, + SUM(urineoutput) AS urineoutput +FROM uo +GROUP BY + stay_id, + charttime \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/measurement/urine_output_rate.sql b/mimic-iv/concepts_duckdb/measurement/urine_output_rate.sql new file mode 100644 index 000000000..d25831eaa --- /dev/null +++ b/mimic-iv/concepts_duckdb/measurement/urine_output_rate.sql @@ -0,0 +1,110 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.urine_output_rate; CREATE TABLE mimiciv_derived.urine_output_rate AS +WITH tm AS ( + SELECT + ie.stay_id, + MIN(charttime) AS intime_hr, + MAX(charttime) AS outtime_hr + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_icu.chartevents AS ce + ON ie.stay_id = ce.stay_id + AND ce.itemid = 220045 + AND ce.charttime > ie.intime - INTERVAL '1' MONTH + AND ce.charttime < ie.outtime + INTERVAL '1' MONTH + GROUP BY + ie.stay_id +), uo_tm AS ( + SELECT + tm.stay_id, + CASE + WHEN LAG(charttime) OVER w IS NULL + THEN DATE_DIFF('microseconds', intime_hr, charttime)/60000000.0 + ELSE DATE_DIFF('microseconds', LAG(charttime) OVER w, charttime)/60000000.0 + END AS tm_since_last_uo, + uo.charttime, + uo.urineoutput + FROM tm + INNER JOIN mimiciv_derived.urine_output AS uo + ON tm.stay_id = uo.stay_id + WINDOW w AS (PARTITION BY tm.stay_id ORDER BY charttime NULLS FIRST) +), ur_stg AS ( + SELECT + io.stay_id, + io.charttime, + SUM(DISTINCT io.urineoutput) AS uo, + SUM( + CASE + WHEN DATE_DIFF('microseconds', iosum.charttime, io.charttime)/3600000000.0 <= 5 + THEN iosum.urineoutput + ELSE NULL + END + ) AS urineoutput_6hr, + SUM( + CASE + WHEN DATE_DIFF('microseconds', iosum.charttime, io.charttime)/3600000000.0 <= 5 + THEN iosum.tm_since_last_uo + ELSE NULL + END + ) / 60.0 AS uo_tm_6hr, + SUM( + CASE + WHEN DATE_DIFF('microseconds', iosum.charttime, io.charttime)/3600000000.0 <= 11 + THEN iosum.urineoutput + ELSE NULL + END + ) AS urineoutput_12hr, + SUM( + CASE + WHEN DATE_DIFF('microseconds', iosum.charttime, io.charttime)/3600000000.0 <= 11 + THEN iosum.tm_since_last_uo + ELSE NULL + END + ) / 60.0 AS uo_tm_12hr, + SUM(iosum.urineoutput) AS urineoutput_24hr, + SUM(iosum.tm_since_last_uo) / 60.0 AS uo_tm_24hr + FROM uo_tm AS io + LEFT JOIN uo_tm AS iosum + ON io.stay_id = iosum.stay_id + AND io.charttime >= iosum.charttime + AND io.charttime <= ( + iosum.charttime + INTERVAL '23' HOUR + ) + GROUP BY + io.stay_id, + io.charttime +) +SELECT + ur.stay_id, + ur.charttime, + wd.weight, + ur.uo, + ur.urineoutput_6hr, + ur.urineoutput_12hr, + ur.urineoutput_24hr, + CASE + WHEN uo_tm_6hr >= 6 + THEN ROUND(TRY_CAST(( + ur.urineoutput_6hr / wd.weight / uo_tm_6hr + ) AS DECIMAL), 4) + END AS uo_mlkghr_6hr, + CASE + WHEN uo_tm_12hr >= 12 + THEN ROUND(TRY_CAST(( + ur.urineoutput_12hr / wd.weight / uo_tm_12hr + ) AS DECIMAL), 4) + END AS uo_mlkghr_12hr, + CASE + WHEN uo_tm_24hr >= 24 + THEN ROUND(TRY_CAST(( + ur.urineoutput_24hr / wd.weight / uo_tm_24hr + ) AS DECIMAL), 4) + END AS uo_mlkghr_24hr, + ROUND(TRY_CAST(uo_tm_6hr AS DECIMAL), 2) AS uo_tm_6hr, + ROUND(TRY_CAST(uo_tm_12hr AS DECIMAL), 2) AS uo_tm_12hr, + ROUND(TRY_CAST(uo_tm_24hr AS DECIMAL), 2) AS uo_tm_24hr +FROM ur_stg AS ur +LEFT JOIN mimiciv_derived.weight_durations AS wd + ON ur.stay_id = wd.stay_id + AND ur.charttime > wd.starttime + AND ur.charttime <= wd.endtime + AND wd.weight > 0 \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/measurement/ventilator_setting.sql b/mimic-iv/concepts_duckdb/measurement/ventilator_setting.sql new file mode 100644 index 000000000..166293c93 --- /dev/null +++ b/mimic-iv/concepts_duckdb/measurement/ventilator_setting.sql @@ -0,0 +1,54 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.ventilator_setting; CREATE TABLE mimiciv_derived.ventilator_setting AS +WITH ce AS ( + SELECT + ce.subject_id, + ce.stay_id, + ce.charttime, + itemid, + value, + CASE + WHEN itemid = 223835 + THEN CASE + WHEN valuenum >= 0.20 AND valuenum <= 1 + THEN valuenum * 100 + WHEN valuenum > 1 AND valuenum < 20 + THEN NULL + WHEN valuenum >= 20 AND valuenum <= 100 + THEN valuenum + ELSE NULL + END + WHEN itemid IN (220339, 224700) + THEN CASE WHEN valuenum > 100 THEN NULL WHEN valuenum < 0 THEN NULL ELSE valuenum END + ELSE valuenum + END AS valuenum, + valueuom, + storetime + FROM mimiciv_icu.chartevents AS ce + WHERE + NOT ce.value IS NULL + AND NOT ce.stay_id IS NULL + AND ce.itemid IN (224688, 224689, 224690, 224687, 224685, 224684, 224686, 224696, 220339, 224700, 223835, 223849, 229314, 223848, 224691) +) +SELECT + subject_id, + MAX(stay_id) AS stay_id, + charttime, + MAX(CASE WHEN itemid = 224688 THEN valuenum ELSE NULL END) AS respiratory_rate_set, + MAX(CASE WHEN itemid = 224690 THEN valuenum ELSE NULL END) AS respiratory_rate_total, + MAX(CASE WHEN itemid = 224689 THEN valuenum ELSE NULL END) AS respiratory_rate_spontaneous, + MAX(CASE WHEN itemid = 224687 THEN valuenum ELSE NULL END) AS minute_volume, + MAX(CASE WHEN itemid = 224684 THEN valuenum ELSE NULL END) AS tidal_volume_set, + MAX(CASE WHEN itemid = 224685 THEN valuenum ELSE NULL END) AS tidal_volume_observed, + MAX(CASE WHEN itemid = 224686 THEN valuenum ELSE NULL END) AS tidal_volume_spontaneous, + MAX(CASE WHEN itemid = 224696 THEN valuenum ELSE NULL END) AS plateau_pressure, + MAX(CASE WHEN itemid IN (220339, 224700) THEN valuenum ELSE NULL END) AS peep, + MAX(CASE WHEN itemid = 223835 THEN valuenum ELSE NULL END) AS fio2, + MAX(CASE WHEN itemid = 224691 THEN valuenum ELSE NULL END) AS flow_rate, + MAX(CASE WHEN itemid = 223849 THEN value ELSE NULL END) AS ventilator_mode, + MAX(CASE WHEN itemid = 229314 THEN value ELSE NULL END) AS ventilator_mode_hamilton, + MAX(CASE WHEN itemid = 223848 THEN value ELSE NULL END) AS ventilator_type +FROM ce +GROUP BY + subject_id, + charttime \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/measurement/vitalsign.sql b/mimic-iv/concepts_duckdb/measurement/vitalsign.sql new file mode 100644 index 000000000..a76f4f01d --- /dev/null +++ b/mimic-iv/concepts_duckdb/measurement/vitalsign.sql @@ -0,0 +1,62 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.vitalsign; CREATE TABLE mimiciv_derived.vitalsign AS +SELECT + ce.subject_id, + ce.stay_id, + ce.charttime, + AVG( + CASE WHEN itemid IN (220045) AND valuenum > 0 AND valuenum < 300 THEN valuenum END + ) AS heart_rate, + AVG( + CASE + WHEN itemid IN (220179, 220050, 225309) AND valuenum > 0 AND valuenum < 400 + THEN valuenum + END + ) AS sbp, + AVG( + CASE + WHEN itemid IN (220180, 220051, 225310) AND valuenum > 0 AND valuenum < 300 + THEN valuenum + END + ) AS dbp, + AVG( + CASE + WHEN itemid IN (220052, 220181, 225312) AND valuenum > 0 AND valuenum < 300 + THEN valuenum + END + ) AS mbp, + AVG(CASE WHEN itemid = 220179 AND valuenum > 0 AND valuenum < 400 THEN valuenum END) AS sbp_ni, + AVG(CASE WHEN itemid = 220180 AND valuenum > 0 AND valuenum < 300 THEN valuenum END) AS dbp_ni, + AVG(CASE WHEN itemid = 220181 AND valuenum > 0 AND valuenum < 300 THEN valuenum END) AS mbp_ni, + AVG( + CASE + WHEN itemid IN (220210, 224690) AND valuenum > 0 AND valuenum < 70 + THEN valuenum + END + ) AS resp_rate, + ROUND( + TRY_CAST(AVG( + CASE + WHEN itemid IN (223761) AND valuenum > 70 AND valuenum < 120 + THEN ( + valuenum - 32 + ) / 1.8 + WHEN itemid IN (223762) AND valuenum > 10 AND valuenum < 50 + THEN valuenum + END + ) AS DECIMAL), + 2 + ) AS temperature, + MAX(CASE WHEN itemid = 224642 THEN value END) AS temperature_site, + AVG( + CASE WHEN itemid IN (220277) AND valuenum > 0 AND valuenum <= 100 THEN valuenum END + ) AS spo2, + AVG(CASE WHEN itemid IN (225664, 220621, 226537) AND valuenum > 0 THEN valuenum END) AS glucose +FROM mimiciv_icu.chartevents AS ce +WHERE + NOT ce.stay_id IS NULL + AND ce.itemid IN (220045, 225309, 225310, 225312, 220050, 220051, 220052, 220179, 220180, 220181, 220210, 224690, 220277, 225664, 220621, 226537, 223762, 223761, 224642) +GROUP BY + ce.subject_id, + ce.stay_id, + ce.charttime \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/medication/acei.sql b/mimic-iv/concepts_duckdb/medication/acei.sql new file mode 100644 index 000000000..d9e2a9ff3 --- /dev/null +++ b/mimic-iv/concepts_duckdb/medication/acei.sql @@ -0,0 +1,41 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.acei; CREATE TABLE mimiciv_derived.acei AS +WITH acei_drug AS ( + SELECT DISTINCT + drug, + CASE + WHEN UPPER(drug) LIKE '%BENAZEPRIL%' + THEN 1 + WHEN UPPER(drug) LIKE '%CAPTOPRIL%' + THEN 1 + WHEN UPPER(drug) LIKE '%ENALAPRIL%' + THEN 1 + WHEN UPPER(drug) LIKE '%FOSINOPRIL%' + THEN 1 + WHEN UPPER(drug) LIKE '%LISINOPRIL%' + THEN 1 + WHEN UPPER(drug) LIKE '%MOEXIPRIL%' + THEN 1 + WHEN UPPER(drug) LIKE '%PERINDOPRIL%' + THEN 1 + WHEN UPPER(drug) LIKE '%QUINAPRIL%' + THEN 1 + WHEN UPPER(drug) LIKE '%RAMIPRIL%' + THEN 1 + WHEN UPPER(drug) LIKE '%TRANDOLAPRIL%' + THEN 1 + ELSE 0 + END AS acei + FROM mimiciv_hosp.prescriptions +) +SELECT + pr.subject_id, + pr.hadm_id, + pr.drug AS acei, + pr.starttime, + pr.stoptime +FROM mimiciv_hosp.prescriptions AS pr +INNER JOIN acei_drug + ON pr.drug = acei_drug.drug +WHERE + acei_drug.acei = 1 \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/medication/antibiotic.sql b/mimic-iv/concepts_duckdb/medication/antibiotic.sql new file mode 100644 index 000000000..5b85b7201 --- /dev/null +++ b/mimic-iv/concepts_duckdb/medication/antibiotic.sql @@ -0,0 +1,343 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.antibiotic; CREATE TABLE mimiciv_derived.antibiotic AS +WITH abx AS ( + SELECT DISTINCT + drug, + route, + CASE + WHEN LOWER(drug) LIKE '%adoxa%' + THEN 1 + WHEN LOWER(drug) LIKE '%ala-tet%' + THEN 1 + WHEN LOWER(drug) LIKE '%alodox%' + THEN 1 + WHEN LOWER(drug) LIKE '%amikacin%' + THEN 1 + WHEN LOWER(drug) LIKE '%amikin%' + THEN 1 + WHEN LOWER(drug) LIKE '%amoxicill%' + THEN 1 + WHEN LOWER(drug) LIKE '%amphotericin%' + THEN 1 + WHEN LOWER(drug) LIKE '%anidulafungin%' + THEN 1 + WHEN LOWER(drug) LIKE '%ancef%' + THEN 1 + WHEN LOWER(drug) LIKE '%clavulanate%' + THEN 1 + WHEN LOWER(drug) LIKE '%ampicillin%' + THEN 1 + WHEN LOWER(drug) LIKE '%augmentin%' + THEN 1 + WHEN LOWER(drug) LIKE '%avelox%' + THEN 1 + WHEN LOWER(drug) LIKE '%avidoxy%' + THEN 1 + WHEN LOWER(drug) LIKE '%azactam%' + THEN 1 + WHEN LOWER(drug) LIKE '%azithromycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%aztreonam%' + THEN 1 + WHEN LOWER(drug) LIKE '%axetil%' + THEN 1 + WHEN LOWER(drug) LIKE '%bactocill%' + THEN 1 + WHEN LOWER(drug) LIKE '%bactrim%' + THEN 1 + WHEN LOWER(drug) LIKE '%bactroban%' + THEN 1 + WHEN LOWER(drug) LIKE '%bethkis%' + THEN 1 + WHEN LOWER(drug) LIKE '%biaxin%' + THEN 1 + WHEN LOWER(drug) LIKE '%bicillin l-a%' + THEN 1 + WHEN LOWER(drug) LIKE '%cayston%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefazolin%' + THEN 1 + WHEN LOWER(drug) LIKE '%cedax%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefoxitin%' + THEN 1 + WHEN LOWER(drug) LIKE '%ceftazidime%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefaclor%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefadroxil%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefdinir%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefditoren%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefepime%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefotan%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefotetan%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefotaxime%' + THEN 1 + WHEN LOWER(drug) LIKE '%ceftaroline%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefpodoxime%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefpirome%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefprozil%' + THEN 1 + WHEN LOWER(drug) LIKE '%ceftibuten%' + THEN 1 + WHEN LOWER(drug) LIKE '%ceftin%' + THEN 1 + WHEN LOWER(drug) LIKE '%ceftriaxone%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefuroxime%' + THEN 1 + WHEN LOWER(drug) LIKE '%cephalexin%' + THEN 1 + WHEN LOWER(drug) LIKE '%cephalothin%' + THEN 1 + WHEN LOWER(drug) LIKE '%cephapririn%' + THEN 1 + WHEN LOWER(drug) LIKE '%chloramphenicol%' + THEN 1 + WHEN LOWER(drug) LIKE '%cipro%' + THEN 1 + WHEN LOWER(drug) LIKE '%ciprofloxacin%' + THEN 1 + WHEN LOWER(drug) LIKE '%claforan%' + THEN 1 + WHEN LOWER(drug) LIKE '%clarithromycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%cleocin%' + THEN 1 + WHEN LOWER(drug) LIKE '%clindamycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%cubicin%' + THEN 1 + WHEN LOWER(drug) LIKE '%dicloxacillin%' + THEN 1 + WHEN LOWER(drug) LIKE '%dirithromycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%doryx%' + THEN 1 + WHEN LOWER(drug) LIKE '%doxycy%' + THEN 1 + WHEN LOWER(drug) LIKE '%duricef%' + THEN 1 + WHEN LOWER(drug) LIKE '%dynacin%' + THEN 1 + WHEN LOWER(drug) LIKE '%ery-tab%' + THEN 1 + WHEN LOWER(drug) LIKE '%eryped%' + THEN 1 + WHEN LOWER(drug) LIKE '%eryc%' + THEN 1 + WHEN LOWER(drug) LIKE '%erythrocin%' + THEN 1 + WHEN LOWER(drug) LIKE '%erythromycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%factive%' + THEN 1 + WHEN LOWER(drug) LIKE '%flagyl%' + THEN 1 + WHEN LOWER(drug) LIKE '%fortaz%' + THEN 1 + WHEN LOWER(drug) LIKE '%furadantin%' + THEN 1 + WHEN LOWER(drug) LIKE '%garamycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%gentamicin%' + THEN 1 + WHEN LOWER(drug) LIKE '%kanamycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%keflex%' + THEN 1 + WHEN LOWER(drug) LIKE '%kefzol%' + THEN 1 + WHEN LOWER(drug) LIKE '%ketek%' + THEN 1 + WHEN LOWER(drug) LIKE '%levaquin%' + THEN 1 + WHEN LOWER(drug) LIKE '%levofloxacin%' + THEN 1 + WHEN LOWER(drug) LIKE '%lincocin%' + THEN 1 + WHEN LOWER(drug) LIKE '%linezolid%' + THEN 1 + WHEN LOWER(drug) LIKE '%macrobid%' + THEN 1 + WHEN LOWER(drug) LIKE '%macrodantin%' + THEN 1 + WHEN LOWER(drug) LIKE '%maxipime%' + THEN 1 + WHEN LOWER(drug) LIKE '%mefoxin%' + THEN 1 + WHEN LOWER(drug) LIKE '%metronidazole%' + THEN 1 + WHEN LOWER(drug) LIKE '%meropenem%' + THEN 1 + WHEN LOWER(drug) LIKE '%methicillin%' + THEN 1 + WHEN LOWER(drug) LIKE '%minocin%' + THEN 1 + WHEN LOWER(drug) LIKE '%minocycline%' + THEN 1 + WHEN LOWER(drug) LIKE '%monodox%' + THEN 1 + WHEN LOWER(drug) LIKE '%monurol%' + THEN 1 + WHEN LOWER(drug) LIKE '%morgidox%' + THEN 1 + WHEN LOWER(drug) LIKE '%moxatag%' + THEN 1 + WHEN LOWER(drug) LIKE '%moxifloxacin%' + THEN 1 + WHEN LOWER(drug) LIKE '%mupirocin%' + THEN 1 + WHEN LOWER(drug) LIKE '%myrac%' + THEN 1 + WHEN LOWER(drug) LIKE '%nafcillin%' + THEN 1 + WHEN LOWER(drug) LIKE '%neomycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%nicazel doxy 30%' + THEN 1 + WHEN LOWER(drug) LIKE '%nitrofurantoin%' + THEN 1 + WHEN LOWER(drug) LIKE '%norfloxacin%' + THEN 1 + WHEN LOWER(drug) LIKE '%noroxin%' + THEN 1 + WHEN LOWER(drug) LIKE '%ocudox%' + THEN 1 + WHEN LOWER(drug) LIKE '%ofloxacin%' + THEN 1 + WHEN LOWER(drug) LIKE '%omnicef%' + THEN 1 + WHEN LOWER(drug) LIKE '%oracea%' + THEN 1 + WHEN LOWER(drug) LIKE '%oraxyl%' + THEN 1 + WHEN LOWER(drug) LIKE '%oxacillin%' + THEN 1 + WHEN LOWER(drug) LIKE '%pc pen vk%' + THEN 1 + WHEN LOWER(drug) LIKE '%pce dispertab%' + THEN 1 + WHEN LOWER(drug) LIKE '%panixine%' + THEN 1 + WHEN LOWER(drug) LIKE '%pediazole%' + THEN 1 + WHEN LOWER(drug) LIKE '%penicillin%' + THEN 1 + WHEN LOWER(drug) LIKE '%periostat%' + THEN 1 + WHEN LOWER(drug) LIKE '%pfizerpen%' + THEN 1 + WHEN LOWER(drug) LIKE '%piperacillin%' + THEN 1 + WHEN LOWER(drug) LIKE '%tazobactam%' + THEN 1 + WHEN LOWER(drug) LIKE '%primsol%' + THEN 1 + WHEN LOWER(drug) LIKE '%proquin%' + THEN 1 + WHEN LOWER(drug) LIKE '%raniclor%' + THEN 1 + WHEN LOWER(drug) LIKE '%rifadin%' + THEN 1 + WHEN LOWER(drug) LIKE '%rifampin%' + THEN 1 + WHEN LOWER(drug) LIKE '%rocephin%' + THEN 1 + WHEN LOWER(drug) LIKE '%smz-tmp%' + THEN 1 + WHEN LOWER(drug) LIKE '%septra%' + THEN 1 + WHEN LOWER(drug) LIKE '%septra ds%' + THEN 1 + WHEN LOWER(drug) LIKE '%septra%' + THEN 1 + WHEN LOWER(drug) LIKE '%solodyn%' + THEN 1 + WHEN LOWER(drug) LIKE '%spectracef%' + THEN 1 + WHEN LOWER(drug) LIKE '%streptomycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%sulfadiazine%' + THEN 1 + WHEN LOWER(drug) LIKE '%sulfamethoxazole%' + THEN 1 + WHEN LOWER(drug) LIKE '%trimethoprim%' + THEN 1 + WHEN LOWER(drug) LIKE '%sulfatrim%' + THEN 1 + WHEN LOWER(drug) LIKE '%sulfisoxazole%' + THEN 1 + WHEN LOWER(drug) LIKE '%suprax%' + THEN 1 + WHEN LOWER(drug) LIKE '%synercid%' + THEN 1 + WHEN LOWER(drug) LIKE '%tazicef%' + THEN 1 + WHEN LOWER(drug) LIKE '%tetracycline%' + THEN 1 + WHEN LOWER(drug) LIKE '%timentin%' + THEN 1 + WHEN LOWER(drug) LIKE '%tobramycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%trimethoprim%' + THEN 1 + WHEN LOWER(drug) LIKE '%unasyn%' + THEN 1 + WHEN LOWER(drug) LIKE '%vancocin%' + THEN 1 + WHEN LOWER(drug) LIKE '%vancomycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%vantin%' + THEN 1 + WHEN LOWER(drug) LIKE '%vibativ%' + THEN 1 + WHEN LOWER(drug) LIKE '%vibra-tabs%' + THEN 1 + WHEN LOWER(drug) LIKE '%vibramycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%zinacef%' + THEN 1 + WHEN LOWER(drug) LIKE '%zithromax%' + THEN 1 + WHEN LOWER(drug) LIKE '%zosyn%' + THEN 1 + WHEN LOWER(drug) LIKE '%zyvox%' + THEN 1 + ELSE 0 + END AS antibiotic + FROM mimiciv_hosp.prescriptions + WHERE + NOT drug_type IN ('BASE') + AND NOT route IN ('OU', 'OS', 'OD', 'AU', 'AS', 'AD', 'TP') + AND NOT LOWER(route) LIKE '%ear%' + AND NOT LOWER(route) LIKE '%eye%' + AND NOT LOWER(drug) LIKE '%cream%' + AND NOT LOWER(drug) LIKE '%desensitization%' + AND NOT LOWER(drug) LIKE '%ophth oint%' + AND NOT LOWER(drug) LIKE '%gel%' +) +SELECT + pr.subject_id, + pr.hadm_id, + ie.stay_id, + pr.drug AS antibiotic, + pr.route, + pr.starttime, + pr.stoptime +FROM mimiciv_hosp.prescriptions AS pr +INNER JOIN abx + ON pr.drug = abx.drug AND pr.route = abx.route +LEFT JOIN mimiciv_icu.icustays AS ie + ON pr.hadm_id = ie.hadm_id AND pr.starttime >= ie.intime AND pr.starttime < ie.outtime +WHERE + abx.antibiotic = 1 \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/medication/dobutamine.sql b/mimic-iv/concepts_duckdb/medication/dobutamine.sql new file mode 100644 index 000000000..e1eebe267 --- /dev/null +++ b/mimic-iv/concepts_duckdb/medication/dobutamine.sql @@ -0,0 +1,12 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.dobutamine; CREATE TABLE mimiciv_derived.dobutamine AS +SELECT + stay_id, + linkorderid, + rate AS vaso_rate, + amount AS vaso_amount, + starttime, + endtime +FROM mimiciv_icu.inputevents +WHERE + itemid = 221653 \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/medication/dopamine.sql b/mimic-iv/concepts_duckdb/medication/dopamine.sql new file mode 100644 index 000000000..3b92ab772 --- /dev/null +++ b/mimic-iv/concepts_duckdb/medication/dopamine.sql @@ -0,0 +1,12 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.dopamine; CREATE TABLE mimiciv_derived.dopamine AS +SELECT + stay_id, + linkorderid, + rate AS vaso_rate, + amount AS vaso_amount, + starttime, + endtime +FROM mimiciv_icu.inputevents +WHERE + itemid = 221662 \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/medication/epinephrine.sql b/mimic-iv/concepts_duckdb/medication/epinephrine.sql new file mode 100644 index 000000000..cf48272e0 --- /dev/null +++ b/mimic-iv/concepts_duckdb/medication/epinephrine.sql @@ -0,0 +1,12 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.epinephrine; CREATE TABLE mimiciv_derived.epinephrine AS +SELECT + stay_id, + linkorderid, + rate AS vaso_rate, + amount AS vaso_amount, + starttime, + endtime +FROM mimiciv_icu.inputevents +WHERE + itemid = 221289 \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/medication/milrinone.sql b/mimic-iv/concepts_duckdb/medication/milrinone.sql new file mode 100644 index 000000000..d43e7f188 --- /dev/null +++ b/mimic-iv/concepts_duckdb/medication/milrinone.sql @@ -0,0 +1,12 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.milrinone; CREATE TABLE mimiciv_derived.milrinone AS +SELECT + stay_id, + linkorderid, + rate AS vaso_rate, + amount AS vaso_amount, + starttime, + endtime +FROM mimiciv_icu.inputevents +WHERE + itemid = 221986 \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/medication/neuroblock.sql b/mimic-iv/concepts_duckdb/medication/neuroblock.sql new file mode 100644 index 000000000..014a4f26e --- /dev/null +++ b/mimic-iv/concepts_duckdb/medication/neuroblock.sql @@ -0,0 +1,12 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.neuroblock; CREATE TABLE mimiciv_derived.neuroblock AS +SELECT + stay_id, + orderid, + rate AS drug_rate, + amount AS drug_amount, + starttime, + endtime +FROM mimiciv_icu.inputevents +WHERE + itemid IN (222062, 221555) AND NOT rate IS NULL \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/medication/norepinephrine.sql b/mimic-iv/concepts_duckdb/medication/norepinephrine.sql new file mode 100644 index 000000000..0ef6b3254 --- /dev/null +++ b/mimic-iv/concepts_duckdb/medication/norepinephrine.sql @@ -0,0 +1,18 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.norepinephrine; CREATE TABLE mimiciv_derived.norepinephrine AS +SELECT + stay_id, + linkorderid, + CASE + WHEN rateuom = 'mg/kg/min' AND patientweight = 1 + THEN rate + WHEN rateuom = 'mg/kg/min' + THEN rate * 1000.0 + ELSE rate + END AS vaso_rate, + amount AS vaso_amount, + starttime, + endtime +FROM mimiciv_icu.inputevents +WHERE + itemid = 221906 \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/medication/norepinephrine_equivalent_dose.sql b/mimic-iv/concepts_duckdb/medication/norepinephrine_equivalent_dose.sql new file mode 100644 index 000000000..65b027e36 --- /dev/null +++ b/mimic-iv/concepts_duckdb/medication/norepinephrine_equivalent_dose.sql @@ -0,0 +1,17 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.norepinephrine_equivalent_dose; CREATE TABLE mimiciv_derived.norepinephrine_equivalent_dose AS +SELECT + stay_id, + starttime, + endtime, + ROUND( + TRY_CAST(COALESCE(norepinephrine, 0) + COALESCE(epinephrine, 0) + COALESCE(phenylephrine / 10, 0) + COALESCE(dopamine / 100, 0) + COALESCE(vasopressin * 2.5 / 60, 0) AS DECIMAL), + 4 + ) AS norepinephrine_equivalent_dose +FROM mimiciv_derived.vasoactive_agent +WHERE + NOT norepinephrine IS NULL + OR NOT epinephrine IS NULL + OR NOT phenylephrine IS NULL + OR NOT dopamine IS NULL + OR NOT vasopressin IS NULL \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/medication/nsaid.sql b/mimic-iv/concepts_duckdb/medication/nsaid.sql new file mode 100644 index 000000000..146e278d3 --- /dev/null +++ b/mimic-iv/concepts_duckdb/medication/nsaid.sql @@ -0,0 +1,61 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.nsaid; CREATE TABLE mimiciv_derived.nsaid AS +WITH nsaid_drug AS ( + SELECT DISTINCT + drug, + CASE + WHEN UPPER(drug) LIKE '%ASPIRIN%' + THEN 1 + WHEN UPPER(drug) LIKE '%BROMFENAC%' + THEN 1 + WHEN UPPER(drug) LIKE '%CELECOXIB%' + THEN 1 + WHEN UPPER(drug) LIKE '%DICLOFENAC%' + THEN 1 + WHEN UPPER(drug) LIKE '%DIFLUNISAL%' + THEN 1 + WHEN UPPER(drug) LIKE '%ETODOLAC%' + THEN 1 + WHEN UPPER(drug) LIKE '%FENOPROFEN%' + THEN 1 + WHEN UPPER(drug) LIKE '%FLURBIPROFEN%' + THEN 1 + WHEN UPPER(drug) LIKE '%IBUPROFEN%' + THEN 1 + WHEN UPPER(drug) LIKE '%INDOMETHACIN%' + THEN 1 + WHEN UPPER(drug) LIKE '%KETOPROFEN%' + THEN 1 + WHEN UPPER(drug) LIKE '%MEFENAMIC ACID%' + THEN 1 + WHEN UPPER(drug) LIKE '%MELOXICAM%' + THEN 1 + WHEN UPPER(drug) LIKE '%NABUMETONE%' + THEN 1 + WHEN UPPER(drug) LIKE '%NAPROXEN%' + THEN 1 + WHEN UPPER(drug) LIKE '%NEPAFENAC%' + THEN 1 + WHEN UPPER(drug) LIKE '%OXAPROZIN%' + THEN 1 + WHEN UPPER(drug) LIKE '%PIROXICAM%' + THEN 1 + WHEN UPPER(drug) LIKE '%SULINDAC%' + THEN 1 + WHEN UPPER(drug) LIKE '%TOLMETIN%' + THEN 1 + ELSE 0 + END AS nsaid + FROM mimiciv_hosp.prescriptions +) +SELECT + pr.subject_id, + pr.hadm_id, + pr.drug AS nsaid, + pr.starttime, + pr.stoptime +FROM mimiciv_hosp.prescriptions AS pr +INNER JOIN nsaid_drug + ON pr.drug = nsaid_drug.drug +WHERE + nsaid_drug.nsaid = 1 \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/medication/phenylephrine.sql b/mimic-iv/concepts_duckdb/medication/phenylephrine.sql new file mode 100644 index 000000000..f2049a01c --- /dev/null +++ b/mimic-iv/concepts_duckdb/medication/phenylephrine.sql @@ -0,0 +1,12 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.phenylephrine; CREATE TABLE mimiciv_derived.phenylephrine AS +SELECT + stay_id, + linkorderid, + CASE WHEN rateuom = 'mcg/min' THEN rate / patientweight ELSE rate END AS vaso_rate, + amount AS vaso_amount, + starttime, + endtime +FROM mimiciv_icu.inputevents +WHERE + itemid = 221749 \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/medication/vasoactive_agent.sql b/mimic-iv/concepts_duckdb/medication/vasoactive_agent.sql new file mode 100644 index 000000000..4e7e0c44a --- /dev/null +++ b/mimic-iv/concepts_duckdb/medication/vasoactive_agent.sql @@ -0,0 +1,107 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.vasoactive_agent; CREATE TABLE mimiciv_derived.vasoactive_agent AS +WITH tm AS ( + SELECT + stay_id, + starttime AS vasotime + FROM mimiciv_derived.dobutamine + UNION + SELECT + stay_id, + starttime AS vasotime + FROM mimiciv_derived.dopamine + UNION + SELECT + stay_id, + starttime AS vasotime + FROM mimiciv_derived.epinephrine + UNION + SELECT + stay_id, + starttime AS vasotime + FROM mimiciv_derived.norepinephrine + UNION + SELECT + stay_id, + starttime AS vasotime + FROM mimiciv_derived.phenylephrine + UNION + SELECT + stay_id, + starttime AS vasotime + FROM mimiciv_derived.vasopressin + UNION + SELECT + stay_id, + starttime AS vasotime + FROM mimiciv_derived.milrinone + UNION + SELECT + stay_id, + endtime AS vasotime + FROM mimiciv_derived.dobutamine + UNION + SELECT + stay_id, + endtime AS vasotime + FROM mimiciv_derived.dopamine + UNION + SELECT + stay_id, + endtime AS vasotime + FROM mimiciv_derived.epinephrine + UNION + SELECT + stay_id, + endtime AS vasotime + FROM mimiciv_derived.norepinephrine + UNION + SELECT + stay_id, + endtime AS vasotime + FROM mimiciv_derived.phenylephrine + UNION + SELECT + stay_id, + endtime AS vasotime + FROM mimiciv_derived.vasopressin + UNION + SELECT + stay_id, + endtime AS vasotime + FROM mimiciv_derived.milrinone +), tm_lag AS ( + SELECT + stay_id, + vasotime AS starttime, + LEAD(vasotime, 1) OVER (PARTITION BY stay_id ORDER BY vasotime NULLS FIRST) AS endtime + FROM tm +) +SELECT + t.stay_id, + t.starttime, + t.endtime, + dop.vaso_rate AS dopamine, + epi.vaso_rate AS epinephrine, + nor.vaso_rate AS norepinephrine, + phe.vaso_rate AS phenylephrine, + vas.vaso_rate AS vasopressin, + dob.vaso_rate AS dobutamine, + mil.vaso_rate AS milrinone +FROM tm_lag AS t +LEFT JOIN mimiciv_derived.dobutamine AS dob + ON t.stay_id = dob.stay_id AND t.starttime >= dob.starttime AND t.endtime <= dob.endtime +LEFT JOIN mimiciv_derived.dopamine AS dop + ON t.stay_id = dop.stay_id AND t.starttime >= dop.starttime AND t.endtime <= dop.endtime +LEFT JOIN mimiciv_derived.epinephrine AS epi + ON t.stay_id = epi.stay_id AND t.starttime >= epi.starttime AND t.endtime <= epi.endtime +LEFT JOIN mimiciv_derived.norepinephrine AS nor + ON t.stay_id = nor.stay_id AND t.starttime >= nor.starttime AND t.endtime <= nor.endtime +LEFT JOIN mimiciv_derived.phenylephrine AS phe + ON t.stay_id = phe.stay_id AND t.starttime >= phe.starttime AND t.endtime <= phe.endtime +LEFT JOIN mimiciv_derived.vasopressin AS vas + ON t.stay_id = vas.stay_id AND t.starttime >= vas.starttime AND t.endtime <= vas.endtime +LEFT JOIN mimiciv_derived.milrinone AS mil + ON t.stay_id = mil.stay_id AND t.starttime >= mil.starttime AND t.endtime <= mil.endtime +WHERE + NOT t.endtime IS NULL \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/medication/vasopressin.sql b/mimic-iv/concepts_duckdb/medication/vasopressin.sql new file mode 100644 index 000000000..6506c782d --- /dev/null +++ b/mimic-iv/concepts_duckdb/medication/vasopressin.sql @@ -0,0 +1,12 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.vasopressin; CREATE TABLE mimiciv_derived.vasopressin AS +SELECT + stay_id, + linkorderid, + CASE WHEN rateuom = 'units/min' THEN rate * 60.0 ELSE rate END AS vaso_rate, + amount AS vaso_amount, + starttime, + endtime +FROM mimiciv_icu.inputevents +WHERE + itemid = 222315 \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/organfailure/kdigo_creatinine.sql b/mimic-iv/concepts_duckdb/organfailure/kdigo_creatinine.sql new file mode 100644 index 000000000..281947719 --- /dev/null +++ b/mimic-iv/concepts_duckdb/organfailure/kdigo_creatinine.sql @@ -0,0 +1,59 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.kdigo_creatinine; CREATE TABLE mimiciv_derived.kdigo_creatinine AS +WITH cr AS ( + SELECT + ie.hadm_id, + ie.stay_id, + le.charttime, + AVG(le.valuenum) AS creat + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_hosp.labevents AS le + ON ie.subject_id = le.subject_id + AND le.itemid = 50912 + AND NOT le.valuenum IS NULL + AND le.valuenum <= 150 + AND le.charttime >= ie.intime - INTERVAL '7' DAY + AND le.charttime <= ie.outtime + GROUP BY + ie.hadm_id, + ie.stay_id, + le.charttime +), cr48 AS ( + SELECT + cr.stay_id, + cr.charttime, + MIN(cr48.creat) AS creat_low_past_48hr + FROM cr + LEFT JOIN cr AS cr48 + ON cr.stay_id = cr48.stay_id + AND cr48.charttime < cr.charttime + AND cr48.charttime >= cr.charttime - INTERVAL '48' HOUR + GROUP BY + cr.stay_id, + cr.charttime +), cr7 AS ( + SELECT + cr.stay_id, + cr.charttime, + MIN(cr7.creat) AS creat_low_past_7day + FROM cr + LEFT JOIN cr AS cr7 + ON cr.stay_id = cr7.stay_id + AND cr7.charttime < cr.charttime + AND cr7.charttime >= cr.charttime - INTERVAL '7' DAY + GROUP BY + cr.stay_id, + cr.charttime +) +SELECT + cr.hadm_id, + cr.stay_id, + cr.charttime, + cr.creat, + cr48.creat_low_past_48hr, + cr7.creat_low_past_7day +FROM cr +LEFT JOIN cr48 + ON cr.stay_id = cr48.stay_id AND cr.charttime = cr48.charttime +LEFT JOIN cr7 + ON cr.stay_id = cr7.stay_id AND cr.charttime = cr7.charttime \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/organfailure/kdigo_stages.sql b/mimic-iv/concepts_duckdb/organfailure/kdigo_stages.sql new file mode 100644 index 000000000..e644a487b --- /dev/null +++ b/mimic-iv/concepts_duckdb/organfailure/kdigo_stages.sql @@ -0,0 +1,121 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.kdigo_stages; CREATE TABLE mimiciv_derived.kdigo_stages AS +WITH cr_stg AS ( + SELECT + cr.stay_id, + cr.charttime, + cr.creat_low_past_7day, + cr.creat_low_past_48hr, + cr.creat, + CASE + WHEN cr.creat >= ( + cr.creat_low_past_7day * 3.0 + ) + THEN 3 + WHEN cr.creat >= 4 + AND ( + cr.creat_low_past_48hr <= 3.7 OR cr.creat >= ( + 1.5 * cr.creat_low_past_7day + ) + ) + THEN 3 + WHEN cr.creat >= ( + cr.creat_low_past_7day * 2.0 + ) + THEN 2 + WHEN cr.creat >= ( + cr.creat_low_past_48hr + 0.3 + ) + THEN 1 + WHEN cr.creat >= ( + cr.creat_low_past_7day * 1.5 + ) + THEN 1 + ELSE 0 + END AS aki_stage_creat + FROM mimiciv_derived.kdigo_creatinine AS cr +), uo_stg AS ( + SELECT + uo.stay_id, + uo.charttime, + uo.weight, + uo.uo_rt_6hr, + uo.uo_rt_12hr, + uo.uo_rt_24hr, + CASE + WHEN uo.uo_rt_6hr IS NULL + THEN NULL + WHEN uo.charttime <= ie.intime + INTERVAL '6' HOUR + THEN 0 + WHEN uo.uo_tm_24hr >= 24 AND uo.uo_rt_24hr < 0.3 + THEN 3 + WHEN uo.uo_tm_12hr >= 12 AND uo.uo_rt_12hr = 0 + THEN 3 + WHEN uo.uo_tm_12hr >= 12 AND uo.uo_rt_12hr < 0.5 + THEN 2 + WHEN uo.uo_tm_6hr >= 6 AND uo.uo_rt_6hr < 0.5 + THEN 1 + ELSE 0 + END AS aki_stage_uo + FROM mimiciv_derived.kdigo_uo AS uo + INNER JOIN mimiciv_icu.icustays AS ie + ON uo.stay_id = ie.stay_id +), crrt_stg AS ( + SELECT + stay_id, + charttime, + CASE WHEN NOT charttime IS NULL THEN 3 ELSE NULL END AS aki_stage_crrt + FROM mimiciv_derived.crrt + WHERE + NOT crrt_mode IS NULL +), tm_stg AS ( + SELECT + stay_id, + charttime + FROM cr_stg + UNION + SELECT + stay_id, + charttime + FROM uo_stg + UNION + SELECT + stay_id, + charttime + FROM crrt_stg +) +SELECT + ie.subject_id, + ie.hadm_id, + ie.stay_id, + tm.charttime, + cr.creat_low_past_7day, + cr.creat_low_past_48hr, + cr.creat, + cr.aki_stage_creat, + uo.uo_rt_6hr, + uo.uo_rt_12hr, + uo.uo_rt_24hr, + uo.aki_stage_uo, + crrt.aki_stage_crrt, + GREATEST( + COALESCE(cr.aki_stage_creat, 0), + COALESCE(uo.aki_stage_uo, 0), + COALESCE(crrt.aki_stage_crrt, 0) + ) AS aki_stage, + MAX( + GREATEST( + COALESCE(cr.aki_stage_creat, 0), + COALESCE(uo.aki_stage_uo, 0), + COALESCE(crrt.aki_stage_crrt, 0) + ) + ) OVER (PARTITION BY ie.subject_id ORDER BY DATE_DIFF('microseconds', ie.intime, tm.charttime)/1000000.0 NULLS FIRST RANGE BETWEEN 21600 PRECEDING AND CURRENT ROW) AS aki_stage_smoothed +FROM mimiciv_icu.icustays AS ie +LEFT JOIN tm_stg AS tm + ON ie.stay_id = tm.stay_id +LEFT JOIN cr_stg AS cr + ON ie.stay_id = cr.stay_id AND tm.charttime = cr.charttime +LEFT JOIN uo_stg AS uo + ON ie.stay_id = uo.stay_id AND tm.charttime = uo.charttime +LEFT JOIN crrt_stg AS crrt + ON ie.stay_id = crrt.stay_id AND tm.charttime = crrt.charttime \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/organfailure/kdigo_uo.sql b/mimic-iv/concepts_duckdb/organfailure/kdigo_uo.sql new file mode 100644 index 000000000..7737fcb07 --- /dev/null +++ b/mimic-iv/concepts_duckdb/organfailure/kdigo_uo.sql @@ -0,0 +1,63 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.kdigo_uo; CREATE TABLE mimiciv_derived.kdigo_uo AS +WITH uo_stg1 AS ( + SELECT + ie.stay_id, + uo.charttime, + TRY_CAST(DATE_DIFF('microseconds', intime, charttime)/1000000.0 AS INT) AS seconds_since_admit, + COALESCE( + DATE_DIFF('microseconds', LAG(charttime) OVER (PARTITION BY ie.stay_id ORDER BY charttime NULLS FIRST), charttime)/1000000.0 / 3600.0, + 1 + ) AS hours_since_previous_row, + urineoutput + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_derived.urine_output AS uo + ON ie.stay_id = uo.stay_id +), uo_stg2 AS ( + SELECT + stay_id, + charttime, + hours_since_previous_row, + urineoutput, + SUM(urineoutput) OVER (PARTITION BY stay_id ORDER BY seconds_since_admit NULLS FIRST RANGE BETWEEN 21600 PRECEDING AND CURRENT ROW) AS urineoutput_6hr, + SUM(urineoutput) OVER (PARTITION BY stay_id ORDER BY seconds_since_admit NULLS FIRST RANGE BETWEEN 43200 PRECEDING AND CURRENT ROW) AS urineoutput_12hr, + SUM(urineoutput) OVER (PARTITION BY stay_id ORDER BY seconds_since_admit NULLS FIRST RANGE BETWEEN 86400 PRECEDING AND CURRENT ROW) AS urineoutput_24hr, + SUM(hours_since_previous_row) OVER (PARTITION BY stay_id ORDER BY seconds_since_admit NULLS FIRST RANGE BETWEEN 21600 PRECEDING AND CURRENT ROW) AS uo_tm_6hr, + SUM(hours_since_previous_row) OVER (PARTITION BY stay_id ORDER BY seconds_since_admit NULLS FIRST RANGE BETWEEN 43200 PRECEDING AND CURRENT ROW) AS uo_tm_12hr, + SUM(hours_since_previous_row) OVER (PARTITION BY stay_id ORDER BY seconds_since_admit NULLS FIRST RANGE BETWEEN 86400 PRECEDING AND CURRENT ROW) AS uo_tm_24hr + FROM uo_stg1 +) +SELECT + ur.stay_id, + ur.charttime, + wd.weight, + ur.urineoutput_6hr, + ur.urineoutput_12hr, + ur.urineoutput_24hr, + CASE + WHEN uo_tm_6hr >= 6 AND uo_tm_6hr < 12 + THEN ROUND(TRY_CAST(( + ur.urineoutput_6hr / wd.weight / uo_tm_6hr + ) AS DECIMAL), 4) + ELSE NULL + END AS uo_rt_6hr, + CASE + WHEN uo_tm_12hr >= 12 + THEN ROUND(TRY_CAST(( + ur.urineoutput_12hr / wd.weight / uo_tm_12hr + ) AS DECIMAL), 4) + ELSE NULL + END AS uo_rt_12hr, + CASE + WHEN uo_tm_24hr >= 24 + THEN ROUND(TRY_CAST(( + ur.urineoutput_24hr / wd.weight / uo_tm_24hr + ) AS DECIMAL), 4) + ELSE NULL + END AS uo_rt_24hr, + uo_tm_6hr, + uo_tm_12hr, + uo_tm_24hr +FROM uo_stg2 AS ur +LEFT JOIN mimiciv_derived.weight_durations AS wd + ON ur.stay_id = wd.stay_id AND ur.charttime >= wd.starttime AND ur.charttime < wd.endtime \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/organfailure/meld.sql b/mimic-iv/concepts_duckdb/organfailure/meld.sql new file mode 100644 index 000000000..357be4102 --- /dev/null +++ b/mimic-iv/concepts_duckdb/organfailure/meld.sql @@ -0,0 +1,103 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.meld; CREATE TABLE mimiciv_derived.meld AS +WITH cohort AS ( + SELECT + ie.subject_id, + ie.hadm_id, + ie.stay_id, + ie.intime, + ie.outtime, + labs.creatinine_max, + labs.bilirubin_total_max, + labs.inr_max, + labs.sodium_min, + r.dialysis_present AS rrt + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.first_day_lab AS labs + ON ie.stay_id = labs.stay_id + LEFT JOIN mimiciv_derived.first_day_rrt AS r + ON ie.stay_id = r.stay_id +), score AS ( + SELECT + subject_id, + hadm_id, + stay_id, + rrt, + creatinine_max, + bilirubin_total_max, + inr_max, + sodium_min, + CASE + WHEN sodium_min IS NULL + THEN 0.0 + WHEN sodium_min > 137 + THEN 0.0 + WHEN sodium_min < 125 + THEN 12.0 + ELSE 137.0 - sodium_min + END AS sodium_score, + CASE + WHEN rrt = 1 OR creatinine_max > 4.0 + THEN ( + 0.957 * LN(4) + ) + WHEN creatinine_max < 1 + THEN ( + 0.957 * LN(1) + ) + ELSE 0.957 * COALESCE(LN(creatinine_max), LN(1)) + END AS creatinine_score, + CASE + WHEN bilirubin_total_max < 1 + THEN 0.378 * LN(1) + ELSE 0.378 * COALESCE(LN(bilirubin_total_max), LN(1)) + END AS bilirubin_score, + CASE + WHEN inr_max < 1 + THEN ( + 1.120 * LN(1) + 0.643 + ) + ELSE ( + 1.120 * COALESCE(LN(inr_max), LN(1)) + 0.643 + ) + END AS inr_score + FROM cohort +), score2 AS ( + SELECT + subject_id, + hadm_id, + stay_id, + rrt, + creatinine_max, + bilirubin_total_max, + inr_max, + sodium_min, + creatinine_score, + sodium_score, + bilirubin_score, + inr_score, + CASE + WHEN ( + creatinine_score + bilirubin_score + inr_score + ) > 4 + THEN 40.0 + ELSE ROUND(TRY_CAST(creatinine_score + bilirubin_score + inr_score AS DECIMAL), 1) * 10 + END AS meld_initial + FROM score +) +SELECT + subject_id, + hadm_id, + stay_id, + meld_initial, + CASE + WHEN meld_initial > 11 + THEN meld_initial + 1.32 * sodium_score - 0.033 * meld_initial * sodium_score + ELSE meld_initial + END AS meld, + rrt, + creatinine_max, + bilirubin_total_max, + inr_max, + sodium_min +FROM score2 \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/score/apsiii.sql b/mimic-iv/concepts_duckdb/score/apsiii.sql new file mode 100644 index 000000000..6f56eefc3 --- /dev/null +++ b/mimic-iv/concepts_duckdb/score/apsiii.sql @@ -0,0 +1,866 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.apsiii; CREATE TABLE mimiciv_derived.apsiii AS +WITH pa AS ( + SELECT + ie.stay_id, + bg.charttime, + po2 AS pao2, + ROW_NUMBER() OVER (PARTITION BY ie.stay_id ORDER BY bg.po2 DESC) AS rn + FROM mimiciv_derived.bg AS bg + INNER JOIN mimiciv_icu.icustays AS ie + ON bg.hadm_id = ie.hadm_id AND bg.charttime >= ie.intime AND bg.charttime < ie.outtime + LEFT JOIN mimiciv_derived.ventilation AS vd + ON ie.stay_id = vd.stay_id + AND bg.charttime >= vd.starttime + AND bg.charttime <= vd.endtime + AND vd.ventilation_status = 'InvasiveVent' + WHERE + vd.stay_id IS NULL + AND COALESCE(fio2, fio2_chartevents, 21) < 50 + AND NOT bg.po2 IS NULL + AND bg.specimen = 'ART.' +), aa AS ( + SELECT + ie.stay_id, + bg.charttime, + bg.aado2, + ROW_NUMBER() OVER (PARTITION BY ie.stay_id ORDER BY bg.aado2 DESC) AS rn + FROM mimiciv_derived.bg AS bg + INNER JOIN mimiciv_icu.icustays AS ie + ON bg.hadm_id = ie.hadm_id AND bg.charttime >= ie.intime AND bg.charttime < ie.outtime + INNER JOIN mimiciv_derived.ventilation AS vd + ON ie.stay_id = vd.stay_id + AND bg.charttime >= vd.starttime + AND bg.charttime <= vd.endtime + AND vd.ventilation_status = 'InvasiveVent' + WHERE + NOT vd.stay_id IS NULL + AND COALESCE(fio2, fio2_chartevents) >= 50 + AND NOT bg.aado2 IS NULL + AND bg.specimen = 'ART.' +), acidbase AS ( + SELECT + ie.stay_id, + ph, + pco2 AS paco2, + CASE + WHEN ph IS NULL OR pco2 IS NULL + THEN NULL + WHEN ph < 7.20 + THEN CASE WHEN pco2 < 50 THEN 12 ELSE 4 END + WHEN ph < 7.30 + THEN CASE WHEN pco2 < 30 THEN 9 WHEN pco2 < 40 THEN 6 WHEN pco2 < 50 THEN 3 ELSE 2 END + WHEN ph < 7.35 + THEN CASE WHEN pco2 < 30 THEN 9 WHEN pco2 < 45 THEN 0 ELSE 1 END + WHEN ph < 7.45 + THEN CASE WHEN pco2 < 30 THEN 5 WHEN pco2 < 45 THEN 0 ELSE 1 END + WHEN ph < 7.50 + THEN CASE WHEN pco2 < 30 THEN 5 WHEN pco2 < 35 THEN 0 WHEN pco2 < 45 THEN 2 ELSE 12 END + WHEN ph < 7.60 + THEN CASE WHEN pco2 < 40 THEN 3 ELSE 12 END + ELSE CASE WHEN pco2 < 25 THEN 0 WHEN pco2 < 40 THEN 3 ELSE 12 END + END AS acidbase_score + FROM mimiciv_derived.bg AS bg + INNER JOIN mimiciv_icu.icustays AS ie + ON bg.hadm_id = ie.hadm_id AND bg.charttime >= ie.intime AND bg.charttime < ie.outtime + WHERE + NOT ph IS NULL AND NOT pco2 IS NULL AND bg.specimen = 'ART.' +), acidbase_max AS ( + SELECT + stay_id, + acidbase_score, + ph, + paco2, + ROW_NUMBER() OVER (PARTITION BY stay_id ORDER BY acidbase_score DESC) AS acidbase_rn + FROM acidbase +), arf AS ( + SELECT + ie.stay_id, + CASE + WHEN labs.creatinine_max >= 1.5 AND uo.urineoutput < 410 AND icd.ckd = 0 + THEN 1 + ELSE 0 + END AS arf + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.first_day_urine_output AS uo + ON ie.stay_id = uo.stay_id + LEFT JOIN mimiciv_derived.first_day_lab AS labs + ON ie.stay_id = labs.stay_id + LEFT JOIN ( + SELECT + hadm_id, + MAX( + CASE + WHEN icd_version = 9 AND SUBSTR(icd_code, 1, 4) IN ('5854', '5855', '5856') + THEN 1 + WHEN icd_version = 10 AND SUBSTR(icd_code, 1, 4) IN ('N184', 'N185', 'N186') + THEN 1 + ELSE 0 + END + ) AS ckd + FROM mimiciv_hosp.diagnoses_icd + GROUP BY + hadm_id + ) AS icd + ON ie.hadm_id = icd.hadm_id +), vent AS ( + SELECT + ie.stay_id, + MAX(CASE WHEN NOT v.stay_id IS NULL THEN 1 ELSE 0 END) AS vent + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.ventilation AS v + ON ie.stay_id = v.stay_id + AND v.ventilation_status = 'InvasiveVent' + AND ( + ( + v.starttime >= ie.intime AND v.starttime <= ie.intime + INTERVAL '1' DAY + ) + OR ( + v.endtime >= ie.intime AND v.endtime <= ie.intime + INTERVAL '1' DAY + ) + OR ( + v.starttime <= ie.intime AND v.endtime >= ie.intime + INTERVAL '1' DAY + ) + ) + GROUP BY + ie.stay_id +), cohort AS ( + SELECT + ie.subject_id, + ie.hadm_id, + ie.stay_id, + ie.intime, + ie.outtime, + vital.heart_rate_min, + vital.heart_rate_max, + vital.mbp_min, + vital.mbp_max, + vital.temperature_min, + vital.temperature_max, + vital.resp_rate_min, + vital.resp_rate_max, + pa.pao2, + aa.aado2, + ab.ph, + ab.paco2, + ab.acidbase_score, + labs.hematocrit_min, + labs.hematocrit_max, + labs.wbc_min, + labs.wbc_max, + labs.creatinine_min, + labs.creatinine_max, + labs.bun_min, + labs.bun_max, + labs.sodium_min, + labs.sodium_max, + labs.albumin_min, + labs.albumin_max, + labs.bilirubin_total_min AS bilirubin_min, + labs.bilirubin_total_max AS bilirubin_max, + CASE + WHEN labs.glucose_max IS NULL AND vital.glucose_max IS NULL + THEN NULL + WHEN labs.glucose_max IS NULL OR vital.glucose_max > labs.glucose_max + THEN vital.glucose_max + WHEN vital.glucose_max IS NULL OR labs.glucose_max > vital.glucose_max + THEN labs.glucose_max + ELSE labs.glucose_max + END AS glucose_max, + CASE + WHEN labs.glucose_min IS NULL AND vital.glucose_min IS NULL + THEN NULL + WHEN labs.glucose_min IS NULL OR vital.glucose_min < labs.glucose_min + THEN vital.glucose_min + WHEN vital.glucose_min IS NULL OR labs.glucose_min < vital.glucose_min + THEN labs.glucose_min + ELSE labs.glucose_min + END AS glucose_min, + vent.vent, + uo.urineoutput, + gcs.gcs_min AS mingcs, + gcs.gcs_motor, + gcs.gcs_verbal, + gcs.gcs_eyes, + gcs.gcs_unable, + arf.arf AS arf + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_hosp.admissions AS adm + ON ie.hadm_id = adm.hadm_id + INNER JOIN mimiciv_hosp.patients AS pat + ON ie.subject_id = pat.subject_id + LEFT JOIN pa + ON ie.stay_id = pa.stay_id AND pa.rn = 1 + LEFT JOIN aa + ON ie.stay_id = aa.stay_id AND aa.rn = 1 + LEFT JOIN acidbase_max AS ab + ON ie.stay_id = ab.stay_id AND ab.acidbase_rn = 1 + LEFT JOIN arf + ON ie.stay_id = arf.stay_id + LEFT JOIN vent + ON ie.stay_id = vent.stay_id + LEFT JOIN mimiciv_derived.first_day_gcs AS gcs + ON ie.stay_id = gcs.stay_id + LEFT JOIN mimiciv_derived.first_day_vitalsign AS vital + ON ie.stay_id = vital.stay_id + LEFT JOIN mimiciv_derived.first_day_urine_output AS uo + ON ie.stay_id = uo.stay_id + LEFT JOIN mimiciv_derived.first_day_lab AS labs + ON ie.stay_id = labs.stay_id +), score_min AS ( + SELECT + cohort.subject_id, + cohort.hadm_id, + cohort.stay_id, + CASE + WHEN heart_rate_min IS NULL + THEN NULL + WHEN heart_rate_min < 40 + THEN 8 + WHEN heart_rate_min < 50 + THEN 5 + WHEN heart_rate_min < 100 + THEN 0 + WHEN heart_rate_min < 110 + THEN 1 + WHEN heart_rate_min < 120 + THEN 5 + WHEN heart_rate_min < 140 + THEN 7 + WHEN heart_rate_min < 155 + THEN 13 + WHEN heart_rate_min >= 155 + THEN 17 + END AS hr_score, + CASE + WHEN mbp_min IS NULL + THEN NULL + WHEN mbp_min < 40 + THEN 23 + WHEN mbp_min < 60 + THEN 15 + WHEN mbp_min < 70 + THEN 7 + WHEN mbp_min < 80 + THEN 6 + WHEN mbp_min < 100 + THEN 0 + WHEN mbp_min < 120 + THEN 4 + WHEN mbp_min < 130 + THEN 7 + WHEN mbp_min < 140 + THEN 9 + WHEN mbp_min >= 140 + THEN 10 + END AS mbp_score, + CASE + WHEN temperature_min IS NULL + THEN NULL + WHEN temperature_min < 33.0 + THEN 20 + WHEN temperature_min < 33.5 + THEN 16 + WHEN temperature_min < 34.0 + THEN 13 + WHEN temperature_min < 35.0 + THEN 8 + WHEN temperature_min < 36.0 + THEN 2 + WHEN temperature_min < 40.0 + THEN 0 + WHEN temperature_min >= 40.0 + THEN 4 + END AS temp_score, + CASE + WHEN resp_rate_min IS NULL + THEN NULL + WHEN vent = 1 AND resp_rate_min < 14 + THEN 0 + WHEN resp_rate_min < 6 + THEN 17 + WHEN resp_rate_min < 12 + THEN 8 + WHEN resp_rate_min < 14 + THEN 7 + WHEN resp_rate_min < 25 + THEN 0 + WHEN resp_rate_min < 35 + THEN 6 + WHEN resp_rate_min < 40 + THEN 9 + WHEN resp_rate_min < 50 + THEN 11 + WHEN resp_rate_min >= 50 + THEN 18 + END AS resp_rate_score, + CASE + WHEN hematocrit_min IS NULL + THEN NULL + WHEN hematocrit_min < 41.0 + THEN 3 + WHEN hematocrit_min < 50.0 + THEN 0 + WHEN hematocrit_min >= 50.0 + THEN 3 + END AS hematocrit_score, + CASE + WHEN wbc_min IS NULL + THEN NULL + WHEN wbc_min < 1.0 + THEN 19 + WHEN wbc_min < 3.0 + THEN 5 + WHEN wbc_min < 20.0 + THEN 0 + WHEN wbc_min < 25.0 + THEN 1 + WHEN wbc_min >= 25.0 + THEN 5 + END AS wbc_score, + CASE + WHEN creatinine_min IS NULL + THEN NULL + WHEN arf = 1 AND creatinine_min < 1.5 + THEN 0 + WHEN arf = 1 AND creatinine_min >= 1.5 + THEN 10 + WHEN creatinine_min < 0.5 + THEN 3 + WHEN creatinine_min < 1.5 + THEN 0 + WHEN creatinine_min < 1.95 + THEN 4 + WHEN creatinine_min >= 1.95 + THEN 7 + END AS creatinine_score, + CASE + WHEN bun_min IS NULL + THEN NULL + WHEN bun_min < 17.0 + THEN 0 + WHEN bun_min < 20.0 + THEN 2 + WHEN bun_min < 40.0 + THEN 7 + WHEN bun_min < 80.0 + THEN 11 + WHEN bun_min >= 80.0 + THEN 12 + END AS bun_score, + CASE + WHEN sodium_min IS NULL + THEN NULL + WHEN sodium_min < 120 + THEN 3 + WHEN sodium_min < 135 + THEN 2 + WHEN sodium_min < 155 + THEN 0 + WHEN sodium_min >= 155 + THEN 4 + END AS sodium_score, + CASE + WHEN albumin_min IS NULL + THEN NULL + WHEN albumin_min < 2.0 + THEN 11 + WHEN albumin_min < 2.5 + THEN 6 + WHEN albumin_min < 4.5 + THEN 0 + WHEN albumin_min >= 4.5 + THEN 4 + END AS albumin_score, + CASE + WHEN bilirubin_min IS NULL + THEN NULL + WHEN bilirubin_min < 2.0 + THEN 0 + WHEN bilirubin_min < 3.0 + THEN 5 + WHEN bilirubin_min < 5.0 + THEN 6 + WHEN bilirubin_min < 8.0 + THEN 8 + WHEN bilirubin_min >= 8.0 + THEN 16 + END AS bilirubin_score, + CASE + WHEN glucose_min IS NULL + THEN NULL + WHEN glucose_min < 40 + THEN 8 + WHEN glucose_min < 60 + THEN 9 + WHEN glucose_min < 200 + THEN 0 + WHEN glucose_min < 350 + THEN 3 + WHEN glucose_min >= 350 + THEN 5 + END AS glucose_score + FROM cohort +), score_max AS ( + SELECT + cohort.subject_id, + cohort.hadm_id, + cohort.stay_id, + CASE + WHEN heart_rate_max IS NULL + THEN NULL + WHEN heart_rate_max < 40 + THEN 8 + WHEN heart_rate_max < 50 + THEN 5 + WHEN heart_rate_max < 100 + THEN 0 + WHEN heart_rate_max < 110 + THEN 1 + WHEN heart_rate_max < 120 + THEN 5 + WHEN heart_rate_max < 140 + THEN 7 + WHEN heart_rate_max < 155 + THEN 13 + WHEN heart_rate_max >= 155 + THEN 17 + END AS hr_score, + CASE + WHEN mbp_max IS NULL + THEN NULL + WHEN mbp_max < 40 + THEN 23 + WHEN mbp_max < 60 + THEN 15 + WHEN mbp_max < 70 + THEN 7 + WHEN mbp_max < 80 + THEN 6 + WHEN mbp_max < 100 + THEN 0 + WHEN mbp_max < 120 + THEN 4 + WHEN mbp_max < 130 + THEN 7 + WHEN mbp_max < 140 + THEN 9 + WHEN mbp_max >= 140 + THEN 10 + END AS mbp_score, + CASE + WHEN temperature_max IS NULL + THEN NULL + WHEN temperature_max < 33.0 + THEN 20 + WHEN temperature_max < 33.5 + THEN 16 + WHEN temperature_max < 34.0 + THEN 13 + WHEN temperature_max < 35.0 + THEN 8 + WHEN temperature_max < 36.0 + THEN 2 + WHEN temperature_max < 40.0 + THEN 0 + WHEN temperature_max >= 40.0 + THEN 4 + END AS temp_score, + CASE + WHEN resp_rate_max IS NULL + THEN NULL + WHEN vent = 1 AND resp_rate_max < 14 + THEN 0 + WHEN resp_rate_max < 6 + THEN 17 + WHEN resp_rate_max < 12 + THEN 8 + WHEN resp_rate_max < 14 + THEN 7 + WHEN resp_rate_max < 25 + THEN 0 + WHEN resp_rate_max < 35 + THEN 6 + WHEN resp_rate_max < 40 + THEN 9 + WHEN resp_rate_max < 50 + THEN 11 + WHEN resp_rate_max >= 50 + THEN 18 + END AS resp_rate_score, + CASE + WHEN hematocrit_max IS NULL + THEN NULL + WHEN hematocrit_max < 41.0 + THEN 3 + WHEN hematocrit_max < 50.0 + THEN 0 + WHEN hematocrit_max >= 50.0 + THEN 3 + END AS hematocrit_score, + CASE + WHEN wbc_max IS NULL + THEN NULL + WHEN wbc_max < 1.0 + THEN 19 + WHEN wbc_max < 3.0 + THEN 5 + WHEN wbc_max < 20.0 + THEN 0 + WHEN wbc_max < 25.0 + THEN 1 + WHEN wbc_max >= 25.0 + THEN 5 + END AS wbc_score, + CASE + WHEN creatinine_max IS NULL + THEN NULL + WHEN arf = 1 AND creatinine_max < 1.5 + THEN 0 + WHEN arf = 1 AND creatinine_max >= 1.5 + THEN 10 + WHEN creatinine_max < 0.5 + THEN 3 + WHEN creatinine_max < 1.5 + THEN 0 + WHEN creatinine_max < 1.95 + THEN 4 + WHEN creatinine_max >= 1.95 + THEN 7 + END AS creatinine_score, + CASE + WHEN bun_max IS NULL + THEN NULL + WHEN bun_max < 17.0 + THEN 0 + WHEN bun_max < 20.0 + THEN 2 + WHEN bun_max < 40.0 + THEN 7 + WHEN bun_max < 80.0 + THEN 11 + WHEN bun_max >= 80.0 + THEN 12 + END AS bun_score, + CASE + WHEN sodium_max IS NULL + THEN NULL + WHEN sodium_max < 120 + THEN 3 + WHEN sodium_max < 135 + THEN 2 + WHEN sodium_max < 155 + THEN 0 + WHEN sodium_max >= 155 + THEN 4 + END AS sodium_score, + CASE + WHEN albumin_max IS NULL + THEN NULL + WHEN albumin_max < 2.0 + THEN 11 + WHEN albumin_max < 2.5 + THEN 6 + WHEN albumin_max < 4.5 + THEN 0 + WHEN albumin_max >= 4.5 + THEN 4 + END AS albumin_score, + CASE + WHEN bilirubin_max IS NULL + THEN NULL + WHEN bilirubin_max < 2.0 + THEN 0 + WHEN bilirubin_max < 3.0 + THEN 5 + WHEN bilirubin_max < 5.0 + THEN 6 + WHEN bilirubin_max < 8.0 + THEN 8 + WHEN bilirubin_max >= 8.0 + THEN 16 + END AS bilirubin_score, + CASE + WHEN glucose_max IS NULL + THEN NULL + WHEN glucose_max < 40 + THEN 8 + WHEN glucose_max < 60 + THEN 9 + WHEN glucose_max < 200 + THEN 0 + WHEN glucose_max < 350 + THEN 3 + WHEN glucose_max >= 350 + THEN 5 + END AS glucose_score + FROM cohort +), scorecomp AS ( + SELECT + co.*, + CASE + WHEN heart_rate_max IS NULL + THEN NULL + WHEN ABS(heart_rate_max - 75) > ABS(heart_rate_min - 75) + THEN smax.hr_score + WHEN ABS(heart_rate_max - 75) < ABS(heart_rate_min - 75) + THEN smin.hr_score + WHEN ABS(heart_rate_max - 75) = ABS(heart_rate_min - 75) + AND smax.hr_score >= smin.hr_score + THEN smax.hr_score + WHEN ABS(heart_rate_max - 75) = ABS(heart_rate_min - 75) AND smax.hr_score < smin.hr_score + THEN smin.hr_score + END AS hr_score, + CASE + WHEN mbp_max IS NULL + THEN NULL + WHEN ABS(mbp_max - 90) > ABS(mbp_min - 90) + THEN smax.mbp_score + WHEN ABS(mbp_max - 90) < ABS(mbp_min - 90) + THEN smin.mbp_score + WHEN ABS(mbp_max - 90) = ABS(mbp_min - 90) AND smax.mbp_score >= smin.mbp_score + THEN smax.mbp_score + WHEN ABS(mbp_max - 90) = ABS(mbp_min - 90) AND smax.mbp_score < smin.mbp_score + THEN smin.mbp_score + END AS mbp_score, + CASE + WHEN temperature_max IS NULL + THEN NULL + WHEN ABS(temperature_max - 38) > ABS(temperature_min - 38) + THEN smax.temp_score + WHEN ABS(temperature_max - 38) < ABS(temperature_min - 38) + THEN smin.temp_score + WHEN ABS(temperature_max - 38) = ABS(temperature_min - 38) + AND smax.temp_score >= smin.temp_score + THEN smax.temp_score + WHEN ABS(temperature_max - 38) = ABS(temperature_min - 38) + AND smax.temp_score < smin.temp_score + THEN smin.temp_score + END AS temp_score, + CASE + WHEN resp_rate_max IS NULL + THEN NULL + WHEN ABS(resp_rate_max - 19) > ABS(resp_rate_min - 19) + THEN smax.resp_rate_score + WHEN ABS(resp_rate_max - 19) < ABS(resp_rate_min - 19) + THEN smin.resp_rate_score + WHEN ABS(resp_rate_max - 19) = ABS(resp_rate_max - 19) + AND smax.resp_rate_score >= smin.resp_rate_score + THEN smax.resp_rate_score + WHEN ABS(resp_rate_max - 19) = ABS(resp_rate_max - 19) + AND smax.resp_rate_score < smin.resp_rate_score + THEN smin.resp_rate_score + END AS resp_rate_score, + CASE + WHEN hematocrit_max IS NULL + THEN NULL + WHEN ABS(hematocrit_max - 45.5) > ABS(hematocrit_min - 45.5) + THEN smax.hematocrit_score + WHEN ABS(hematocrit_max - 45.5) < ABS(hematocrit_min - 45.5) + THEN smin.hematocrit_score + WHEN ABS(hematocrit_max - 45.5) = ABS(hematocrit_max - 45.5) + AND smax.hematocrit_score >= smin.hematocrit_score + THEN smax.hematocrit_score + WHEN ABS(hematocrit_max - 45.5) = ABS(hematocrit_max - 45.5) + AND smax.hematocrit_score < smin.hematocrit_score + THEN smin.hematocrit_score + END AS hematocrit_score, + CASE + WHEN wbc_max IS NULL + THEN NULL + WHEN ABS(wbc_max - 11.5) > ABS(wbc_min - 11.5) + THEN smax.wbc_score + WHEN ABS(wbc_max - 11.5) < ABS(wbc_min - 11.5) + THEN smin.wbc_score + WHEN ABS(wbc_max - 11.5) = ABS(wbc_max - 11.5) AND smax.wbc_score >= smin.wbc_score + THEN smax.wbc_score + WHEN ABS(wbc_max - 11.5) = ABS(wbc_max - 11.5) AND smax.wbc_score < smin.wbc_score + THEN smin.wbc_score + END AS wbc_score, + CASE + WHEN creatinine_max IS NULL + THEN NULL + WHEN arf = 1 + THEN smax.creatinine_score + WHEN ABS(creatinine_max - 1) > ABS(creatinine_min - 1) + THEN smax.creatinine_score + WHEN ABS(creatinine_max - 1) < ABS(creatinine_min - 1) + THEN smin.creatinine_score + WHEN smax.creatinine_score >= smin.creatinine_score + THEN smax.creatinine_score + WHEN smax.creatinine_score < smin.creatinine_score + THEN smin.creatinine_score + END AS creatinine_score, + CASE WHEN bun_max IS NULL THEN NULL ELSE smax.bun_score END AS bun_score, + CASE + WHEN sodium_max IS NULL + THEN NULL + WHEN ABS(sodium_max - 145.5) > ABS(sodium_min - 145.5) + THEN smax.sodium_score + WHEN ABS(sodium_max - 145.5) < ABS(sodium_min - 145.5) + THEN smin.sodium_score + WHEN ABS(sodium_max - 145.5) = ABS(sodium_max - 145.5) + AND smax.sodium_score >= smin.sodium_score + THEN smax.sodium_score + WHEN ABS(sodium_max - 145.5) = ABS(sodium_max - 145.5) + AND smax.sodium_score < smin.sodium_score + THEN smin.sodium_score + END AS sodium_score, + CASE + WHEN albumin_max IS NULL + THEN NULL + WHEN ABS(albumin_max - 3.5) > ABS(albumin_min - 3.5) + THEN smax.albumin_score + WHEN ABS(albumin_max - 3.5) < ABS(albumin_min - 3.5) + THEN smin.albumin_score + WHEN ABS(albumin_max - 3.5) = ABS(albumin_max - 3.5) + AND smax.albumin_score >= smin.albumin_score + THEN smax.albumin_score + WHEN ABS(albumin_max - 3.5) = ABS(albumin_max - 3.5) + AND smax.albumin_score < smin.albumin_score + THEN smin.albumin_score + END AS albumin_score, + CASE WHEN bilirubin_max IS NULL THEN NULL ELSE smax.bilirubin_score END AS bilirubin_score, + CASE + WHEN glucose_max IS NULL + THEN NULL + WHEN ABS(glucose_max - 130) > ABS(glucose_min - 130) + THEN smax.glucose_score + WHEN ABS(glucose_max - 130) < ABS(glucose_min - 130) + THEN smin.glucose_score + WHEN ABS(glucose_max - 130) = ABS(glucose_max - 130) + AND smax.glucose_score >= smin.glucose_score + THEN smax.glucose_score + WHEN ABS(glucose_max - 130) = ABS(glucose_max - 130) + AND smax.glucose_score < smin.glucose_score + THEN smin.glucose_score + END AS glucose_score, + CASE + WHEN urineoutput IS NULL + THEN NULL + WHEN urineoutput < 400 + THEN 15 + WHEN urineoutput < 600 + THEN 8 + WHEN urineoutput < 900 + THEN 7 + WHEN urineoutput < 1500 + THEN 5 + WHEN urineoutput < 2000 + THEN 4 + WHEN urineoutput < 4000 + THEN 0 + WHEN urineoutput >= 4000 + THEN 1 + END AS uo_score, + CASE + WHEN gcs_unable = 1 + THEN 0 + WHEN gcs_eyes = 1 + THEN CASE + WHEN gcs_verbal = 1 AND gcs_motor IN (1, 2) + THEN 48 + WHEN gcs_verbal = 1 AND gcs_motor IN (3, 4) + THEN 33 + WHEN gcs_verbal = 1 AND gcs_motor IN (5, 6) + THEN 16 + WHEN gcs_verbal IN (2, 3) AND gcs_motor IN (1, 2) + THEN 29 + WHEN gcs_verbal IN (2, 3) AND gcs_motor IN (3, 4) + THEN 24 + WHEN gcs_verbal IN (2, 3) AND gcs_motor >= 5 + THEN NULL + WHEN gcs_verbal >= 4 + THEN NULL + END + WHEN gcs_eyes > 1 + THEN CASE + WHEN gcs_verbal = 1 AND gcs_motor IN (1, 2) + THEN 29 + WHEN gcs_verbal = 1 AND gcs_motor IN (3, 4) + THEN 24 + WHEN gcs_verbal = 1 AND gcs_motor IN (5, 6) + THEN 15 + WHEN gcs_verbal IN (2, 3) AND gcs_motor IN (1, 2) + THEN 29 + WHEN gcs_verbal IN (2, 3) AND gcs_motor IN (3, 4) + THEN 24 + WHEN gcs_verbal IN (2, 3) AND gcs_motor = 5 + THEN 13 + WHEN gcs_verbal IN (2, 3) AND gcs_motor = 6 + THEN 10 + WHEN gcs_verbal = 4 AND gcs_motor IN (1, 2, 3, 4) + THEN 13 + WHEN gcs_verbal = 4 AND gcs_motor = 5 + THEN 8 + WHEN gcs_verbal = 4 AND gcs_motor = 6 + THEN 3 + WHEN gcs_verbal = 5 AND gcs_motor IN (1, 2, 3, 4, 5) + THEN 3 + WHEN gcs_verbal = 5 AND gcs_motor = 6 + THEN 0 + END + ELSE NULL + END AS gcs_score, + CASE + WHEN pao2 IS NULL AND aado2 IS NULL + THEN NULL + WHEN NOT pao2 IS NULL + THEN CASE WHEN pao2 < 50 THEN 15 WHEN pao2 < 70 THEN 5 WHEN pao2 < 80 THEN 2 ELSE 0 END + WHEN NOT aado2 IS NULL + THEN CASE + WHEN aado2 < 100 + THEN 0 + WHEN aado2 < 250 + THEN 7 + WHEN aado2 < 350 + THEN 9 + WHEN aado2 < 500 + THEN 11 + WHEN aado2 >= 500 + THEN 14 + ELSE 0 + END + END AS pao2_aado2_score + FROM cohort AS co + LEFT JOIN score_min AS smin + ON co.stay_id = smin.stay_id + LEFT JOIN score_max AS smax + ON co.stay_id = smax.stay_id +), score AS ( + SELECT + s.*, + COALESCE(hr_score, 0) + COALESCE(mbp_score, 0) + COALESCE(temp_score, 0) + COALESCE(resp_rate_score, 0) + COALESCE(pao2_aado2_score, 0) + COALESCE(hematocrit_score, 0) + COALESCE(wbc_score, 0) + COALESCE(creatinine_score, 0) + COALESCE(uo_score, 0) + COALESCE(bun_score, 0) + COALESCE(sodium_score, 0) + COALESCE(albumin_score, 0) + COALESCE(bilirubin_score, 0) + COALESCE(glucose_score, 0) + COALESCE(acidbase_score, 0) + COALESCE(gcs_score, 0) AS apsiii + FROM scorecomp AS s +) +SELECT + ie.subject_id, + ie.hadm_id, + ie.stay_id, + apsiii, + 1 / ( + 1 + EXP(-( + -4.4360 + 0.04726 * ( + apsiii + ) + )) + ) AS apsiii_prob, + hr_score, + mbp_score, + temp_score, + resp_rate_score, + pao2_aado2_score, + hematocrit_score, + wbc_score, + creatinine_score, + uo_score, + bun_score, + sodium_score, + albumin_score, + bilirubin_score, + glucose_score, + acidbase_score, + gcs_score +FROM mimiciv_icu.icustays AS ie +LEFT JOIN score AS s + ON ie.stay_id = s.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/score/lods.sql b/mimic-iv/concepts_duckdb/score/lods.sql new file mode 100644 index 000000000..4d2185506 --- /dev/null +++ b/mimic-iv/concepts_duckdb/score/lods.sql @@ -0,0 +1,203 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.lods; CREATE TABLE mimiciv_derived.lods AS +WITH cpap AS ( + SELECT + ie.stay_id, + MIN(charttime - INTERVAL '1' HOUR) AS starttime, + MAX(charttime + INTERVAL '4' HOUR) AS endtime, + MAX( + CASE + WHEN LOWER(ce.value) LIKE '%cpap%' + THEN 1 + WHEN LOWER(ce.value) LIKE '%bipap mask%' + THEN 1 + ELSE 0 + END + ) AS cpap + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_icu.chartevents AS ce + ON ie.stay_id = ce.stay_id + AND ce.charttime >= ie.intime + AND ce.charttime <= ie.intime + INTERVAL '1' DAY + WHERE + itemid = 226732 + AND ( + LOWER(ce.value) LIKE '%cpap%' OR LOWER(ce.value) LIKE '%bipap mask%' + ) + GROUP BY + ie.stay_id +), pafi1 AS ( + SELECT + ie.stay_id, + bg.charttime, + pao2fio2ratio, + CASE WHEN NOT vd.stay_id IS NULL THEN 1 ELSE 0 END AS vent, + CASE WHEN NOT cp.stay_id IS NULL THEN 1 ELSE 0 END AS cpap + FROM mimiciv_derived.bg AS bg + INNER JOIN mimiciv_icu.icustays AS ie + ON bg.hadm_id = ie.hadm_id AND bg.charttime >= ie.intime AND bg.charttime < ie.outtime + LEFT JOIN mimiciv_derived.ventilation AS vd + ON ie.stay_id = vd.stay_id + AND bg.charttime >= vd.starttime + AND bg.charttime <= vd.endtime + AND vd.ventilation_status = 'InvasiveVent' + LEFT JOIN cpap AS cp + ON ie.stay_id = cp.stay_id AND bg.charttime >= cp.starttime AND bg.charttime <= cp.endtime +), pafi2 AS ( + SELECT + stay_id, + MIN(pao2fio2ratio) AS pao2fio2_vent_min + FROM pafi1 + WHERE + vent = 1 OR cpap = 1 + GROUP BY + stay_id +), cohort AS ( + SELECT + ie.subject_id, + ie.hadm_id, + ie.stay_id, + ie.intime, + ie.outtime, + gcs.gcs_min, + vital.heart_rate_max, + vital.heart_rate_min, + vital.sbp_max, + vital.sbp_min, + pf.pao2fio2_vent_min, + labs.bun_max, + labs.bun_min, + labs.wbc_max, + labs.wbc_min, + labs.bilirubin_total_max AS bilirubin_max, + labs.creatinine_max, + labs.pt_min, + labs.pt_max, + labs.platelets_min AS platelet_min, + uo.urineoutput + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_hosp.admissions AS adm + ON ie.hadm_id = adm.hadm_id + INNER JOIN mimiciv_hosp.patients AS pat + ON ie.subject_id = pat.subject_id + LEFT JOIN pafi2 AS pf + ON ie.stay_id = pf.stay_id + LEFT JOIN mimiciv_derived.first_day_gcs AS gcs + ON ie.stay_id = gcs.stay_id + LEFT JOIN mimiciv_derived.first_day_vitalsign AS vital + ON ie.stay_id = vital.stay_id + LEFT JOIN mimiciv_derived.first_day_urine_output AS uo + ON ie.stay_id = uo.stay_id + LEFT JOIN mimiciv_derived.first_day_lab AS labs + ON ie.stay_id = labs.stay_id +), scorecomp AS ( + SELECT + cohort.*, + CASE + WHEN gcs_min IS NULL + THEN NULL + WHEN gcs_min < 3 + THEN NULL + WHEN gcs_min <= 5 + THEN 5 + WHEN gcs_min <= 8 + THEN 3 + WHEN gcs_min <= 13 + THEN 1 + ELSE 0 + END AS neurologic, + CASE + WHEN heart_rate_max IS NULL AND sbp_min IS NULL + THEN NULL + WHEN heart_rate_min < 30 + THEN 5 + WHEN sbp_min < 40 + THEN 5 + WHEN sbp_min < 70 + THEN 3 + WHEN sbp_max >= 270 + THEN 3 + WHEN heart_rate_max >= 140 + THEN 1 + WHEN sbp_max >= 240 + THEN 1 + WHEN sbp_min < 90 + THEN 1 + ELSE 0 + END AS cardiovascular, + CASE + WHEN bun_max IS NULL OR urineoutput IS NULL OR creatinine_max IS NULL + THEN NULL + WHEN urineoutput < 500.0 + THEN 5 + WHEN bun_max >= 56.0 + THEN 5 + WHEN creatinine_max >= 1.60 + THEN 3 + WHEN urineoutput < 750.0 + THEN 3 + WHEN bun_max >= 28.0 + THEN 3 + WHEN urineoutput >= 10000.0 + THEN 3 + WHEN creatinine_max >= 1.20 + THEN 1 + WHEN bun_max >= 17.0 + THEN 1 + WHEN bun_max >= 7.50 + THEN 1 + ELSE 0 + END AS renal, + CASE + WHEN pao2fio2_vent_min IS NULL + THEN 0 + WHEN pao2fio2_vent_min >= 150 + THEN 1 + WHEN pao2fio2_vent_min < 150 + THEN 3 + ELSE NULL + END AS pulmonary, + CASE + WHEN wbc_max IS NULL AND platelet_min IS NULL + THEN NULL + WHEN wbc_min < 1.0 + THEN 3 + WHEN wbc_min < 2.5 + THEN 1 + WHEN platelet_min < 50.0 + THEN 1 + WHEN wbc_max >= 50.0 + THEN 1 + ELSE 0 + END AS hematologic, + CASE + WHEN pt_max IS NULL AND bilirubin_max IS NULL + THEN NULL + WHEN bilirubin_max >= 2.0 + THEN 1 + WHEN pt_max > ( + 12 + 3 + ) + THEN 1 + WHEN pt_min < ( + 12 * 0.25 + ) + THEN 1 + ELSE 0 + END AS hepatic + FROM cohort +) +SELECT + ie.subject_id, + ie.hadm_id, + ie.stay_id, + COALESCE(neurologic, 0) + COALESCE(cardiovascular, 0) + COALESCE(renal, 0) + COALESCE(pulmonary, 0) + COALESCE(hematologic, 0) + COALESCE(hepatic, 0) AS lods, + neurologic, + cardiovascular, + renal, + pulmonary, + hematologic, + hepatic +FROM mimiciv_icu.icustays AS ie +LEFT JOIN scorecomp AS s + ON ie.stay_id = s.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/score/oasis.sql b/mimic-iv/concepts_duckdb/score/oasis.sql new file mode 100644 index 000000000..1ae7d49c0 --- /dev/null +++ b/mimic-iv/concepts_duckdb/score/oasis.sql @@ -0,0 +1,326 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.oasis; CREATE TABLE mimiciv_derived.oasis AS +WITH surgflag AS ( + SELECT + ie.stay_id, + MAX( + CASE + WHEN LOWER(curr_service) LIKE '%surg%' + THEN 1 + WHEN curr_service = 'ORTHO' + THEN 1 + ELSE 0 + END + ) AS surgical + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_hosp.services AS se + ON ie.hadm_id = se.hadm_id AND se.transfertime < ie.intime + INTERVAL '1' DAY + GROUP BY + ie.stay_id +), vent AS ( + SELECT + ie.stay_id, + MAX(CASE WHEN NOT v.stay_id IS NULL THEN 1 ELSE 0 END) AS vent + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.ventilation AS v + ON ie.stay_id = v.stay_id + AND v.ventilation_status = 'InvasiveVent' + AND ( + ( + v.starttime >= ie.intime AND v.starttime <= ie.intime + INTERVAL '1' DAY + ) + OR ( + v.endtime >= ie.intime AND v.endtime <= ie.intime + INTERVAL '1' DAY + ) + OR ( + v.starttime <= ie.intime AND v.endtime >= ie.intime + INTERVAL '1' DAY + ) + ) + GROUP BY + ie.stay_id +), cohort AS ( + SELECT + ie.subject_id, + ie.hadm_id, + ie.stay_id, + ie.intime, + ie.outtime, + adm.deathtime, + DATE_DIFF('microseconds', adm.admittime, ie.intime)/60000000.0 AS preiculos, + ag.age, + gcs.gcs_min, + vital.heart_rate_max, + vital.heart_rate_min, + vital.mbp_max, + vital.mbp_min, + vital.resp_rate_max, + vital.resp_rate_min, + vital.temperature_max, + vital.temperature_min, + vent.vent AS mechvent, + uo.urineoutput, + CASE + WHEN adm.admission_type = 'ELECTIVE' AND sf.surgical = 1 + THEN 1 + WHEN adm.admission_type IS NULL OR sf.surgical IS NULL + THEN NULL + ELSE 0 + END AS electivesurgery, + CASE + WHEN adm.deathtime BETWEEN ie.intime AND ie.outtime + THEN 1 + WHEN adm.deathtime <= ie.intime + THEN 1 + WHEN adm.dischtime <= ie.outtime AND adm.discharge_location = 'DEAD/EXPIRED' + THEN 1 + ELSE 0 + END AS icustay_expire_flag, + adm.hospital_expire_flag + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_hosp.admissions AS adm + ON ie.hadm_id = adm.hadm_id + INNER JOIN mimiciv_hosp.patients AS pat + ON ie.subject_id = pat.subject_id + LEFT JOIN mimiciv_derived.age AS ag + ON ie.hadm_id = ag.hadm_id + LEFT JOIN surgflag AS sf + ON ie.stay_id = sf.stay_id + LEFT JOIN mimiciv_derived.first_day_gcs AS gcs + ON ie.stay_id = gcs.stay_id + LEFT JOIN mimiciv_derived.first_day_vitalsign AS vital + ON ie.stay_id = vital.stay_id + LEFT JOIN mimiciv_derived.first_day_urine_output AS uo + ON ie.stay_id = uo.stay_id + LEFT JOIN vent + ON ie.stay_id = vent.stay_id +), scorecomp AS ( + SELECT + co.subject_id, + co.hadm_id, + co.stay_id, + co.icustay_expire_flag, + co.hospital_expire_flag, + CASE + WHEN preiculos IS NULL + THEN NULL + WHEN preiculos < 10.2 + THEN 5 + WHEN preiculos < 297 + THEN 3 + WHEN preiculos < 1440 + THEN 0 + WHEN preiculos < 18708 + THEN 2 + ELSE 1 + END AS preiculos_score, + CASE + WHEN age IS NULL + THEN NULL + WHEN age < 24 + THEN 0 + WHEN age <= 53 + THEN 3 + WHEN age <= 77 + THEN 6 + WHEN age <= 89 + THEN 9 + WHEN age >= 90 + THEN 7 + ELSE 0 + END AS age_score, + CASE + WHEN gcs_min IS NULL + THEN NULL + WHEN gcs_min <= 7 + THEN 10 + WHEN gcs_min < 14 + THEN 4 + WHEN gcs_min = 14 + THEN 3 + ELSE 0 + END AS gcs_score, + CASE + WHEN heart_rate_max IS NULL + THEN NULL + WHEN heart_rate_max > 125 + THEN 6 + WHEN heart_rate_min < 33 + THEN 4 + WHEN heart_rate_max >= 107 AND heart_rate_max <= 125 + THEN 3 + WHEN heart_rate_max >= 89 AND heart_rate_max <= 106 + THEN 1 + ELSE 0 + END AS heart_rate_score, + CASE + WHEN mbp_min IS NULL + THEN NULL + WHEN mbp_min < 20.65 + THEN 4 + WHEN mbp_min < 51 + THEN 3 + WHEN mbp_max > 143.44 + THEN 3 + WHEN mbp_min >= 51 AND mbp_min < 61.33 + THEN 2 + ELSE 0 + END AS mbp_score, + CASE + WHEN resp_rate_min IS NULL + THEN NULL + WHEN resp_rate_min < 6 + THEN 10 + WHEN resp_rate_max > 44 + THEN 9 + WHEN resp_rate_max > 30 + THEN 6 + WHEN resp_rate_max > 22 + THEN 1 + WHEN resp_rate_min < 13 + THEN 1 + ELSE 0 + END AS resp_rate_score, + CASE + WHEN temperature_max IS NULL + THEN NULL + WHEN temperature_max > 39.88 + THEN 6 + WHEN temperature_min >= 33.22 AND temperature_min <= 35.93 + THEN 4 + WHEN temperature_max >= 33.22 AND temperature_max <= 35.93 + THEN 4 + WHEN temperature_min < 33.22 + THEN 3 + WHEN temperature_min > 35.93 AND temperature_min <= 36.39 + THEN 2 + WHEN temperature_max >= 36.89 AND temperature_max <= 39.88 + THEN 2 + ELSE 0 + END AS temp_score, + CASE + WHEN urineoutput IS NULL + THEN NULL + WHEN urineoutput < 671.09 + THEN 10 + WHEN urineoutput > 6896.80 + THEN 8 + WHEN urineoutput >= 671.09 AND urineoutput <= 1426.99 + THEN 5 + WHEN urineoutput >= 1427.00 AND urineoutput <= 2544.14 + THEN 1 + ELSE 0 + END AS urineoutput_score, + CASE WHEN mechvent IS NULL THEN NULL WHEN mechvent = 1 THEN 9 ELSE 0 END AS mechvent_score, + CASE WHEN electivesurgery IS NULL THEN NULL WHEN electivesurgery = 1 THEN 0 ELSE 6 END AS electivesurgery_score, + preiculos, + age, + gcs_min AS gcs, + CASE + WHEN heart_rate_max IS NULL + THEN NULL + WHEN heart_rate_max > 125 + THEN heart_rate_max + WHEN heart_rate_min < 33 + THEN heart_rate_min + WHEN heart_rate_max >= 107 AND heart_rate_max <= 125 + THEN heart_rate_max + WHEN heart_rate_max >= 89 AND heart_rate_max <= 106 + THEN heart_rate_max + ELSE ( + heart_rate_min + heart_rate_max + ) / 2 + END AS heartrate, + CASE + WHEN mbp_min IS NULL + THEN NULL + WHEN mbp_min < 20.65 + THEN mbp_min + WHEN mbp_min < 51 + THEN mbp_min + WHEN mbp_max > 143.44 + THEN mbp_max + WHEN mbp_min >= 51 AND mbp_min < 61.33 + THEN mbp_min + ELSE ( + mbp_min + mbp_max + ) / 2 + END AS meanbp, + CASE + WHEN resp_rate_min IS NULL + THEN NULL + WHEN resp_rate_min < 6 + THEN resp_rate_min + WHEN resp_rate_max > 44 + THEN resp_rate_max + WHEN resp_rate_max > 30 + THEN resp_rate_max + WHEN resp_rate_max > 22 + THEN resp_rate_max + WHEN resp_rate_min < 13 + THEN resp_rate_min + ELSE ( + resp_rate_min + resp_rate_max + ) / 2 + END AS resprate, + CASE + WHEN temperature_max IS NULL + THEN NULL + WHEN temperature_max > 39.88 + THEN temperature_max + WHEN temperature_min >= 33.22 AND temperature_min <= 35.93 + THEN temperature_min + WHEN temperature_max >= 33.22 AND temperature_max <= 35.93 + THEN temperature_max + WHEN temperature_min < 33.22 + THEN temperature_min + WHEN temperature_min > 35.93 AND temperature_min <= 36.39 + THEN temperature_min + WHEN temperature_max >= 36.89 AND temperature_max <= 39.88 + THEN temperature_max + ELSE ( + temperature_min + temperature_max + ) / 2 + END AS temp, + urineoutput, + mechvent, + electivesurgery + FROM cohort AS co +), score AS ( + SELECT + s.*, + COALESCE(age_score, 0) + COALESCE(preiculos_score, 0) + COALESCE(gcs_score, 0) + COALESCE(heart_rate_score, 0) + COALESCE(mbp_score, 0) + COALESCE(resp_rate_score, 0) + COALESCE(temp_score, 0) + COALESCE(urineoutput_score, 0) + COALESCE(mechvent_score, 0) + COALESCE(electivesurgery_score, 0) AS oasis + FROM scorecomp AS s +) +SELECT + subject_id, + hadm_id, + stay_id, + oasis, + 1 / ( + 1 + EXP(-( + -6.1746 + 0.1275 * ( + oasis + ) + )) + ) AS oasis_prob, + age, + age_score, + preiculos, + preiculos_score, + gcs, + gcs_score, + heartrate, + heart_rate_score, + meanbp, + mbp_score, + resprate, + resp_rate_score, + temp, + temp_score, + urineoutput, + urineoutput_score, + mechvent, + mechvent_score, + electivesurgery, + electivesurgery_score +FROM score \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/score/sapsii.sql b/mimic-iv/concepts_duckdb/score/sapsii.sql new file mode 100644 index 000000000..7bd5a9e87 --- /dev/null +++ b/mimic-iv/concepts_duckdb/score/sapsii.sql @@ -0,0 +1,471 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.sapsii; CREATE TABLE mimiciv_derived.sapsii AS +WITH co AS ( + SELECT + subject_id, + hadm_id, + stay_id, + intime AS starttime, + intime + INTERVAL '24' HOUR AS endtime + FROM mimiciv_icu.icustays +), cpap AS ( + SELECT + co.subject_id, + co.stay_id, + GREATEST(MIN(charttime - INTERVAL '1' HOUR), co.starttime) AS starttime, + LEAST(MAX(charttime + INTERVAL '4' HOUR), co.endtime) AS endtime, + MAX(CASE WHEN REGEXP_MATCHES(LOWER(ce.value), '(cpap mask|bipap)') THEN 1 ELSE 0 END) AS cpap + FROM co + INNER JOIN mimiciv_icu.chartevents AS ce + ON co.stay_id = ce.stay_id AND ce.charttime > co.starttime AND ce.charttime <= co.endtime + WHERE + ce.itemid = 226732 AND REGEXP_MATCHES(LOWER(ce.value), '(cpap mask|bipap)') + GROUP BY + co.subject_id, + co.stay_id, + co.starttime, + co.endtime +), surgflag AS ( + SELECT + adm.hadm_id, + CASE WHEN LOWER(curr_service) LIKE '%surg%' THEN 1 ELSE 0 END AS surgical, + ROW_NUMBER() OVER (PARTITION BY adm.hadm_id ORDER BY transfertime NULLS FIRST) AS serviceorder + FROM mimiciv_hosp.admissions AS adm + LEFT JOIN mimiciv_hosp.services AS se + ON adm.hadm_id = se.hadm_id +), comorb AS ( + SELECT + hadm_id, + MAX( + CASE + WHEN icd_version = 9 AND SUBSTR(icd_code, 1, 3) BETWEEN '042' AND '044' + THEN 1 + WHEN icd_version = 10 AND SUBSTR(icd_code, 1, 3) BETWEEN 'B20' AND 'B22' + THEN 1 + WHEN icd_version = 10 AND SUBSTR(icd_code, 1, 3) = 'B24' + THEN 1 + ELSE 0 + END + ) AS aids, + MAX( + CASE + WHEN icd_version = 9 + THEN CASE + WHEN SUBSTR(icd_code, 1, 5) BETWEEN '20000' AND '20238' + THEN 1 + WHEN SUBSTR(icd_code, 1, 5) BETWEEN '20240' AND '20248' + THEN 1 + WHEN SUBSTR(icd_code, 1, 5) BETWEEN '20250' AND '20302' + THEN 1 + WHEN SUBSTR(icd_code, 1, 5) BETWEEN '20310' AND '20312' + THEN 1 + WHEN SUBSTR(icd_code, 1, 5) BETWEEN '20302' AND '20382' + THEN 1 + WHEN SUBSTR(icd_code, 1, 5) BETWEEN '20400' AND '20522' + THEN 1 + WHEN SUBSTR(icd_code, 1, 5) BETWEEN '20580' AND '20702' + THEN 1 + WHEN SUBSTR(icd_code, 1, 5) BETWEEN '20720' AND '20892' + THEN 1 + WHEN SUBSTR(icd_code, 1, 4) IN ('2386', '2733') + THEN 1 + ELSE 0 + END + WHEN icd_version = 10 AND SUBSTR(icd_code, 1, 3) BETWEEN 'C81' AND 'C96' + THEN 1 + ELSE 0 + END + ) AS hem, + MAX( + CASE + WHEN icd_version = 9 + THEN CASE + WHEN SUBSTR(icd_code, 1, 4) BETWEEN '1960' AND '1991' + THEN 1 + WHEN SUBSTR(icd_code, 1, 5) BETWEEN '20970' AND '20975' + THEN 1 + WHEN SUBSTR(icd_code, 1, 5) IN ('20979', '78951') + THEN 1 + ELSE 0 + END + WHEN icd_version = 10 AND SUBSTR(icd_code, 1, 3) BETWEEN 'C77' AND 'C79' + THEN 1 + WHEN icd_version = 10 AND SUBSTR(icd_code, 1, 4) = 'C800' + THEN 1 + ELSE 0 + END + ) AS mets + FROM mimiciv_hosp.diagnoses_icd + GROUP BY + hadm_id +), pafi1 AS ( + SELECT + co.stay_id, + bg.charttime, + pao2fio2ratio AS pao2fio2, + CASE WHEN NOT vd.stay_id IS NULL THEN 1 ELSE 0 END AS vent, + CASE WHEN NOT cp.subject_id IS NULL THEN 1 ELSE 0 END AS cpap + FROM co + LEFT JOIN mimiciv_derived.bg AS bg + ON co.subject_id = bg.subject_id + AND bg.specimen = 'ART.' + AND bg.charttime > co.starttime + AND bg.charttime <= co.endtime + LEFT JOIN mimiciv_derived.ventilation AS vd + ON co.stay_id = vd.stay_id + AND bg.charttime > vd.starttime + AND bg.charttime <= vd.endtime + AND vd.ventilation_status = 'InvasiveVent' + LEFT JOIN cpap AS cp + ON bg.subject_id = cp.subject_id + AND bg.charttime > cp.starttime + AND bg.charttime <= cp.endtime +), pafi2 AS ( + SELECT + stay_id, + MIN(pao2fio2) AS pao2fio2_vent_min + FROM pafi1 + WHERE + vent = 1 OR cpap = 1 + GROUP BY + stay_id +), gcs AS ( + SELECT + co.stay_id, + MIN(gcs.gcs) AS mingcs + FROM co + LEFT JOIN mimiciv_derived.gcs AS gcs + ON co.stay_id = gcs.stay_id AND co.starttime < gcs.charttime AND gcs.charttime <= co.endtime + GROUP BY + co.stay_id +), vital AS ( + SELECT + co.stay_id, + MIN(vital.heart_rate) AS heartrate_min, + MAX(vital.heart_rate) AS heartrate_max, + MIN(vital.sbp) AS sysbp_min, + MAX(vital.sbp) AS sysbp_max, + MIN(vital.temperature) AS tempc_min, + MAX(vital.temperature) AS tempc_max + FROM co + LEFT JOIN mimiciv_derived.vitalsign AS vital + ON co.subject_id = vital.subject_id + AND co.starttime < vital.charttime + AND co.endtime >= vital.charttime + GROUP BY + co.stay_id +), uo AS ( + SELECT + co.stay_id, + SUM(uo.urineoutput) AS urineoutput + FROM co + LEFT JOIN mimiciv_derived.urine_output AS uo + ON co.stay_id = uo.stay_id AND co.starttime < uo.charttime AND co.endtime >= uo.charttime + GROUP BY + co.stay_id +), labs AS ( + SELECT + co.stay_id, + MIN(labs.bun) AS bun_min, + MAX(labs.bun) AS bun_max, + MIN(labs.potassium) AS potassium_min, + MAX(labs.potassium) AS potassium_max, + MIN(labs.sodium) AS sodium_min, + MAX(labs.sodium) AS sodium_max, + MIN(labs.bicarbonate) AS bicarbonate_min, + MAX(labs.bicarbonate) AS bicarbonate_max + FROM co + LEFT JOIN mimiciv_derived.chemistry AS labs + ON co.subject_id = labs.subject_id + AND co.starttime < labs.charttime + AND co.endtime >= labs.charttime + GROUP BY + co.stay_id +), cbc AS ( + SELECT + co.stay_id, + MIN(cbc.wbc) AS wbc_min, + MAX(cbc.wbc) AS wbc_max + FROM co + LEFT JOIN mimiciv_derived.complete_blood_count AS cbc + ON co.subject_id = cbc.subject_id + AND co.starttime < cbc.charttime + AND co.endtime >= cbc.charttime + GROUP BY + co.stay_id +), enz AS ( + SELECT + co.stay_id, + MIN(enz.bilirubin_total) AS bilirubin_min, + MAX(enz.bilirubin_total) AS bilirubin_max + FROM co + LEFT JOIN mimiciv_derived.enzyme AS enz + ON co.subject_id = enz.subject_id + AND co.starttime < enz.charttime + AND co.endtime >= enz.charttime + GROUP BY + co.stay_id +), cohort AS ( + SELECT + ie.subject_id, + ie.hadm_id, + ie.stay_id, + ie.intime, + ie.outtime, + va.age, + co.starttime, + co.endtime, + vital.heartrate_max, + vital.heartrate_min, + vital.sysbp_max, + vital.sysbp_min, + vital.tempc_max, + vital.tempc_min, + pf.pao2fio2_vent_min, + uo.urineoutput, + labs.bun_min, + labs.bun_max, + cbc.wbc_min, + cbc.wbc_max, + labs.potassium_min, + labs.potassium_max, + labs.sodium_min, + labs.sodium_max, + labs.bicarbonate_min, + labs.bicarbonate_max, + enz.bilirubin_min, + enz.bilirubin_max, + gcs.mingcs, + comorb.aids, + comorb.hem, + comorb.mets, + CASE + WHEN adm.admission_type = 'ELECTIVE' AND sf.surgical = 1 + THEN 'ScheduledSurgical' + WHEN adm.admission_type <> 'ELECTIVE' AND sf.surgical = 1 + THEN 'UnscheduledSurgical' + ELSE 'Medical' + END AS admissiontype + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_hosp.admissions AS adm + ON ie.hadm_id = adm.hadm_id + LEFT JOIN mimiciv_derived.age AS va + ON ie.hadm_id = va.hadm_id + INNER JOIN co + ON ie.stay_id = co.stay_id + LEFT JOIN pafi2 AS pf + ON ie.stay_id = pf.stay_id + LEFT JOIN surgflag AS sf + ON adm.hadm_id = sf.hadm_id AND sf.serviceorder = 1 + LEFT JOIN comorb + ON ie.hadm_id = comorb.hadm_id + LEFT JOIN gcs AS gcs + ON ie.stay_id = gcs.stay_id + LEFT JOIN vital + ON ie.stay_id = vital.stay_id + LEFT JOIN uo + ON ie.stay_id = uo.stay_id + LEFT JOIN labs + ON ie.stay_id = labs.stay_id + LEFT JOIN cbc + ON ie.stay_id = cbc.stay_id + LEFT JOIN enz + ON ie.stay_id = enz.stay_id +), scorecomp AS ( + SELECT + cohort.*, + CASE + WHEN age IS NULL + THEN NULL + WHEN age < 40 + THEN 0 + WHEN age < 60 + THEN 7 + WHEN age < 70 + THEN 12 + WHEN age < 75 + THEN 15 + WHEN age < 80 + THEN 16 + WHEN age >= 80 + THEN 18 + END AS age_score, + CASE + WHEN heartrate_max IS NULL + THEN NULL + WHEN heartrate_min < 40 + THEN 11 + WHEN heartrate_max >= 160 + THEN 7 + WHEN heartrate_max >= 120 + THEN 4 + WHEN heartrate_min < 70 + THEN 2 + WHEN heartrate_max >= 70 AND heartrate_max < 120 AND heartrate_min >= 70 AND heartrate_min < 120 + THEN 0 + END AS hr_score, + CASE + WHEN sysbp_min IS NULL + THEN NULL + WHEN sysbp_min < 70 + THEN 13 + WHEN sysbp_min < 100 + THEN 5 + WHEN sysbp_max >= 200 + THEN 2 + WHEN sysbp_max >= 100 AND sysbp_max < 200 AND sysbp_min >= 100 AND sysbp_min < 200 + THEN 0 + END AS sysbp_score, + CASE + WHEN tempc_max IS NULL + THEN NULL + WHEN tempc_max >= 39.0 + THEN 3 + WHEN tempc_min < 39.0 + THEN 0 + END AS temp_score, + CASE + WHEN pao2fio2_vent_min IS NULL + THEN NULL + WHEN pao2fio2_vent_min < 100 + THEN 11 + WHEN pao2fio2_vent_min < 200 + THEN 9 + WHEN pao2fio2_vent_min >= 200 + THEN 6 + END AS pao2fio2_score, + CASE + WHEN urineoutput IS NULL + THEN NULL + WHEN urineoutput < 500.0 + THEN 11 + WHEN urineoutput < 1000.0 + THEN 4 + WHEN urineoutput >= 1000.0 + THEN 0 + END AS uo_score, + CASE + WHEN bun_max IS NULL + THEN NULL + WHEN bun_max < 28.0 + THEN 0 + WHEN bun_max < 84.0 + THEN 6 + WHEN bun_max >= 84.0 + THEN 10 + END AS bun_score, + CASE + WHEN wbc_max IS NULL + THEN NULL + WHEN wbc_min < 1.0 + THEN 12 + WHEN wbc_max >= 20.0 + THEN 3 + WHEN wbc_max >= 1.0 AND wbc_max < 20.0 AND wbc_min >= 1.0 AND wbc_min < 20.0 + THEN 0 + END AS wbc_score, + CASE + WHEN potassium_max IS NULL + THEN NULL + WHEN potassium_min < 3.0 + THEN 3 + WHEN potassium_max >= 5.0 + THEN 3 + WHEN potassium_max >= 3.0 AND potassium_max < 5.0 AND potassium_min >= 3.0 AND potassium_min < 5.0 + THEN 0 + END AS potassium_score, + CASE + WHEN sodium_max IS NULL + THEN NULL + WHEN sodium_min < 125 + THEN 5 + WHEN sodium_max >= 145 + THEN 1 + WHEN sodium_max >= 125 AND sodium_max < 145 AND sodium_min >= 125 AND sodium_min < 145 + THEN 0 + END AS sodium_score, + CASE + WHEN bicarbonate_max IS NULL + THEN NULL + WHEN bicarbonate_min < 15.0 + THEN 6 + WHEN bicarbonate_min < 20.0 + THEN 3 + WHEN bicarbonate_max >= 20.0 AND bicarbonate_min >= 20.0 + THEN 0 + END AS bicarbonate_score, + CASE + WHEN bilirubin_max IS NULL + THEN NULL + WHEN bilirubin_max < 4.0 + THEN 0 + WHEN bilirubin_max < 6.0 + THEN 4 + WHEN bilirubin_max >= 6.0 + THEN 9 + END AS bilirubin_score, + CASE + WHEN mingcs IS NULL + THEN NULL + WHEN mingcs < 3 + THEN NULL + WHEN mingcs < 6 + THEN 26 + WHEN mingcs < 9 + THEN 13 + WHEN mingcs < 11 + THEN 7 + WHEN mingcs < 14 + THEN 5 + WHEN mingcs >= 14 AND mingcs <= 15 + THEN 0 + END AS gcs_score, + CASE WHEN aids = 1 THEN 17 WHEN hem = 1 THEN 10 WHEN mets = 1 THEN 9 ELSE 0 END AS comorbidity_score, + CASE + WHEN admissiontype = 'ScheduledSurgical' + THEN 0 + WHEN admissiontype = 'Medical' + THEN 6 + WHEN admissiontype = 'UnscheduledSurgical' + THEN 8 + ELSE NULL + END AS admissiontype_score + FROM cohort +), score AS ( + SELECT + s.*, + COALESCE(age_score, 0) + COALESCE(hr_score, 0) + COALESCE(sysbp_score, 0) + COALESCE(temp_score, 0) + COALESCE(pao2fio2_score, 0) + COALESCE(uo_score, 0) + COALESCE(bun_score, 0) + COALESCE(wbc_score, 0) + COALESCE(potassium_score, 0) + COALESCE(sodium_score, 0) + COALESCE(bicarbonate_score, 0) + COALESCE(bilirubin_score, 0) + COALESCE(gcs_score, 0) + COALESCE(comorbidity_score, 0) + COALESCE(admissiontype_score, 0) AS sapsii + FROM scorecomp AS s +) +SELECT + s.subject_id, + s.hadm_id, + s.stay_id, + s.starttime, + s.endtime, + sapsii, + 1 / ( + 1 + EXP(-( + -7.7631 + 0.0737 * ( + sapsii + ) + 0.9971 * ( + LN(sapsii + 1) + ) + )) + ) AS sapsii_prob, + age_score, + hr_score, + sysbp_score, + temp_score, + pao2fio2_score, + uo_score, + bun_score, + wbc_score, + potassium_score, + sodium_score, + bicarbonate_score, + bilirubin_score, + gcs_score, + comorbidity_score, + admissiontype_score +FROM score AS s \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/score/sirs.sql b/mimic-iv/concepts_duckdb/score/sirs.sql new file mode 100644 index 000000000..a806e7c72 --- /dev/null +++ b/mimic-iv/concepts_duckdb/score/sirs.sql @@ -0,0 +1,73 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.sirs; CREATE TABLE mimiciv_derived.sirs AS +WITH scorecomp AS ( + SELECT + ie.stay_id, + v.temperature_min, + v.temperature_max, + v.heart_rate_max, + v.resp_rate_max, + bg.pco2_min AS paco2_min, + l.wbc_min, + l.wbc_max, + l.bands_max + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.first_day_bg_art AS bg + ON ie.stay_id = bg.stay_id + LEFT JOIN mimiciv_derived.first_day_vitalsign AS v + ON ie.stay_id = v.stay_id + LEFT JOIN mimiciv_derived.first_day_lab AS l + ON ie.stay_id = l.stay_id +), scorecalc AS ( + SELECT + stay_id, + CASE + WHEN temperature_min < 36.0 + THEN 1 + WHEN temperature_max > 38.0 + THEN 1 + WHEN temperature_min IS NULL + THEN NULL + ELSE 0 + END AS temp_score, + CASE + WHEN heart_rate_max > 90.0 + THEN 1 + WHEN heart_rate_max IS NULL + THEN NULL + ELSE 0 + END AS heart_rate_score, + CASE + WHEN resp_rate_max > 20.0 + THEN 1 + WHEN paco2_min < 32.0 + THEN 1 + WHEN COALESCE(resp_rate_max, paco2_min) IS NULL + THEN NULL + ELSE 0 + END AS resp_score, + CASE + WHEN wbc_min < 4.0 + THEN 1 + WHEN wbc_max > 12.0 + THEN 1 + WHEN bands_max > 10 + THEN 1 + WHEN COALESCE(wbc_min, bands_max) IS NULL + THEN NULL + ELSE 0 + END AS wbc_score + FROM scorecomp +) +SELECT + ie.subject_id, + ie.hadm_id, + ie.stay_id, + COALESCE(temp_score, 0) + COALESCE(heart_rate_score, 0) + COALESCE(resp_score, 0) + COALESCE(wbc_score, 0) AS sirs, + temp_score, + heart_rate_score, + resp_score, + wbc_score +FROM mimiciv_icu.icustays AS ie +LEFT JOIN scorecalc AS s + ON ie.stay_id = s.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/score/sofa.sql b/mimic-iv/concepts_duckdb/score/sofa.sql new file mode 100644 index 000000000..bc4f5725b --- /dev/null +++ b/mimic-iv/concepts_duckdb/score/sofa.sql @@ -0,0 +1,297 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.sofa; CREATE TABLE mimiciv_derived.sofa AS +WITH co AS ( + SELECT + ih.stay_id, + ie.hadm_id, + hr, + ih.endtime - INTERVAL '1' HOUR AS starttime, + ih.endtime + FROM mimiciv_derived.icustay_hourly AS ih + INNER JOIN mimiciv_icu.icustays AS ie + ON ih.stay_id = ie.stay_id +), pafi AS ( + SELECT + ie.stay_id, + bg.charttime, + CASE WHEN vd.stay_id IS NULL THEN pao2fio2ratio ELSE NULL END AS pao2fio2ratio_novent, + CASE WHEN NOT vd.stay_id IS NULL THEN pao2fio2ratio ELSE NULL END AS pao2fio2ratio_vent + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_derived.bg AS bg + ON ie.subject_id = bg.subject_id + LEFT JOIN mimiciv_derived.ventilation AS vd + ON ie.stay_id = vd.stay_id + AND bg.charttime >= vd.starttime + AND bg.charttime <= vd.endtime + AND vd.ventilation_status = 'InvasiveVent' + WHERE + specimen = 'ART.' +), vs AS ( + SELECT + co.stay_id, + co.hr, + MIN(vs.mbp) AS meanbp_min + FROM co + LEFT JOIN mimiciv_derived.vitalsign AS vs + ON co.stay_id = vs.stay_id AND co.starttime < vs.charttime AND co.endtime >= vs.charttime + GROUP BY + co.stay_id, + co.hr +), gcs AS ( + SELECT + co.stay_id, + co.hr, + MIN(gcs.gcs) AS gcs_min + FROM co + LEFT JOIN mimiciv_derived.gcs AS gcs + ON co.stay_id = gcs.stay_id AND co.starttime < gcs.charttime AND co.endtime >= gcs.charttime + GROUP BY + co.stay_id, + co.hr +), bili AS ( + SELECT + co.stay_id, + co.hr, + MAX(enz.bilirubin_total) AS bilirubin_max + FROM co + LEFT JOIN mimiciv_derived.enzyme AS enz + ON co.hadm_id = enz.hadm_id AND co.starttime < enz.charttime AND co.endtime >= enz.charttime + GROUP BY + co.stay_id, + co.hr +), cr AS ( + SELECT + co.stay_id, + co.hr, + MAX(chem.creatinine) AS creatinine_max + FROM co + LEFT JOIN mimiciv_derived.chemistry AS chem + ON co.hadm_id = chem.hadm_id + AND co.starttime < chem.charttime + AND co.endtime >= chem.charttime + GROUP BY + co.stay_id, + co.hr +), plt AS ( + SELECT + co.stay_id, + co.hr, + MIN(cbc.platelet) AS platelet_min + FROM co + LEFT JOIN mimiciv_derived.complete_blood_count AS cbc + ON co.hadm_id = cbc.hadm_id AND co.starttime < cbc.charttime AND co.endtime >= cbc.charttime + GROUP BY + co.stay_id, + co.hr +), pf AS ( + SELECT + co.stay_id, + co.hr, + MIN(pafi.pao2fio2ratio_novent) AS pao2fio2ratio_novent, + MIN(pafi.pao2fio2ratio_vent) AS pao2fio2ratio_vent + FROM co + LEFT JOIN pafi + ON co.stay_id = pafi.stay_id + AND co.starttime < pafi.charttime + AND co.endtime >= pafi.charttime + GROUP BY + co.stay_id, + co.hr +), uo AS ( + SELECT + co.stay_id, + co.hr, + MAX( + CASE + WHEN uo.uo_tm_24hr >= 22 AND uo.uo_tm_24hr <= 30 + THEN uo.urineoutput_24hr / uo.uo_tm_24hr * 24 + END + ) AS uo_24hr + FROM co + LEFT JOIN mimiciv_derived.urine_output_rate AS uo + ON co.stay_id = uo.stay_id AND co.starttime < uo.charttime AND co.endtime >= uo.charttime + GROUP BY + co.stay_id, + co.hr +), vaso AS ( + SELECT + co.stay_id, + co.hr, + MAX(epi.vaso_rate) AS rate_epinephrine, + MAX(nor.vaso_rate) AS rate_norepinephrine, + MAX(dop.vaso_rate) AS rate_dopamine, + MAX(dob.vaso_rate) AS rate_dobutamine + FROM co + LEFT JOIN mimiciv_derived.epinephrine AS epi + ON co.stay_id = epi.stay_id AND co.endtime > epi.starttime AND co.endtime <= epi.endtime + LEFT JOIN mimiciv_derived.norepinephrine AS nor + ON co.stay_id = nor.stay_id AND co.endtime > nor.starttime AND co.endtime <= nor.endtime + LEFT JOIN mimiciv_derived.dopamine AS dop + ON co.stay_id = dop.stay_id AND co.endtime > dop.starttime AND co.endtime <= dop.endtime + LEFT JOIN mimiciv_derived.dobutamine AS dob + ON co.stay_id = dob.stay_id AND co.endtime > dob.starttime AND co.endtime <= dob.endtime + WHERE + NOT epi.stay_id IS NULL + OR NOT nor.stay_id IS NULL + OR NOT dop.stay_id IS NULL + OR NOT dob.stay_id IS NULL + GROUP BY + co.stay_id, + co.hr +), scorecomp AS ( + SELECT + co.stay_id, + co.hr, + co.starttime, + co.endtime, + pf.pao2fio2ratio_novent, + pf.pao2fio2ratio_vent, + vaso.rate_epinephrine, + vaso.rate_norepinephrine, + vaso.rate_dopamine, + vaso.rate_dobutamine, + vs.meanbp_min, + gcs.gcs_min, + uo.uo_24hr, + bili.bilirubin_max, + cr.creatinine_max, + plt.platelet_min + FROM co + LEFT JOIN vs + ON co.stay_id = vs.stay_id AND co.hr = vs.hr + LEFT JOIN gcs + ON co.stay_id = gcs.stay_id AND co.hr = gcs.hr + LEFT JOIN bili + ON co.stay_id = bili.stay_id AND co.hr = bili.hr + LEFT JOIN cr + ON co.stay_id = cr.stay_id AND co.hr = cr.hr + LEFT JOIN plt + ON co.stay_id = plt.stay_id AND co.hr = plt.hr + LEFT JOIN pf + ON co.stay_id = pf.stay_id AND co.hr = pf.hr + LEFT JOIN uo + ON co.stay_id = uo.stay_id AND co.hr = uo.hr + LEFT JOIN vaso + ON co.stay_id = vaso.stay_id AND co.hr = vaso.hr +), scorecalc AS ( + SELECT + scorecomp.*, + CASE + WHEN pao2fio2ratio_vent < 100 + THEN 4 + WHEN pao2fio2ratio_vent < 200 + THEN 3 + WHEN pao2fio2ratio_novent < 300 + THEN 2 + WHEN pao2fio2ratio_vent < 300 + THEN 2 + WHEN pao2fio2ratio_novent < 400 + THEN 1 + WHEN pao2fio2ratio_vent < 400 + THEN 1 + WHEN COALESCE(pao2fio2ratio_vent, pao2fio2ratio_novent) IS NULL + THEN NULL + ELSE 0 + END AS respiration, + CASE + WHEN platelet_min < 20 + THEN 4 + WHEN platelet_min < 50 + THEN 3 + WHEN platelet_min < 100 + THEN 2 + WHEN platelet_min < 150 + THEN 1 + WHEN platelet_min IS NULL + THEN NULL + ELSE 0 + END AS coagulation, + CASE + WHEN bilirubin_max >= 12.0 + THEN 4 + WHEN bilirubin_max >= 6.0 + THEN 3 + WHEN bilirubin_max >= 2.0 + THEN 2 + WHEN bilirubin_max >= 1.2 + THEN 1 + WHEN bilirubin_max IS NULL + THEN NULL + ELSE 0 + END AS liver, + CASE + WHEN rate_dopamine > 15 OR rate_epinephrine > 0.1 OR rate_norepinephrine > 0.1 + THEN 4 + WHEN rate_dopamine > 5 OR rate_epinephrine <= 0.1 OR rate_norepinephrine <= 0.1 + THEN 3 + WHEN rate_dopamine > 0 OR rate_dobutamine > 0 + THEN 2 + WHEN meanbp_min < 70 + THEN 1 + WHEN COALESCE(meanbp_min, rate_dopamine, rate_dobutamine, rate_epinephrine, rate_norepinephrine) IS NULL + THEN NULL + ELSE 0 + END AS cardiovascular, + CASE + WHEN ( + gcs_min >= 13 AND gcs_min <= 14 + ) + THEN 1 + WHEN ( + gcs_min >= 10 AND gcs_min <= 12 + ) + THEN 2 + WHEN ( + gcs_min >= 6 AND gcs_min <= 9 + ) + THEN 3 + WHEN gcs_min < 6 + THEN 4 + WHEN gcs_min IS NULL + THEN NULL + ELSE 0 + END AS cns, + CASE + WHEN ( + creatinine_max >= 5.0 + ) + THEN 4 + WHEN uo_24hr < 200 + THEN 4 + WHEN ( + creatinine_max >= 3.5 AND creatinine_max < 5.0 + ) + THEN 3 + WHEN uo_24hr < 500 + THEN 3 + WHEN ( + creatinine_max >= 2.0 AND creatinine_max < 3.5 + ) + THEN 2 + WHEN ( + creatinine_max >= 1.2 AND creatinine_max < 2.0 + ) + THEN 1 + WHEN COALESCE(uo_24hr, creatinine_max) IS NULL + THEN NULL + ELSE 0 + END AS renal + FROM scorecomp +), score_final AS ( + SELECT + s.*, + COALESCE(MAX(respiration) OVER w, 0) AS respiration_24hours, + COALESCE(MAX(coagulation) OVER w, 0) AS coagulation_24hours, + COALESCE(MAX(liver) OVER w, 0) AS liver_24hours, + COALESCE(MAX(cardiovascular) OVER w, 0) AS cardiovascular_24hours, + COALESCE(MAX(cns) OVER w, 0) AS cns_24hours, + COALESCE(MAX(renal) OVER w, 0) AS renal_24hours, + COALESCE(MAX(respiration) OVER w, 0) + COALESCE(MAX(coagulation) OVER w, 0) + COALESCE(MAX(liver) OVER w, 0) + COALESCE(MAX(cardiovascular) OVER w, 0) + COALESCE(MAX(cns) OVER w, 0) + COALESCE(MAX(renal) OVER w, 0) AS sofa_24hours + FROM scorecalc AS s + WINDOW w AS (PARTITION BY stay_id ORDER BY hr NULLS FIRST ROWS BETWEEN 23 PRECEDING AND 0 FOLLOWING) +) +SELECT + * +FROM score_final +WHERE + hr >= 0 \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/sepsis/sepsis3.sql b/mimic-iv/concepts_duckdb/sepsis/sepsis3.sql new file mode 100644 index 000000000..ffbd9b78d --- /dev/null +++ b/mimic-iv/concepts_duckdb/sepsis/sepsis3.sql @@ -0,0 +1,66 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.sepsis3; CREATE TABLE mimiciv_derived.sepsis3 AS +WITH sofa AS ( + SELECT + stay_id, + starttime, + endtime, + respiration_24hours AS respiration, + coagulation_24hours AS coagulation, + liver_24hours AS liver, + cardiovascular_24hours AS cardiovascular, + cns_24hours AS cns, + renal_24hours AS renal, + sofa_24hours AS sofa_score + FROM mimiciv_derived.sofa + WHERE + sofa_24hours >= 2 +), s1 AS ( + SELECT + soi.subject_id, + soi.stay_id, + soi.ab_id, + soi.antibiotic, + soi.antibiotic_time, + soi.culture_time, + soi.suspected_infection, + soi.suspected_infection_time, + soi.specimen, + soi.positive_culture, + starttime, + endtime, + respiration, + coagulation, + liver, + cardiovascular, + cns, + renal, + sofa_score, + sofa_score >= 2 AND suspected_infection = 1 AS sepsis3, + ROW_NUMBER() OVER (PARTITION BY soi.stay_id ORDER BY suspected_infection_time NULLS FIRST, antibiotic_time NULLS FIRST, culture_time NULLS FIRST, endtime NULLS FIRST) AS rn_sus + FROM mimiciv_derived.suspicion_of_infection AS soi + INNER JOIN sofa + ON soi.stay_id = sofa.stay_id + AND sofa.endtime >= soi.suspected_infection_time - INTERVAL '48' HOUR + AND sofa.endtime <= soi.suspected_infection_time + INTERVAL '24' HOUR + WHERE + NOT soi.stay_id IS NULL +) +SELECT + subject_id, + stay_id, + antibiotic_time, + culture_time, + suspected_infection_time, + endtime AS sofa_time, + sofa_score, + respiration, + coagulation, + liver, + cardiovascular, + cns, + renal, + sepsis3 +FROM s1 +WHERE + rn_sus = 1 \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/sepsis/suspicion_of_infection.sql b/mimic-iv/concepts_duckdb/sepsis/suspicion_of_infection.sql new file mode 100644 index 000000000..1f3302cb9 --- /dev/null +++ b/mimic-iv/concepts_duckdb/sepsis/suspicion_of_infection.sql @@ -0,0 +1,109 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.suspicion_of_infection; CREATE TABLE mimiciv_derived.suspicion_of_infection AS +WITH ab_tbl AS ( + SELECT + abx.subject_id, + abx.hadm_id, + abx.stay_id, + abx.antibiotic, + abx.starttime AS antibiotic_time, + DATE_TRUNC('DAY', abx.starttime) AS antibiotic_date, + abx.stoptime AS antibiotic_stoptime, + ROW_NUMBER() OVER (PARTITION BY subject_id ORDER BY starttime NULLS FIRST, stoptime NULLS FIRST, antibiotic NULLS FIRST) AS ab_id + FROM mimiciv_derived.antibiotic AS abx +), me AS ( + SELECT + micro_specimen_id, + MAX(subject_id) AS subject_id, + MAX(hadm_id) AS hadm_id, + TRY_CAST(MAX(chartdate) AS DATE) AS chartdate, + MAX(charttime) AS charttime, + MAX(spec_type_desc) AS spec_type_desc, + MAX( + CASE + WHEN NOT org_name IS NULL AND org_itemid <> 90856 AND org_name <> '' + THEN 1 + ELSE 0 + END + ) AS positiveculture + FROM mimiciv_hosp.microbiologyevents + GROUP BY + micro_specimen_id +), me_then_ab AS ( + SELECT + ab_tbl.subject_id, + ab_tbl.hadm_id, + ab_tbl.stay_id, + ab_tbl.ab_id, + me72.micro_specimen_id, + COALESCE(me72.charttime, CAST(me72.chartdate AS TIMESTAMP)) AS last72_charttime, + me72.positiveculture AS last72_positiveculture, + me72.spec_type_desc AS last72_specimen, + ROW_NUMBER() OVER (PARTITION BY ab_tbl.subject_id, ab_tbl.ab_id ORDER BY me72.chartdate NULLS FIRST, me72.charttime) AS micro_seq + FROM ab_tbl + LEFT JOIN me AS me72 + ON ab_tbl.subject_id = me72.subject_id + AND ( + ( + NOT me72.charttime IS NULL + AND ab_tbl.antibiotic_time > me72.charttime + AND ab_tbl.antibiotic_time <= me72.charttime + INTERVAL '72' HOUR + ) + OR ( + me72.charttime IS NULL + AND antibiotic_date >= me72.chartdate + AND antibiotic_date <= me72.chartdate + INTERVAL 3 DAY + ) + ) +), ab_then_me AS ( + SELECT + ab_tbl.subject_id, + ab_tbl.hadm_id, + ab_tbl.stay_id, + ab_tbl.ab_id, + me24.micro_specimen_id, + COALESCE(me24.charttime, CAST(me24.chartdate AS TIMESTAMP)) AS next24_charttime, + me24.positiveculture AS next24_positiveculture, + me24.spec_type_desc AS next24_specimen, + ROW_NUMBER() OVER (PARTITION BY ab_tbl.subject_id, ab_tbl.ab_id ORDER BY me24.chartdate NULLS FIRST, me24.charttime) AS micro_seq + FROM ab_tbl + LEFT JOIN me AS me24 + ON ab_tbl.subject_id = me24.subject_id + AND ( + ( + NOT me24.charttime IS NULL + AND ab_tbl.antibiotic_time >= me24.charttime - INTERVAL '24' HOUR + AND ab_tbl.antibiotic_time < me24.charttime + ) + OR ( + me24.charttime IS NULL + AND ab_tbl.antibiotic_date >= me24.chartdate - INTERVAL 1 DAY + AND ab_tbl.antibiotic_date <= me24.chartdate + ) + ) +) +SELECT + ab_tbl.subject_id, + ab_tbl.stay_id, + ab_tbl.hadm_id, + ab_tbl.ab_id, + ab_tbl.antibiotic, + ab_tbl.antibiotic_time, + CASE WHEN last72_specimen IS NULL AND next24_specimen IS NULL THEN 0 ELSE 1 END AS suspected_infection, + CASE + WHEN last72_specimen IS NULL AND next24_specimen IS NULL + THEN NULL + ELSE COALESCE(last72_charttime, antibiotic_time) + END AS suspected_infection_time, + COALESCE(last72_charttime, next24_charttime) AS culture_time, + COALESCE(last72_specimen, next24_specimen) AS specimen, + COALESCE(last72_positiveculture, next24_positiveculture) AS positive_culture +FROM ab_tbl +LEFT JOIN ab_then_me AS ab2me + ON ab_tbl.subject_id = ab2me.subject_id + AND ab_tbl.ab_id = ab2me.ab_id + AND ab2me.micro_seq = 1 +LEFT JOIN me_then_ab AS me2ab + ON ab_tbl.subject_id = me2ab.subject_id + AND ab_tbl.ab_id = me2ab.ab_id + AND me2ab.micro_seq = 1 \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/treatment/code_status.sql b/mimic-iv/concepts_duckdb/treatment/code_status.sql new file mode 100644 index 000000000..f63ad9571 --- /dev/null +++ b/mimic-iv/concepts_duckdb/treatment/code_status.sql @@ -0,0 +1,65 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.code_status; CREATE TABLE mimiciv_derived.code_status AS +WITH t1 AS ( + SELECT + subject_id, + hadm_id, + stay_id, + charttime, + CASE WHEN value IN ('Full code') THEN 1 ELSE 0 END AS fullcode, + CASE WHEN value IN ('Comfort measures only') THEN 1 ELSE 0 END AS cmo, + CASE WHEN value IN ('DNI (do not intubate)', 'DNR / DNI') THEN 1 ELSE 0 END AS dni, + CASE WHEN value IN ('DNR (do not resuscitate)', 'DNR / DNI') THEN 1 ELSE 0 END AS dnr + FROM mimiciv_icu.chartevents + WHERE + itemid IN (223758) +), poe AS ( + SELECT + p.subject_id, + p.hadm_id, + ie.stay_id, + p.ordertime, + CASE + WHEN pd.field_value = 'Resuscitate (Full code)' + THEN 1 + WHEN pd.field_value = 'Full code (attempt resuscitation)' + THEN 1 + ELSE 0 + END AS fullcode, + CASE + WHEN pd.field_value = 'DNAR (DO NOT attempt resuscitation for cardiac arrest) ' + THEN 1 + WHEN pd.field_value = 'Do not resuscitate (DNR/DNI)' + THEN 1 + ELSE 0 + END AS dnr, + CASE WHEN pd.field_value = 'Do not resuscitate (DNR/DNI)' THEN 1 ELSE 0 END AS dni + FROM mimiciv_hosp.poe AS p + INNER JOIN mimiciv_hosp.poe_detail AS pd + ON p.poe_id = pd.poe_id + LEFT JOIN mimiciv_icu.icustays AS ie + ON p.hadm_id = ie.hadm_id AND p.ordertime >= ie.intime AND p.ordertime <= ie.outtime + WHERE + p.order_type = 'General Care' AND order_subtype = 'Code status' +) +SELECT + t1.subject_id, + t1.hadm_id, + t1.stay_id, + t1.charttime, + t1.fullcode, + t1.cmo, + t1.dni, + t1.dnr +FROM t1 +UNION ALL +SELECT + poe.subject_id, + poe.hadm_id, + poe.stay_id, + poe.ordertime AS charttime, + poe.fullcode, + 0 AS cmo, + poe.dni, + poe.dnr +FROM poe \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/treatment/crrt.sql b/mimic-iv/concepts_duckdb/treatment/crrt.sql new file mode 100644 index 000000000..4394ffafd --- /dev/null +++ b/mimic-iv/concepts_duckdb/treatment/crrt.sql @@ -0,0 +1,79 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.crrt; CREATE TABLE mimiciv_derived.crrt AS +WITH crrt_settings AS ( + SELECT + ce.stay_id, + ce.charttime, + CASE WHEN ce.itemid = 227290 THEN ce.value END AS crrt_mode, + CASE WHEN ce.itemid = 224149 THEN ce.valuenum ELSE NULL END AS accesspressure, + CASE WHEN ce.itemid = 224144 THEN ce.valuenum ELSE NULL END AS bloodflow, + CASE WHEN ce.itemid = 228004 THEN ce.valuenum ELSE NULL END AS citrate, + CASE WHEN ce.itemid = 225183 THEN ce.valuenum ELSE NULL END AS currentgoal, + CASE WHEN ce.itemid = 225977 THEN ce.value ELSE NULL END AS dialysatefluid, + CASE WHEN ce.itemid = 224154 THEN ce.valuenum ELSE NULL END AS dialysaterate, + CASE WHEN ce.itemid = 224151 THEN ce.valuenum ELSE NULL END AS effluentpressure, + CASE WHEN ce.itemid = 224150 THEN ce.valuenum ELSE NULL END AS filterpressure, + CASE WHEN ce.itemid = 225958 THEN ce.value ELSE NULL END AS heparinconcentration, + CASE WHEN ce.itemid = 224145 THEN ce.valuenum ELSE NULL END AS heparindose, + CASE WHEN ce.itemid = 224191 THEN ce.valuenum ELSE NULL END AS hourlypatientfluidremoval, + CASE WHEN ce.itemid = 228005 THEN ce.valuenum ELSE NULL END AS prefilterreplacementrate, + CASE WHEN ce.itemid = 228006 THEN ce.valuenum ELSE NULL END AS postfilterreplacementrate, + CASE WHEN ce.itemid = 225976 THEN ce.value ELSE NULL END AS replacementfluid, + CASE WHEN ce.itemid = 224153 THEN ce.valuenum ELSE NULL END AS replacementrate, + CASE WHEN ce.itemid = 224152 THEN ce.valuenum ELSE NULL END AS returnpressure, + CASE WHEN ce.itemid = 226457 THEN ce.valuenum END AS ultrafiltrateoutput, + CASE + WHEN ce.itemid = 224146 + AND ce.value IN ('Active', 'Initiated', 'Reinitiated', 'New Filter') + THEN 1 + WHEN ce.itemid = 224146 AND ce.value IN ('Recirculating', 'Discontinued') + THEN 0 + ELSE NULL + END AS system_active, + CASE + WHEN ce.itemid = 224146 AND ce.value IN ('Clots Present', 'Clots Present') + THEN 1 + WHEN ce.itemid = 224146 AND ce.value IN ('No Clot Present', 'No Clot Present') + THEN 0 + ELSE NULL + END AS clots, + CASE + WHEN ce.itemid = 224146 AND ce.value IN ('Clots Increasing', 'Clot Increasing') + THEN 1 + ELSE NULL + END AS clots_increasing, + CASE WHEN ce.itemid = 224146 AND ce.value IN ('Clotted') THEN 1 ELSE NULL END AS clotted + FROM mimiciv_icu.chartevents AS ce + WHERE + ce.itemid IN (227290, 224146, 224149, 224144, 228004, 225183, 225977, 224154, 224151, 224150, 225958, 224145, 224191, 228005, 228006, 225976, 224153, 224152, 226457) + AND NOT ce.value IS NULL +) +SELECT + stay_id, + charttime, + MAX(crrt_mode) AS crrt_mode, + MAX(accesspressure) AS access_pressure, + MAX(bloodflow) AS blood_flow, + MAX(citrate) AS citrate, + MAX(currentgoal) AS current_goal, + MAX(dialysatefluid) AS dialysate_fluid, + MAX(dialysaterate) AS dialysate_rate, + MAX(effluentpressure) AS effluent_pressure, + MAX(filterpressure) AS filter_pressure, + MAX(heparinconcentration) AS heparin_concentration, + MAX(heparindose) AS heparin_dose, + MAX(hourlypatientfluidremoval) AS hourly_patient_fluid_removal, + MAX(prefilterreplacementrate) AS prefilter_replacement_rate, + MAX(postfilterreplacementrate) AS postfilter_replacement_rate, + MAX(replacementfluid) AS replacement_fluid, + MAX(replacementrate) AS replacement_rate, + MAX(returnpressure) AS return_pressure, + MAX(ultrafiltrateoutput) AS ultrafiltrate_output, + MAX(system_active) AS system_active, + MAX(clots) AS clots, + MAX(clots_increasing) AS clots_increasing, + MAX(clotted) AS clotted +FROM crrt_settings +GROUP BY + stay_id, + charttime \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/treatment/invasive_line.sql b/mimic-iv/concepts_duckdb/treatment/invasive_line.sql new file mode 100644 index 000000000..2987b8ca1 --- /dev/null +++ b/mimic-iv/concepts_duckdb/treatment/invasive_line.sql @@ -0,0 +1,72 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.invasive_line; CREATE TABLE mimiciv_derived.invasive_line AS +WITH mv AS ( + SELECT + stay_id, + mv.itemid AS line_number, + di.label AS line_type, + mv.location AS line_site, + starttime, + endtime + FROM mimiciv_icu.procedureevents AS mv + INNER JOIN mimiciv_icu.d_items AS di + ON mv.itemid = di.itemid + WHERE + mv.itemid IN (227719, 225752, 224269, 224267, 224270, 224272, 226124, 228169, 225202, 228286, 225204, 224263, 224560, 224264, 225203, 224273, 225789, 225761, 228201, 228202, 224268, 225199, 225315, 225205) +) +SELECT + stay_id, + CASE + WHEN line_type IN ('Arterial Line', 'A-Line') + THEN 'Arterial' + WHEN line_type IN ('CCO PA Line', 'CCO PAC') + THEN 'Continuous Cardiac Output PA' + WHEN line_type IN ('Dialysis Catheter', 'Dialysis Line') + THEN 'Dialysis' + WHEN line_type IN ('Hickman', 'Tunneled (Hickman) Line') + THEN 'Hickman' + WHEN line_type IN ('IABP', 'IABP line') + THEN 'IABP' + WHEN line_type IN ('Multi Lumen', 'Multi-lumen') + THEN 'Multi Lumen' + WHEN line_type IN ('PA Catheter', 'PA line') + THEN 'PA' + WHEN line_type IN ('PICC Line', 'PICC line') + THEN 'PICC' + WHEN line_type IN ('Pre-Sep Catheter', 'Presep Catheter') + THEN 'Pre-Sep' + WHEN line_type IN ('Trauma Line', 'Trauma line') + THEN 'Trauma' + WHEN line_type IN ('Triple Introducer', 'TripleIntroducer') + THEN 'Triple Introducer' + WHEN line_type IN ('Portacath', 'Indwelling Port (PortaCath)') + THEN 'Portacath' + ELSE line_type + END AS line_type, + CASE + WHEN line_site IN ('Left Antecub', 'Left Antecube') + THEN 'Left Antecube' + WHEN line_site IN ('Left Axilla', 'Left Axilla.') + THEN 'Left Axilla' + WHEN line_site IN ('Left Brachial', 'Left Brachial.') + THEN 'Left Brachial' + WHEN line_site IN ('Left Femoral', 'Left Femoral.') + THEN 'Left Femoral' + WHEN line_site IN ('Right Antecub', 'Right Antecube') + THEN 'Right Antecube' + WHEN line_site IN ('Right Axilla', 'Right Axilla.') + THEN 'Right Axilla' + WHEN line_site IN ('Right Brachial', 'Right Brachial.') + THEN 'Right Brachial' + WHEN line_site IN ('Right Femoral', 'Right Femoral.') + THEN 'Right Femoral' + ELSE line_site + END AS line_site, + starttime, + endtime +FROM mv +ORDER BY + stay_id NULLS FIRST, + starttime NULLS FIRST, + line_type NULLS FIRST, + line_site NULLS FIRST \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/treatment/rrt.sql b/mimic-iv/concepts_duckdb/treatment/rrt.sql new file mode 100644 index 000000000..910927292 --- /dev/null +++ b/mimic-iv/concepts_duckdb/treatment/rrt.sql @@ -0,0 +1,102 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.rrt; CREATE TABLE mimiciv_derived.rrt AS +WITH ce AS ( + SELECT + ce.stay_id, + ce.charttime, + CASE + WHEN ce.itemid IN (226118, 227357, 225725) + THEN 1 + WHEN ce.itemid IN (226499, 224154, 225810, 225959, 227639, 225183, 227438, 224191, 225806, 225807, 228004, 228005, 228006, 224144, 224145, 224149, 224150, 224151, 224152, 224153, 224404, 224406, 226457) + THEN 1 + WHEN ce.itemid IN (224135, 224139, 224146, 225323, 225740, 225776, 225951, 225952, 225953, 225954, 225956, 225958, 225961, 225963, 225965, 225976, 225977, 227124, 227290, 227638, 227640, 227753) + THEN 1 + ELSE 0 + END AS dialysis_present, + CASE + WHEN ce.itemid = 225965 AND value = 'In use' + THEN 1 + WHEN ce.itemid IN (226499, 224154, 225183, 227438, 224191, 225806, 225807, 228004, 228005, 228006, 224144, 224145, 224153, 226457) + THEN 1 + ELSE 0 + END AS dialysis_active, + CASE + WHEN ce.itemid = 227290 + THEN value + WHEN ce.itemid IN (225810, 225806, 225807, 225810, 227639, 225959, 225951, 225952, 225961, 225953, 225963, 225965, 227638, 227640) + THEN 'Peritoneal' + WHEN ce.itemid = 226499 + THEN 'IHD' + ELSE NULL + END AS dialysis_type + FROM mimiciv_icu.chartevents AS ce + WHERE + ce.itemid IN (226118, 227357, 225725, 226499, 224154, 225810, 227639, 225183, 227438, 224191, 225806, 225807, 228004, 228005, 228006, 224144, 224145, 224149, 224150, 224151, 224152, 224153, 224404, 224406, 226457, 225959, 224135, 224139, 224146, 225323, 225740, 225776, 225951, 225952, 225953, 225954, 225956, 225958, 225961, 225963, 225965, 225976, 225977, 227124, 227290, 227638, 227640, 227753) + AND NOT ce.value IS NULL +), mv_ranges AS ( + SELECT + stay_id, + starttime, + endtime, + 1 AS dialysis_present, + 1 AS dialysis_active, + 'CRRT' AS dialysis_type + FROM mimiciv_icu.inputevents + WHERE + itemid IN (227536, 227525) AND amount > 0 + UNION + SELECT + stay_id, + starttime, + endtime, + 1 AS dialysis_present, + CASE WHEN NOT itemid IN (224270, 225436) THEN 1 ELSE 0 END AS dialysis_active, + CASE + WHEN itemid = 225441 + THEN 'IHD' + WHEN itemid = 225802 + THEN 'CRRT' + WHEN itemid = 225803 + THEN 'CVVHD' + WHEN itemid = 225805 + THEN 'Peritoneal' + WHEN itemid = 225809 + THEN 'CVVHDF' + WHEN itemid = 225955 + THEN 'SCUF' + ELSE NULL + END AS dialysis_type + FROM mimiciv_icu.procedureevents + WHERE + itemid IN (225441, 225802, 225803, 225805, 224270, 225809, 225955, 225436) + AND NOT value IS NULL +), stg0 AS ( + SELECT + stay_id, + charttime, + dialysis_present, + dialysis_active, + dialysis_type + FROM ce + WHERE + dialysis_present = 1 + UNION + SELECT + stay_id, + starttime AS charttime, + dialysis_present, + dialysis_active, + dialysis_type + FROM mv_ranges +) +SELECT + stg0.stay_id, + charttime, + COALESCE(mv.dialysis_present, stg0.dialysis_present) AS dialysis_present, + COALESCE(mv.dialysis_active, stg0.dialysis_active) AS dialysis_active, + COALESCE(mv.dialysis_type, stg0.dialysis_type) AS dialysis_type +FROM stg0 +LEFT JOIN mv_ranges AS mv + ON stg0.stay_id = mv.stay_id + AND stg0.charttime >= mv.starttime + AND stg0.charttime <= mv.endtime \ No newline at end of file diff --git a/mimic-iv/concepts_duckdb/treatment/ventilation.sql b/mimic-iv/concepts_duckdb/treatment/ventilation.sql new file mode 100644 index 000000000..7e562dfae --- /dev/null +++ b/mimic-iv/concepts_duckdb/treatment/ventilation.sql @@ -0,0 +1,100 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.ventilation; CREATE TABLE mimiciv_derived.ventilation AS +WITH tm AS ( + SELECT + stay_id, + charttime + FROM mimiciv_derived.ventilator_setting + UNION + SELECT + stay_id, + charttime + FROM mimiciv_derived.oxygen_delivery +), vs AS ( + SELECT + tm.stay_id, + tm.charttime, + o2_delivery_device_1, + COALESCE(ventilator_mode, ventilator_mode_hamilton) AS vent_mode, + CASE + WHEN o2_delivery_device_1 IN ('Tracheostomy tube', 'Trach mask ') + THEN 'Tracheostomy' + WHEN o2_delivery_device_1 IN ('Endotracheal tube') + OR ventilator_mode IN ('(S) CMV', 'APRV', 'APRV/Biphasic+ApnPress', 'APRV/Biphasic+ApnVol', 'APV (cmv)', 'Ambient', 'Apnea Ventilation', 'CMV', 'CMV/ASSIST', 'CMV/ASSIST/AutoFlow', 'CMV/AutoFlow', 'CPAP/PPS', 'CPAP/PSV', 'CPAP/PSV+Apn TCPL', 'CPAP/PSV+ApnPres', 'CPAP/PSV+ApnVol', 'MMV', 'MMV/AutoFlow', 'MMV/PSV', 'MMV/PSV/AutoFlow', 'P-CMV', 'PCV+', 'PCV+/PSV', 'PCV+Assist', 'PRES/AC', 'PRVC/AC', 'PRVC/SIMV', 'PSV/SBT', 'SIMV', 'SIMV/AutoFlow', 'SIMV/PRES', 'SIMV/PSV', 'SIMV/PSV/AutoFlow', 'SIMV/VOL', 'SYNCHRON MASTER', 'SYNCHRON SLAVE', 'VOL/AC') + OR ventilator_mode_hamilton IN ('APRV', 'APV (cmv)', 'Ambient', '(S) CMV', 'P-CMV', 'SIMV', 'APV (simv)', 'P-SIMV', 'VS', 'ASV') + THEN 'InvasiveVent' + WHEN o2_delivery_device_1 IN ('Bipap mask ', 'CPAP mask ') + OR ventilator_mode_hamilton IN ('DuoPaP', 'NIV', 'NIV-ST') + THEN 'NonInvasiveVent' + WHEN o2_delivery_device_1 IN ('High flow nasal cannula') + THEN 'HFNC' + WHEN o2_delivery_device_1 IN ('Non-rebreather', 'Face tent', 'Aerosol-cool', 'Venti mask ', 'Medium conc mask ', 'Ultrasonic neb', 'Vapomist', 'Oxymizer', 'High flow neb', 'Nasal cannula') + THEN 'SupplementalOxygen' + WHEN o2_delivery_device_1 IN ('None') + THEN 'None' + ELSE NULL + END AS ventilation_status + FROM tm + LEFT JOIN mimiciv_derived.ventilator_setting AS vs + ON tm.stay_id = vs.stay_id AND tm.charttime = vs.charttime + LEFT JOIN mimiciv_derived.oxygen_delivery AS od + ON tm.stay_id = od.stay_id AND tm.charttime = od.charttime +), vd0 AS ( + SELECT + stay_id, + charttime, + LAG(charttime, 1) OVER (PARTITION BY stay_id, ventilation_status ORDER BY charttime NULLS FIRST) AS charttime_lag, + LEAD(charttime, 1) OVER w AS charttime_lead, + ventilation_status, + LAG(ventilation_status, 1) OVER w AS ventilation_status_lag + FROM vs + WHERE + NOT ventilation_status IS NULL + WINDOW w AS (PARTITION BY stay_id ORDER BY charttime NULLS FIRST) +), vd1 AS ( + SELECT + stay_id, + charttime, + charttime_lag, + charttime_lead, + ventilation_status, + DATE_DIFF('microseconds', charttime_lag, charttime)/60000000.0 / 60 AS ventduration, + CASE + WHEN ventilation_status_lag IS NULL + THEN 1 + WHEN DATE_DIFF('microseconds', charttime_lag, charttime)/3600000000.0 >= 14 + THEN 1 + WHEN ventilation_status_lag <> ventilation_status + THEN 1 + ELSE 0 + END AS new_ventilation_event + FROM vd0 +), vd2 AS ( + SELECT + vd1.stay_id, + vd1.charttime, + vd1.charttime_lead, + vd1.ventilation_status, + ventduration, + new_ventilation_event, + SUM(new_ventilation_event) OVER (PARTITION BY stay_id ORDER BY charttime NULLS FIRST) AS vent_seq + FROM vd1 +) +SELECT + stay_id, + MIN(charttime) AS starttime, + MAX( + CASE + WHEN charttime_lead IS NULL + OR DATE_DIFF('microseconds', charttime, charttime_lead)/3600000000.0 >= 14 + THEN charttime + ELSE charttime_lead + END + ) AS endtime, + MAX(ventilation_status) AS ventilation_status +FROM vd2 +GROUP BY + stay_id, + vent_seq +HAVING + MIN(charttime) <> MAX(charttime) \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/README.md b/mimic-iv/concepts_postgres/README.md index 8f550fc5c..ec5c652b6 100644 --- a/mimic-iv/concepts_postgres/README.md +++ b/mimic-iv/concepts_postgres/README.md @@ -2,15 +2,14 @@ This folder contains scripts to generate useful abstractions of raw MIMIC-IV data ("concepts"). The scripts are intended to be run against the MIMIC-IV data in a PostgreSQL database. - -**These scripts are automatically generated by a shell script in the concepts folder.** -If you would like to contribute a correction, please look at the conversion shell script to ensure you edit the right script! +If you would like to contribute a correction, it should be for the corresponding file in the concepts folder. To generate concepts, change to this directory and run `psql`. Then within psql, run: ```sql -\i postgres-functions.sql -- only needs to be run once \i postgres-make-concepts.sql ``` -... or, execute the SQL files in your GUI of choice. +... or, run the SQL files in your GUI of choice. + +The postgres-functions.sql contains definitions for a few functions which exist in BigQuery but do not exist in PostgreSQL. It is not required but these functions are convenient if you find yourself switching back and forth between the two. \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/comorbidity/charlson.sql b/mimic-iv/concepts_postgres/comorbidity/charlson.sql index 4e1a4aa8b..17e2ef9f5 100644 --- a/mimic-iv/concepts_postgres/comorbidity/charlson.sql +++ b/mimic-iv/concepts_postgres/comorbidity/charlson.sql @@ -1,402 +1,234 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS charlson; CREATE TABLE charlson AS --- ------------------------------------------------------------------ --- This query extracts Charlson Comorbidity Index (CCI) based on the --- recorded ICD-9 and ICD-10 codes. --- --- Reference for CCI: --- (1) Charlson ME, Pompei P, Ales KL, MacKenzie CR. (1987) A new method --- of classifying prognostic comorbidity in longitudinal studies: --- development and validation.J Chronic Dis; 40(5):373-83. --- --- (2) Charlson M, Szatrowski TP, Peterson J, Gold J. (1994) Validation --- of a combined comorbidity index. J Clin Epidemiol; 47(11):1245-51. --- --- Reference for ICD-9-CM and ICD-10 Coding Algorithms for Charlson --- Comorbidities: --- (3) Quan H, Sundararajan V, Halfon P, et al. Coding algorithms for --- defining Comorbidities in ICD-9-CM and ICD-10 administrative data. --- Med Care. 2005 Nov; 43(11): 1130-9. --- ------------------------------------------------------------------ - +DROP TABLE IF EXISTS mimiciv_derived.charlson; CREATE TABLE mimiciv_derived.charlson AS +/* ------------------------------------------------------------------ */ /* This query extracts Charlson Comorbidity Index (CCI) based on the */ /* recorded ICD-9 and ICD-10 codes. */ /* Reference for CCI: */ /* (1) Charlson ME, Pompei P, Ales KL, MacKenzie CR. (1987) A new method */ /* of classifying prognostic comorbidity in longitudinal studies: */ /* development and validation.J Chronic Dis; 40(5):373-83. */ /* (2) Charlson M, Szatrowski TP, Peterson J, Gold J. (1994) Validation */ /* of a combined comorbidity index. J Clin Epidemiol; 47(11):1245-51. */ /* */ /* Reference for ICD-9-CM and ICD-10 Coding Algorithms for Charlson */ /* Comorbidities: */ /* (3) Quan H, Sundararajan V, Halfon P, et al. Coding algorithms for */ /* defining Comorbidities in ICD-9-CM and ICD-10 administrative data. */ /* Med Care. 2005 Nov; 43(11): 1130-9. */ /* ------------------------------------------------------------------ */ WITH diag AS ( - SELECT - hadm_id - , CASE WHEN icd_version = 9 THEN icd_code ELSE NULL END AS icd9_code - , CASE WHEN icd_version = 10 THEN icd_code ELSE NULL END AS icd10_code - FROM mimiciv_hosp.diagnoses_icd + SELECT + hadm_id, + CASE WHEN icd_version = 9 THEN icd_code ELSE NULL END AS icd9_code, + CASE WHEN icd_version = 10 THEN icd_code ELSE NULL END AS icd10_code + FROM mimiciv_hosp.diagnoses_icd +), com AS ( + SELECT + ad.hadm_id, /* Myocardial infarction */ + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) IN ('410', '412') + OR SUBSTR(icd10_code, 1, 3) IN ('I21', 'I22') + OR SUBSTR(icd10_code, 1, 4) = 'I252' + THEN 1 + ELSE 0 + END + ) AS myocardial_infarct, /* Congestive heart failure */ + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) = '428' + OR SUBSTR(icd9_code, 1, 5) IN ('39891', '40201', '40211', '40291', '40401', '40403', '40411', '40413', '40491', '40493') + OR SUBSTR(icd9_code, 1, 4) BETWEEN '4254' AND '4259' + OR SUBSTR(icd10_code, 1, 3) IN ('I43', 'I50') + OR SUBSTR(icd10_code, 1, 4) IN ('I099', 'I110', 'I130', 'I132', 'I255', 'I420', 'I425', 'I426', 'I427', 'I428', 'I429', 'P290') + THEN 1 + ELSE 0 + END + ) AS congestive_heart_failure, /* Peripheral vascular disease */ + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) IN ('440', '441') + OR SUBSTR(icd9_code, 1, 4) IN ('0930', '4373', '4471', '5571', '5579', 'V434') + OR SUBSTR(icd9_code, 1, 4) BETWEEN '4431' AND '4439' + OR SUBSTR(icd10_code, 1, 3) IN ('I70', 'I71') + OR SUBSTR(icd10_code, 1, 4) IN ('I731', 'I738', 'I739', 'I771', 'I790', 'I792', 'K551', 'K558', 'K559', 'Z958', 'Z959') + THEN 1 + ELSE 0 + END + ) AS peripheral_vascular_disease, /* Cerebrovascular disease */ + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) BETWEEN '430' AND '438' + OR SUBSTR(icd9_code, 1, 5) = '36234' + OR SUBSTR(icd10_code, 1, 3) IN ('G45', 'G46') + OR SUBSTR(icd10_code, 1, 3) BETWEEN 'I60' AND 'I69' + OR SUBSTR(icd10_code, 1, 4) = 'H340' + THEN 1 + ELSE 0 + END + ) AS cerebrovascular_disease, /* Dementia */ + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) = '290' + OR SUBSTR(icd9_code, 1, 4) IN ('2941', '3312') + OR SUBSTR(icd10_code, 1, 3) IN ('F00', 'F01', 'F02', 'F03', 'G30') + OR SUBSTR(icd10_code, 1, 4) IN ('F051', 'G311') + THEN 1 + ELSE 0 + END + ) AS dementia, /* Chronic pulmonary disease */ + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) BETWEEN '490' AND '505' + OR SUBSTR(icd9_code, 1, 4) IN ('4168', '4169', '5064', '5081', '5088') + OR SUBSTR(icd10_code, 1, 3) BETWEEN 'J40' AND 'J47' + OR SUBSTR(icd10_code, 1, 3) BETWEEN 'J60' AND 'J67' + OR SUBSTR(icd10_code, 1, 4) IN ('I278', 'I279', 'J684', 'J701', 'J703') + THEN 1 + ELSE 0 + END + ) AS chronic_pulmonary_disease, /* Rheumatic disease */ + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) = '725' + OR SUBSTR(icd9_code, 1, 4) IN ('4465', '7100', '7101', '7102', '7103', '7104', '7140', '7141', '7142', '7148') + OR SUBSTR(icd10_code, 1, 3) IN ('M05', 'M06', 'M32', 'M33', 'M34') + OR SUBSTR(icd10_code, 1, 4) IN ('M315', 'M351', 'M353', 'M360') + THEN 1 + ELSE 0 + END + ) AS rheumatic_disease, /* Peptic ulcer disease */ + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) IN ('531', '532', '533', '534') + OR SUBSTR(icd10_code, 1, 3) IN ('K25', 'K26', 'K27', 'K28') + THEN 1 + ELSE 0 + END + ) AS peptic_ulcer_disease, /* Mild liver disease */ + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) IN ('570', '571') + OR SUBSTR(icd9_code, 1, 4) IN ('0706', '0709', '5733', '5734', '5738', '5739', 'V427') + OR SUBSTR(icd9_code, 1, 5) IN ('07022', '07023', '07032', '07033', '07044', '07054') + OR SUBSTR(icd10_code, 1, 3) IN ('B18', 'K73', 'K74') + OR SUBSTR(icd10_code, 1, 4) IN ('K700', 'K701', 'K702', 'K703', 'K709', 'K713', 'K714', 'K715', 'K717', 'K760', 'K762', 'K763', 'K764', 'K768', 'K769', 'Z944') + THEN 1 + ELSE 0 + END + ) AS mild_liver_disease, /* Diabetes without chronic complication */ + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 4) IN ('2500', '2501', '2502', '2503', '2508', '2509') + OR SUBSTR(icd10_code, 1, 4) IN ('E100', 'E101', 'E106', 'E108', 'E109', 'E110', 'E111', 'E116', 'E118', 'E119', 'E120', 'E121', 'E126', 'E128', 'E129', 'E130', 'E131', 'E136', 'E138', 'E139', 'E140', 'E141', 'E146', 'E148', 'E149') + THEN 1 + ELSE 0 + END + ) AS diabetes_without_cc, /* Diabetes with chronic complication */ + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 4) IN ('2504', '2505', '2506', '2507') + OR SUBSTR(icd10_code, 1, 4) IN ('E102', 'E103', 'E104', 'E105', 'E107', 'E112', 'E113', 'E114', 'E115', 'E117', 'E122', 'E123', 'E124', 'E125', 'E127', 'E132', 'E133', 'E134', 'E135', 'E137', 'E142', 'E143', 'E144', 'E145', 'E147') + THEN 1 + ELSE 0 + END + ) AS diabetes_with_cc, /* Hemiplegia or paraplegia */ + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) IN ('342', '343') + OR SUBSTR(icd9_code, 1, 4) IN ('3341', '3440', '3441', '3442', '3443', '3444', '3445', '3446', '3449') + OR SUBSTR(icd10_code, 1, 3) IN ('G81', 'G82') + OR SUBSTR(icd10_code, 1, 4) IN ('G041', 'G114', 'G801', 'G802', 'G830', 'G831', 'G832', 'G833', 'G834', 'G839') + THEN 1 + ELSE 0 + END + ) AS paraplegia, /* Renal disease */ + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) IN ('582', '585', '586', 'V56') + OR SUBSTR(icd9_code, 1, 4) IN ('5880', 'V420', 'V451') + OR SUBSTR(icd9_code, 1, 4) BETWEEN '5830' AND '5837' + OR SUBSTR(icd9_code, 1, 5) IN ('40301', '40311', '40391', '40402', '40403', '40412', '40413', '40492', '40493') + OR SUBSTR(icd10_code, 1, 3) IN ('N18', 'N19') + OR SUBSTR(icd10_code, 1, 4) IN ('I120', 'I131', 'N032', 'N033', 'N034', 'N035', 'N036', 'N037', 'N052', 'N053', 'N054', 'N055', 'N056', 'N057', 'N250', 'Z490', 'Z491', 'Z492', 'Z940', 'Z992') + THEN 1 + ELSE 0 + END + ) AS renal_disease, /* Any malignancy, including lymphoma and leukemia, */ /* except malignant neoplasm of skin. */ + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) BETWEEN '140' AND '172' + OR SUBSTR(icd9_code, 1, 4) BETWEEN '1740' AND '1958' + OR SUBSTR(icd9_code, 1, 3) BETWEEN '200' AND '208' + OR SUBSTR(icd9_code, 1, 4) = '2386' + OR SUBSTR(icd10_code, 1, 3) IN ('C43', 'C88') + OR SUBSTR(icd10_code, 1, 3) BETWEEN 'C00' AND 'C26' + OR SUBSTR(icd10_code, 1, 3) BETWEEN 'C30' AND 'C34' + OR SUBSTR(icd10_code, 1, 3) BETWEEN 'C37' AND 'C41' + OR SUBSTR(icd10_code, 1, 3) BETWEEN 'C45' AND 'C58' + OR SUBSTR(icd10_code, 1, 3) BETWEEN 'C60' AND 'C76' + OR SUBSTR(icd10_code, 1, 3) BETWEEN 'C81' AND 'C85' + OR SUBSTR(icd10_code, 1, 3) BETWEEN 'C90' AND 'C97' + THEN 1 + ELSE 0 + END + ) AS malignant_cancer, /* Moderate or severe liver disease */ + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 4) IN ('4560', '4561', '4562') + OR SUBSTR(icd9_code, 1, 4) BETWEEN '5722' AND '5728' + OR SUBSTR(icd10_code, 1, 4) IN ('I850', 'I859', 'I864', 'I982', 'K704', 'K711', 'K721', 'K729', 'K765', 'K766', 'K767') + THEN 1 + ELSE 0 + END + ) AS severe_liver_disease, /* Metastatic solid tumor */ + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) IN ('196', '197', '198', '199') + OR SUBSTR(icd10_code, 1, 3) IN ('C77', 'C78', 'C79', 'C80') + THEN 1 + ELSE 0 + END + ) AS metastatic_solid_tumor, /* AIDS/HIV */ + MAX( + CASE + WHEN SUBSTR(icd9_code, 1, 3) IN ('042', '043', '044') + OR SUBSTR(icd10_code, 1, 3) IN ('B20', 'B21', 'B22', 'B24') + THEN 1 + ELSE 0 + END + ) AS aids + FROM mimiciv_hosp.admissions AS ad + LEFT JOIN diag + ON ad.hadm_id = diag.hadm_id + GROUP BY + ad.hadm_id +), ag AS ( + SELECT + hadm_id, + age, + CASE + WHEN age <= 50 + THEN 0 + WHEN age <= 60 + THEN 1 + WHEN age <= 70 + THEN 2 + WHEN age <= 80 + THEN 3 + ELSE 4 + END AS age_score + FROM mimiciv_derived.age ) - -, com AS ( - SELECT - ad.hadm_id - - -- Myocardial infarction - , MAX(CASE WHEN - SUBSTR(icd9_code, 1, 3) IN ('410', '412') - OR - SUBSTR(icd10_code, 1, 3) IN ('I21', 'I22') - OR - SUBSTR(icd10_code, 1, 4) = 'I252' - THEN 1 - ELSE 0 END) AS myocardial_infarct - - -- Congestive heart failure - , MAX(CASE WHEN - SUBSTR(icd9_code, 1, 3) = '428' - OR - SUBSTR( - icd9_code, 1, 5 - ) IN ('39891', '40201', '40211', '40291', '40401', '40403' - , '40411', '40413', '40491', '40493') - OR - SUBSTR(icd9_code, 1, 4) BETWEEN '4254' AND '4259' - OR - SUBSTR(icd10_code, 1, 3) IN ('I43', 'I50') - OR - SUBSTR( - icd10_code, 1, 4 - ) IN ('I099', 'I110', 'I130', 'I132', 'I255', 'I420' - , 'I425', 'I426', 'I427', 'I428', 'I429', 'P290' - ) - THEN 1 - ELSE 0 END) AS congestive_heart_failure - - -- Peripheral vascular disease - , MAX(CASE WHEN - SUBSTR(icd9_code, 1, 3) IN ('440', '441') - OR - SUBSTR( - icd9_code, 1, 4 - ) IN ('0930', '4373', '4471', '5571', '5579', 'V434') - OR - SUBSTR(icd9_code, 1, 4) BETWEEN '4431' AND '4439' - OR - SUBSTR(icd10_code, 1, 3) IN ('I70', 'I71') - OR - SUBSTR(icd10_code, 1, 4) IN ('I731', 'I738', 'I739', 'I771', 'I790' - , 'I792' - , 'K551' - , 'K558' - , 'K559' - , 'Z958' - , 'Z959' - ) - THEN 1 - ELSE 0 END) AS peripheral_vascular_disease - - -- Cerebrovascular disease - , MAX(CASE WHEN - SUBSTR(icd9_code, 1, 3) BETWEEN '430' AND '438' - OR - SUBSTR(icd9_code, 1, 5) = '36234' - OR - SUBSTR(icd10_code, 1, 3) IN ('G45', 'G46') - OR - SUBSTR(icd10_code, 1, 3) BETWEEN 'I60' AND 'I69' - OR - SUBSTR(icd10_code, 1, 4) = 'H340' - THEN 1 - ELSE 0 END) AS cerebrovascular_disease - - -- Dementia - , MAX(CASE WHEN - SUBSTR(icd9_code, 1, 3) = '290' - OR - SUBSTR(icd9_code, 1, 4) IN ('2941', '3312') - OR - SUBSTR(icd10_code, 1, 3) IN ('F00', 'F01', 'F02', 'F03', 'G30') - OR - SUBSTR(icd10_code, 1, 4) IN ('F051', 'G311') - THEN 1 - ELSE 0 END) AS dementia - - -- Chronic pulmonary disease - , MAX(CASE WHEN - SUBSTR(icd9_code, 1, 3) BETWEEN '490' AND '505' - OR - SUBSTR(icd9_code, 1, 4) IN ('4168', '4169', '5064', '5081', '5088') - OR - SUBSTR(icd10_code, 1, 3) BETWEEN 'J40' AND 'J47' - OR - SUBSTR(icd10_code, 1, 3) BETWEEN 'J60' AND 'J67' - OR - SUBSTR(icd10_code, 1, 4) IN ('I278', 'I279', 'J684', 'J701', 'J703') - THEN 1 - ELSE 0 END) AS chronic_pulmonary_disease - - -- Rheumatic disease - , MAX(CASE WHEN - SUBSTR(icd9_code, 1, 3) = '725' - OR - SUBSTR(icd9_code, 1, 4) IN ('4465', '7100', '7101', '7102', '7103' - , '7104', '7140', '7141', '7142', '7148' - ) - OR - SUBSTR(icd10_code, 1, 3) IN ('M05', 'M06', 'M32', 'M33', 'M34') - OR - SUBSTR(icd10_code, 1, 4) IN ('M315', 'M351', 'M353', 'M360') - THEN 1 - ELSE 0 END) AS rheumatic_disease - - -- Peptic ulcer disease - , MAX(CASE WHEN - SUBSTR(icd9_code, 1, 3) IN ('531', '532', '533', '534') - OR - SUBSTR(icd10_code, 1, 3) IN ('K25', 'K26', 'K27', 'K28') - THEN 1 - ELSE 0 END) AS peptic_ulcer_disease - - -- Mild liver disease - , MAX(CASE WHEN - SUBSTR(icd9_code, 1, 3) IN ('570', '571') - OR - SUBSTR( - icd9_code, 1, 4 - ) IN ('0706', '0709', '5733', '5734', '5738', '5739', 'V427') - OR - SUBSTR( - icd9_code, 1, 5 - ) IN ('07022', '07023', '07032', '07033', '07044', '07054') - OR - SUBSTR(icd10_code, 1, 3) IN ('B18', 'K73', 'K74') - OR - SUBSTR( - icd10_code, 1, 4 - ) IN ('K700', 'K701', 'K702', 'K703', 'K709', 'K713' - , 'K714', 'K715', 'K717', 'K760', 'K762' - , 'K763', 'K764', 'K768', 'K769', 'Z944') - THEN 1 - ELSE 0 END) AS mild_liver_disease - - -- Diabetes without chronic complication - , MAX(CASE WHEN - SUBSTR( - icd9_code, 1, 4 - ) IN ('2500', '2501', '2502', '2503', '2508', '2509') - OR - SUBSTR( - icd10_code, 1, 4 - ) IN ('E100', 'E10l', 'E106', 'E108', 'E109', 'E110', 'E111' - , 'E116' - , 'E118' - , 'E119' - , 'E120' - , 'E121' - , 'E126' - , 'E128' - , 'E129' - , 'E130' - , 'E131' - , 'E136' - , 'E138' - , 'E139' - , 'E140' - , 'E141', 'E146', 'E148', 'E149') - THEN 1 - ELSE 0 END) AS diabetes_without_cc - - -- Diabetes with chronic complication - , MAX(CASE WHEN - SUBSTR(icd9_code, 1, 4) IN ('2504', '2505', '2506', '2507') - OR - SUBSTR( - icd10_code, 1, 4 - ) IN ('E102', 'E103', 'E104', 'E105', 'E107', 'E112', 'E113' - , 'E114' - , 'E115' - , 'E117' - , 'E122' - , 'E123' - , 'E124' - , 'E125' - , 'E127' - , 'E132' - , 'E133' - , 'E134' - , 'E135' - , 'E137' - , 'E142' - , 'E143', 'E144', 'E145', 'E147') - THEN 1 - ELSE 0 END) AS diabetes_with_cc - - -- Hemiplegia or paraplegia - , MAX(CASE WHEN - SUBSTR(icd9_code, 1, 3) IN ('342', '343') - OR - SUBSTR(icd9_code, 1, 4) IN ('3341', '3440', '3441', '3442' - , '3443', '3444', '3445', '3446', '3449' - ) - OR - SUBSTR(icd10_code, 1, 3) IN ('G81', 'G82') - OR - SUBSTR(icd10_code, 1, 4) IN ('G041', 'G114', 'G801', 'G802', 'G830' - , 'G831' - , 'G832' - , 'G833' - , 'G834' - , 'G839' - ) - THEN 1 - ELSE 0 END) AS paraplegia - - -- Renal disease - , MAX(CASE WHEN - SUBSTR(icd9_code, 1, 3) IN ('582', '585', '586', 'V56') - OR - SUBSTR(icd9_code, 1, 4) IN ('5880', 'V420', 'V451') - OR - SUBSTR(icd9_code, 1, 4) BETWEEN '5830' AND '5837' - OR - SUBSTR( - icd9_code, 1, 5 - ) IN ( - '40301' - , '40311' - , '40391' - , '40402' - , '40403' - , '40412' - , '40413' - , '40492' - , '40493' - ) - OR - SUBSTR(icd10_code, 1, 3) IN ('N18', 'N19') - OR - SUBSTR(icd10_code, 1, 4) IN ('I120', 'I131', 'N032', 'N033', 'N034' - , 'N035' - , 'N036' - , 'N037' - , 'N052' - , 'N053' - , 'N054' - , 'N055' - , 'N056' - , 'N057' - , 'N250' - , 'Z490' - , 'Z491' - , 'Z492' - , 'Z940' - , 'Z992' - ) - THEN 1 - ELSE 0 END) AS renal_disease - - -- Any malignancy, including lymphoma and leukemia, - -- except malignant neoplasm of skin. - , MAX(CASE WHEN - SUBSTR(icd9_code, 1, 3) BETWEEN '140' AND '172' - OR - SUBSTR(icd9_code, 1, 4) BETWEEN '1740' AND '1958' - OR - SUBSTR(icd9_code, 1, 3) BETWEEN '200' AND '208' - OR - SUBSTR(icd9_code, 1, 4) = '2386' - OR - SUBSTR(icd10_code, 1, 3) IN ('C43', 'C88') - OR - SUBSTR(icd10_code, 1, 3) BETWEEN 'C00' AND 'C26' - OR - SUBSTR(icd10_code, 1, 3) BETWEEN 'C30' AND 'C34' - OR - SUBSTR(icd10_code, 1, 3) BETWEEN 'C37' AND 'C41' - OR - SUBSTR(icd10_code, 1, 3) BETWEEN 'C45' AND 'C58' - OR - SUBSTR(icd10_code, 1, 3) BETWEEN 'C60' AND 'C76' - OR - SUBSTR(icd10_code, 1, 3) BETWEEN 'C81' AND 'C85' - OR - SUBSTR(icd10_code, 1, 3) BETWEEN 'C90' AND 'C97' - THEN 1 - ELSE 0 END) AS malignant_cancer - - -- Moderate or severe liver disease - , MAX(CASE WHEN - SUBSTR(icd9_code, 1, 4) IN ('4560', '4561', '4562') - OR - SUBSTR(icd9_code, 1, 4) BETWEEN '5722' AND '5728' - OR - SUBSTR( - icd10_code, 1, 4 - ) IN ('I850', 'I859', 'I864', 'I982', 'K704', 'K711' - , 'K721', 'K729', 'K765', 'K766', 'K767') - THEN 1 - ELSE 0 END) AS severe_liver_disease - - -- Metastatic solid tumor - , MAX(CASE WHEN - SUBSTR(icd9_code, 1, 3) IN ('196', '197', '198', '199') - OR - SUBSTR(icd10_code, 1, 3) IN ('C77', 'C78', 'C79', 'C80') - THEN 1 - ELSE 0 END) AS metastatic_solid_tumor - - -- AIDS/HIV - , MAX(CASE WHEN - SUBSTR(icd9_code, 1, 3) IN ('042', '043', '044') - OR - SUBSTR(icd10_code, 1, 3) IN ('B20', 'B21', 'B22', 'B24') - THEN 1 - ELSE 0 END) AS aids - FROM mimiciv_hosp.admissions ad - LEFT JOIN diag - ON ad.hadm_id = diag.hadm_id - GROUP BY ad.hadm_id -) - -, ag AS ( - SELECT - hadm_id - , age - , CASE WHEN age <= 50 THEN 0 - WHEN age <= 60 THEN 1 - WHEN age <= 70 THEN 2 - WHEN age <= 80 THEN 3 - ELSE 4 END AS age_score - FROM mimiciv_derived.age -) - SELECT - ad.subject_id - , ad.hadm_id - , ag.age_score - , myocardial_infarct - , congestive_heart_failure - , peripheral_vascular_disease - , cerebrovascular_disease - , dementia - , chronic_pulmonary_disease - , rheumatic_disease - , peptic_ulcer_disease - , mild_liver_disease - , diabetes_without_cc - , diabetes_with_cc - , paraplegia - , renal_disease - , malignant_cancer - , severe_liver_disease - , metastatic_solid_tumor - , aids - -- Calculate the Charlson Comorbidity Score using the original - -- weights from Charlson, 1987. - , age_score - + myocardial_infarct + congestive_heart_failure - + peripheral_vascular_disease + cerebrovascular_disease - + dementia + chronic_pulmonary_disease - + rheumatic_disease + peptic_ulcer_disease - + GREATEST(mild_liver_disease, 3 * severe_liver_disease) - + GREATEST(2 * diabetes_with_cc, diabetes_without_cc) - + GREATEST(2 * malignant_cancer, 6 * metastatic_solid_tumor) - + 2 * paraplegia + 2 * renal_disease - + 6 * aids - AS charlson_comorbidity_index -FROM mimiciv_hosp.admissions ad + ad.subject_id, + ad.hadm_id, + ag.age_score, + myocardial_infarct, + congestive_heart_failure, + peripheral_vascular_disease, + cerebrovascular_disease, + dementia, + chronic_pulmonary_disease, + rheumatic_disease, + peptic_ulcer_disease, + mild_liver_disease, + diabetes_without_cc, + diabetes_with_cc, + paraplegia, + renal_disease, + malignant_cancer, + severe_liver_disease, + metastatic_solid_tumor, + aids, /* Calculate the Charlson Comorbidity Score using the original */ /* weights from Charlson, 1987. */ + age_score + myocardial_infarct + congestive_heart_failure + peripheral_vascular_disease + cerebrovascular_disease + dementia + chronic_pulmonary_disease + rheumatic_disease + peptic_ulcer_disease + GREATEST(mild_liver_disease, 3 * severe_liver_disease) + GREATEST(2 * diabetes_with_cc, diabetes_without_cc) + GREATEST(2 * malignant_cancer, 6 * metastatic_solid_tumor) + 2 * paraplegia + 2 * renal_disease + 6 * aids AS charlson_comorbidity_index +FROM mimiciv_hosp.admissions AS ad LEFT JOIN com - ON ad.hadm_id = com.hadm_id + ON ad.hadm_id = com.hadm_id LEFT JOIN ag - ON com.hadm_id = ag.hadm_id -; + ON com.hadm_id = ag.hadm_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/demographics/age.sql b/mimic-iv/concepts_postgres/demographics/age.sql index 762e6f055..4370bfe13 100644 --- a/mimic-iv/concepts_postgres/demographics/age.sql +++ b/mimic-iv/concepts_postgres/demographics/age.sql @@ -1,36 +1,13 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS age; CREATE TABLE age AS --- This query calculates the age of a patient on admission to the hospital. - --- The columns of the table patients: anchor_age, anchor_year, anchor_year_group --- provide information regarding the actual patient year for the patient --- admission, and the patient's age at that time. - --- anchor_year is a shifted year for the patient. --- anchor_year_group is a range of years - the patient's anchor_year occurred --- during this range. --- anchor_age is the patient's age in the anchor_year. --- Example: a patient has an anchor_year of 2153, --- anchor_year_group of 2008 - 2010, and an anchor_age of 60. --- The year 2153 for the patient corresponds to 2008, 2009, or 2010. --- The patient was 60 in the shifted year of 2153, --- i.e. they were 60 in 2008, 2009, or 2010. --- A patient admission in 2154 will occur in 2009-2011, --- an admission in 2155 will occur in 2010-2012, and so on. - --- Therefore, the age of a patient = admission time - anchor_year + anchor_age +DROP TABLE IF EXISTS mimiciv_derived.age; CREATE TABLE mimiciv_derived.age AS +/* This query calculates the age of a patient on admission to the hospital. */ /* The columns of the table patients: anchor_age, anchor_year, anchor_year_group */ /* provide information regarding the actual patient year for the patient */ /* admission, and the patient's age at that time. */ /* anchor_year is a shifted year for the patient. */ /* anchor_year_group is a range of years - the patient's anchor_year occurred */ /* during this range. */ /* anchor_age is the patient's age in the anchor_year. */ /* Example: a patient has an anchor_year of 2153, */ /* anchor_year_group of 2008 - 2010, and an anchor_age of 60. */ /* The year 2153 for the patient corresponds to 2008, 2009, or 2010. */ /* The patient was 60 in the shifted year of 2153, */ /* i.e. they were 60 in 2008, 2009, or 2010. */ /* A patient admission in 2154 will occur in 2009-2011, */ /* an admission in 2155 will occur in 2010-2012, and so on. */ /* Therefore, the age of a patient = admission time - anchor_year + anchor_age */ SELECT - ad.subject_id - , ad.hadm_id - , ad.admittime - , pa.anchor_age - , pa.anchor_year - -- calculate the age as anchor_age (60) plus difference between - -- admit year and the anchor year. - -- the noqa retains the extra long line so the - -- convert to postgres bash script works - , pa.anchor_age + DATETIME_DIFF(ad.admittime, DATETIME(pa.anchor_year, 1, 1, 0, 0, 0), 'YEAR') AS age -- noqa: L016 -FROM mimiciv_hosp.admissions ad -INNER JOIN mimiciv_hosp.patients pa - ON ad.subject_id = pa.subject_id -; + ad.subject_id, + ad.hadm_id, + ad.admittime, + pa.anchor_age, + pa.anchor_year, /* calculate the age as anchor_age (60) plus difference between */ /* admit year and the anchor year. */ /* the noqa retains the extra long line so the */ /* convert to postgres bash script works */ + pa.anchor_age + EXTRACT(EPOCH FROM ad.admittime - TO_TIMESTAMP(TO_CHAR(pa.anchor_year, '0000') || TO_CHAR(1, '00') || TO_CHAR(1, '00') || TO_CHAR(0, '00') || TO_CHAR(0, '00') || TO_CHAR(0, '00'), 'yyyymmddHH24MISS')) / 31556908.8 AS age /* noqa: L016 */ +FROM mimiciv_hosp.admissions AS ad +INNER JOIN mimiciv_hosp.patients AS pa + ON ad.subject_id = pa.subject_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/demographics/icustay_detail.sql b/mimic-iv/concepts_postgres/demographics/icustay_detail.sql index f039c4132..378be879c 100644 --- a/mimic-iv/concepts_postgres/demographics/icustay_detail.sql +++ b/mimic-iv/concepts_postgres/demographics/icustay_detail.sql @@ -1,49 +1,37 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS icustay_detail; CREATE TABLE icustay_detail AS -SELECT ie.subject_id, ie.hadm_id, ie.stay_id - - -- patient level factors - , pat.gender, pat.dod - - -- hospital level factors - , adm.admittime, adm.dischtime - , DATETIME_DIFF(adm.dischtime, adm.admittime, 'DAY') AS los_hospital - -- calculate the age as anchor_age (60) plus difference between - -- admit year and the anchor year. - -- the noqa retains the extra long line so the - -- convert to postgres bash script works - , pat.anchor_age + DATETIME_DIFF(adm.admittime, DATETIME(pat.anchor_year, 1, 1, 0, 0, 0), 'YEAR') AS admission_age -- noqa: L016 - , adm.race - , adm.hospital_expire_flag - , DENSE_RANK() OVER ( - PARTITION BY adm.subject_id ORDER BY adm.admittime - ) AS hospstay_seq - , CASE - WHEN - DENSE_RANK() OVER ( - PARTITION BY adm.subject_id ORDER BY adm.admittime - ) = 1 THEN True - ELSE False END AS first_hosp_stay - - -- icu level factors - , ie.intime AS icu_intime, ie.outtime AS icu_outtime - , ROUND( - CAST(DATETIME_DIFF(ie.outtime, ie.intime, 'HOUR') / 24.0 AS NUMERIC), 2 - ) AS los_icu - , DENSE_RANK() OVER ( - PARTITION BY ie.hadm_id ORDER BY ie.intime - ) AS icustay_seq - - -- first ICU stay *for the current hospitalization* - , CASE - WHEN - DENSE_RANK() OVER ( - PARTITION BY ie.hadm_id ORDER BY ie.intime - ) = 1 THEN True - ELSE False END AS first_icu_stay - -FROM mimiciv_icu.icustays ie -INNER JOIN mimiciv_hosp.admissions adm - ON ie.hadm_id = adm.hadm_id -INNER JOIN mimiciv_hosp.patients pat - ON ie.subject_id = pat.subject_id +DROP TABLE IF EXISTS mimiciv_derived.icustay_detail; CREATE TABLE mimiciv_derived.icustay_detail AS +SELECT + ie.subject_id, + ie.hadm_id, + ie.stay_id, /* patient level factors */ + pat.gender, + pat.dod, /* hospital level factors */ + adm.admittime, + adm.dischtime, + EXTRACT(EPOCH FROM adm.dischtime - adm.admittime) / 86400.0 AS los_hospital, /* calculate the age as anchor_age (60) plus difference between */ /* admit year and the anchor year. */ /* the noqa retains the extra long line so the */ /* convert to postgres bash script works */ + pat.anchor_age + EXTRACT(EPOCH FROM adm.admittime - TO_TIMESTAMP(TO_CHAR(pat.anchor_year, '0000') || TO_CHAR(1, '00') || TO_CHAR(1, '00') || TO_CHAR(0, '00') || TO_CHAR(0, '00') || TO_CHAR(0, '00'), 'yyyymmddHH24MISS')) / 31556908.8 AS admission_age, /* noqa: L016 */ + adm.race, + adm.hospital_expire_flag, + DENSE_RANK() OVER (PARTITION BY adm.subject_id ORDER BY adm.admittime NULLS FIRST) AS hospstay_seq, + CASE + WHEN DENSE_RANK() OVER (PARTITION BY adm.subject_id ORDER BY adm.admittime NULLS FIRST) = 1 + THEN TRUE + ELSE FALSE + END AS first_hosp_stay, /* icu level factors */ + ie.intime AS icu_intime, + ie.outtime AS icu_outtime, + ROUND( + CAST(CAST(EXTRACT(EPOCH FROM ie.outtime - ie.intime) / 3600.0 AS DOUBLE PRECISION) / 24.0 AS DECIMAL), + 2 + ) AS los_icu, + DENSE_RANK() OVER (PARTITION BY ie.hadm_id ORDER BY ie.intime NULLS FIRST) AS icustay_seq, /* first ICU stay *for the current hospitalization* */ + CASE + WHEN DENSE_RANK() OVER (PARTITION BY ie.hadm_id ORDER BY ie.intime NULLS FIRST) = 1 + THEN TRUE + ELSE FALSE + END AS first_icu_stay +FROM mimiciv_icu.icustays AS ie +INNER JOIN mimiciv_hosp.admissions AS adm + ON ie.hadm_id = adm.hadm_id +INNER JOIN mimiciv_hosp.patients AS pat + ON ie.subject_id = pat.subject_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/demographics/icustay_hourly.sql b/mimic-iv/concepts_postgres/demographics/icustay_hourly.sql index 899533734..0c553168e 100644 --- a/mimic-iv/concepts_postgres/demographics/icustay_hourly.sql +++ b/mimic-iv/concepts_postgres/demographics/icustay_hourly.sql @@ -1,39 +1,20 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS icustay_hourly; CREATE TABLE icustay_hourly AS --- This query generates a row for every hour the patient is in the ICU. --- The hours are based on clock-hours (i.e. 02:00, 03:00). --- The hour clock starts 24 hours before the first heart rate measurement. --- Note that the time of the first heart rate measurement is ceilinged to --- the hour. - --- this query extracts the cohort and every possible hour they were in the ICU --- this table can be to other tables on stay_id and (ENDTIME - 1 hour,ENDTIME] - --- get first/last measurement time +DROP TABLE IF EXISTS mimiciv_derived.icustay_hourly; CREATE TABLE mimiciv_derived.icustay_hourly AS +/* This query generates a row for every hour the patient is in the ICU. */ /* The hours are based on clock-hours (i.e. 02:00, 03:00). */ /* The hour clock starts 24 hours before the first heart rate measurement. */ /* Note that the time of the first heart rate measurement is ceilinged to */ /* the hour. */ /* this query extracts the cohort and every possible hour they were in the ICU */ /* this table can be to other tables on stay_id and (ENDTIME - 1 hour,ENDTIME] */ /* get first/last measurement time */ WITH all_hours AS ( - SELECT - it.stay_id - - -- ceiling the intime to the nearest hour by adding 59 minutes, - -- then applying truncate by parsing as string - -- string truncate is done to enable compatibility with psql - , PARSE_DATETIME( - '%Y-%m-%d %H:00:00' - , FORMAT_DATETIME( - '%Y-%m-%d %H:00:00' - , DATETIME_ADD(it.intime_hr, INTERVAL '59' MINUTE) - )) AS endtime - - -- create integers for each charttime in hours from admission - -- so 0 is admission time, 1 is one hour after admission, etc, - -- up to ICU disch - -- we allow 24 hours before ICU admission (to grab labs before admit) - , ARRAY(SELECT * FROM generate_series(-24, CEIL(DATETIME_DIFF(it.outtime_hr, it.intime_hr, 'HOUR')))) AS hrs -- noqa: L016 - FROM mimiciv_derived.icustay_times it + SELECT + it.stay_id, /* round the intime up to the nearest hour */ + CASE + WHEN DATE_TRUNC('HOUR', it.intime_hr) = it.intime_hr + THEN it.intime_hr + ELSE DATE_TRUNC('HOUR', it.intime_hr) + INTERVAL '1 HOUR' + END AS endtime, /* create integers for each charttime in hours from admission */ /* so 0 is admission time, 1 is one hour after admission, etc, */ /* up to ICU disch */ /* we allow 24 hours before ICU admission (to grab labs before admit) */ + GENERATE_SERIES(-24, CAST(CEIL(EXTRACT(EPOCH FROM it.outtime_hr - it.intime_hr) / 3600.0) AS INT)) AS hrs /* noqa: L016 */ + FROM mimiciv_derived.icustay_times AS it ) - -SELECT stay_id - , CAST(hr AS bigint) AS hr - , DATETIME_ADD(endtime, interval '1' hour * CAST(hr AS bigint)) AS endtime +SELECT + stay_id, + CAST(hr_unnested AS BIGINT) AS hr, + endtime + CAST(hr_unnested AS BIGINT) * INTERVAL '1 HOUR' AS endtime FROM all_hours -CROSS JOIN UNNEST(all_hours.hrs) AS hr; +CROSS JOIN UNNEST(all_hours.hrs) AS _t(hr_unnested) \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/demographics/icustay_times.sql b/mimic-iv/concepts_postgres/demographics/icustay_times.sql index 73bd98154..437bdedeb 100644 --- a/mimic-iv/concepts_postgres/demographics/icustay_times.sql +++ b/mimic-iv/concepts_postgres/demographics/icustay_times.sql @@ -1,23 +1,25 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS icustay_times; CREATE TABLE icustay_times AS --- create a table which has fuzzy boundaries on hospital admission --- involves first creating a lag/lead version of disch/admit time --- get first/last heart rate measurement during hospitalization for each stay_id +DROP TABLE IF EXISTS mimiciv_derived.icustay_times; CREATE TABLE mimiciv_derived.icustay_times AS +/* add in subject_id/hadm_id */ +/* create a table which has fuzzy boundaries on hospital admission */ /* involves first creating a lag/lead version of disch/admit time */ /* get first/last heart rate measurement during hospitalization for each stay_id */ WITH t1 AS ( - SELECT ce.stay_id - , MIN(charttime) AS intime_hr - , MAX(charttime) AS outtime_hr - FROM mimiciv_icu.chartevents ce - -- only look at heart rate - WHERE ce.itemid = 220045 - GROUP BY ce.stay_id + SELECT + ce.stay_id, + MIN(charttime) AS intime_hr, + MAX(charttime) AS outtime_hr + FROM mimiciv_icu.chartevents AS ce + /* only look at heart rate */ + WHERE + ce.itemid = 220045 + GROUP BY + ce.stay_id ) - --- add in subject_id/hadm_id SELECT - ie.subject_id, ie.hadm_id, ie.stay_id - , t1.intime_hr - , t1.outtime_hr -FROM mimiciv_icu.icustays ie + ie.subject_id, + ie.hadm_id, + ie.stay_id, + t1.intime_hr, + t1.outtime_hr +FROM mimiciv_icu.icustays AS ie LEFT JOIN t1 - ON ie.stay_id = t1.stay_id; + ON ie.stay_id = t1.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/demographics/weight_durations.sql b/mimic-iv/concepts_postgres/demographics/weight_durations.sql index 6b6c82f92..3a4986ba4 100644 --- a/mimic-iv/concepts_postgres/demographics/weight_durations.sql +++ b/mimic-iv/concepts_postgres/demographics/weight_durations.sql @@ -1,129 +1,99 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS weight_durations; CREATE TABLE weight_durations AS --- This query extracts weights for adult ICU patients with start/stop times --- if an admission weight is given, then this is assigned from intime to outtime +DROP TABLE IF EXISTS mimiciv_derived.weight_durations; CREATE TABLE mimiciv_derived.weight_durations AS +/* This query extracts weights for adult ICU patients with start/stop times */ /* if an admission weight is given, then this is assigned from intime to outtime */ WITH wt_stg AS ( + SELECT + c.stay_id, + c.charttime, + CASE WHEN c.itemid = 226512 THEN 'admit' ELSE 'daily' END AS weight_type, /* TODO: eliminate obvious outliers if there is a reasonable weight */ + c.valuenum AS weight + FROM mimiciv_icu.chartevents AS c + WHERE + NOT c.valuenum IS NULL + AND c.itemid IN (226512 /* Admit Wt */, 224639 /* Daily Weight */) + AND c.valuenum > 0 +), wt_stg1 AS ( + SELECT + stay_id, + charttime, + weight_type, + weight, + ROW_NUMBER() OVER (PARTITION BY stay_id, weight_type ORDER BY charttime NULLS FIRST) AS rn + FROM wt_stg + WHERE + NOT weight IS NULL +), wt_stg2 AS ( + SELECT + wt_stg1.stay_id, + ie.intime, + ie.outtime, + wt_stg1.weight_type, + CASE + WHEN wt_stg1.weight_type = 'admit' AND wt_stg1.rn = 1 + THEN ie.intime - INTERVAL '2 HOUR' + ELSE wt_stg1.charttime + END AS starttime, + wt_stg1.weight + FROM wt_stg1 + INNER JOIN mimiciv_icu.icustays AS ie + ON ie.stay_id = wt_stg1.stay_id +), wt_stg3 AS ( + SELECT + stay_id, + intime, + outtime, + starttime, + COALESCE( + LEAD(starttime) OVER (PARTITION BY stay_id ORDER BY starttime NULLS FIRST), + outtime + INTERVAL '2 HOUR' + ) AS endtime, + weight, + weight_type + FROM wt_stg2 +), wt1 AS ( + SELECT + stay_id, + starttime, + COALESCE( + endtime, + LEAD(starttime) OVER (PARTITION BY stay_id ORDER BY starttime NULLS FIRST) /* impute ICU discharge as the end of the final weight measurement */ /* plus a 2 hour "fuzziness" window */, + outtime + INTERVAL '2 HOUR' + ) AS endtime, + weight, + weight_type + FROM wt_stg3 +), wt_fix AS ( + SELECT + ie.stay_id, /* we add a 2 hour "fuzziness" window */ + ie.intime - INTERVAL '2 HOUR' AS starttime, + wt.starttime AS endtime, + wt.weight, + wt.weight_type + FROM mimiciv_icu.icustays AS ie + INNER JOIN ( SELECT - c.stay_id - , c.charttime - , CASE WHEN c.itemid = 226512 THEN 'admit' - ELSE 'daily' END AS weight_type - -- TODO: eliminate obvious outliers if there is a reasonable weight - , c.valuenum AS weight - FROM mimiciv_icu.chartevents c - WHERE c.valuenum IS NOT NULL - AND c.itemid IN - ( - 226512 -- Admit Wt - , 224639 -- Daily Weight - ) - AND c.valuenum > 0 + wt1.stay_id, + wt1.starttime, + wt1.weight, + weight_type, + ROW_NUMBER() OVER (PARTITION BY wt1.stay_id ORDER BY wt1.starttime NULLS FIRST) AS rn + FROM wt1 + ) AS wt + ON ie.stay_id = wt.stay_id AND wt.rn = 1 AND ie.intime < wt.starttime ) - --- assign ascending row number -, wt_stg1 AS ( - SELECT - stay_id - , charttime - , weight_type - , weight - , ROW_NUMBER() OVER ( - PARTITION BY stay_id, weight_type ORDER BY charttime - ) AS rn - FROM wt_stg - WHERE weight IS NOT NULL -) - --- change charttime to intime for the first admission weight recorded -, wt_stg2 AS ( - SELECT - wt_stg1.stay_id - , ie.intime, ie.outtime - , wt_stg1.weight_type - , CASE WHEN wt_stg1.weight_type = 'admit' AND wt_stg1.rn = 1 - THEN DATETIME_SUB(ie.intime, INTERVAL '2' HOUR) - ELSE wt_stg1.charttime END AS starttime - , wt_stg1.weight - FROM wt_stg1 - INNER JOIN mimiciv_icu.icustays ie - ON ie.stay_id = wt_stg1.stay_id -) - -, wt_stg3 AS ( - SELECT - stay_id - , intime, outtime - , starttime - , COALESCE( - LEAD(starttime) OVER (PARTITION BY stay_id ORDER BY starttime) - , DATETIME_ADD(outtime, INTERVAL '2' HOUR) - ) AS endtime - , weight - , weight_type - FROM wt_stg2 -) - --- this table is the start/stop times from admit/daily weight in charted data -, wt1 AS ( - SELECT - stay_id - , starttime - , COALESCE( - endtime - , LEAD( - starttime - ) OVER (PARTITION BY stay_id ORDER BY starttime) - -- impute ICU discharge as the end of the final weight measurement - -- plus a 2 hour "fuzziness" window - , DATETIME_ADD(outtime, INTERVAL '2' HOUR) - ) AS endtime - , weight - , weight_type - FROM wt_stg3 -) - --- if the intime for the patient is < the first charted daily weight --- then we will have a "gap" at the start of their stay --- to prevent this, we look for these gaps and backfill the first weight --- this adds (153255-149657)=3598 rows, meaning this fix helps for up --- to 3598 stay_id -, wt_fix AS ( - SELECT ie.stay_id - -- we add a 2 hour "fuzziness" window - , DATETIME_SUB(ie.intime, INTERVAL '2' HOUR) AS starttime - , wt.starttime AS endtime - , wt.weight - , wt.weight_type - FROM mimiciv_icu.icustays ie - INNER JOIN - -- the below subquery returns one row for each unique stay_id - -- the row contains: the first starttime and the corresponding weight - ( - SELECT wt1.stay_id, wt1.starttime, wt1.weight - , weight_type - , ROW_NUMBER() OVER ( - PARTITION BY wt1.stay_id ORDER BY wt1.starttime - ) AS rn - FROM wt1 - ) wt - ON ie.stay_id = wt.stay_id - AND wt.rn = 1 - AND ie.intime < wt.starttime -) - --- add the backfill rows to the main weight table +/* add the backfill rows to the main weight table */ SELECT - wt1.stay_id - , wt1.starttime - , wt1.endtime - , wt1.weight - , wt1.weight_type + wt1.stay_id, + wt1.starttime, + wt1.endtime, + wt1.weight, + wt1.weight_type FROM wt1 UNION ALL SELECT - wt_fix.stay_id - , wt_fix.starttime - , wt_fix.endtime - , wt_fix.weight - , wt_fix.weight_type -FROM wt_fix; + wt_fix.stay_id, + wt_fix.starttime, + wt_fix.endtime, + wt_fix.weight, + wt_fix.weight_type +FROM wt_fix \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/firstday/first_day_bg.sql b/mimic-iv/concepts_postgres/firstday/first_day_bg.sql index 18f85a38a..adac46a2b 100644 --- a/mimic-iv/concepts_postgres/firstday/first_day_bg.sql +++ b/mimic-iv/concepts_postgres/firstday/first_day_bg.sql @@ -1,38 +1,56 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS first_day_bg; CREATE TABLE first_day_bg AS --- Highest/lowest blood gas values for all blood specimens, --- including venous/arterial/mixed +DROP TABLE IF EXISTS mimiciv_derived.first_day_bg; CREATE TABLE mimiciv_derived.first_day_bg AS +/* Highest/lowest blood gas values for all blood specimens, */ /* including venous/arterial/mixed */ SELECT - ie.subject_id - , ie.stay_id - , MIN(lactate) AS lactate_min, MAX(lactate) AS lactate_max - , MIN(ph) AS ph_min, MAX(ph) AS ph_max - , MIN(so2) AS so2_min, MAX(so2) AS so2_max - , MIN(po2) AS po2_min, MAX(po2) AS po2_max - , MIN(pco2) AS pco2_min, MAX(pco2) AS pco2_max - , MIN(aado2) AS aado2_min, MAX(aado2) AS aado2_max - , MIN(aado2_calc) AS aado2_calc_min, MAX(aado2_calc) AS aado2_calc_max - , MIN(pao2fio2ratio) AS pao2fio2ratio_min - , MAX(pao2fio2ratio) AS pao2fio2ratio_max - , MIN(baseexcess) AS baseexcess_min, MAX(baseexcess) AS baseexcess_max - , MIN(bicarbonate) AS bicarbonate_min, MAX(bicarbonate) AS bicarbonate_max - , MIN(totalco2) AS totalco2_min, MAX(totalco2) AS totalco2_max - , MIN(hematocrit) AS hematocrit_min, MAX(hematocrit) AS hematocrit_max - , MIN(hemoglobin) AS hemoglobin_min, MAX(hemoglobin) AS hemoglobin_max - , MIN(carboxyhemoglobin) AS carboxyhemoglobin_min - , MAX(carboxyhemoglobin) AS carboxyhemoglobin_max - , MIN(methemoglobin) AS methemoglobin_min - , MAX(methemoglobin) AS methemoglobin_max - , MIN(temperature) AS temperature_min, MAX(temperature) AS temperature_max - , MIN(chloride) AS chloride_min, MAX(chloride) AS chloride_max - , MIN(calcium) AS calcium_min, MAX(calcium) AS calcium_max - , MIN(glucose) AS glucose_min, MAX(glucose) AS glucose_max - , MIN(potassium) AS potassium_min, MAX(potassium) AS potassium_max - , MIN(sodium) AS sodium_min, MAX(sodium) AS sodium_max -FROM mimiciv_icu.icustays ie -LEFT JOIN mimiciv_derived.bg bg - ON ie.subject_id = bg.subject_id - AND bg.charttime >= DATETIME_SUB(ie.intime, INTERVAL '6' HOUR) - AND bg.charttime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) -GROUP BY ie.subject_id, ie.stay_id -; + ie.subject_id, + ie.stay_id, + MIN(lactate) AS lactate_min, + MAX(lactate) AS lactate_max, + MIN(ph) AS ph_min, + MAX(ph) AS ph_max, + MIN(so2) AS so2_min, + MAX(so2) AS so2_max, + MIN(po2) AS po2_min, + MAX(po2) AS po2_max, + MIN(pco2) AS pco2_min, + MAX(pco2) AS pco2_max, + MIN(aado2) AS aado2_min, + MAX(aado2) AS aado2_max, + MIN(aado2_calc) AS aado2_calc_min, + MAX(aado2_calc) AS aado2_calc_max, + MIN(pao2fio2ratio) AS pao2fio2ratio_min, + MAX(pao2fio2ratio) AS pao2fio2ratio_max, + MIN(baseexcess) AS baseexcess_min, + MAX(baseexcess) AS baseexcess_max, + MIN(bicarbonate) AS bicarbonate_min, + MAX(bicarbonate) AS bicarbonate_max, + MIN(totalco2) AS totalco2_min, + MAX(totalco2) AS totalco2_max, + MIN(hematocrit) AS hematocrit_min, + MAX(hematocrit) AS hematocrit_max, + MIN(hemoglobin) AS hemoglobin_min, + MAX(hemoglobin) AS hemoglobin_max, + MIN(carboxyhemoglobin) AS carboxyhemoglobin_min, + MAX(carboxyhemoglobin) AS carboxyhemoglobin_max, + MIN(methemoglobin) AS methemoglobin_min, + MAX(methemoglobin) AS methemoglobin_max, + MIN(temperature) AS temperature_min, + MAX(temperature) AS temperature_max, + MIN(chloride) AS chloride_min, + MAX(chloride) AS chloride_max, + MIN(calcium) AS calcium_min, + MAX(calcium) AS calcium_max, + MIN(glucose) AS glucose_min, + MAX(glucose) AS glucose_max, + MIN(potassium) AS potassium_min, + MAX(potassium) AS potassium_max, + MIN(sodium) AS sodium_min, + MAX(sodium) AS sodium_max +FROM mimiciv_icu.icustays AS ie +LEFT JOIN mimiciv_derived.bg AS bg + ON ie.subject_id = bg.subject_id + AND bg.charttime >= ie.intime - INTERVAL '6 HOUR' + AND bg.charttime <= ie.intime + INTERVAL '1 DAY' +GROUP BY + ie.subject_id, + ie.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/firstday/first_day_bg_art.sql b/mimic-iv/concepts_postgres/firstday/first_day_bg_art.sql index 9b7cc8f40..d37450524 100644 --- a/mimic-iv/concepts_postgres/firstday/first_day_bg_art.sql +++ b/mimic-iv/concepts_postgres/firstday/first_day_bg_art.sql @@ -1,38 +1,57 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS first_day_bg_art; CREATE TABLE first_day_bg_art AS --- Highest/lowest blood gas values for arterial blood specimens +DROP TABLE IF EXISTS mimiciv_derived.first_day_bg_art; CREATE TABLE mimiciv_derived.first_day_bg_art AS +/* Highest/lowest blood gas values for arterial blood specimens */ SELECT - ie.subject_id - , ie.stay_id - , MIN(lactate) AS lactate_min, MAX(lactate) AS lactate_max - , MIN(ph) AS ph_min, MAX(ph) AS ph_max - , MIN(so2) AS so2_min, MAX(so2) AS so2_max - , MIN(po2) AS po2_min, MAX(po2) AS po2_max - , MIN(pco2) AS pco2_min, MAX(pco2) AS pco2_max - , MIN(aado2) AS aado2_min, MAX(aado2) AS aado2_max - , MIN(aado2_calc) AS aado2_calc_min, MAX(aado2_calc) AS aado2_calc_max - , MIN(pao2fio2ratio) AS pao2fio2ratio_min - , MAX(pao2fio2ratio) AS pao2fio2ratio_max - , MIN(baseexcess) AS baseexcess_min, MAX(baseexcess) AS baseexcess_max - , MIN(bicarbonate) AS bicarbonate_min, MAX(bicarbonate) AS bicarbonate_max - , MIN(totalco2) AS totalco2_min, MAX(totalco2) AS totalco2_max - , MIN(hematocrit) AS hematocrit_min, MAX(hematocrit) AS hematocrit_max - , MIN(hemoglobin) AS hemoglobin_min, MAX(hemoglobin) AS hemoglobin_max - , MIN(carboxyhemoglobin) AS carboxyhemoglobin_min - , MAX(carboxyhemoglobin) AS carboxyhemoglobin_max - , MIN(methemoglobin) AS methemoglobin_min - , MAX(methemoglobin) AS methemoglobin_max - , MIN(temperature) AS temperature_min, MAX(temperature) AS temperature_max - , MIN(chloride) AS chloride_min, MAX(chloride) AS chloride_max - , MIN(calcium) AS calcium_min, MAX(calcium) AS calcium_max - , MIN(glucose) AS glucose_min, MAX(glucose) AS glucose_max - , MIN(potassium) AS potassium_min, MAX(potassium) AS potassium_max - , MIN(sodium) AS sodium_min, MAX(sodium) AS sodium_max -FROM mimiciv_icu.icustays ie -LEFT JOIN mimiciv_derived.bg bg - ON ie.subject_id = bg.subject_id - AND bg.specimen = 'ART.' - AND bg.charttime >= DATETIME_SUB(ie.intime, INTERVAL '6' HOUR) - AND bg.charttime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) -GROUP BY ie.subject_id, ie.stay_id -; + ie.subject_id, + ie.stay_id, + MIN(lactate) AS lactate_min, + MAX(lactate) AS lactate_max, + MIN(ph) AS ph_min, + MAX(ph) AS ph_max, + MIN(so2) AS so2_min, + MAX(so2) AS so2_max, + MIN(po2) AS po2_min, + MAX(po2) AS po2_max, + MIN(pco2) AS pco2_min, + MAX(pco2) AS pco2_max, + MIN(aado2) AS aado2_min, + MAX(aado2) AS aado2_max, + MIN(aado2_calc) AS aado2_calc_min, + MAX(aado2_calc) AS aado2_calc_max, + MIN(pao2fio2ratio) AS pao2fio2ratio_min, + MAX(pao2fio2ratio) AS pao2fio2ratio_max, + MIN(baseexcess) AS baseexcess_min, + MAX(baseexcess) AS baseexcess_max, + MIN(bicarbonate) AS bicarbonate_min, + MAX(bicarbonate) AS bicarbonate_max, + MIN(totalco2) AS totalco2_min, + MAX(totalco2) AS totalco2_max, + MIN(hematocrit) AS hematocrit_min, + MAX(hematocrit) AS hematocrit_max, + MIN(hemoglobin) AS hemoglobin_min, + MAX(hemoglobin) AS hemoglobin_max, + MIN(carboxyhemoglobin) AS carboxyhemoglobin_min, + MAX(carboxyhemoglobin) AS carboxyhemoglobin_max, + MIN(methemoglobin) AS methemoglobin_min, + MAX(methemoglobin) AS methemoglobin_max, + MIN(temperature) AS temperature_min, + MAX(temperature) AS temperature_max, + MIN(chloride) AS chloride_min, + MAX(chloride) AS chloride_max, + MIN(calcium) AS calcium_min, + MAX(calcium) AS calcium_max, + MIN(glucose) AS glucose_min, + MAX(glucose) AS glucose_max, + MIN(potassium) AS potassium_min, + MAX(potassium) AS potassium_max, + MIN(sodium) AS sodium_min, + MAX(sodium) AS sodium_max +FROM mimiciv_icu.icustays AS ie +LEFT JOIN mimiciv_derived.bg AS bg + ON ie.subject_id = bg.subject_id + AND bg.specimen = 'ART.' + AND bg.charttime >= ie.intime - INTERVAL '6 HOUR' + AND bg.charttime <= ie.intime + INTERVAL '1 DAY' +GROUP BY + ie.subject_id, + ie.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/firstday/first_day_gcs.sql b/mimic-iv/concepts_postgres/firstday/first_day_gcs.sql index e573021e0..f01e7a751 100644 --- a/mimic-iv/concepts_postgres/firstday/first_day_gcs.sql +++ b/mimic-iv/concepts_postgres/firstday/first_day_gcs.sql @@ -1,53 +1,31 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS first_day_gcs; CREATE TABLE first_day_gcs AS --- Glasgow Coma Scale, a measure of neurological function. --- Ranges from 3 (worst, comatose) to 15 (best, normal function). - --- Note: --- The GCS for sedated patients is defaulted to 15 in this code. --- This follows common practice for scoring patients with severity --- of illness scores. --- --- e.g., from the SAPS II publication: --- For sedated patients, the Glasgow Coma Score before sedation was used. --- This was ascertained either from interviewing the physician who ordered --- the sedation, or by reviewing the patient's medical record. - +DROP TABLE IF EXISTS mimiciv_derived.first_day_gcs; CREATE TABLE mimiciv_derived.first_day_gcs AS +/* Glasgow Coma Scale, a measure of neurological function. */ /* Ranges from 3 (worst, comatose) to 15 (best, normal function). */ /* Note: */ /* The GCS for sedated patients is defaulted to 15 in this code. */ /* This follows common practice for scoring patients with severity */ /* of illness scores. */ /* e.g., from the SAPS II publication: */ /* For sedated patients, the Glasgow Coma Score before sedation was used. */ /* This was ascertained either from interviewing the physician who ordered */ /* the sedation, or by reviewing the patient's medical record. */ WITH gcs_final AS ( - SELECT - ie.subject_id, ie.stay_id - , g.gcs - , g.gcs_motor - , g.gcs_verbal - , g.gcs_eyes - , g.gcs_unable - -- This sorts the data by GCS - -- rn = 1 is the the lowest total GCS value - , ROW_NUMBER() OVER - ( - PARTITION BY g.stay_id - ORDER BY g.gcs - ) AS gcs_seq - FROM mimiciv_icu.icustays ie - -- Only get data for the first 24 hours - LEFT JOIN mimiciv_derived.gcs g - ON ie.stay_id = g.stay_id - AND g.charttime >= DATETIME_SUB(ie.intime, INTERVAL '6' HOUR) - AND g.charttime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) + SELECT + ie.subject_id, + ie.stay_id, + g.gcs, + g.gcs_motor, + g.gcs_verbal, + g.gcs_eyes, + g.gcs_unable, /* This sorts the data by GCS */ /* rn = 1 is the the lowest total GCS value */ + ROW_NUMBER() OVER (PARTITION BY g.stay_id ORDER BY g.gcs NULLS FIRST) AS gcs_seq + FROM mimiciv_icu.icustays AS ie + /* Only get data for the first 24 hours */ + LEFT JOIN mimiciv_derived.gcs AS g + ON ie.stay_id = g.stay_id + AND g.charttime >= ie.intime - INTERVAL '6 HOUR' + AND g.charttime <= ie.intime + INTERVAL '1 DAY' ) - SELECT - ie.subject_id - , ie.stay_id - -- The minimum GCS is determined by the above row partition - -- we only join if gcs_seq = 1 - , gcs AS gcs_min - , gcs_motor - , gcs_verbal - , gcs_eyes - , gcs_unable -FROM mimiciv_icu.icustays ie -LEFT JOIN gcs_final gs - ON ie.stay_id = gs.stay_id - AND gs.gcs_seq = 1 -; + ie.subject_id, + ie.stay_id, /* The minimum GCS is determined by the above row partition */ /* we only join if gcs_seq = 1 */ + gcs AS gcs_min, + gcs_motor, + gcs_verbal, + gcs_eyes, + gcs_unable +FROM mimiciv_icu.icustays AS ie +LEFT JOIN gcs_final AS gs + ON ie.stay_id = gs.stay_id AND gs.gcs_seq = 1 \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/firstday/first_day_height.sql b/mimic-iv/concepts_postgres/firstday/first_day_height.sql index 735826a47..dcd33ecce 100644 --- a/mimic-iv/concepts_postgres/firstday/first_day_height.sql +++ b/mimic-iv/concepts_postgres/firstday/first_day_height.sql @@ -1,17 +1,15 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS first_day_height; CREATE TABLE first_day_height AS --- This query extracts heights for adult ICU patients. --- It uses all information from the patient's first ICU day. --- This is done for consistency with other queries. --- Height is unlikely to change throughout a patient's stay. - +DROP TABLE IF EXISTS mimiciv_derived.first_day_height; CREATE TABLE mimiciv_derived.first_day_height AS +/* This query extracts heights for adult ICU patients. */ /* It uses all information from the patient's first ICU day. */ /* This is done for consistency with other queries. */ /* Height is unlikely to change throughout a patient's stay. */ SELECT - ie.subject_id - , ie.stay_id - , ROUND(CAST(AVG(height) AS NUMERIC), 2) AS height -FROM mimiciv_icu.icustays ie -LEFT JOIN mimiciv_derived.height ht - ON ie.stay_id = ht.stay_id - AND ht.charttime >= DATETIME_SUB(ie.intime, INTERVAL '6' HOUR) - AND ht.charttime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) -GROUP BY ie.subject_id, ie.stay_id; + ie.subject_id, + ie.stay_id, + ROUND(CAST(AVG(height) AS DECIMAL), 2) AS height +FROM mimiciv_icu.icustays AS ie +LEFT JOIN mimiciv_derived.height AS ht + ON ie.stay_id = ht.stay_id + AND ht.charttime >= ie.intime - INTERVAL '6 HOUR' + AND ht.charttime <= ie.intime + INTERVAL '1 DAY' +GROUP BY + ie.subject_id, + ie.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/firstday/first_day_lab.sql b/mimic-iv/concepts_postgres/firstday/first_day_lab.sql index df93c035b..841d85588 100644 --- a/mimic-iv/concepts_postgres/firstday/first_day_lab.sql +++ b/mimic-iv/concepts_postgres/firstday/first_day_lab.sql @@ -1,180 +1,239 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS first_day_lab; CREATE TABLE first_day_lab AS +DROP TABLE IF EXISTS mimiciv_derived.first_day_lab; CREATE TABLE mimiciv_derived.first_day_lab AS WITH cbc AS ( - SELECT - ie.stay_id - , MIN(hematocrit) AS hematocrit_min - , MAX(hematocrit) AS hematocrit_max - , MIN(hemoglobin) AS hemoglobin_min - , MAX(hemoglobin) AS hemoglobin_max - , MIN(platelet) AS platelets_min - , MAX(platelet) AS platelets_max - , MIN(wbc) AS wbc_min - , MAX(wbc) AS wbc_max - FROM mimiciv_icu.icustays ie - LEFT JOIN mimiciv_derived.complete_blood_count le - ON le.subject_id = ie.subject_id - AND le.charttime >= DATETIME_SUB(ie.intime, INTERVAL '6' HOUR) - AND le.charttime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) - GROUP BY ie.stay_id + SELECT + ie.stay_id, + MIN(hematocrit) AS hematocrit_min, + MAX(hematocrit) AS hematocrit_max, + MIN(hemoglobin) AS hemoglobin_min, + MAX(hemoglobin) AS hemoglobin_max, + MIN(platelet) AS platelets_min, + MAX(platelet) AS platelets_max, + MIN(wbc) AS wbc_min, + MAX(wbc) AS wbc_max + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.complete_blood_count AS le + ON le.subject_id = ie.subject_id + AND le.charttime >= ie.intime - INTERVAL '6 HOUR' + AND le.charttime <= ie.intime + INTERVAL '1 DAY' + GROUP BY + ie.stay_id +), chem AS ( + SELECT + ie.stay_id, + MIN(albumin) AS albumin_min, + MAX(albumin) AS albumin_max, + MIN(globulin) AS globulin_min, + MAX(globulin) AS globulin_max, + MIN(total_protein) AS total_protein_min, + MAX(total_protein) AS total_protein_max, + MIN(aniongap) AS aniongap_min, + MAX(aniongap) AS aniongap_max, + MIN(bicarbonate) AS bicarbonate_min, + MAX(bicarbonate) AS bicarbonate_max, + MIN(bun) AS bun_min, + MAX(bun) AS bun_max, + MIN(calcium) AS calcium_min, + MAX(calcium) AS calcium_max, + MIN(chloride) AS chloride_min, + MAX(chloride) AS chloride_max, + MIN(creatinine) AS creatinine_min, + MAX(creatinine) AS creatinine_max, + MIN(glucose) AS glucose_min, + MAX(glucose) AS glucose_max, + MIN(sodium) AS sodium_min, + MAX(sodium) AS sodium_max, + MIN(potassium) AS potassium_min, + MAX(potassium) AS potassium_max + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.chemistry AS le + ON le.subject_id = ie.subject_id + AND le.charttime >= ie.intime - INTERVAL '6 HOUR' + AND le.charttime <= ie.intime + INTERVAL '1 DAY' + GROUP BY + ie.stay_id +), diff AS ( + SELECT + ie.stay_id, + MIN(basophils_abs) AS abs_basophils_min, + MAX(basophils_abs) AS abs_basophils_max, + MIN(eosinophils_abs) AS abs_eosinophils_min, + MAX(eosinophils_abs) AS abs_eosinophils_max, + MIN(lymphocytes_abs) AS abs_lymphocytes_min, + MAX(lymphocytes_abs) AS abs_lymphocytes_max, + MIN(monocytes_abs) AS abs_monocytes_min, + MAX(monocytes_abs) AS abs_monocytes_max, + MIN(neutrophils_abs) AS abs_neutrophils_min, + MAX(neutrophils_abs) AS abs_neutrophils_max, + MIN(atypical_lymphocytes) AS atyps_min, + MAX(atypical_lymphocytes) AS atyps_max, + MIN(bands) AS bands_min, + MAX(bands) AS bands_max, + MIN(immature_granulocytes) AS imm_granulocytes_min, + MAX(immature_granulocytes) AS imm_granulocytes_max, + MIN(metamyelocytes) AS metas_min, + MAX(metamyelocytes) AS metas_max, + MIN(nrbc) AS nrbc_min, + MAX(nrbc) AS nrbc_max + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.blood_differential AS le + ON le.subject_id = ie.subject_id + AND le.charttime >= ie.intime - INTERVAL '6 HOUR' + AND le.charttime <= ie.intime + INTERVAL '1 DAY' + GROUP BY + ie.stay_id +), coag AS ( + SELECT + ie.stay_id, + MIN(d_dimer) AS d_dimer_min, + MAX(d_dimer) AS d_dimer_max, + MIN(fibrinogen) AS fibrinogen_min, + MAX(fibrinogen) AS fibrinogen_max, + MIN(thrombin) AS thrombin_min, + MAX(thrombin) AS thrombin_max, + MIN(inr) AS inr_min, + MAX(inr) AS inr_max, + MIN(pt) AS pt_min, + MAX(pt) AS pt_max, + MIN(ptt) AS ptt_min, + MAX(ptt) AS ptt_max + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.coagulation AS le + ON le.subject_id = ie.subject_id + AND le.charttime >= ie.intime - INTERVAL '6 HOUR' + AND le.charttime <= ie.intime + INTERVAL '1 DAY' + GROUP BY + ie.stay_id +), enz AS ( + SELECT + ie.stay_id, + MIN(alt) AS alt_min, + MAX(alt) AS alt_max, + MIN(alp) AS alp_min, + MAX(alp) AS alp_max, + MIN(ast) AS ast_min, + MAX(ast) AS ast_max, + MIN(amylase) AS amylase_min, + MAX(amylase) AS amylase_max, + MIN(bilirubin_total) AS bilirubin_total_min, + MAX(bilirubin_total) AS bilirubin_total_max, + MIN(bilirubin_direct) AS bilirubin_direct_min, + MAX(bilirubin_direct) AS bilirubin_direct_max, + MIN(bilirubin_indirect) AS bilirubin_indirect_min, + MAX(bilirubin_indirect) AS bilirubin_indirect_max, + MIN(ck_cpk) AS ck_cpk_min, + MAX(ck_cpk) AS ck_cpk_max, + MIN(ck_mb) AS ck_mb_min, + MAX(ck_mb) AS ck_mb_max, + MIN(ggt) AS ggt_min, + MAX(ggt) AS ggt_max, + MIN(ld_ldh) AS ld_ldh_min, + MAX(ld_ldh) AS ld_ldh_max + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.enzyme AS le + ON le.subject_id = ie.subject_id + AND le.charttime >= ie.intime - INTERVAL '6 HOUR' + AND le.charttime <= ie.intime + INTERVAL '1 DAY' + GROUP BY + ie.stay_id ) - -, chem AS ( - SELECT - ie.stay_id - , MIN(albumin) AS albumin_min, MAX(albumin) AS albumin_max - , MIN(globulin) AS globulin_min, MAX(globulin) AS globulin_max - , MIN(total_protein) AS total_protein_min - , MAX(total_protein) AS total_protein_max - , MIN(aniongap) AS aniongap_min, MAX(aniongap) AS aniongap_max - , MIN(bicarbonate) AS bicarbonate_min - , MAX(bicarbonate) AS bicarbonate_max - , MIN(bun) AS bun_min, MAX(bun) AS bun_max - , MIN(calcium) AS calcium_min, MAX(calcium) AS calcium_max - , MIN(chloride) AS chloride_min, MAX(chloride) AS chloride_max - , MIN(creatinine) AS creatinine_min, MAX(creatinine) AS creatinine_max - , MIN(glucose) AS glucose_min, MAX(glucose) AS glucose_max - , MIN(sodium) AS sodium_min, MAX(sodium) AS sodium_max - , MIN(potassium) AS potassium_min, MAX(potassium) AS potassium_max - FROM mimiciv_icu.icustays ie - LEFT JOIN mimiciv_derived.chemistry le - ON le.subject_id = ie.subject_id - AND le.charttime >= DATETIME_SUB(ie.intime, INTERVAL '6' HOUR) - AND le.charttime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) - GROUP BY ie.stay_id -) - -, diff AS ( - SELECT - ie.stay_id - , MIN(basophils_abs) AS abs_basophils_min - , MAX(basophils_abs) AS abs_basophils_max - , MIN(eosinophils_abs) AS abs_eosinophils_min - , MAX(eosinophils_abs) AS abs_eosinophils_max - , MIN(lymphocytes_abs) AS abs_lymphocytes_min - , MAX(lymphocytes_abs) AS abs_lymphocytes_max - , MIN(monocytes_abs) AS abs_monocytes_min - , MAX(monocytes_abs) AS abs_monocytes_max - , MIN(neutrophils_abs) AS abs_neutrophils_min - , MAX(neutrophils_abs) AS abs_neutrophils_max - , MIN(atypical_lymphocytes) AS atyps_min - , MAX(atypical_lymphocytes) AS atyps_max - , MIN(bands) AS bands_min, MAX(bands) AS bands_max - , MIN(immature_granulocytes) AS imm_granulocytes_min - , MAX(immature_granulocytes) AS imm_granulocytes_max - , MIN(metamyelocytes) AS metas_min, MAX(metamyelocytes) AS metas_max - , MIN(nrbc) AS nrbc_min, MAX(nrbc) AS nrbc_max - FROM mimiciv_icu.icustays ie - LEFT JOIN mimiciv_derived.blood_differential le - ON le.subject_id = ie.subject_id - AND le.charttime >= DATETIME_SUB(ie.intime, INTERVAL '6' HOUR) - AND le.charttime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) - GROUP BY ie.stay_id -) - -, coag AS ( - SELECT - ie.stay_id - , MIN(d_dimer) AS d_dimer_min, MAX(d_dimer) AS d_dimer_max - , MIN(fibrinogen) AS fibrinogen_min, MAX(fibrinogen) AS fibrinogen_max - , MIN(thrombin) AS thrombin_min, MAX(thrombin) AS thrombin_max - , MIN(inr) AS inr_min, MAX(inr) AS inr_max - , MIN(pt) AS pt_min, MAX(pt) AS pt_max - , MIN(ptt) AS ptt_min, MAX(ptt) AS ptt_max - FROM mimiciv_icu.icustays ie - LEFT JOIN mimiciv_derived.coagulation le - ON le.subject_id = ie.subject_id - AND le.charttime >= DATETIME_SUB(ie.intime, INTERVAL '6' HOUR) - AND le.charttime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) - GROUP BY ie.stay_id -) - -, enz AS ( - SELECT - ie.stay_id - - , MIN(alt) AS alt_min, MAX(alt) AS alt_max - , MIN(alp) AS alp_min, MAX(alp) AS alp_max - , MIN(ast) AS ast_min, MAX(ast) AS ast_max - , MIN(amylase) AS amylase_min, MAX(amylase) AS amylase_max - , MIN(bilirubin_total) AS bilirubin_total_min - , MAX(bilirubin_total) AS bilirubin_total_max - , MIN(bilirubin_direct) AS bilirubin_direct_min - , MAX(bilirubin_direct) AS bilirubin_direct_max - , MIN(bilirubin_indirect) AS bilirubin_indirect_min - , MAX(bilirubin_indirect) AS bilirubin_indirect_max - , MIN(ck_cpk) AS ck_cpk_min, MAX(ck_cpk) AS ck_cpk_max - , MIN(ck_mb) AS ck_mb_min, MAX(ck_mb) AS ck_mb_max - , MIN(ggt) AS ggt_min, MAX(ggt) AS ggt_max - , MIN(ld_ldh) AS ld_ldh_min, MAX(ld_ldh) AS ld_ldh_max - FROM mimiciv_icu.icustays ie - LEFT JOIN mimiciv_derived.enzyme le - ON le.subject_id = ie.subject_id - AND le.charttime >= DATETIME_SUB(ie.intime, INTERVAL '6' HOUR) - AND le.charttime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) - GROUP BY ie.stay_id -) - SELECT - ie.subject_id - , ie.stay_id - -- complete blood count - , hematocrit_min, hematocrit_max - , hemoglobin_min, hemoglobin_max - , platelets_min, platelets_max - , wbc_min, wbc_max - -- chemistry - , albumin_min, albumin_max - , globulin_min, globulin_max - , total_protein_min, total_protein_max - , aniongap_min, aniongap_max - , bicarbonate_min, bicarbonate_max - , bun_min, bun_max - , calcium_min, calcium_max - , chloride_min, chloride_max - , creatinine_min, creatinine_max - , glucose_min, glucose_max - , sodium_min, sodium_max - , potassium_min, potassium_max - -- blood differential - , abs_basophils_min, abs_basophils_max - , abs_eosinophils_min, abs_eosinophils_max - , abs_lymphocytes_min, abs_lymphocytes_max - , abs_monocytes_min, abs_monocytes_max - , abs_neutrophils_min, abs_neutrophils_max - , atyps_min, atyps_max - , bands_min, bands_max - , imm_granulocytes_min, imm_granulocytes_max - , metas_min, metas_max - , nrbc_min, nrbc_max - -- coagulation - , d_dimer_min, d_dimer_max - , fibrinogen_min, fibrinogen_max - , thrombin_min, thrombin_max - , inr_min, inr_max - , pt_min, pt_max - , ptt_min, ptt_max - -- enzymes and bilirubin - , alt_min, alt_max - , alp_min, alp_max - , ast_min, ast_max - , amylase_min, amylase_max - , bilirubin_total_min, bilirubin_total_max - , bilirubin_direct_min, bilirubin_direct_max - , bilirubin_indirect_min, bilirubin_indirect_max - , ck_cpk_min, ck_cpk_max - , ck_mb_min, ck_mb_max - , ggt_min, ggt_max - , ld_ldh_min, ld_ldh_max -FROM mimiciv_icu.icustays ie + ie.subject_id, + ie.stay_id, /* complete blood count */ + hematocrit_min, + hematocrit_max, + hemoglobin_min, + hemoglobin_max, + platelets_min, + platelets_max, + wbc_min, + wbc_max, /* chemistry */ + albumin_min, + albumin_max, + globulin_min, + globulin_max, + total_protein_min, + total_protein_max, + aniongap_min, + aniongap_max, + bicarbonate_min, + bicarbonate_max, + bun_min, + bun_max, + calcium_min, + calcium_max, + chloride_min, + chloride_max, + creatinine_min, + creatinine_max, + glucose_min, + glucose_max, + sodium_min, + sodium_max, + potassium_min, + potassium_max, /* blood differential */ + abs_basophils_min, + abs_basophils_max, + abs_eosinophils_min, + abs_eosinophils_max, + abs_lymphocytes_min, + abs_lymphocytes_max, + abs_monocytes_min, + abs_monocytes_max, + abs_neutrophils_min, + abs_neutrophils_max, + atyps_min, + atyps_max, + bands_min, + bands_max, + imm_granulocytes_min, + imm_granulocytes_max, + metas_min, + metas_max, + nrbc_min, + nrbc_max, /* coagulation */ + d_dimer_min, + d_dimer_max, + fibrinogen_min, + fibrinogen_max, + thrombin_min, + thrombin_max, + inr_min, + inr_max, + pt_min, + pt_max, + ptt_min, + ptt_max, /* enzymes and bilirubin */ + alt_min, + alt_max, + alp_min, + alp_max, + ast_min, + ast_max, + amylase_min, + amylase_max, + bilirubin_total_min, + bilirubin_total_max, + bilirubin_direct_min, + bilirubin_direct_max, + bilirubin_indirect_min, + bilirubin_indirect_max, + ck_cpk_min, + ck_cpk_max, + ck_mb_min, + ck_mb_max, + ggt_min, + ggt_max, + ld_ldh_min, + ld_ldh_max +FROM mimiciv_icu.icustays AS ie LEFT JOIN cbc - ON ie.stay_id = cbc.stay_id + ON ie.stay_id = cbc.stay_id LEFT JOIN chem - ON ie.stay_id = chem.stay_id + ON ie.stay_id = chem.stay_id LEFT JOIN diff - ON ie.stay_id = diff.stay_id + ON ie.stay_id = diff.stay_id LEFT JOIN coag - ON ie.stay_id = coag.stay_id + ON ie.stay_id = coag.stay_id LEFT JOIN enz - ON ie.stay_id = enz.stay_id -; + ON ie.stay_id = enz.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/firstday/first_day_rrt.sql b/mimic-iv/concepts_postgres/firstday/first_day_rrt.sql index c26237ac4..44280d041 100644 --- a/mimic-iv/concepts_postgres/firstday/first_day_rrt.sql +++ b/mimic-iv/concepts_postgres/firstday/first_day_rrt.sql @@ -1,16 +1,17 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS first_day_rrt; CREATE TABLE first_day_rrt AS --- flag indicating if patients received dialysis during --- the first day of their ICU stay +DROP TABLE IF EXISTS mimiciv_derived.first_day_rrt; CREATE TABLE mimiciv_derived.first_day_rrt AS +/* flag indicating if patients received dialysis during */ /* the first day of their ICU stay */ SELECT - ie.subject_id - , ie.stay_id - , MAX(dialysis_present) AS dialysis_present - , MAX(dialysis_active) AS dialysis_active - , STRING_AGG(DISTINCT dialysis_type, ', ') AS dialysis_type -FROM mimiciv_icu.icustays ie -LEFT JOIN mimiciv_derived.rrt rrt - ON ie.stay_id = rrt.stay_id - AND rrt.charttime >= DATETIME_SUB(ie.intime, INTERVAL '6' HOUR) - AND rrt.charttime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) -GROUP BY ie.subject_id, ie.stay_id + ie.subject_id, + ie.stay_id, + MAX(dialysis_present) AS dialysis_present, + MAX(dialysis_active) AS dialysis_active, + STRING_AGG(DISTINCT dialysis_type, ', ') AS dialysis_type +FROM mimiciv_icu.icustays AS ie +LEFT JOIN mimiciv_derived.rrt AS rrt + ON ie.stay_id = rrt.stay_id + AND rrt.charttime >= ie.intime - INTERVAL '6 HOUR' + AND rrt.charttime <= ie.intime + INTERVAL '1 DAY' +GROUP BY + ie.subject_id, + ie.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/firstday/first_day_sofa.sql b/mimic-iv/concepts_postgres/firstday/first_day_sofa.sql index 051cf16fb..b2b9ab924 100644 --- a/mimic-iv/concepts_postgres/firstday/first_day_sofa.sql +++ b/mimic-iv/concepts_postgres/firstday/first_day_sofa.sql @@ -1,259 +1,225 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS first_day_sofa; CREATE TABLE first_day_sofa AS --- ------------------------------------------------------------------ --- Title: Sequential Organ Failure Assessment (SOFA) --- This query extracts the sequential organ failure assessment --- (formerly: sepsis-related organ failure assessment). --- This score is a measure of organ failure for patients in the ICU. --- The score is calculated on the first day of each ICU patients' stay. --- ------------------------------------------------------------------ - --- Reference for SOFA: --- Jean-Louis Vincent, Rui Moreno, Jukka Takala, Sheila Willatts, --- Arnaldo De Mendonça, Hajo Bruining, C. K. Reinhart, Peter M Suter, --- and L. G. Thijs. --- "The SOFA (Sepsis-related Organ Failure Assessment) score to describe --- organ dysfunction/failure." --- Intensive care medicine 22, no. 7 (1996): 707-710. - --- Variables used in SOFA: --- GCS, MAP, FiO2, Ventilation status (sourced from CHARTEVENTS) --- Creatinine, Bilirubin, FiO2, PaO2, Platelets (sourced from LABEVENTS) --- Dopamine, Dobutamine, Epinephrine, Norepinephrine (sourced from INPUTEVENTS) --- Urine output (sourced from OUTPUTEVENTS) - --- The following views required to run this query: --- 1) first_day_urine_output --- 2) first_day_vitalsign --- 3) first_day_gcs --- 4) first_day_lab --- 5) first_day_bg_art --- 6) ventdurations - --- extract drug rates from derived vasopressor tables +DROP TABLE IF EXISTS mimiciv_derived.first_day_sofa; CREATE TABLE mimiciv_derived.first_day_sofa AS +/* ------------------------------------------------------------------ */ /* Title: Sequential Organ Failure Assessment (SOFA) */ /* This query extracts the sequential organ failure assessment */ /* (formerly: sepsis-related organ failure assessment). */ /* This score is a measure of organ failure for patients in the ICU. */ /* The score is calculated on the first day of each ICU patients' stay. */ /* ------------------------------------------------------------------ */ /* Reference for SOFA: */ /* Jean-Louis Vincent, Rui Moreno, Jukka Takala, Sheila Willatts, */ /* Arnaldo De Mendonça, Hajo Bruining, C. K. Reinhart, Peter M Suter, */ /* and L. G. Thijs. */ /* "The SOFA (Sepsis-related Organ Failure Assessment) score to describe */ /* organ dysfunction/failure." */ /* Intensive care medicine 22, no. 7 (1996): 707-710. */ /* Variables used in SOFA: */ /* GCS, MAP, FiO2, Ventilation status (sourced from CHARTEVENTS) */ /* Creatinine, Bilirubin, FiO2, PaO2, Platelets (sourced from LABEVENTS) */ /* Dopamine, Dobutamine, Epinephrine, Norepinephrine (sourced from INPUTEVENTS) */ /* Urine output (sourced from OUTPUTEVENTS) */ /* The following views required to run this query: */ /* 1) first_day_urine_output */ /* 2) first_day_vitalsign */ /* 3) first_day_gcs */ /* 4) first_day_lab */ /* 5) first_day_bg_art */ /* 6) ventdurations */ /* extract drug rates from derived vasopressor tables */ WITH vaso_stg AS ( - SELECT ie.stay_id, 'norepinephrine' AS treatment, vaso_rate AS rate - FROM mimiciv_icu.icustays ie - INNER JOIN mimiciv_derived.norepinephrine mv - ON ie.stay_id = mv.stay_id - AND mv.starttime >= DATETIME_SUB(ie.intime, INTERVAL '6' HOUR) - AND mv.starttime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) - UNION ALL - SELECT ie.stay_id, 'epinephrine' AS treatment, vaso_rate AS rate - FROM mimiciv_icu.icustays ie - INNER JOIN mimiciv_derived.epinephrine mv - ON ie.stay_id = mv.stay_id - AND mv.starttime >= DATETIME_SUB(ie.intime, INTERVAL '6' HOUR) - AND mv.starttime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) - UNION ALL - SELECT ie.stay_id, 'dobutamine' AS treatment, vaso_rate AS rate - FROM mimiciv_icu.icustays ie - INNER JOIN mimiciv_derived.dobutamine mv - ON ie.stay_id = mv.stay_id - AND mv.starttime >= DATETIME_SUB(ie.intime, INTERVAL '6' HOUR) - AND mv.starttime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) - UNION ALL - SELECT ie.stay_id, 'dopamine' AS treatment, vaso_rate AS rate - FROM mimiciv_icu.icustays ie - INNER JOIN mimiciv_derived.dopamine mv - ON ie.stay_id = mv.stay_id - AND mv.starttime >= DATETIME_SUB(ie.intime, INTERVAL '6' HOUR) - AND mv.starttime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) + SELECT + ie.stay_id, + 'norepinephrine' AS treatment, + vaso_rate AS rate + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_derived.norepinephrine AS mv + ON ie.stay_id = mv.stay_id + AND mv.starttime >= ie.intime - INTERVAL '6 HOUR' + AND mv.starttime <= ie.intime + INTERVAL '1 DAY' + UNION ALL + SELECT + ie.stay_id, + 'epinephrine' AS treatment, + vaso_rate AS rate + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_derived.epinephrine AS mv + ON ie.stay_id = mv.stay_id + AND mv.starttime >= ie.intime - INTERVAL '6 HOUR' + AND mv.starttime <= ie.intime + INTERVAL '1 DAY' + UNION ALL + SELECT + ie.stay_id, + 'dobutamine' AS treatment, + vaso_rate AS rate + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_derived.dobutamine AS mv + ON ie.stay_id = mv.stay_id + AND mv.starttime >= ie.intime - INTERVAL '6 HOUR' + AND mv.starttime <= ie.intime + INTERVAL '1 DAY' + UNION ALL + SELECT + ie.stay_id, + 'dopamine' AS treatment, + vaso_rate AS rate + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_derived.dopamine AS mv + ON ie.stay_id = mv.stay_id + AND mv.starttime >= ie.intime - INTERVAL '6 HOUR' + AND mv.starttime <= ie.intime + INTERVAL '1 DAY' +), vaso_mv AS ( + SELECT + ie.stay_id, + MAX(CASE WHEN treatment = 'norepinephrine' THEN rate ELSE NULL END) AS rate_norepinephrine, + MAX(CASE WHEN treatment = 'epinephrine' THEN rate ELSE NULL END) AS rate_epinephrine, + MAX(CASE WHEN treatment = 'dopamine' THEN rate ELSE NULL END) AS rate_dopamine, + MAX(CASE WHEN treatment = 'dobutamine' THEN rate ELSE NULL END) AS rate_dobutamine + FROM mimiciv_icu.icustays AS ie + LEFT JOIN vaso_stg AS v + ON ie.stay_id = v.stay_id + GROUP BY + ie.stay_id +), pafi1 AS ( + /* join blood gas to ventilation durations to determine if patient was vent */ + SELECT + ie.stay_id, + bg.charttime, + bg.pao2fio2ratio, + CASE WHEN NOT vd.stay_id IS NULL THEN 1 ELSE 0 END AS isvent + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.bg AS bg + ON ie.subject_id = bg.subject_id + AND bg.charttime >= ie.intime - INTERVAL '6 HOUR' + AND bg.charttime <= ie.intime + INTERVAL '1 DAY' + LEFT JOIN mimiciv_derived.ventilation AS vd + ON ie.stay_id = vd.stay_id + AND bg.charttime >= vd.starttime + AND bg.charttime <= vd.endtime + AND vd.ventilation_status = 'InvasiveVent' +), pafi2 AS ( + /* because pafi has an interaction between vent/PaO2:FiO2, */ /* we need two columns for the score */ /* it can happen that the lowest unventilated PaO2/FiO2 is 68, */ /* but the lowest ventilated PaO2/FiO2 is 120 */ /* in this case, the SOFA score is 3, *not* 4. */ + SELECT + stay_id, + MIN(CASE WHEN isvent = 0 THEN pao2fio2ratio ELSE NULL END) AS pao2fio2_novent_min, + MIN(CASE WHEN isvent = 1 THEN pao2fio2ratio ELSE NULL END) AS pao2fio2_vent_min + FROM pafi1 + GROUP BY + stay_id +), scorecomp AS ( + SELECT + ie.stay_id, + v.mbp_min, + mv.rate_norepinephrine, + mv.rate_epinephrine, + mv.rate_dopamine, + mv.rate_dobutamine, + l.creatinine_max, + l.bilirubin_total_max AS bilirubin_max, + l.platelets_min AS platelet_min, + pf.pao2fio2_novent_min, + pf.pao2fio2_vent_min, + uo.urineoutput, + gcs.gcs_min + FROM mimiciv_icu.icustays AS ie + LEFT JOIN vaso_mv AS mv + ON ie.stay_id = mv.stay_id + LEFT JOIN pafi2 AS pf + ON ie.stay_id = pf.stay_id + LEFT JOIN mimiciv_derived.first_day_vitalsign AS v + ON ie.stay_id = v.stay_id + LEFT JOIN mimiciv_derived.first_day_lab AS l + ON ie.stay_id = l.stay_id + LEFT JOIN mimiciv_derived.first_day_urine_output AS uo + ON ie.stay_id = uo.stay_id + LEFT JOIN mimiciv_derived.first_day_gcs AS gcs + ON ie.stay_id = gcs.stay_id +), scorecalc AS ( + /* Calculate the final score */ /* note that if the underlying data is missing, the component is null */ /* eventually these are treated as 0 (normal), but knowing when data */ /* is missing is useful for debugging */ + SELECT + stay_id, /* Respiration */ + CASE + WHEN pao2fio2_vent_min < 100 + THEN 4 + WHEN pao2fio2_vent_min < 200 + THEN 3 + WHEN pao2fio2_novent_min < 300 + THEN 2 + WHEN pao2fio2_novent_min < 400 + THEN 1 + WHEN COALESCE(pao2fio2_vent_min, pao2fio2_novent_min) IS NULL + THEN NULL + ELSE 0 + END AS respiration, /* Coagulation */ + CASE + WHEN platelet_min < 20 + THEN 4 + WHEN platelet_min < 50 + THEN 3 + WHEN platelet_min < 100 + THEN 2 + WHEN platelet_min < 150 + THEN 1 + WHEN platelet_min IS NULL + THEN NULL + ELSE 0 + END AS coagulation, /* Liver */ + CASE + WHEN bilirubin_max >= 12.0 + THEN 4 + WHEN bilirubin_max >= 6.0 + THEN 3 + WHEN bilirubin_max >= 2.0 + THEN 2 + WHEN bilirubin_max >= 1.2 + THEN 1 + WHEN bilirubin_max IS NULL + THEN NULL + ELSE 0 + END AS liver, /* Cardiovascular */ + CASE + WHEN rate_dopamine > 15 OR rate_epinephrine > 0.1 OR rate_norepinephrine > 0.1 + THEN 4 + WHEN rate_dopamine > 5 OR rate_epinephrine <= 0.1 OR rate_norepinephrine <= 0.1 + THEN 3 + WHEN rate_dopamine > 0 OR rate_dobutamine > 0 + THEN 2 + WHEN mbp_min < 70 + THEN 1 + WHEN COALESCE(mbp_min, rate_dopamine, rate_dobutamine, rate_epinephrine, rate_norepinephrine) IS NULL + THEN NULL + ELSE 0 + END AS cardiovascular, /* Neurological failure (GCS) */ + CASE + WHEN ( + gcs_min >= 13 AND gcs_min <= 14 + ) + THEN 1 + WHEN ( + gcs_min >= 10 AND gcs_min <= 12 + ) + THEN 2 + WHEN ( + gcs_min >= 6 AND gcs_min <= 9 + ) + THEN 3 + WHEN gcs_min < 6 + THEN 4 + WHEN gcs_min IS NULL + THEN NULL + ELSE 0 + END AS cns, /* Renal failure - high creatinine or low urine output */ + CASE + WHEN ( + creatinine_max >= 5.0 + ) + THEN 4 + WHEN urineoutput < 200 + THEN 4 + WHEN ( + creatinine_max >= 3.5 AND creatinine_max < 5.0 + ) + THEN 3 + WHEN urineoutput < 500 + THEN 3 + WHEN ( + creatinine_max >= 2.0 AND creatinine_max < 3.5 + ) + THEN 2 + WHEN ( + creatinine_max >= 1.2 AND creatinine_max < 2.0 + ) + THEN 1 + WHEN COALESCE(urineoutput, creatinine_max) IS NULL + THEN NULL + ELSE 0 + END AS renal + FROM scorecomp ) - -, vaso_mv AS ( - SELECT - ie.stay_id - , MAX( - CASE WHEN treatment = 'norepinephrine' THEN rate ELSE NULL END - ) AS rate_norepinephrine - , MAX( - CASE WHEN treatment = 'epinephrine' THEN rate ELSE NULL END - ) AS rate_epinephrine - , MAX( - CASE WHEN treatment = 'dopamine' THEN rate ELSE NULL END - ) AS rate_dopamine - , MAX( - CASE WHEN treatment = 'dobutamine' THEN rate ELSE NULL END - ) AS rate_dobutamine - FROM mimiciv_icu.icustays ie - LEFT JOIN vaso_stg v - ON ie.stay_id = v.stay_id - GROUP BY ie.stay_id -) - -, pafi1 AS ( - -- join blood gas to ventilation durations to determine if patient was vent - SELECT ie.stay_id, bg.charttime - , bg.pao2fio2ratio - , CASE WHEN vd.stay_id IS NOT NULL THEN 1 ELSE 0 END AS isvent - FROM mimiciv_icu.icustays ie - LEFT JOIN mimiciv_derived.bg bg - ON ie.subject_id = bg.subject_id - AND bg.charttime >= DATETIME_SUB(ie.intime, INTERVAL '6' HOUR) - AND bg.charttime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) - LEFT JOIN mimiciv_derived.ventilation vd - ON ie.stay_id = vd.stay_id - AND bg.charttime >= vd.starttime - AND bg.charttime <= vd.endtime - AND vd.ventilation_status = 'InvasiveVent' -) - -, pafi2 AS ( - -- because pafi has an interaction between vent/PaO2:FiO2, - -- we need two columns for the score - -- it can happen that the lowest unventilated PaO2/FiO2 is 68, - -- but the lowest ventilated PaO2/FiO2 is 120 - -- in this case, the SOFA score is 3, *not* 4. - SELECT stay_id - , MIN( - CASE WHEN isvent = 0 THEN pao2fio2ratio ELSE NULL END - ) AS pao2fio2_novent_min - , MIN( - CASE WHEN isvent = 1 THEN pao2fio2ratio ELSE NULL END - ) AS pao2fio2_vent_min - FROM pafi1 - GROUP BY stay_id -) - --- Aggregate the components for the score -, scorecomp AS ( - SELECT ie.stay_id - , v.mbp_min - , mv.rate_norepinephrine - , mv.rate_epinephrine - , mv.rate_dopamine - , mv.rate_dobutamine - - , l.creatinine_max - , l.bilirubin_total_max AS bilirubin_max - , l.platelets_min AS platelet_min - - , pf.pao2fio2_novent_min - , pf.pao2fio2_vent_min - - , uo.urineoutput - - , gcs.gcs_min - FROM mimiciv_icu.icustays ie - LEFT JOIN vaso_mv mv - ON ie.stay_id = mv.stay_id - LEFT JOIN pafi2 pf - ON ie.stay_id = pf.stay_id - LEFT JOIN mimiciv_derived.first_day_vitalsign v - ON ie.stay_id = v.stay_id - LEFT JOIN mimiciv_derived.first_day_lab l - ON ie.stay_id = l.stay_id - LEFT JOIN mimiciv_derived.first_day_urine_output uo - ON ie.stay_id = uo.stay_id - LEFT JOIN mimiciv_derived.first_day_gcs gcs - ON ie.stay_id = gcs.stay_id -) - -, scorecalc AS ( - -- Calculate the final score - -- note that if the underlying data is missing, the component is null - -- eventually these are treated as 0 (normal), but knowing when data - -- is missing is useful for debugging - SELECT stay_id - -- Respiration - , CASE - WHEN pao2fio2_vent_min < 100 THEN 4 - WHEN pao2fio2_vent_min < 200 THEN 3 - WHEN pao2fio2_novent_min < 300 THEN 2 - WHEN pao2fio2_novent_min < 400 THEN 1 - WHEN - COALESCE( - pao2fio2_vent_min, pao2fio2_novent_min - ) IS NULL THEN NULL - ELSE 0 - END AS respiration - - -- Coagulation - , CASE - WHEN platelet_min < 20 THEN 4 - WHEN platelet_min < 50 THEN 3 - WHEN platelet_min < 100 THEN 2 - WHEN platelet_min < 150 THEN 1 - WHEN platelet_min IS NULL THEN NULL - ELSE 0 - END AS coagulation - - -- Liver - , CASE - -- Bilirubin checks in mg/dL - WHEN bilirubin_max >= 12.0 THEN 4 - WHEN bilirubin_max >= 6.0 THEN 3 - WHEN bilirubin_max >= 2.0 THEN 2 - WHEN bilirubin_max >= 1.2 THEN 1 - WHEN bilirubin_max IS NULL THEN NULL - ELSE 0 - END AS liver - - -- Cardiovascular - , CASE - WHEN rate_dopamine > 15 - OR rate_epinephrine > 0.1 - OR rate_norepinephrine > 0.1 - THEN 4 - WHEN rate_dopamine > 5 - OR rate_epinephrine <= 0.1 - OR rate_norepinephrine <= 0.1 - THEN 3 - WHEN rate_dopamine > 0 OR rate_dobutamine > 0 THEN 2 - WHEN mbp_min < 70 THEN 1 - WHEN - COALESCE( - mbp_min - , rate_dopamine - , rate_dobutamine - , rate_epinephrine - , rate_norepinephrine - ) IS NULL THEN NULL - ELSE 0 - END AS cardiovascular - - -- Neurological failure (GCS) - , CASE - WHEN (gcs_min >= 13 AND gcs_min <= 14) THEN 1 - WHEN (gcs_min >= 10 AND gcs_min <= 12) THEN 2 - WHEN (gcs_min >= 6 AND gcs_min <= 9) THEN 3 - WHEN gcs_min < 6 THEN 4 - WHEN gcs_min IS NULL THEN NULL - ELSE 0 END - AS cns - - -- Renal failure - high creatinine or low urine output - , CASE - WHEN (creatinine_max >= 5.0) THEN 4 - WHEN urineoutput < 200 THEN 4 - WHEN (creatinine_max >= 3.5 AND creatinine_max < 5.0) THEN 3 - WHEN urineoutput < 500 THEN 3 - WHEN (creatinine_max >= 2.0 AND creatinine_max < 3.5) THEN 2 - WHEN (creatinine_max >= 1.2 AND creatinine_max < 2.0) THEN 1 - WHEN COALESCE(urineoutput, creatinine_max) IS NULL THEN NULL - ELSE 0 END - AS renal - FROM scorecomp -) - -SELECT ie.subject_id, ie.hadm_id, ie.stay_id - -- Combine all the scores to get SOFA - -- Impute 0 if the score is missing - , COALESCE(respiration, 0) - + COALESCE(coagulation, 0) - + COALESCE(liver, 0) - + COALESCE(cardiovascular, 0) - + COALESCE(cns, 0) - + COALESCE(renal, 0) - AS sofa - , respiration - , coagulation - , liver - , cardiovascular - , cns - , renal -FROM mimiciv_icu.icustays ie -LEFT JOIN scorecalc s - ON ie.stay_id = s.stay_id -; +SELECT + ie.subject_id, + ie.hadm_id, + ie.stay_id, /* Combine all the scores to get SOFA */ /* Impute 0 if the score is missing */ + COALESCE(respiration, 0) + COALESCE(coagulation, 0) + COALESCE(liver, 0) + COALESCE(cardiovascular, 0) + COALESCE(cns, 0) + COALESCE(renal, 0) AS sofa, + respiration, + coagulation, + liver, + cardiovascular, + cns, + renal +FROM mimiciv_icu.icustays AS ie +LEFT JOIN scorecalc AS s + ON ie.stay_id = s.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/firstday/first_day_urine_output.sql b/mimic-iv/concepts_postgres/firstday/first_day_urine_output.sql index 9ce3c8516..3fff48082 100644 --- a/mimic-iv/concepts_postgres/firstday/first_day_urine_output.sql +++ b/mimic-iv/concepts_postgres/firstday/first_day_urine_output.sql @@ -1,16 +1,16 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS first_day_urine_output; CREATE TABLE first_day_urine_output AS --- Total urine output over the first 24 hours in the ICU +DROP TABLE IF EXISTS mimiciv_derived.first_day_urine_output; CREATE TABLE mimiciv_derived.first_day_urine_output AS +/* Total urine output over the first 24 hours in the ICU */ SELECT - -- patient identifiers - ie.subject_id - , ie.stay_id - , SUM(urineoutput) AS urineoutput -FROM mimiciv_icu.icustays ie --- Join to the outputevents table to get urine output -LEFT JOIN mimiciv_derived.urine_output uo - ON ie.stay_id = uo.stay_id - -- ensure the data occurs during the first day - AND uo.charttime >= ie.intime - AND uo.charttime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) -GROUP BY ie.subject_id, ie.stay_id + ie.subject_id, + ie.stay_id, + SUM(urineoutput) AS urineoutput +FROM mimiciv_icu.icustays AS ie +/* Join to the outputevents table to get urine output */ +LEFT JOIN mimiciv_derived.urine_output AS uo + ON ie.stay_id = uo.stay_id + AND uo.charttime >= ie.intime + AND uo.charttime <= ie.intime + INTERVAL '1 DAY' +GROUP BY + ie.subject_id, + ie.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/firstday/first_day_vitalsign.sql b/mimic-iv/concepts_postgres/firstday/first_day_vitalsign.sql index 83eb543c1..d91e6530f 100644 --- a/mimic-iv/concepts_postgres/firstday/first_day_vitalsign.sql +++ b/mimic-iv/concepts_postgres/firstday/first_day_vitalsign.sql @@ -1,37 +1,38 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS first_day_vitalsign; CREATE TABLE first_day_vitalsign AS --- This query pivots vital signs and aggregates them --- for the first 24 hours of a patient's stay. +DROP TABLE IF EXISTS mimiciv_derived.first_day_vitalsign; CREATE TABLE mimiciv_derived.first_day_vitalsign AS +/* This query pivots vital signs and aggregates them */ /* for the first 24 hours of a patient's stay. */ SELECT - ie.subject_id - , ie.stay_id - , MIN(heart_rate) AS heart_rate_min - , MAX(heart_rate) AS heart_rate_max - , AVG(heart_rate) AS heart_rate_mean - , MIN(sbp) AS sbp_min - , MAX(sbp) AS sbp_max - , AVG(sbp) AS sbp_mean - , MIN(dbp) AS dbp_min - , MAX(dbp) AS dbp_max - , AVG(dbp) AS dbp_mean - , MIN(mbp) AS mbp_min - , MAX(mbp) AS mbp_max - , AVG(mbp) AS mbp_mean - , MIN(resp_rate) AS resp_rate_min - , MAX(resp_rate) AS resp_rate_max - , AVG(resp_rate) AS resp_rate_mean - , MIN(temperature) AS temperature_min - , MAX(temperature) AS temperature_max - , AVG(temperature) AS temperature_mean - , MIN(spo2) AS spo2_min - , MAX(spo2) AS spo2_max - , AVG(spo2) AS spo2_mean - , MIN(glucose) AS glucose_min - , MAX(glucose) AS glucose_max - , AVG(glucose) AS glucose_mean -FROM mimiciv_icu.icustays ie -LEFT JOIN mimiciv_derived.vitalsign ce - ON ie.stay_id = ce.stay_id - AND ce.charttime >= DATETIME_SUB(ie.intime, INTERVAL '6' HOUR) - AND ce.charttime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) -GROUP BY ie.subject_id, ie.stay_id; + ie.subject_id, + ie.stay_id, + MIN(heart_rate) AS heart_rate_min, + MAX(heart_rate) AS heart_rate_max, + AVG(heart_rate) AS heart_rate_mean, + MIN(sbp) AS sbp_min, + MAX(sbp) AS sbp_max, + AVG(sbp) AS sbp_mean, + MIN(dbp) AS dbp_min, + MAX(dbp) AS dbp_max, + AVG(dbp) AS dbp_mean, + MIN(mbp) AS mbp_min, + MAX(mbp) AS mbp_max, + AVG(mbp) AS mbp_mean, + MIN(resp_rate) AS resp_rate_min, + MAX(resp_rate) AS resp_rate_max, + AVG(resp_rate) AS resp_rate_mean, + MIN(temperature) AS temperature_min, + MAX(temperature) AS temperature_max, + AVG(temperature) AS temperature_mean, + MIN(spo2) AS spo2_min, + MAX(spo2) AS spo2_max, + AVG(spo2) AS spo2_mean, + MIN(glucose) AS glucose_min, + MAX(glucose) AS glucose_max, + AVG(glucose) AS glucose_mean +FROM mimiciv_icu.icustays AS ie +LEFT JOIN mimiciv_derived.vitalsign AS ce + ON ie.stay_id = ce.stay_id + AND ce.charttime >= ie.intime - INTERVAL '6 HOUR' + AND ce.charttime <= ie.intime + INTERVAL '1 DAY' +GROUP BY + ie.subject_id, + ie.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/firstday/first_day_weight.sql b/mimic-iv/concepts_postgres/firstday/first_day_weight.sql index f7720f010..c41dbea6e 100644 --- a/mimic-iv/concepts_postgres/firstday/first_day_weight.sql +++ b/mimic-iv/concepts_postgres/firstday/first_day_weight.sql @@ -1,23 +1,17 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS first_day_weight; CREATE TABLE first_day_weight AS --- This query extracts weights for adult ICU patients on their first ICU day. --- It does *not* use any information after the first ICU day, as weight is --- sometimes used to monitor fluid balance. --- The MIMIC-III version used echodata but this isn't available in MIMIC-IV. +DROP TABLE IF EXISTS mimiciv_derived.first_day_weight; CREATE TABLE mimiciv_derived.first_day_weight AS +/* This query extracts weights for adult ICU patients on their first ICU day. */ /* It does *not* use any information after the first ICU day, as weight is */ /* sometimes used to monitor fluid balance. */ /* The MIMIC-III version used echodata but this isn't available in MIMIC-IV. */ SELECT - ie.subject_id - , ie.stay_id - , AVG( - CASE WHEN weight_type = 'admit' THEN ce.weight ELSE NULL END - ) AS weight_admit - , AVG(ce.weight) AS weight - , MIN(ce.weight) AS weight_min - , MAX(ce.weight) AS weight_max -FROM mimiciv_icu.icustays ie --- admission weight -LEFT JOIN mimiciv_derived.weight_durations ce - ON ie.stay_id = ce.stay_id - -- we filter to weights documented during or before the 1st day - AND ce.starttime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) -GROUP BY ie.subject_id, ie.stay_id -; + ie.subject_id, + ie.stay_id, + AVG(CASE WHEN weight_type = 'admit' THEN ce.weight ELSE NULL END) AS weight_admit, + AVG(ce.weight) AS weight, + MIN(ce.weight) AS weight_min, + MAX(ce.weight) AS weight_max +FROM mimiciv_icu.icustays AS ie +/* admission weight */ +LEFT JOIN mimiciv_derived.weight_durations AS ce + ON ie.stay_id = ce.stay_id AND ce.starttime <= ie.intime + INTERVAL '1 DAY' +GROUP BY + ie.subject_id, + ie.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/measurement/bg.sql b/mimic-iv/concepts_postgres/measurement/bg.sql index 2d9aa0da9..3964da607 100644 --- a/mimic-iv/concepts_postgres/measurement/bg.sql +++ b/mimic-iv/concepts_postgres/measurement/bg.sql @@ -1,244 +1,170 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS bg; CREATE TABLE bg AS --- The aim of this query is to pivot entries related to blood gases --- which were found in LABEVENTS +DROP TABLE IF EXISTS mimiciv_derived.bg; CREATE TABLE mimiciv_derived.bg AS +/* The aim of this query is to pivot entries related to blood gases */ /* which were found in LABEVENTS */ WITH bg AS ( - SELECT - -- specimen_id only ever has 1 measurement for each itemid - -- so, we may simply collapse rows using MAX() - MAX(subject_id) AS subject_id - , MAX(hadm_id) AS hadm_id - , MAX(charttime) AS charttime - -- specimen_id *may* have different storetimes, so this - -- is taking the latest - , MAX(storetime) AS storetime - , le.specimen_id - , MAX(CASE WHEN itemid = 52033 THEN value ELSE NULL END) AS specimen - , MAX(CASE WHEN itemid = 50801 THEN valuenum ELSE NULL END) AS aado2 - , MAX( - CASE WHEN itemid = 50802 THEN valuenum ELSE NULL END - ) AS baseexcess - , MAX( - CASE WHEN itemid = 50803 THEN valuenum ELSE NULL END - ) AS bicarbonate - , MAX(CASE WHEN itemid = 50804 THEN valuenum ELSE NULL END) AS totalco2 - , MAX( - CASE WHEN itemid = 50805 THEN valuenum ELSE NULL END - ) AS carboxyhemoglobin - , MAX(CASE WHEN itemid = 50806 THEN valuenum ELSE NULL END) AS chloride - , MAX(CASE WHEN itemid = 50808 THEN valuenum ELSE NULL END) AS calcium - , MAX( - CASE - WHEN - itemid = 50809 AND valuenum <= 10000 THEN valuenum - ELSE NULL - END - ) AS glucose - , MAX( - CASE - WHEN itemid = 50810 AND valuenum <= 100 THEN valuenum ELSE NULL - END - ) AS hematocrit - , MAX( - CASE WHEN itemid = 50811 THEN valuenum ELSE NULL END - ) AS hemoglobin - , MAX( - CASE - WHEN - itemid = 50813 AND valuenum <= 10000 THEN valuenum - ELSE NULL - END - ) AS lactate - , MAX( - CASE WHEN itemid = 50814 THEN valuenum ELSE NULL END - ) AS methemoglobin - , MAX(CASE WHEN itemid = 50815 THEN valuenum ELSE NULL END) AS o2flow - -- fix a common unit conversion error for fio2 - -- atmospheric o2 is 20.89%, so any value <= 20 is unphysiologic - -- usually this is a misplaced O2 flow measurement - , MAX(CASE WHEN itemid = 50816 THEN - CASE - WHEN valuenum > 20 AND valuenum <= 100 THEN valuenum - WHEN - valuenum > 0.2 AND valuenum <= 1.0 THEN valuenum * 100.0 - ELSE NULL END - ELSE NULL END) AS fio2 - , MAX( - CASE - WHEN itemid = 50817 AND valuenum <= 100 THEN valuenum ELSE NULL - END - ) AS so2 - , MAX(CASE WHEN itemid = 50818 THEN valuenum ELSE NULL END) AS pco2 - , MAX(CASE WHEN itemid = 50819 THEN valuenum ELSE NULL END) AS peep - , MAX(CASE WHEN itemid = 50820 THEN valuenum ELSE NULL END) AS ph - , MAX(CASE WHEN itemid = 50821 THEN valuenum ELSE NULL END) AS po2 - , MAX(CASE WHEN itemid = 50822 THEN valuenum ELSE NULL END) AS potassium - , MAX( - CASE WHEN itemid = 50823 THEN valuenum ELSE NULL END - ) AS requiredo2 - , MAX(CASE WHEN itemid = 50824 THEN valuenum ELSE NULL END) AS sodium - , MAX( - CASE WHEN itemid = 50825 THEN valuenum ELSE NULL END - ) AS temperature - , MAX(CASE WHEN itemid = 50807 THEN value ELSE NULL END) AS comments - FROM mimiciv_hosp.labevents le - WHERE le.itemid IN - -- blood gases - ( - 52033 -- specimen - , 50801 -- aado2 - , 50802 -- base excess - , 50803 -- bicarb - , 50804 -- calc tot co2 - , 50805 -- carboxyhgb - , 50806 -- chloride - -- , 52390 -- chloride, WB CL- - , 50807 -- comments - , 50808 -- free calcium - , 50809 -- glucose - , 50810 -- hct - , 50811 -- hgb - , 50813 -- lactate - , 50814 -- methemoglobin - , 50815 -- o2 flow - , 50816 -- fio2 - , 50817 -- o2 sat - , 50818 -- pco2 - , 50819 -- peep - , 50820 -- pH - , 50821 -- pO2 - , 50822 -- potassium - -- , 52408 -- potassium, WB K+ - , 50823 -- required O2 - , 50824 -- sodium - -- , 52411 -- sodium, WB NA + - , 50825 -- temperature - ) - GROUP BY le.specimen_id -) - -, stg_spo2 AS ( - SELECT subject_id, charttime - -- avg here is just used to group SpO2 by charttime - , AVG(valuenum) AS spo2 - FROM mimiciv_icu.chartevents - WHERE itemid = 220277 -- O2 saturation pulseoxymetry - AND valuenum > 0 AND valuenum <= 100 - GROUP BY subject_id, charttime -) - -, stg_fio2 AS ( - SELECT subject_id, charttime - -- pre-process the FiO2s to ensure they are between 21-100% - , MAX( - CASE - WHEN valuenum > 0.2 AND valuenum <= 1 - THEN valuenum * 100 - -- improperly input data - looks like O2 flow in litres - WHEN valuenum > 1 AND valuenum < 20 - THEN NULL - WHEN valuenum >= 20 AND valuenum <= 100 - THEN valuenum - ELSE NULL END - ) AS fio2_chartevents - FROM mimiciv_icu.chartevents - WHERE itemid = 223835 -- Inspired O2 Fraction (FiO2) - AND valuenum > 0 AND valuenum <= 100 - GROUP BY subject_id, charttime -) - -, stg2 AS ( - SELECT bg.* - , ROW_NUMBER() OVER ( - PARTITION BY bg.subject_id, bg.charttime ORDER BY s1.charttime DESC - ) AS lastrowspo2 - , s1.spo2 - FROM bg - LEFT JOIN stg_spo2 s1 - -- same hospitalization - ON bg.subject_id = s1.subject_id - -- spo2 occurred at most 2 hours before this blood gas - AND s1.charttime - BETWEEN DATETIME_SUB(bg.charttime, INTERVAL '2' HOUR) - AND bg.charttime - WHERE bg.po2 IS NOT NULL -) - -, stg3 AS ( - SELECT bg.* - , ROW_NUMBER() OVER ( - PARTITION BY bg.subject_id, bg.charttime ORDER BY s2.charttime DESC - ) AS lastrowfio2 - , s2.fio2_chartevents - FROM stg2 bg - LEFT JOIN stg_fio2 s2 - -- same patient - ON bg.subject_id = s2.subject_id - -- fio2 occurred at most 4 hours before this blood gas - AND s2.charttime >= DATETIME_SUB(bg.charttime, INTERVAL '4' HOUR) - AND s2.charttime <= bg.charttime - AND s2.fio2_chartevents > 0 - -- only the row with the most recent SpO2 (if no SpO2 found lastRowSpO2 = 1) - WHERE bg.lastrowspo2 = 1 -) - -SELECT - stg3.subject_id - , stg3.hadm_id - , stg3.charttime - -- drop down text indicating the specimen type - , specimen - - -- oxygen related parameters - , so2 - , po2 - , pco2 - , fio2_chartevents, fio2 - , aado2 - -- also calculate AADO2 - , CASE - WHEN po2 IS NULL - OR pco2 IS NULL - THEN NULL - WHEN fio2 IS NOT NULL - -- multiple by 100 because fio2 is in a % but should be a fraction - THEN (fio2 / 100) * (760 - 47) - (pco2 / 0.8) - po2 - WHEN fio2_chartevents IS NOT NULL - THEN (fio2_chartevents / 100) * (760 - 47) - (pco2 / 0.8) - po2 + SELECT + MAX(subject_id) AS subject_id, + MAX(hadm_id) AS hadm_id, + MAX(charttime) AS charttime, /* specimen_id *may* have different storetimes, so this */ /* is taking the latest */ + MAX(storetime) AS storetime, + le.specimen_id, + MAX(CASE WHEN itemid = 52033 THEN value ELSE NULL END) AS specimen, + MAX(CASE WHEN itemid = 50801 THEN valuenum ELSE NULL END) AS aado2, + MAX(CASE WHEN itemid = 50802 THEN valuenum ELSE NULL END) AS baseexcess, + MAX(CASE WHEN itemid = 50803 THEN valuenum ELSE NULL END) AS bicarbonate, + MAX(CASE WHEN itemid = 50804 THEN valuenum ELSE NULL END) AS totalco2, + MAX(CASE WHEN itemid = 50805 THEN valuenum ELSE NULL END) AS carboxyhemoglobin, + MAX(CASE WHEN itemid = 50806 THEN valuenum ELSE NULL END) AS chloride, + MAX(CASE WHEN itemid = 50808 THEN valuenum ELSE NULL END) AS calcium, + MAX(CASE WHEN itemid = 50809 AND valuenum <= 10000 THEN valuenum ELSE NULL END) AS glucose, + MAX(CASE WHEN itemid = 50810 AND valuenum <= 100 THEN valuenum ELSE NULL END) AS hematocrit, + MAX(CASE WHEN itemid = 50811 THEN valuenum ELSE NULL END) AS hemoglobin, + MAX(CASE WHEN itemid = 50813 AND valuenum <= 10000 THEN valuenum ELSE NULL END) AS lactate, + MAX(CASE WHEN itemid = 50814 THEN valuenum ELSE NULL END) AS methemoglobin, + MAX(CASE WHEN itemid = 50815 THEN valuenum ELSE NULL END) AS o2flow, /* fix a common unit conversion error for fio2 */ /* atmospheric o2 is 20.89%, so any value <= 20 is unphysiologic */ /* usually this is a misplaced O2 flow measurement */ + MAX( + CASE + WHEN itemid = 50816 + THEN CASE + WHEN valuenum > 20 AND valuenum <= 100 + THEN valuenum + WHEN valuenum > 0.2 AND valuenum <= 1.0 + THEN valuenum * 100.0 + ELSE NULL + END ELSE NULL - END AS aado2_calc - , CASE - WHEN po2 IS NULL - THEN NULL - WHEN fio2 IS NOT NULL - -- multiply by 100 because fio2 is in a % but should be a fraction - THEN 100 * po2 / fio2 - WHEN fio2_chartevents IS NOT NULL - -- multiply by 100 because fio2 is in a % but should be a fraction - THEN 100 * po2 / fio2_chartevents + END + ) AS fio2, + MAX(CASE WHEN itemid = 50817 AND valuenum <= 100 THEN valuenum ELSE NULL END) AS so2, + MAX(CASE WHEN itemid = 50818 THEN valuenum ELSE NULL END) AS pco2, + MAX(CASE WHEN itemid = 50819 THEN valuenum ELSE NULL END) AS peep, + MAX(CASE WHEN itemid = 50820 THEN valuenum ELSE NULL END) AS ph, + MAX(CASE WHEN itemid = 50821 THEN valuenum ELSE NULL END) AS po2, + MAX(CASE WHEN itemid = 50822 THEN valuenum ELSE NULL END) AS potassium, + MAX(CASE WHEN itemid = 50823 THEN valuenum ELSE NULL END) AS requiredo2, + MAX(CASE WHEN itemid = 50824 THEN valuenum ELSE NULL END) AS sodium, + MAX(CASE WHEN itemid = 50825 THEN valuenum ELSE NULL END) AS temperature, + MAX(CASE WHEN itemid = 50807 THEN value ELSE NULL END) AS comments + FROM mimiciv_hosp.labevents AS le + WHERE + le.itemid IN (52033 /* specimen */, 50801 /* aado2 */, 50802 /* base excess */, 50803 /* bicarb */, 50804 /* calc tot co2 */, 50805 /* carboxyhgb */, 50806 /* chloride */ /* , 52390 -- chloride, WB CL- */, 50807 /* comments */, 50808 /* free calcium */, 50809 /* glucose */, 50810 /* hct */, 50811 /* hgb */, 50813 /* lactate */, 50814 /* methemoglobin */, 50815 /* o2 flow */, 50816 /* fio2 */, 50817 /* o2 sat */, 50818 /* pco2 */, 50819 /* peep */, 50820 /* pH */, 50821 /* pO2 */, 50822 /* potassium */ /* , 52408 -- potassium, WB K+ */, 50823 /* required O2 */, 50824 /* sodium */ /* , 52411 -- sodium, WB NA + */, 50825 /* temperature */) + GROUP BY + le.specimen_id +), stg_spo2 AS ( + SELECT + subject_id, + charttime, /* avg here is just used to group SpO2 by charttime */ + AVG(valuenum) AS spo2 + FROM mimiciv_icu.chartevents + WHERE + itemid = 220277 /* O2 saturation pulseoxymetry */ AND valuenum > 0 AND valuenum <= 100 + GROUP BY + subject_id, + charttime +), stg_fio2 AS ( + SELECT + subject_id, + charttime, /* pre-process the FiO2s to ensure they are between 21-100% */ + MAX( + CASE + WHEN valuenum > 0.2 AND valuenum <= 1 + THEN valuenum * 100 + WHEN valuenum > 1 AND valuenum < 20 + THEN NULL + WHEN valuenum >= 20 AND valuenum <= 100 + THEN valuenum ELSE NULL - END AS pao2fio2ratio - -- acid-base parameters - , ph, baseexcess - , bicarbonate, totalco2 - - -- blood count parameters - , hematocrit - , hemoglobin - , carboxyhemoglobin - , methemoglobin - - -- chemistry - , chloride, calcium - , temperature - , potassium, sodium - , lactate - , glucose - --- ventilation stuff that's sometimes input --- , intubated, tidalvolume, ventilationrate, ventilator --- , peep, o2flow --- , requiredo2 + END + ) AS fio2_chartevents + FROM mimiciv_icu.chartevents + WHERE + itemid = 223835 /* Inspired O2 Fraction (FiO2) */ AND valuenum > 0 AND valuenum <= 100 + GROUP BY + subject_id, + charttime +), stg2 AS ( + SELECT + bg.*, + ROW_NUMBER() OVER (PARTITION BY bg.subject_id, bg.charttime ORDER BY s1.charttime DESC NULLS LAST) AS lastrowspo2, + s1.spo2 + FROM bg + LEFT JOIN stg_spo2 AS s1 + ON bg.subject_id = s1.subject_id + AND s1.charttime BETWEEN bg.charttime - INTERVAL '2 HOUR' AND bg.charttime + WHERE + NOT bg.po2 IS NULL +), stg3 AS ( + SELECT + bg.*, + ROW_NUMBER() OVER (PARTITION BY bg.subject_id, bg.charttime ORDER BY s2.charttime DESC NULLS LAST) AS lastrowfio2, + s2.fio2_chartevents + FROM stg2 AS bg + LEFT JOIN stg_fio2 AS s2 + ON bg.subject_id = s2.subject_id + AND s2.charttime >= bg.charttime - INTERVAL '4 HOUR' + AND s2.charttime <= bg.charttime + AND s2.fio2_chartevents > 0 + /* only the row with the most recent SpO2 (if no SpO2 found lastRowSpO2 = 1) */ + WHERE + bg.lastrowspo2 = 1 +) +SELECT + stg3.subject_id, + stg3.hadm_id, + stg3.charttime, /* drop down text indicating the specimen type */ + specimen, /* oxygen related parameters */ + so2, + po2, + pco2, + fio2_chartevents, + fio2, + aado2, /* also calculate AADO2 */ + CASE + WHEN po2 IS NULL OR pco2 IS NULL + THEN NULL + WHEN NOT fio2 IS NULL + THEN ( + CAST(fio2 AS DOUBLE PRECISION) / 100 + ) * ( + 760 - 47 + ) - ( + CAST(pco2 AS DOUBLE PRECISION) / 0.8 + ) - po2 + WHEN NOT fio2_chartevents IS NULL + THEN ( + CAST(fio2_chartevents AS DOUBLE PRECISION) / 100 + ) * ( + 760 - 47 + ) - ( + CAST(pco2 AS DOUBLE PRECISION) / 0.8 + ) - po2 + ELSE NULL + END AS aado2_calc, + CASE + WHEN po2 IS NULL + THEN NULL + WHEN NOT fio2 IS NULL + THEN CAST(100 * po2 AS DOUBLE PRECISION) / fio2 + WHEN NOT fio2_chartevents IS NULL + THEN CAST(100 * po2 AS DOUBLE PRECISION) / fio2_chartevents + ELSE NULL + END AS pao2fio2ratio, /* acid-base parameters */ + ph, + baseexcess, + bicarbonate, + totalco2, /* blood count parameters */ + hematocrit, + hemoglobin, + carboxyhemoglobin, + methemoglobin, /* chemistry */ + chloride, + calcium, + temperature, + potassium, + sodium, + lactate, + glucose +/* ventilation stuff that's sometimes input */ /* , intubated, tidalvolume, ventilationrate, ventilator */ /* , peep, o2flow */ /* , requiredo2 */ FROM stg3 -WHERE lastrowfio2 = 1 -- only the most recent FiO2 -; +WHERE + lastrowfio2 = 1 /* only the most recent FiO2 */ \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/measurement/blood_differential.sql b/mimic-iv/concepts_postgres/measurement/blood_differential.sql index 258cae355..9369f703b 100644 --- a/mimic-iv/concepts_postgres/measurement/blood_differential.sql +++ b/mimic-iv/concepts_postgres/measurement/blood_differential.sql @@ -1,205 +1,133 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS blood_differential; CREATE TABLE blood_differential AS --- For reference, some common unit conversions: --- 10^9/L == K/uL == 10^3/uL +DROP TABLE IF EXISTS mimiciv_derived.blood_differential; CREATE TABLE mimiciv_derived.blood_differential AS +/* For reference, some common unit conversions: */ /* 10^9/L == K/uL == 10^3/uL */ WITH blood_diff AS ( - SELECT - MAX(subject_id) AS subject_id - , MAX(hadm_id) AS hadm_id - , MAX(charttime) AS charttime - , le.specimen_id - - -- create one set of columns for percentages, one set for counts - -- we harmonize all count units into K/uL == 10^9/L - -- counts have an "_abs" suffix, percentages do not - -- absolute counts - , MAX( - CASE - WHEN itemid IN (51300, 51301, 51755) THEN valuenum ELSE NULL - END - ) AS wbc - , MAX( - CASE WHEN itemid = 52069 THEN valuenum ELSE NULL END - ) AS basophils_abs - -- 52073 in K/uL, 51199 in #/uL - , MAX( - CASE - WHEN - itemid = 52073 THEN valuenum - WHEN itemid = 51199 THEN valuenum / 1000.0 ELSE NULL - END - ) AS eosinophils_abs - -- 51133 in K/uL, 52769 in #/uL - , MAX( - CASE - WHEN - itemid = 51133 THEN valuenum - WHEN itemid = 52769 THEN valuenum / 1000.0 ELSE NULL - END - ) AS lymphocytes_abs - -- 52074 in K/uL, 51253 in #/uL - , MAX( - CASE - WHEN - itemid = 52074 THEN valuenum - WHEN itemid = 51253 THEN valuenum / 1000.0 ELSE NULL - END - ) AS monocytes_abs - , MAX( - CASE WHEN itemid = 52075 THEN valuenum ELSE NULL END - ) AS neutrophils_abs - -- convert from #/uL to K/uL - , MAX( - CASE WHEN itemid = 51218 THEN valuenum / 1000.0 ELSE NULL END - ) AS granulocytes_abs - - -- percentages, equal to cell count / white blood cell count - , MAX(CASE WHEN itemid = 51146 THEN valuenum ELSE NULL END) AS basophils - , MAX( - CASE WHEN itemid = 51200 THEN valuenum ELSE NULL END - ) AS eosinophils - , MAX( - CASE WHEN itemid IN (51244, 51245) THEN valuenum ELSE NULL END - ) AS lymphocytes - , MAX(CASE WHEN itemid = 51254 THEN valuenum ELSE NULL END) AS monocytes - , MAX( - CASE WHEN itemid = 51256 THEN valuenum ELSE NULL END - ) AS neutrophils - - -- other cell count percentages - , MAX( - CASE WHEN itemid = 51143 THEN valuenum ELSE NULL END - ) AS atypical_lymphocytes - , MAX(CASE WHEN itemid = 51144 THEN valuenum ELSE NULL END) AS bands - , MAX( - CASE WHEN itemid = 52135 THEN valuenum ELSE NULL END - ) AS immature_granulocytes - , MAX( - CASE WHEN itemid = 51251 THEN valuenum ELSE NULL END - ) AS metamyelocytes - , MAX(CASE WHEN itemid = 51257 THEN valuenum ELSE NULL END) AS nrbc - - -- utility flags which determine whether imputation is possible - , CASE - -- WBC is available - WHEN - MAX( - CASE - WHEN - itemid IN (51300, 51301, 51755) THEN valuenum - ELSE NULL - END - ) > 0 - -- and we have at least one percentage from the diff - -- sometimes the entire diff is 0%, which looks like bad data - AND SUM( - CASE - WHEN - itemid IN ( - 51146, 51200, 51244, 51245, 51254, 51256 - ) THEN valuenum - ELSE NULL - END - ) > 0 - THEN 1 ELSE 0 END AS impute_abs - - FROM mimiciv_hosp.labevents le - WHERE le.itemid IN - ( - 51146 -- basophils - , 52069 -- Absolute basophil count - , 51199 -- Eosinophil Count - , 51200 -- Eosinophils - , 52073 -- Absolute Eosinophil count - , 51244 -- Lymphocytes - , 51245 -- Lymphocytes, Percent - , 51133 -- Absolute Lymphocyte Count - , 52769 -- Absolute Lymphocyte Count - , 51253 -- Monocyte Count - , 51254 -- Monocytes - , 52074 -- Absolute Monocyte Count - , 51256 -- Neutrophils - , 52075 -- Absolute Neutrophil Count - , 51143 -- Atypical lymphocytes - , 51144 -- Bands (%) - , 51218 -- Granulocyte Count - , 52135 -- Immature granulocytes (%) - , 51251 -- Metamyelocytes - , 51257 -- Nucleated Red Cells - - -- wbc totals measured in K/uL - -- 52220 (wbcp) is percentage - , 51300, 51301, 51755 - - -- below are point of care tests which are extremely infrequent - -- and usually low quality - -- 51697, -- Neutrophils (mmol/L) - - -- below itemid do not have data as of MIMIC-IV v1.0 - -- 51536, -- Absolute Lymphocyte Count - -- 51537, -- Absolute Neutrophil - -- 51690, -- Lymphocytes - -- 52151, -- NRBC - - ) - AND valuenum IS NOT NULL - -- differential values cannot be negative - AND valuenum >= 0 - GROUP BY le.specimen_id + SELECT + MAX(subject_id) AS subject_id, + MAX(hadm_id) AS hadm_id, + MAX(charttime) AS charttime, + le.specimen_id, /* create one set of columns for percentages, one set for counts */ /* we harmonize all count units into K/uL == 10^9/L */ /* counts have an "_abs" suffix, percentages do not */ /* absolute counts */ + MAX(CASE WHEN itemid IN (51300, 51301, 51755) THEN valuenum ELSE NULL END) AS wbc, + MAX(CASE WHEN itemid = 52069 THEN valuenum ELSE NULL END) AS basophils_abs, /* 52073 in K/uL, 51199 in #/uL */ + MAX( + CASE + WHEN itemid = 52073 + THEN valuenum + WHEN itemid = 51199 + THEN CAST(valuenum AS DOUBLE PRECISION) / 1000.0 + ELSE NULL + END + ) AS eosinophils_abs, /* 51133 in K/uL, 52769 in #/uL */ + MAX( + CASE + WHEN itemid = 51133 + THEN valuenum + WHEN itemid = 52769 + THEN CAST(valuenum AS DOUBLE PRECISION) / 1000.0 + ELSE NULL + END + ) AS lymphocytes_abs, /* 52074 in K/uL, 51253 in #/uL */ + MAX( + CASE + WHEN itemid = 52074 + THEN valuenum + WHEN itemid = 51253 + THEN CAST(valuenum AS DOUBLE PRECISION) / 1000.0 + ELSE NULL + END + ) AS monocytes_abs, + MAX(CASE WHEN itemid = 52075 THEN valuenum ELSE NULL END) AS neutrophils_abs, /* convert from #/uL to K/uL */ + MAX( + CASE + WHEN itemid = 51218 + THEN CAST(valuenum AS DOUBLE PRECISION) / 1000.0 + ELSE NULL + END + ) AS granulocytes_abs, /* percentages, equal to cell count / white blood cell count */ + MAX(CASE WHEN itemid = 51146 THEN valuenum ELSE NULL END) AS basophils, + MAX(CASE WHEN itemid = 51200 THEN valuenum ELSE NULL END) AS eosinophils, + MAX(CASE WHEN itemid IN (51244, 51245) THEN valuenum ELSE NULL END) AS lymphocytes, + MAX(CASE WHEN itemid = 51254 THEN valuenum ELSE NULL END) AS monocytes, + MAX(CASE WHEN itemid = 51256 THEN valuenum ELSE NULL END) AS neutrophils, /* other cell count percentages */ + MAX(CASE WHEN itemid = 51143 THEN valuenum ELSE NULL END) AS atypical_lymphocytes, + MAX(CASE WHEN itemid = 51144 THEN valuenum ELSE NULL END) AS bands, + MAX(CASE WHEN itemid = 52135 THEN valuenum ELSE NULL END) AS immature_granulocytes, + MAX(CASE WHEN itemid = 51251 THEN valuenum ELSE NULL END) AS metamyelocytes, + MAX(CASE WHEN itemid = 51257 THEN valuenum ELSE NULL END) AS nrbc, /* utility flags which determine whether imputation is possible */ + CASE + WHEN MAX(CASE WHEN itemid IN (51300, 51301, 51755) THEN valuenum ELSE NULL END) > 0 + AND SUM( + CASE + WHEN itemid IN (51146, 51200, 51244, 51245, 51254, 51256) + THEN valuenum + ELSE NULL + END + ) > 0 + THEN 1 + ELSE 0 + END AS impute_abs + FROM mimiciv_hosp.labevents AS le + WHERE + le.itemid IN (51146 /* basophils */, 52069 /* Absolute basophil count */, 51199 /* Eosinophil Count */, 51200 /* Eosinophils */, 52073 /* Absolute Eosinophil count */, 51244 /* Lymphocytes */, 51245 /* Lymphocytes, Percent */, 51133 /* Absolute Lymphocyte Count */, 52769 /* Absolute Lymphocyte Count */, 51253 /* Monocyte Count */, 51254 /* Monocytes */, 52074 /* Absolute Monocyte Count */, 51256 /* Neutrophils */, 52075 /* Absolute Neutrophil Count */, 51143 /* Atypical lymphocytes */, 51144 /* Bands (%) */, 51218 /* Granulocyte Count */, 52135 /* Immature granulocytes (%) */, 51251 /* Metamyelocytes */, 51257 /* Nucleated Red Cells */ /* wbc totals measured in K/uL */ /* 52220 (wbcp) is percentage */, 51300, 51301, 51755) /* below are point of care tests which are extremely infrequent */ /* and usually low quality */ /* 51697, -- Neutrophils (mmol/L) */ /* below itemid do not have data as of MIMIC-IV v1.0 */ /* 51536, -- Absolute Lymphocyte Count */ /* 51537, -- Absolute Neutrophil */ /* 51690, -- Lymphocytes */ /* 52151, -- NRBC */ + AND NOT valuenum IS NULL + AND valuenum >= 0 + GROUP BY + le.specimen_id ) - SELECT - subject_id, hadm_id, charttime, specimen_id - - , wbc - -- impute absolute count if percentage & WBC is available - , ROUND(CAST(CASE - WHEN basophils_abs IS NULL - AND basophils IS NOT NULL - AND impute_abs = 1 - THEN basophils * wbc / 100 - ELSE basophils_abs - END AS NUMERIC), 4) AS basophils_abs - , ROUND(CAST(CASE - WHEN eosinophils_abs IS NULL - AND eosinophils IS NOT NULL - AND impute_abs = 1 - THEN eosinophils * wbc / 100 - ELSE eosinophils_abs - END AS NUMERIC), 4) AS eosinophils_abs - , ROUND(CAST(CASE - WHEN lymphocytes_abs IS NULL - AND lymphocytes IS NOT NULL - AND impute_abs = 1 - THEN lymphocytes * wbc / 100 - ELSE lymphocytes_abs - END AS NUMERIC), 4) AS lymphocytes_abs - , ROUND(CAST(CASE - WHEN monocytes_abs IS NULL - AND monocytes IS NOT NULL - AND impute_abs = 1 - THEN monocytes * wbc / 100 - ELSE monocytes_abs - END AS NUMERIC), 4) AS monocytes_abs - , ROUND(CAST(CASE - WHEN neutrophils_abs IS NULL - AND neutrophils IS NOT NULL - AND impute_abs = 1 - THEN neutrophils * wbc / 100 - ELSE neutrophils_abs - END AS NUMERIC), 4) AS neutrophils_abs - - , basophils - , eosinophils - , lymphocytes - , monocytes - , neutrophils - - -- impute bands/blasts? - , atypical_lymphocytes - , bands - , immature_granulocytes - , metamyelocytes - , nrbc -FROM blood_diff -; + subject_id, + hadm_id, + charttime, + specimen_id, + wbc, /* impute absolute count if percentage & WBC is available */ + ROUND( + CAST(CASE + WHEN basophils_abs IS NULL AND NOT basophils IS NULL AND impute_abs = 1 + THEN CAST(basophils * wbc AS DOUBLE PRECISION) / 100 + ELSE basophils_abs + END AS DECIMAL), + 4 + ) AS basophils_abs, + ROUND( + CAST(CASE + WHEN eosinophils_abs IS NULL AND NOT eosinophils IS NULL AND impute_abs = 1 + THEN CAST(eosinophils * wbc AS DOUBLE PRECISION) / 100 + ELSE eosinophils_abs + END AS DECIMAL), + 4 + ) AS eosinophils_abs, + ROUND( + CAST(CASE + WHEN lymphocytes_abs IS NULL AND NOT lymphocytes IS NULL AND impute_abs = 1 + THEN CAST(lymphocytes * wbc AS DOUBLE PRECISION) / 100 + ELSE lymphocytes_abs + END AS DECIMAL), + 4 + ) AS lymphocytes_abs, + ROUND( + CAST(CASE + WHEN monocytes_abs IS NULL AND NOT monocytes IS NULL AND impute_abs = 1 + THEN CAST(monocytes * wbc AS DOUBLE PRECISION) / 100 + ELSE monocytes_abs + END AS DECIMAL), + 4 + ) AS monocytes_abs, + ROUND( + CAST(CASE + WHEN neutrophils_abs IS NULL AND NOT neutrophils IS NULL AND impute_abs = 1 + THEN CAST(neutrophils * wbc AS DOUBLE PRECISION) / 100 + ELSE neutrophils_abs + END AS DECIMAL), + 4 + ) AS neutrophils_abs, + basophils, + eosinophils, + lymphocytes, + monocytes, + neutrophils, /* impute bands/blasts? */ + atypical_lymphocytes, + bands, + immature_granulocytes, + metamyelocytes, + nrbc +FROM blood_diff \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/measurement/cardiac_marker.sql b/mimic-iv/concepts_postgres/measurement/cardiac_marker.sql index 7a758a396..dc2020ca9 100644 --- a/mimic-iv/concepts_postgres/measurement/cardiac_marker.sql +++ b/mimic-iv/concepts_postgres/measurement/cardiac_marker.sql @@ -1,24 +1,17 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS cardiac_marker; CREATE TABLE cardiac_marker AS --- begin query that extracts the data +DROP TABLE IF EXISTS mimiciv_derived.cardiac_marker; CREATE TABLE mimiciv_derived.cardiac_marker AS +/* begin query that extracts the data */ SELECT - MAX(subject_id) AS subject_id - , MAX(hadm_id) AS hadm_id - , MAX(charttime) AS charttime - , le.specimen_id - -- convert from itemid into a meaningful column - , MAX(CASE WHEN itemid = 51003 THEN value ELSE NULL END) AS troponin_t - , MAX(CASE WHEN itemid = 50911 THEN valuenum ELSE NULL END) AS ck_mb - , MAX(CASE WHEN itemid = 50963 THEN valuenum ELSE NULL END) AS ntprobnp -FROM mimiciv_hosp.labevents le -WHERE le.itemid IN - ( - -- 51002, -- Troponin I (troponin-I is not measured in MIMIC-IV) - -- 52598, -- Troponin I, point of care, rare/poor quality - 51003 -- Troponin T - , 50911 -- Creatinine Kinase, MB isoenzyme - , 50963 -- N-terminal (NT)-pro hormone BNP (NT-proBNP) - ) - AND valuenum IS NOT NULL -GROUP BY le.specimen_id -; + MAX(subject_id) AS subject_id, + MAX(hadm_id) AS hadm_id, + MAX(charttime) AS charttime, + le.specimen_id, /* convert from itemid into a meaningful column */ + MAX(CASE WHEN itemid = 51003 THEN value ELSE NULL END) AS troponin_t, + MAX(CASE WHEN itemid = 50911 THEN valuenum ELSE NULL END) AS ck_mb, + MAX(CASE WHEN itemid = 50963 THEN valuenum ELSE NULL END) AS ntprobnp +FROM mimiciv_hosp.labevents AS le +WHERE + le.itemid IN (51003 /* 51002, -- Troponin I (troponin-I is not measured in MIMIC-IV) */ /* 52598, -- Troponin I, point of care, rare/poor quality */ /* Troponin T */, 50911 /* Creatinine Kinase, MB isoenzyme */, 50963 /* N-terminal (NT)-pro hormone BNP (NT-proBNP) */) + AND NOT valuenum IS NULL +GROUP BY + le.specimen_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/measurement/chemistry.sql b/mimic-iv/concepts_postgres/measurement/chemistry.sql index 33e56b093..ce9b0e268 100644 --- a/mimic-iv/concepts_postgres/measurement/chemistry.sql +++ b/mimic-iv/concepts_postgres/measurement/chemistry.sql @@ -1,87 +1,29 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS chemistry; CREATE TABLE chemistry AS --- extract chemistry labs --- excludes point of care tests (very rare) --- blood gas measurements are *not* included in this query --- instead they are in bg.sql +DROP TABLE IF EXISTS mimiciv_derived.chemistry; CREATE TABLE mimiciv_derived.chemistry AS +/* extract chemistry labs */ /* excludes point of care tests (very rare) */ /* blood gas measurements are *not* included in this query */ /* instead they are in bg.sql */ SELECT - MAX(subject_id) AS subject_id - , MAX(hadm_id) AS hadm_id - , MAX(charttime) AS charttime - , le.specimen_id - -- convert from itemid into a meaningful column - , MAX( - CASE WHEN itemid = 50862 AND valuenum <= 10 THEN valuenum ELSE NULL END - ) AS albumin - , MAX( - CASE WHEN itemid = 50930 AND valuenum <= 10 THEN valuenum ELSE NULL END - ) AS globulin - , MAX( - CASE WHEN itemid = 50976 AND valuenum <= 20 THEN valuenum ELSE NULL END - ) AS total_protein - , MAX( - CASE - WHEN itemid = 50868 AND valuenum <= 10000 THEN valuenum ELSE NULL - END - ) AS aniongap - , MAX( - CASE - WHEN itemid = 50882 AND valuenum <= 10000 THEN valuenum ELSE NULL - END - ) AS bicarbonate - , MAX( - CASE WHEN itemid = 51006 AND valuenum <= 300 THEN valuenum ELSE NULL END - ) AS bun - , MAX( - CASE - WHEN itemid = 50893 AND valuenum <= 10000 THEN valuenum ELSE NULL - END - ) AS calcium - , MAX( - CASE - WHEN itemid = 50902 AND valuenum <= 10000 THEN valuenum ELSE NULL - END - ) AS chloride - , MAX( - CASE WHEN itemid = 50912 AND valuenum <= 150 THEN valuenum ELSE NULL END - ) AS creatinine - , MAX( - CASE - WHEN itemid = 50931 AND valuenum <= 10000 THEN valuenum ELSE NULL - END - ) AS glucose - , MAX( - CASE WHEN itemid = 50983 AND valuenum <= 200 THEN valuenum ELSE NULL END - ) AS sodium - , MAX( - CASE WHEN itemid = 50971 AND valuenum <= 30 THEN valuenum ELSE NULL END - ) AS potassium -FROM mimiciv_hosp.labevents le -WHERE le.itemid IN - ( - -- comment is: LABEL | CATEGORY | FLUID | NUMBER OF ROWS IN LABEVENTS - 50862 -- ALBUMIN | CHEMISTRY | BLOOD | 146697 - , 50930 -- Globulin - , 50976 -- Total protein - -- 52456, -- Anion gap, point of care test - , 50868 -- ANION GAP | CHEMISTRY | BLOOD | 769895 - , 50882 -- BICARBONATE | CHEMISTRY | BLOOD | 780733 - , 50893 -- Calcium - -- 52502, Creatinine, point of care - , 50912 -- CREATININE | CHEMISTRY | BLOOD | 797476 - , 50902 -- CHLORIDE | CHEMISTRY | BLOOD | 795568 - , 50931 -- GLUCOSE | CHEMISTRY | BLOOD | 748981 - -- 52525, Glucose, point of care - -- 52566, -- Potassium, point of care - , 50971 -- POTASSIUM | CHEMISTRY | BLOOD | 845825 - -- 52579, -- Sodium, point of care - , 50983 -- SODIUM | CHEMISTRY | BLOOD | 808489 - -- 52603, Urea, point of care - , 51006 -- UREA NITROGEN | CHEMISTRY | BLOOD | 791925 - ) - AND valuenum IS NOT NULL - -- lab values cannot be 0 and cannot be negative - -- .. except anion gap. - AND (valuenum > 0 OR itemid = 50868) -GROUP BY le.specimen_id -; + MAX(subject_id) AS subject_id, + MAX(hadm_id) AS hadm_id, + MAX(charttime) AS charttime, + le.specimen_id, /* convert from itemid into a meaningful column */ + MAX(CASE WHEN itemid = 50862 AND valuenum <= 10 THEN valuenum ELSE NULL END) AS albumin, + MAX(CASE WHEN itemid = 50930 AND valuenum <= 10 THEN valuenum ELSE NULL END) AS globulin, + MAX(CASE WHEN itemid = 50976 AND valuenum <= 20 THEN valuenum ELSE NULL END) AS total_protein, + MAX(CASE WHEN itemid = 50868 AND valuenum <= 10000 THEN valuenum ELSE NULL END) AS aniongap, + MAX(CASE WHEN itemid = 50882 AND valuenum <= 10000 THEN valuenum ELSE NULL END) AS bicarbonate, + MAX(CASE WHEN itemid = 51006 AND valuenum <= 300 THEN valuenum ELSE NULL END) AS bun, + MAX(CASE WHEN itemid = 50893 AND valuenum <= 10000 THEN valuenum ELSE NULL END) AS calcium, + MAX(CASE WHEN itemid = 50902 AND valuenum <= 10000 THEN valuenum ELSE NULL END) AS chloride, + MAX(CASE WHEN itemid = 50912 AND valuenum <= 150 THEN valuenum ELSE NULL END) AS creatinine, + MAX(CASE WHEN itemid = 50931 AND valuenum <= 10000 THEN valuenum ELSE NULL END) AS glucose, + MAX(CASE WHEN itemid = 50983 AND valuenum <= 200 THEN valuenum ELSE NULL END) AS sodium, + MAX(CASE WHEN itemid = 50971 AND valuenum <= 30 THEN valuenum ELSE NULL END) AS potassium +FROM mimiciv_hosp.labevents AS le +WHERE + le.itemid IN (50862 /* comment is: LABEL | CATEGORY | FLUID | NUMBER OF ROWS IN LABEVENTS */ /* ALBUMIN | CHEMISTRY | BLOOD | 146697 */, 50930 /* Globulin */, 50976 /* Total protein */ /* 52456, -- Anion gap, point of care test */, 50868 /* ANION GAP | CHEMISTRY | BLOOD | 769895 */, 50882 /* BICARBONATE | CHEMISTRY | BLOOD | 780733 */, 50893 /* Calcium */ /* 52502, Creatinine, point of care */, 50912 /* CREATININE | CHEMISTRY | BLOOD | 797476 */, 50902 /* CHLORIDE | CHEMISTRY | BLOOD | 795568 */, 50931 /* GLUCOSE | CHEMISTRY | BLOOD | 748981 */ /* 52525, Glucose, point of care */ /* 52566, -- Potassium, point of care */, 50971 /* POTASSIUM | CHEMISTRY | BLOOD | 845825 */ /* 52579, -- Sodium, point of care */, 50983 /* SODIUM | CHEMISTRY | BLOOD | 808489 */ /* 52603, Urea, point of care */, 51006 /* UREA NITROGEN | CHEMISTRY | BLOOD | 791925 */) + AND NOT valuenum IS NULL + AND ( + valuenum > 0 OR itemid = 50868 + ) /* lab values cannot be 0 and cannot be negative */ /* .. except anion gap. */ +GROUP BY + le.specimen_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/measurement/coagulation.sql b/mimic-iv/concepts_postgres/measurement/coagulation.sql index f479ae70c..05ca7b489 100644 --- a/mimic-iv/concepts_postgres/measurement/coagulation.sql +++ b/mimic-iv/concepts_postgres/measurement/coagulation.sql @@ -1,33 +1,19 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS coagulation; CREATE TABLE coagulation AS +DROP TABLE IF EXISTS mimiciv_derived.coagulation; CREATE TABLE mimiciv_derived.coagulation AS SELECT - MAX(subject_id) AS subject_id - , MAX(hadm_id) AS hadm_id - , MAX(charttime) AS charttime - , le.specimen_id - -- convert from itemid into a meaningful column - , MAX(CASE WHEN itemid = 51196 THEN valuenum ELSE NULL END) AS d_dimer - , MAX(CASE WHEN itemid = 51214 THEN valuenum ELSE NULL END) AS fibrinogen - , MAX(CASE WHEN itemid = 51297 THEN valuenum ELSE NULL END) AS thrombin - , MAX(CASE WHEN itemid = 51237 THEN valuenum ELSE NULL END) AS inr - , MAX(CASE WHEN itemid = 51274 THEN valuenum ELSE NULL END) AS pt - , MAX(CASE WHEN itemid = 51275 THEN valuenum ELSE NULL END) AS ptt -FROM mimiciv_hosp.labevents le -WHERE le.itemid IN - ( - -- Bleeding Time, no data as of MIMIC-IV v0.4 - -- 51149, 52750, 52072, 52073 - 51196 -- D-Dimer - , 51214 -- Fibrinogen - -- Reptilase Time, no data as of MIMIC-IV v0.4 - -- 51280, 52893, - -- Reptilase Time Control, no data as of MIMIC-IV v0.4 - -- 51281, 52161, - , 51297 -- thrombin - , 51237 -- INR - , 51274 -- PT - , 51275 -- PTT - ) - AND valuenum IS NOT NULL -GROUP BY le.specimen_id -; + MAX(subject_id) AS subject_id, + MAX(hadm_id) AS hadm_id, + MAX(charttime) AS charttime, + le.specimen_id, /* convert from itemid into a meaningful column */ + MAX(CASE WHEN itemid = 51196 THEN valuenum ELSE NULL END) AS d_dimer, + MAX(CASE WHEN itemid = 51214 THEN valuenum ELSE NULL END) AS fibrinogen, + MAX(CASE WHEN itemid = 51297 THEN valuenum ELSE NULL END) AS thrombin, + MAX(CASE WHEN itemid = 51237 THEN valuenum ELSE NULL END) AS inr, + MAX(CASE WHEN itemid = 51274 THEN valuenum ELSE NULL END) AS pt, + MAX(CASE WHEN itemid = 51275 THEN valuenum ELSE NULL END) AS ptt +FROM mimiciv_hosp.labevents AS le +WHERE + le.itemid IN (51196 /* Bleeding Time, no data as of MIMIC-IV v0.4 */ /* 51149, 52750, 52072, 52073 */ /* D-Dimer */, 51214 /* Fibrinogen */ /* Reptilase Time, no data as of MIMIC-IV v0.4 */ /* 51280, 52893, */ /* Reptilase Time Control, no data as of MIMIC-IV v0.4 */ /* 51281, 52161, */, 51297 /* thrombin */, 51237 /* INR */, 51274 /* PT */, 51275 /* PTT */) + AND NOT valuenum IS NULL +GROUP BY + le.specimen_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/measurement/complete_blood_count.sql b/mimic-iv/concepts_postgres/measurement/complete_blood_count.sql index 6bde26810..5fa3db50f 100644 --- a/mimic-iv/concepts_postgres/measurement/complete_blood_count.sql +++ b/mimic-iv/concepts_postgres/measurement/complete_blood_count.sql @@ -1,38 +1,25 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS complete_blood_count; CREATE TABLE complete_blood_count AS --- begin query that extracts the data +DROP TABLE IF EXISTS mimiciv_derived.complete_blood_count; CREATE TABLE mimiciv_derived.complete_blood_count AS +/* begin query that extracts the data */ SELECT - MAX(subject_id) AS subject_id - , MAX(hadm_id) AS hadm_id - , MAX(charttime) AS charttime - , le.specimen_id - -- convert from itemid into a meaningful column - , MAX(CASE WHEN itemid = 51221 THEN valuenum ELSE NULL END) AS hematocrit - , MAX(CASE WHEN itemid = 51222 THEN valuenum ELSE NULL END) AS hemoglobin - , MAX(CASE WHEN itemid = 51248 THEN valuenum ELSE NULL END) AS mch - , MAX(CASE WHEN itemid = 51249 THEN valuenum ELSE NULL END) AS mchc - , MAX(CASE WHEN itemid = 51250 THEN valuenum ELSE NULL END) AS mcv - , MAX(CASE WHEN itemid = 51265 THEN valuenum ELSE NULL END) AS platelet - , MAX(CASE WHEN itemid = 51279 THEN valuenum ELSE NULL END) AS rbc - , MAX(CASE WHEN itemid = 51277 THEN valuenum ELSE NULL END) AS rdw - , MAX(CASE WHEN itemid = 52159 THEN valuenum ELSE NULL END) AS rdwsd - , MAX(CASE WHEN itemid = 51301 THEN valuenum ELSE NULL END) AS wbc -FROM mimiciv_hosp.labevents le -WHERE le.itemid IN - ( - 51221 -- hematocrit - , 51222 -- hemoglobin - , 51248 -- MCH - , 51249 -- MCHC - , 51250 -- MCV - , 51265 -- platelets - , 51279 -- RBC - , 51277 -- RDW - , 52159 -- RDW SD - , 51301 -- WBC - ) - AND valuenum IS NOT NULL - -- lab values cannot be 0 and cannot be negative - AND valuenum > 0 -GROUP BY le.specimen_id -; + MAX(subject_id) AS subject_id, + MAX(hadm_id) AS hadm_id, + MAX(charttime) AS charttime, + le.specimen_id, /* convert from itemid into a meaningful column */ + MAX(CASE WHEN itemid = 51221 THEN valuenum ELSE NULL END) AS hematocrit, + MAX(CASE WHEN itemid = 51222 THEN valuenum ELSE NULL END) AS hemoglobin, + MAX(CASE WHEN itemid = 51248 THEN valuenum ELSE NULL END) AS mch, + MAX(CASE WHEN itemid = 51249 THEN valuenum ELSE NULL END) AS mchc, + MAX(CASE WHEN itemid = 51250 THEN valuenum ELSE NULL END) AS mcv, + MAX(CASE WHEN itemid = 51265 THEN valuenum ELSE NULL END) AS platelet, + MAX(CASE WHEN itemid = 51279 THEN valuenum ELSE NULL END) AS rbc, + MAX(CASE WHEN itemid = 51277 THEN valuenum ELSE NULL END) AS rdw, + MAX(CASE WHEN itemid = 52159 THEN valuenum ELSE NULL END) AS rdwsd, + MAX(CASE WHEN itemid = 51301 THEN valuenum ELSE NULL END) AS wbc +FROM mimiciv_hosp.labevents AS le +WHERE + le.itemid IN (51221 /* hematocrit */, 51222 /* hemoglobin */, 51248 /* MCH */, 51249 /* MCHC */, 51250 /* MCV */, 51265 /* platelets */, 51279 /* RBC */, 51277 /* RDW */, 52159 /* RDW SD */, 51301 /* WBC */) + AND NOT valuenum IS NULL + AND valuenum > 0 +GROUP BY + le.specimen_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/measurement/creatinine_baseline.sql b/mimic-iv/concepts_postgres/measurement/creatinine_baseline.sql index 8563345b9..0186ffc1f 100644 --- a/mimic-iv/concepts_postgres/measurement/creatinine_baseline.sql +++ b/mimic-iv/concepts_postgres/measurement/creatinine_baseline.sql @@ -1,73 +1,60 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS creatinine_baseline; CREATE TABLE creatinine_baseline AS --- This query extracts the serum creatinine baselines of adult patients --- on each hospital admission. --- The baseline is determined by the following rules: --- i. if the lowest creatinine value during this admission is normal (<1.1), --- then use the value --- ii. if the patient is diagnosed with chronic kidney disease (CKD), --- then use the lowest creatinine value during the admission, --- although it may be rather large. --- iii. Otherwise, we estimate the baseline using Simplified MDRD: --- eGFR = 186 × Scr^(-1.154) × Age^(-0.203) × 0.742Female +DROP TABLE IF EXISTS mimiciv_derived.creatinine_baseline; CREATE TABLE mimiciv_derived.creatinine_baseline AS +/* This query extracts the serum creatinine baselines of adult patients */ /* on each hospital admission. */ /* The baseline is determined by the following rules: */ /* i. if the lowest creatinine value during this admission is normal (<1.1), */ /* then use the value */ /* ii. if the patient is diagnosed with chronic kidney disease (CKD), */ /* then use the lowest creatinine value during the admission, */ /* although it may be rather large. */ /* iii. Otherwise, we estimate the baseline using Simplified MDRD: */ /* eGFR = 186 × Scr^(-1.154) × Age^(-0.203) × 0.742Female */ WITH p AS ( - SELECT - ag.subject_id - , ag.hadm_id - , ag.age - , p.gender - , CASE WHEN p.gender = 'F' THEN - POWER(75.0 / 186.0 / POWER(ag.age, -0.203) / 0.742, -1 / 1.154) - ELSE - POWER(75.0 / 186.0 / POWER(ag.age, -0.203), -1 / 1.154) - END - AS mdrd_est - FROM mimiciv_derived.age ag - LEFT JOIN mimiciv_hosp.patients p - ON ag.subject_id = p.subject_id - WHERE ag.age >= 18 + SELECT + ag.subject_id, + ag.hadm_id, + ag.age, + p.gender, + CASE + WHEN p.gender = 'F' + THEN CAST(CAST(CAST(75.0 AS DOUBLE PRECISION) / 186.0 AS DOUBLE PRECISION) / ag.age ^ -0.203 AS DOUBLE PRECISION) / 0.742 ^ CAST(-1 AS DOUBLE PRECISION) / 1.154 + ELSE CAST(CAST(75.0 AS DOUBLE PRECISION) / 186.0 AS DOUBLE PRECISION) / ag.age ^ -0.203 ^ CAST(-1 AS DOUBLE PRECISION) / 1.154 + END AS mdrd_est + FROM mimiciv_derived.age AS ag + LEFT JOIN mimiciv_hosp.patients AS p + ON ag.subject_id = p.subject_id + WHERE + ag.age >= 18 +), lab AS ( + SELECT + hadm_id, + MIN(creatinine) AS scr_min + FROM mimiciv_derived.chemistry + GROUP BY + hadm_id +), ckd AS ( + SELECT + hadm_id, + MAX(1) AS ckd_flag + FROM mimiciv_hosp.diagnoses_icd + WHERE + ( + SUBSTR(icd_code, 1, 3) = '585' AND icd_version = 9 + ) + OR ( + SUBSTR(icd_code, 1, 3) = 'N18' AND icd_version = 10 + ) + GROUP BY + hadm_id ) - -, lab AS ( - SELECT - hadm_id - , MIN(creatinine) AS scr_min - FROM mimiciv_derived.chemistry - GROUP BY hadm_id -) - -, ckd AS ( - SELECT hadm_id, MAX(1) AS ckd_flag - FROM mimiciv_hosp.diagnoses_icd - WHERE - ( - SUBSTR(icd_code, 1, 3) = '585' - AND - icd_version = 9 - ) - OR - ( - SUBSTR(icd_code, 1, 3) = 'N18' - AND - icd_version = 10 - ) - GROUP BY hadm_id -) - SELECT - p.hadm_id - , p.gender - , p.age - , lab.scr_min - , COALESCE(ckd.ckd_flag, 0) AS ckd - , p.mdrd_est - , CASE - WHEN lab.scr_min <= 1.1 THEN scr_min - WHEN ckd.ckd_flag = 1 THEN scr_min - ELSE mdrd_est END AS scr_baseline + p.hadm_id, + p.gender, + p.age, + lab.scr_min, + COALESCE(ckd.ckd_flag, 0) AS ckd, + p.mdrd_est, + CASE + WHEN lab.scr_min <= 1.1 + THEN scr_min + WHEN ckd.ckd_flag = 1 + THEN scr_min + ELSE mdrd_est + END AS scr_baseline FROM p LEFT JOIN lab - ON p.hadm_id = lab.hadm_id + ON p.hadm_id = lab.hadm_id LEFT JOIN ckd - ON p.hadm_id = ckd.hadm_id -; + ON p.hadm_id = ckd.hadm_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/measurement/enzyme.sql b/mimic-iv/concepts_postgres/measurement/enzyme.sql index 7f16194dc..4d256d3f1 100644 --- a/mimic-iv/concepts_postgres/measurement/enzyme.sql +++ b/mimic-iv/concepts_postgres/measurement/enzyme.sql @@ -1,46 +1,26 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS enzyme; CREATE TABLE enzyme AS --- begin query that extracts the data +DROP TABLE IF EXISTS mimiciv_derived.enzyme; CREATE TABLE mimiciv_derived.enzyme AS +/* begin query that extracts the data */ SELECT - MAX(subject_id) AS subject_id - , MAX(hadm_id) AS hadm_id - , MAX(charttime) AS charttime - , le.specimen_id - -- convert from itemid into a meaningful column - , MAX(CASE WHEN itemid = 50861 THEN valuenum ELSE NULL END) AS alt - , MAX(CASE WHEN itemid = 50863 THEN valuenum ELSE NULL END) AS alp - , MAX(CASE WHEN itemid = 50878 THEN valuenum ELSE NULL END) AS ast - , MAX(CASE WHEN itemid = 50867 THEN valuenum ELSE NULL END) AS amylase - , MAX( - CASE WHEN itemid = 50885 THEN valuenum ELSE NULL END - ) AS bilirubin_total - , MAX( - CASE WHEN itemid = 50883 THEN valuenum ELSE NULL END - ) AS bilirubin_direct - , MAX( - CASE WHEN itemid = 50884 THEN valuenum ELSE NULL END - ) AS bilirubin_indirect - , MAX(CASE WHEN itemid = 50910 THEN valuenum ELSE NULL END) AS ck_cpk - , MAX(CASE WHEN itemid = 50911 THEN valuenum ELSE NULL END) AS ck_mb - , MAX(CASE WHEN itemid = 50927 THEN valuenum ELSE NULL END) AS ggt - , MAX(CASE WHEN itemid = 50954 THEN valuenum ELSE NULL END) AS ld_ldh -FROM mimiciv_hosp.labevents le -WHERE le.itemid IN - ( - 50861 -- Alanine transaminase (ALT) - , 50863 -- Alkaline phosphatase (ALP) - , 50878 -- Aspartate transaminase (AST) - , 50867 -- Amylase - , 50885 -- total bili - , 50884 -- indirect bili - , 50883 -- direct bili - , 50910 -- ck_cpk - , 50911 -- CK-MB - , 50927 -- Gamma Glutamyltransferase (GGT) - , 50954 -- ld_ldh - ) - AND valuenum IS NOT NULL - -- lab values cannot be 0 and cannot be negative - AND valuenum > 0 -GROUP BY le.specimen_id -; + MAX(subject_id) AS subject_id, + MAX(hadm_id) AS hadm_id, + MAX(charttime) AS charttime, + le.specimen_id, /* convert from itemid into a meaningful column */ + MAX(CASE WHEN itemid = 50861 THEN valuenum ELSE NULL END) AS alt, + MAX(CASE WHEN itemid = 50863 THEN valuenum ELSE NULL END) AS alp, + MAX(CASE WHEN itemid = 50878 THEN valuenum ELSE NULL END) AS ast, + MAX(CASE WHEN itemid = 50867 THEN valuenum ELSE NULL END) AS amylase, + MAX(CASE WHEN itemid = 50885 THEN valuenum ELSE NULL END) AS bilirubin_total, + MAX(CASE WHEN itemid = 50883 THEN valuenum ELSE NULL END) AS bilirubin_direct, + MAX(CASE WHEN itemid = 50884 THEN valuenum ELSE NULL END) AS bilirubin_indirect, + MAX(CASE WHEN itemid = 50910 THEN valuenum ELSE NULL END) AS ck_cpk, + MAX(CASE WHEN itemid = 50911 THEN valuenum ELSE NULL END) AS ck_mb, + MAX(CASE WHEN itemid = 50927 THEN valuenum ELSE NULL END) AS ggt, + MAX(CASE WHEN itemid = 50954 THEN valuenum ELSE NULL END) AS ld_ldh +FROM mimiciv_hosp.labevents AS le +WHERE + le.itemid IN (50861 /* Alanine transaminase (ALT) */, 50863 /* Alkaline phosphatase (ALP) */, 50878 /* Aspartate transaminase (AST) */, 50867 /* Amylase */, 50885 /* total bili */, 50884 /* indirect bili */, 50883 /* direct bili */, 50910 /* ck_cpk */, 50911 /* CK-MB */, 50927 /* Gamma Glutamyltransferase (GGT) */, 50954 /* ld_ldh */) + AND NOT valuenum IS NULL + AND valuenum > 0 +GROUP BY + le.specimen_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/measurement/gcs.sql b/mimic-iv/concepts_postgres/measurement/gcs.sql index bc146950e..9f01ceac6 100644 --- a/mimic-iv/concepts_postgres/measurement/gcs.sql +++ b/mimic-iv/concepts_postgres/measurement/gcs.sql @@ -1,129 +1,73 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS gcs; CREATE TABLE gcs AS --- This query extracts the Glasgow Coma Scale, a measure of neurological --- function. - --- The query has a few special rules: --- (1) The verbal component can be set to 0 if the patient is ventilated. --- This is corrected to 5 - the overall GCS is set to 15 in these cases. --- (2) Often only one of three components is documented. The other components --- are carried forward. - --- ITEMIDs used: - --- METAVISION --- 223900 GCS - Verbal Response --- 223901 GCS - Motor Response --- 220739 GCS - Eye Opening - --- Note: --- The GCS for sedated patients is defaulted to 15 in this code. --- This is in line with how the data is meant to be collected. --- e.g., from the SAPS II publication: --- For sedated patients, the Glasgow Coma Score before sedation was used. --- This was ascertained either from interviewing the physician who ordered --- the sedation, or by reviewing the patient's medical record. +DROP TABLE IF EXISTS mimiciv_derived.gcs; CREATE TABLE mimiciv_derived.gcs AS +/* This query extracts the Glasgow Coma Scale, a measure of neurological */ /* function. */ /* The query has a few special rules: */ /* (1) The verbal component can be set to 0 if the patient is ventilated. */ /* This is corrected to 5 - the overall GCS is set to 15 in these cases. */ /* (2) Often only one of three components is documented. The other components */ /* are carried forward. */ /* ITEMIDs used: */ /* METAVISION */ /* 223900 GCS - Verbal Response */ /* 223901 GCS - Motor Response */ /* 220739 GCS - Eye Opening */ /* Note: */ /* The GCS for sedated patients is defaulted to 15 in this code. */ /* This is in line with how the data is meant to be collected. */ /* e.g., from the SAPS II publication: */ /* For sedated patients, the Glasgow Coma Score before sedation was used. */ /* This was ascertained either from interviewing the physician who ordered */ /* the sedation, or by reviewing the patient's medical record. */ WITH base AS ( - SELECT - subject_id - , ce.stay_id, ce.charttime - -- pivot each value into its own column - , MAX( - CASE WHEN ce.itemid = 223901 THEN ce.valuenum ELSE null END - ) AS gcsmotor - , MAX(CASE - WHEN ce.itemid = 223900 AND ce.value = 'No Response-ETT' THEN 0 - WHEN ce.itemid = 223900 THEN ce.valuenum - ELSE null - END) AS gcsverbal - , MAX( - CASE WHEN ce.itemid = 220739 THEN ce.valuenum ELSE null END - ) AS gcseyes - -- convert the data into a number, reserving a value of 0 for ET/Trach - , MAX(CASE - -- endotrach/vent is assigned a value of 0 - -- flag it here to later parse specially - -- metavision - WHEN ce.itemid = 223900 AND ce.value = 'No Response-ETT' THEN 1 - ELSE 0 END) - AS endotrachflag - , ROW_NUMBER() - OVER (PARTITION BY ce.stay_id ORDER BY ce.charttime ASC) AS rn - FROM mimiciv_icu.chartevents ce - -- Isolate the desired GCS variables - WHERE ce.itemid IN - ( - -- GCS components, Metavision - 223900, 223901, 220739 - ) - GROUP BY ce.subject_id, ce.stay_id, ce.charttime + SELECT + subject_id, + ce.stay_id, + ce.charttime, /* pivot each value into its own column */ + MAX(CASE WHEN ce.itemid = 223901 THEN ce.valuenum ELSE NULL END) AS gcsmotor, + MAX( + CASE + WHEN ce.itemid = 223900 AND ce.value = 'No Response-ETT' + THEN 0 + WHEN ce.itemid = 223900 + THEN ce.valuenum + ELSE NULL + END + ) AS gcsverbal, + MAX(CASE WHEN ce.itemid = 220739 THEN ce.valuenum ELSE NULL END) AS gcseyes, /* convert the data into a number, reserving a value of 0 for ET/Trach */ + MAX(CASE WHEN ce.itemid = 223900 AND ce.value = 'No Response-ETT' THEN 1 ELSE 0 END) AS endotrachflag, + ROW_NUMBER() OVER (PARTITION BY ce.stay_id ORDER BY ce.charttime ASC NULLS FIRST) AS rn + FROM mimiciv_icu.chartevents AS ce + /* Isolate the desired GCS variables */ + WHERE + ce.itemid IN (223900 /* GCS components, Metavision */, 223901, 220739) + GROUP BY + ce.subject_id, + ce.stay_id, + ce.charttime +), gcs AS ( + SELECT + b.*, + b2.gcsverbal AS gcsverbalprev, + b2.gcsmotor AS gcsmotorprev, + b2.gcseyes AS gcseyesprev, /* Calculate GCS, factoring in special case when they are intubated */ /* note that the coalesce are used to implement the following if: */ /* if current value exists, use it */ /* if previous value exists, use it */ /* otherwise, default to normal */ + CASE + WHEN b.gcsverbal = 0 + THEN 15 + WHEN b.gcsverbal IS NULL AND b2.gcsverbal = 0 + THEN 15 + WHEN b2.gcsverbal = 0 + THEN COALESCE(b.gcsmotor, 6) + COALESCE(b.gcsverbal, 5) + COALESCE(b.gcseyes, 4) + ELSE COALESCE(b.gcsmotor, COALESCE(b2.gcsmotor, 6)) + COALESCE(b.gcsverbal, COALESCE(b2.gcsverbal, 5)) + COALESCE(b.gcseyes, COALESCE(b2.gcseyes, 4)) + END AS gcs + FROM base AS b + /* join to itself within 6 hours to get previous value */ + LEFT JOIN base AS b2 + ON b.stay_id = b2.stay_id + AND b.rn = b2.rn + 1 + AND b2.charttime > b.charttime - INTERVAL '6 HOUR' +), gcs_stg AS ( + SELECT + subject_id, + gs.stay_id, + gs.charttime, + gcs, + COALESCE(gcsmotor, gcsmotorprev) AS gcsmotor, + COALESCE(gcsverbal, gcsverbalprev) AS gcsverbal, + COALESCE(gcseyes, gcseyesprev) AS gcseyes, + CASE WHEN COALESCE(gcsmotor, gcsmotorprev) IS NULL THEN 0 ELSE 1 END + CASE WHEN COALESCE(gcsverbal, gcsverbalprev) IS NULL THEN 0 ELSE 1 END + CASE WHEN COALESCE(gcseyes, gcseyesprev) IS NULL THEN 0 ELSE 1 END AS components_measured, + endotrachflag + FROM gcs AS gs ) - -, gcs AS ( - SELECT b.* - , b2.gcsverbal AS gcsverbalprev - , b2.gcsmotor AS gcsmotorprev - , b2.gcseyes AS gcseyesprev - -- Calculate GCS, factoring in special case when they are intubated - -- note that the coalesce are used to implement the following if: - -- if current value exists, use it - -- if previous value exists, use it - -- otherwise, default to normal - , CASE - -- replace GCS during sedation with 15 - WHEN b.gcsverbal = 0 - THEN 15 - WHEN b.gcsverbal IS NULL AND b2.gcsverbal = 0 - THEN 15 - -- if previously they were intub, but they aren't now, - -- do not use previous GCS values - WHEN b2.gcsverbal = 0 - THEN - COALESCE(b.gcsmotor, 6) - + COALESCE(b.gcsverbal, 5) - + COALESCE(b.gcseyes, 4) - -- otherwise, add up score normally, imputing previous value - -- if none available at current time - ELSE - COALESCE(b.gcsmotor, COALESCE(b2.gcsmotor, 6)) - + COALESCE(b.gcsverbal, COALESCE(b2.gcsverbal, 5)) - + COALESCE(b.gcseyes, COALESCE(b2.gcseyes, 4)) - END AS gcs - FROM base b - -- join to itself within 6 hours to get previous value - LEFT JOIN base b2 - ON b.stay_id = b2.stay_id - AND b.rn = b2.rn + 1 - AND b2.charttime > DATETIME_SUB(b.charttime, INTERVAL '6' HOUR) -) - --- combine components with previous within 6 hours --- filter down to cohort which is not excluded --- truncate charttime to the hour -, gcs_stg AS ( - SELECT - subject_id - , gs.stay_id, gs.charttime - , gcs - , COALESCE(gcsmotor, gcsmotorprev) AS gcsmotor - , COALESCE(gcsverbal, gcsverbalprev) AS gcsverbal - , COALESCE(gcseyes, gcseyesprev) AS gcseyes - , CASE WHEN COALESCE(gcsmotor, gcsmotorprev) IS NULL THEN 0 ELSE 1 END - + CASE WHEN COALESCE(gcsverbal, gcsverbalprev) IS NULL THEN 0 ELSE 1 END - + CASE WHEN COALESCE(gcseyes, gcseyesprev) IS NULL THEN 0 ELSE 1 END - AS components_measured - , endotrachflag - FROM gcs gs -) - SELECT - gs.subject_id - , gs.stay_id - , gs.charttime - , gcs AS gcs - , gcsmotor AS gcs_motor - , gcsverbal AS gcs_verbal - , gcseyes AS gcs_eyes - , endotrachflag AS gcs_unable -FROM gcs_stg gs -; + gs.subject_id, + gs.stay_id, + gs.charttime, + gcs AS gcs, + gcsmotor AS gcs_motor, + gcsverbal AS gcs_verbal, + gcseyes AS gcs_eyes, + endotrachflag AS gcs_unable +FROM gcs_stg AS gs \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/measurement/height.sql b/mimic-iv/concepts_postgres/measurement/height.sql index 42c7e27d0..5902fdd1f 100644 --- a/mimic-iv/concepts_postgres/measurement/height.sql +++ b/mimic-iv/concepts_postgres/measurement/height.sql @@ -1,44 +1,40 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS height; CREATE TABLE height AS --- prep height +DROP TABLE IF EXISTS mimiciv_derived.height; CREATE TABLE mimiciv_derived.height AS +/* prep height */ WITH ht_in AS ( - SELECT - c.subject_id, c.stay_id, c.charttime - -- Ensure that all heights are in centimeters - , ROUND(CAST(c.valuenum * 2.54 AS NUMERIC), 2) AS height - , c.valuenum AS height_orig - FROM mimiciv_icu.chartevents c - WHERE c.valuenum IS NOT NULL - -- Height (measured in inches) - AND c.itemid = 226707 + SELECT + c.subject_id, + c.stay_id, + c.charttime, /* Ensure that all heights are in centimeters */ + ROUND(CAST(c.valuenum * 2.54 AS DECIMAL), 2) AS height, + c.valuenum AS height_orig + FROM mimiciv_icu.chartevents AS c + WHERE + NOT c.valuenum IS NULL /* Height (measured in inches) */ AND c.itemid = 226707 +), ht_cm AS ( + SELECT + c.subject_id, + c.stay_id, + c.charttime, /* Ensure that all heights are in centimeters */ + ROUND(CAST(c.valuenum AS DECIMAL), 2) AS height + FROM mimiciv_icu.chartevents AS c + WHERE + NOT c.valuenum IS NULL /* Height cm */ AND c.itemid = 226730 +), ht_stg0 AS ( + SELECT + COALESCE(h1.subject_id, h1.subject_id) AS subject_id, + COALESCE(h1.stay_id, h1.stay_id) AS stay_id, + COALESCE(h1.charttime, h1.charttime) AS charttime, + COALESCE(h1.height, h2.height) AS height + FROM ht_cm AS h1 + FULL OUTER JOIN ht_in AS h2 + ON h1.subject_id = h2.subject_id AND h1.charttime = h2.charttime ) - -, ht_cm AS ( - SELECT - c.subject_id, c.stay_id, c.charttime - -- Ensure that all heights are in centimeters - , ROUND(CAST(c.valuenum AS NUMERIC), 2) AS height - FROM mimiciv_icu.chartevents c - WHERE c.valuenum IS NOT NULL - -- Height cm - AND c.itemid = 226730 -) - --- merge cm/height, only take 1 value per charted row -, ht_stg0 AS ( - SELECT - COALESCE(h1.subject_id, h1.subject_id) AS subject_id - , COALESCE(h1.stay_id, h1.stay_id) AS stay_id - , COALESCE(h1.charttime, h1.charttime) AS charttime - , COALESCE(h1.height, h2.height) AS height - FROM ht_cm h1 - FULL OUTER JOIN ht_in h2 - ON h1.subject_id = h2.subject_id - AND h1.charttime = h2.charttime -) - -SELECT subject_id, stay_id, charttime, height +SELECT + subject_id, + stay_id, + charttime, + height FROM ht_stg0 -WHERE height IS NOT NULL - -- filter out bad heights - AND height > 120 AND height < 230; +WHERE + NOT height IS NULL /* filter out bad heights */ AND height > 120 AND height < 230 \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/measurement/icp.sql b/mimic-iv/concepts_postgres/measurement/icp.sql index 18a8a5022..5979615bd 100644 --- a/mimic-iv/concepts_postgres/measurement/icp.sql +++ b/mimic-iv/concepts_postgres/measurement/icp.sql @@ -1,28 +1,23 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS icp; CREATE TABLE icp AS +DROP TABLE IF EXISTS mimiciv_derived.icp; CREATE TABLE mimiciv_derived.icp AS WITH ce AS ( - SELECT - ce.subject_id - , ce.stay_id - , ce.charttime - -- TODO: handle high ICPs when monitoring two ICPs - , CASE - WHEN valuenum > 0 AND valuenum < 100 THEN valuenum ELSE null - END AS icp - FROM mimiciv_icu.chartevents ce - -- exclude rows marked as error - WHERE ce.itemid IN - ( - 220765 -- Intra Cranial Pressure -- 92306 - , 227989 -- Intra Cranial Pressure #2 -- 1052 - ) + SELECT + ce.subject_id, + ce.stay_id, + ce.charttime, /* TODO: handle high ICPs when monitoring two ICPs */ + CASE WHEN valuenum > 0 AND valuenum < 100 THEN valuenum ELSE NULL END AS icp + FROM mimiciv_icu.chartevents AS ce + /* exclude rows marked as error */ + WHERE + ce.itemid IN (220765 /* Intra Cranial Pressure -- 92306 */, 227989 /* Intra Cranial Pressure #2 -- 1052 */) ) - SELECT - ce.subject_id - , ce.stay_id - , ce.charttime - , MAX(icp) AS icp + ce.subject_id, + ce.stay_id, + ce.charttime, + MAX(icp) AS icp FROM ce -GROUP BY ce.subject_id, ce.stay_id, ce.charttime -; +GROUP BY + ce.subject_id, + ce.stay_id, + ce.charttime \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/measurement/inflammation.sql b/mimic-iv/concepts_postgres/measurement/inflammation.sql index d0b4bc986..30c2a0d63 100644 --- a/mimic-iv/concepts_postgres/measurement/inflammation.sql +++ b/mimic-iv/concepts_postgres/measurement/inflammation.sql @@ -1,20 +1,15 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS inflammation; CREATE TABLE inflammation AS +DROP TABLE IF EXISTS mimiciv_derived.inflammation; CREATE TABLE mimiciv_derived.inflammation AS SELECT - MAX(subject_id) AS subject_id - , MAX(hadm_id) AS hadm_id - , MAX(charttime) AS charttime - , le.specimen_id - -- convert from itemid into a meaningful column - , MAX(CASE WHEN itemid = 50889 THEN valuenum ELSE NULL END) AS crp -FROM mimiciv_hosp.labevents le -WHERE le.itemid IN - ( - -- 51652 -- high sensitivity CRP - 50889 -- crp - ) - AND valuenum IS NOT NULL - -- lab values cannot be 0 and cannot be negative - AND valuenum > 0 -GROUP BY le.specimen_id -; + MAX(subject_id) AS subject_id, + MAX(hadm_id) AS hadm_id, + MAX(charttime) AS charttime, + le.specimen_id, /* convert from itemid into a meaningful column */ + MAX(CASE WHEN itemid = 50889 THEN valuenum ELSE NULL END) AS crp +FROM mimiciv_hosp.labevents AS le +WHERE + le.itemid IN (50889 /* 51652 -- high sensitivity CRP */ /* crp */) + AND NOT valuenum IS NULL + AND valuenum > 0 +GROUP BY + le.specimen_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/measurement/oxygen_delivery.sql b/mimic-iv/concepts_postgres/measurement/oxygen_delivery.sql index 011a38254..dac9d3711 100644 --- a/mimic-iv/concepts_postgres/measurement/oxygen_delivery.sql +++ b/mimic-iv/concepts_postgres/measurement/oxygen_delivery.sql @@ -1,106 +1,70 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS oxygen_delivery; CREATE TABLE oxygen_delivery AS +DROP TABLE IF EXISTS mimiciv_derived.oxygen_delivery; CREATE TABLE mimiciv_derived.oxygen_delivery AS WITH ce_stg1 AS ( - SELECT - ce.subject_id - , ce.stay_id - , ce.charttime - , CASE - -- merge o2 flows into a single row - WHEN itemid IN (223834, 227582) THEN 223834 - ELSE itemid END AS itemid - , value - , valuenum - , valueuom - , storetime - FROM mimiciv_icu.chartevents ce - WHERE ce.value IS NOT NULL - AND ce.itemid IN - ( - 223834 -- o2 flow - , 227582 -- bipap o2 flow - -- below flow rate is *not* o2 flow, and not included - -- , 224691 -- Flow Rate (L) - -- additional o2 flow is its own column - , 227287 -- additional o2 flow - ) + SELECT + ce.subject_id, + ce.stay_id, + ce.charttime, + CASE WHEN itemid IN (223834, 227582) THEN 223834 ELSE itemid END AS itemid, + value, + valuenum, + valueuom, + storetime + FROM mimiciv_icu.chartevents AS ce + WHERE + NOT ce.value IS NULL + AND ce.itemid IN (223834 /* o2 flow */, 227582 /* bipap o2 flow */ /* below flow rate is *not* o2 flow, and not included */ /* , 224691 -- Flow Rate (L) */ /* additional o2 flow is its own column */, 227287 /* additional o2 flow */) +), ce_stg2 AS ( + SELECT + ce.subject_id, + ce.stay_id, + ce.charttime, + itemid, + value, + valuenum, + valueuom, /* retain only 1 row per charttime */ /* prioritizing the last documented value */ /* primarily used to subselect o2 flows */ + ROW_NUMBER() OVER (PARTITION BY subject_id, charttime, itemid ORDER BY storetime DESC NULLS LAST) AS rn + FROM ce_stg1 AS ce +), o2 AS ( + /* The below ITEMID can have multiple entries for charttime/storetime */ /* These are valid entries, and should be retained in derived tables. */ /* 224181 -- Small Volume Neb Drug #1 | Respiratory | Text */ /* , 227570 -- Small Volume Neb Drug/Dose #1 | Respiratory | Text */ /* , 224833 -- SBT Deferred | Respiratory | Text */ /* , 224716 -- SBT Stopped | Respiratory | Text */ /* , 224740 -- RSBI Deferred | Respiratory | Text */ /* , 224829 -- Trach Tube Type | Respiratory | Text */ /* , 226732 -- O2 Delivery Device(s) | Respiratory | Text */ /* , 226873 -- Inspiratory Ratio | Respiratory | Numeric */ /* , 226871 -- Expiratory Ratio | Respiratory | Numeric */ /* maximum of 4 o2 devices on at once */ + SELECT + subject_id, + stay_id, + charttime, + itemid, + value AS o2_device, + ROW_NUMBER() OVER (PARTITION BY subject_id, charttime, itemid ORDER BY value NULLS FIRST) AS rn + FROM mimiciv_icu.chartevents + WHERE + itemid = 226732 /* oxygen delivery device(s) */ +), stg AS ( + SELECT + COALESCE(ce.subject_id, o2.subject_id) AS subject_id, + COALESCE(ce.stay_id, o2.stay_id) AS stay_id, + COALESCE(ce.charttime, o2.charttime) AS charttime, + COALESCE(ce.itemid, o2.itemid) AS itemid, + ce.value, + ce.valuenum, + o2.o2_device, + o2.rn + FROM ce_stg2 AS ce + FULL OUTER JOIN o2 + ON ce.subject_id = o2.subject_id AND ce.charttime = o2.charttime + /* limit to 1 row per subject_id/charttime/itemid from ce_stg2 */ + WHERE + ce.rn = 1 ) - -, ce_stg2 AS ( - SELECT - ce.subject_id - , ce.stay_id - , ce.charttime - , itemid - , value - , valuenum - , valueuom - -- retain only 1 row per charttime - -- prioritizing the last documented value - -- primarily used to subselect o2 flows - , ROW_NUMBER() OVER ( - PARTITION BY subject_id, charttime, itemid ORDER BY storetime DESC - ) AS rn - FROM ce_stg1 ce -) - -, o2 AS ( - -- The below ITEMID can have multiple entries for charttime/storetime - -- These are valid entries, and should be retained in derived tables. - -- 224181 -- Small Volume Neb Drug #1 | Respiratory | Text - -- , 227570 -- Small Volume Neb Drug/Dose #1 | Respiratory | Text - -- , 224833 -- SBT Deferred | Respiratory | Text - -- , 224716 -- SBT Stopped | Respiratory | Text - -- , 224740 -- RSBI Deferred | Respiratory | Text - -- , 224829 -- Trach Tube Type | Respiratory | Text - -- , 226732 -- O2 Delivery Device(s) | Respiratory | Text - -- , 226873 -- Inspiratory Ratio | Respiratory | Numeric - -- , 226871 -- Expiratory Ratio | Respiratory | Numeric - -- maximum of 4 o2 devices on at once - SELECT - subject_id - , stay_id - , charttime - , itemid - , value AS o2_device - , ROW_NUMBER() OVER ( - PARTITION BY subject_id, charttime, itemid ORDER BY value - ) AS rn - FROM mimiciv_icu.chartevents - WHERE itemid = 226732 -- oxygen delivery device(s) -) - -, stg AS ( - SELECT - COALESCE(ce.subject_id, o2.subject_id) AS subject_id - , COALESCE(ce.stay_id, o2.stay_id) AS stay_id - , COALESCE(ce.charttime, o2.charttime) AS charttime - , COALESCE(ce.itemid, o2.itemid) AS itemid - , ce.value - , ce.valuenum - , o2.o2_device - , o2.rn - FROM ce_stg2 ce - FULL OUTER JOIN o2 - ON ce.subject_id = o2.subject_id - AND ce.charttime = o2.charttime - -- limit to 1 row per subject_id/charttime/itemid from ce_stg2 - WHERE ce.rn = 1 -) - SELECT - subject_id - , MAX(stay_id) AS stay_id - , charttime - , MAX(CASE WHEN itemid = 223834 THEN valuenum ELSE NULL END) AS o2_flow - , MAX( - CASE WHEN itemid = 227287 THEN valuenum ELSE NULL END - ) AS o2_flow_additional - -- ensure we retain all o2 devices for the patient - , MAX(CASE WHEN rn = 1 THEN o2_device ELSE NULL END) AS o2_delivery_device_1 - , MAX(CASE WHEN rn = 2 THEN o2_device ELSE NULL END) AS o2_delivery_device_2 - , MAX(CASE WHEN rn = 3 THEN o2_device ELSE NULL END) AS o2_delivery_device_3 - , MAX(CASE WHEN rn = 4 THEN o2_device ELSE NULL END) AS o2_delivery_device_4 + subject_id, + MAX(stay_id) AS stay_id, + charttime, + MAX(CASE WHEN itemid = 223834 THEN valuenum ELSE NULL END) AS o2_flow, + MAX(CASE WHEN itemid = 227287 THEN valuenum ELSE NULL END) AS o2_flow_additional, /* ensure we retain all o2 devices for the patient */ + MAX(CASE WHEN rn = 1 THEN o2_device ELSE NULL END) AS o2_delivery_device_1, + MAX(CASE WHEN rn = 2 THEN o2_device ELSE NULL END) AS o2_delivery_device_2, + MAX(CASE WHEN rn = 3 THEN o2_device ELSE NULL END) AS o2_delivery_device_3, + MAX(CASE WHEN rn = 4 THEN o2_device ELSE NULL END) AS o2_delivery_device_4 FROM stg -GROUP BY subject_id, charttime -; +GROUP BY + subject_id, + charttime \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/measurement/rhythm.sql b/mimic-iv/concepts_postgres/measurement/rhythm.sql index 154328e82..3e0ea3b31 100644 --- a/mimic-iv/concepts_postgres/measurement/rhythm.sql +++ b/mimic-iv/concepts_postgres/measurement/rhythm.sql @@ -1,29 +1,18 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS rhythm; CREATE TABLE rhythm AS --- Heart rhythm related documentation +DROP TABLE IF EXISTS mimiciv_derived.rhythm; CREATE TABLE mimiciv_derived.rhythm AS +/* Heart rhythm related documentation */ SELECT - ce.subject_id - , ce.charttime - , MAX(CASE WHEN itemid = 220048 THEN value ELSE NULL END) AS heart_rhythm - , MAX(CASE WHEN itemid = 224650 THEN value ELSE NULL END) AS ectopy_type - , MAX( - CASE WHEN itemid = 224651 THEN value ELSE NULL END - ) AS ectopy_frequency - , MAX( - CASE WHEN itemid = 226479 THEN value ELSE NULL END - ) AS ectopy_type_secondary - , MAX( - CASE WHEN itemid = 226480 THEN value ELSE NULL END - ) AS ectopy_frequency_secondary -FROM mimiciv_icu.chartevents ce -WHERE ce.stay_id IS NOT NULL - AND ce.itemid IN - ( - 220048 -- Heart Rhythm - , 224650 -- Ectopy Type 1 - , 224651 -- Ectopy Frequency 1 - , 226479 -- Ectopy Type 2 - , 226480 -- Ectopy Frequency 2 - ) -GROUP BY ce.subject_id, ce.charttime -; + ce.subject_id, + ce.charttime, + MAX(CASE WHEN itemid = 220048 THEN value ELSE NULL END) AS heart_rhythm, + MAX(CASE WHEN itemid = 224650 THEN value ELSE NULL END) AS ectopy_type, + MAX(CASE WHEN itemid = 224651 THEN value ELSE NULL END) AS ectopy_frequency, + MAX(CASE WHEN itemid = 226479 THEN value ELSE NULL END) AS ectopy_type_secondary, + MAX(CASE WHEN itemid = 226480 THEN value ELSE NULL END) AS ectopy_frequency_secondary +FROM mimiciv_icu.chartevents AS ce +WHERE + NOT ce.stay_id IS NULL + AND ce.itemid IN (220048 /* Heart Rhythm */, 224650 /* Ectopy Type 1 */, 224651 /* Ectopy Frequency 1 */, 226479 /* Ectopy Type 2 */, 226480 /* Ectopy Frequency 2 */) +GROUP BY + ce.subject_id, + ce.charttime \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/measurement/urine_output.sql b/mimic-iv/concepts_postgres/measurement/urine_output.sql index 6194bdca5..49169c768 100644 --- a/mimic-iv/concepts_postgres/measurement/urine_output.sql +++ b/mimic-iv/concepts_postgres/measurement/urine_output.sql @@ -1,40 +1,19 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS urine_output; CREATE TABLE urine_output AS +DROP TABLE IF EXISTS mimiciv_derived.urine_output; CREATE TABLE mimiciv_derived.urine_output AS WITH uo AS ( - SELECT - -- patient identifiers - oe.stay_id - , oe.charttime - -- volumes associated with urine output ITEMIDs - -- note we consider input of GU irrigant as a negative volume - -- GU irrigant volume in usually has a corresponding volume out - -- so the net is often 0, despite large irrigant volumes - , CASE - WHEN oe.itemid = 227488 AND oe.value > 0 THEN -1 * oe.value - ELSE oe.value - END AS urineoutput - FROM mimiciv_icu.outputevents oe - WHERE itemid IN - ( - 226559 -- Foley - , 226560 -- Void - , 226561 -- Condom Cath - , 226584 -- Ileoconduit - , 226563 -- Suprapubic - , 226564 -- R Nephrostomy - , 226565 -- L Nephrostomy - , 226567 -- Straight Cath - , 226557 -- R Ureteral Stent - , 226558 -- L Ureteral Stent - , 227488 -- GU Irrigant Volume In - , 227489 -- GU Irrigant/Urine Volume Out - ) + SELECT + oe.stay_id, + oe.charttime, /* volumes associated with urine output ITEMIDs */ /* note we consider input of GU irrigant as a negative volume */ /* GU irrigant volume in usually has a corresponding volume out */ /* so the net is often 0, despite large irrigant volumes */ + CASE WHEN oe.itemid = 227488 AND oe.value > 0 THEN -1 * oe.value ELSE oe.value END AS urineoutput + FROM mimiciv_icu.outputevents AS oe + WHERE + itemid IN (226559 /* Foley */, 226560 /* Void */, 226561 /* Condom Cath */, 226584 /* Ileoconduit */, 226563 /* Suprapubic */, 226564 /* R Nephrostomy */, 226565 /* L Nephrostomy */, 226567 /* Straight Cath */, 226557 /* R Ureteral Stent */, 226558 /* L Ureteral Stent */, 227488 /* GU Irrigant Volume In */, 227489 /* GU Irrigant/Urine Volume Out */) ) - SELECT - stay_id - , charttime - , SUM(urineoutput) AS urineoutput + stay_id, + charttime, + SUM(urineoutput) AS urineoutput FROM uo -GROUP BY stay_id, charttime -; +GROUP BY + stay_id, + charttime \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/measurement/urine_output_rate.sql b/mimic-iv/concepts_postgres/measurement/urine_output_rate.sql index a2b5b1cac..db0a2075b 100644 --- a/mimic-iv/concepts_postgres/measurement/urine_output_rate.sql +++ b/mimic-iv/concepts_postgres/measurement/urine_output_rate.sql @@ -1,115 +1,121 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS urine_output_rate; CREATE TABLE urine_output_rate AS --- attempt to calculate urine output per hour --- rate/hour is the interpretable measure of kidney function --- though it is difficult to estimate from aperiodic point measures --- first we get the earliest heart rate documented for the stay +DROP TABLE IF EXISTS mimiciv_derived.urine_output_rate; CREATE TABLE mimiciv_derived.urine_output_rate AS +/* attempt to calculate urine output per hour */ /* rate/hour is the interpretable measure of kidney function */ /* though it is difficult to estimate from aperiodic point measures */ /* first we get the earliest heart rate documented for the stay */ WITH tm AS ( - SELECT ie.stay_id - , MIN(charttime) AS intime_hr - , MAX(charttime) AS outtime_hr - FROM mimiciv_icu.icustays ie - INNER JOIN mimiciv_icu.chartevents ce - ON ie.stay_id = ce.stay_id - AND ce.itemid = 220045 - AND ce.charttime > DATETIME_SUB(ie.intime, INTERVAL '1' MONTH) - AND ce.charttime < DATETIME_ADD(ie.outtime, INTERVAL '1' MONTH) - GROUP BY ie.stay_id + SELECT + ie.stay_id, + MIN(charttime) AS intime_hr, + MAX(charttime) AS outtime_hr + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_icu.chartevents AS ce + ON ie.stay_id = ce.stay_id + AND ce.itemid = 220045 + AND ce.charttime > ie.intime - INTERVAL '1 MONTH' + AND ce.charttime < ie.outtime + INTERVAL '1 MONTH' + GROUP BY + ie.stay_id +), uo_tm AS ( + SELECT + tm.stay_id, + CASE + WHEN LAG(charttime) OVER w IS NULL + THEN EXTRACT(EPOCH FROM charttime - intime_hr) / 60.0 + ELSE EXTRACT(EPOCH FROM charttime - LAG(charttime) OVER w) / 60.0 + END AS tm_since_last_uo, + uo.charttime, + uo.urineoutput + FROM tm + INNER JOIN mimiciv_derived.urine_output AS uo + ON tm.stay_id = uo.stay_id + WINDOW w AS (PARTITION BY tm.stay_id ORDER BY charttime NULLS FIRST) +), ur_stg AS ( + SELECT + io.stay_id, + io.charttime, /* we have joined each row to all rows preceding within 24 hours */ /* we can now sum these rows to get total UO over the last 24 hours */ /* we can use case statements to restrict it to only the last 6/12 hours */ /* therefore we have three sums: */ /* 1) over a 6 hour period */ /* 2) over a 12 hour period */ /* 3) over a 24 hour period */ + SUM(DISTINCT io.urineoutput) AS uo, /* note that we assume data charted at charttime corresponds */ /* to 1 hour of UO, therefore we use '5' and '11' to restrict the */ /* period, rather than 6/12 this assumption may overestimate UO rate */ /* when documentation is done less than hourly */ + SUM( + CASE + WHEN EXTRACT(EPOCH FROM io.charttime - iosum.charttime) / 3600.0 <= 5 + THEN iosum.urineoutput + ELSE NULL + END + ) AS urineoutput_6hr, + CAST(SUM( + CASE + WHEN EXTRACT(EPOCH FROM io.charttime - iosum.charttime) / 3600.0 <= 5 + THEN iosum.tm_since_last_uo + ELSE NULL + END + ) AS DOUBLE PRECISION) / 60.0 AS uo_tm_6hr, + SUM( + CASE + WHEN EXTRACT(EPOCH FROM io.charttime - iosum.charttime) / 3600.0 <= 11 + THEN iosum.urineoutput + ELSE NULL + END + ) AS urineoutput_12hr, + CAST(SUM( + CASE + WHEN EXTRACT(EPOCH FROM io.charttime - iosum.charttime) / 3600.0 <= 11 + THEN iosum.tm_since_last_uo + ELSE NULL + END + ) AS DOUBLE PRECISION) / 60.0 AS uo_tm_12hr, /* 24 hours */ + SUM(iosum.urineoutput) AS urineoutput_24hr, + CAST(SUM(iosum.tm_since_last_uo) AS DOUBLE PRECISION) / 60.0 AS uo_tm_24hr + FROM uo_tm AS io + /* this join gives you all UO measurements over a 24 hour period */ + LEFT JOIN uo_tm AS iosum + ON io.stay_id = iosum.stay_id + AND io.charttime >= iosum.charttime + AND io.charttime <= ( + iosum.charttime + INTERVAL '23 HOUR' + ) + GROUP BY + io.stay_id, + io.charttime ) - --- now calculate time since last UO measurement -, uo_tm AS ( - SELECT tm.stay_id - , CASE - WHEN LAG(charttime) OVER w IS NULL - THEN DATETIME_DIFF(charttime, intime_hr, 'MINUTE') - ELSE DATETIME_DIFF(charttime, LAG(charttime) OVER w, 'MINUTE') - END AS tm_since_last_uo - , uo.charttime - , uo.urineoutput - FROM tm - INNER JOIN mimiciv_derived.urine_output uo - ON tm.stay_id = uo.stay_id - WINDOW w AS (PARTITION BY tm.stay_id ORDER BY charttime) -) - -, ur_stg AS ( - SELECT io.stay_id, io.charttime - -- we have joined each row to all rows preceding within 24 hours - -- we can now sum these rows to get total UO over the last 24 hours - -- we can use case statements to restrict it to only the last 6/12 hours - -- therefore we have three sums: - -- 1) over a 6 hour period - -- 2) over a 12 hour period - -- 3) over a 24 hour period - , SUM(DISTINCT io.urineoutput) AS uo - -- note that we assume data charted at charttime corresponds - -- to 1 hour of UO, therefore we use '5' and '11' to restrict the - -- period, rather than 6/12 this assumption may overestimate UO rate - -- when documentation is done less than hourly - , SUM(CASE WHEN DATETIME_DIFF(io.charttime, iosum.charttime, 'HOUR') <= 5 - THEN iosum.urineoutput - ELSE null END) AS urineoutput_6hr - , SUM(CASE WHEN DATETIME_DIFF(io.charttime, iosum.charttime, 'HOUR') <= 5 - THEN iosum.tm_since_last_uo - ELSE null END) / 60.0 AS uo_tm_6hr - , SUM(CASE WHEN DATETIME_DIFF(io.charttime, iosum.charttime, 'HOUR') <= 11 - THEN iosum.urineoutput - ELSE null END) AS urineoutput_12hr - , SUM(CASE WHEN DATETIME_DIFF(io.charttime, iosum.charttime, 'HOUR') <= 11 - THEN iosum.tm_since_last_uo - ELSE null END) / 60.0 AS uo_tm_12hr - -- 24 hours - , SUM(iosum.urineoutput) AS urineoutput_24hr - , SUM(iosum.tm_since_last_uo) / 60.0 AS uo_tm_24hr - - FROM uo_tm io - -- this join gives you all UO measurements over a 24 hour period - LEFT JOIN uo_tm iosum - ON io.stay_id = iosum.stay_id - AND io.charttime >= iosum.charttime - AND io.charttime <= ( - DATETIME_ADD(iosum.charttime, INTERVAL '23' HOUR) - ) - GROUP BY io.stay_id, io.charttime -) - SELECT - ur.stay_id - , ur.charttime - , wd.weight - , ur.uo - , ur.urineoutput_6hr - , ur.urineoutput_12hr - , ur.urineoutput_24hr - , CASE - WHEN - uo_tm_6hr >= 6 THEN ROUND( - CAST((ur.urineoutput_6hr / wd.weight / uo_tm_6hr) AS NUMERIC), 4 - ) - END AS uo_mlkghr_6hr - , CASE - WHEN - uo_tm_12hr >= 12 THEN ROUND( - CAST((ur.urineoutput_12hr / wd.weight / uo_tm_12hr) AS NUMERIC) - , 4 - ) - END AS uo_mlkghr_12hr - , CASE - WHEN - uo_tm_24hr >= 24 THEN ROUND( - CAST((ur.urineoutput_24hr / wd.weight / uo_tm_24hr) AS NUMERIC) - , 4 - ) - END AS uo_mlkghr_24hr - -- time of earliest UO measurement that was used to calculate the rate - , ROUND(CAST(uo_tm_6hr AS NUMERIC), 2) AS uo_tm_6hr - , ROUND(CAST(uo_tm_12hr AS NUMERIC), 2) AS uo_tm_12hr - , ROUND(CAST(uo_tm_24hr AS NUMERIC), 2) AS uo_tm_24hr -FROM ur_stg ur -LEFT JOIN mimiciv_derived.weight_durations wd - ON ur.stay_id = wd.stay_id - AND ur.charttime > wd.starttime - AND ur.charttime <= wd.endtime - AND wd.weight > 0 -; + ur.stay_id, + ur.charttime, + wd.weight, + ur.uo, + ur.urineoutput_6hr, + ur.urineoutput_12hr, + ur.urineoutput_24hr, + CASE + WHEN uo_tm_6hr >= 6 + THEN ROUND( + CAST(( + CAST(CAST(ur.urineoutput_6hr AS DOUBLE PRECISION) / wd.weight AS DOUBLE PRECISION) / uo_tm_6hr + ) AS DECIMAL), + 4 + ) + END AS uo_mlkghr_6hr, + CASE + WHEN uo_tm_12hr >= 12 + THEN ROUND( + CAST(( + CAST(CAST(ur.urineoutput_12hr AS DOUBLE PRECISION) / wd.weight AS DOUBLE PRECISION) / uo_tm_12hr + ) AS DECIMAL), + 4 + ) + END AS uo_mlkghr_12hr, + CASE + WHEN uo_tm_24hr >= 24 + THEN ROUND( + CAST(( + CAST(CAST(ur.urineoutput_24hr AS DOUBLE PRECISION) / wd.weight AS DOUBLE PRECISION) / uo_tm_24hr + ) AS DECIMAL), + 4 + ) + END AS uo_mlkghr_24hr, /* time of earliest UO measurement that was used to calculate the rate */ + ROUND(CAST(uo_tm_6hr AS DECIMAL), 2) AS uo_tm_6hr, + ROUND(CAST(uo_tm_12hr AS DECIMAL), 2) AS uo_tm_12hr, + ROUND(CAST(uo_tm_24hr AS DECIMAL), 2) AS uo_tm_24hr +FROM ur_stg AS ur +LEFT JOIN mimiciv_derived.weight_durations AS wd + ON ur.stay_id = wd.stay_id + AND ur.charttime > wd.starttime + AND ur.charttime <= wd.endtime + AND wd.weight > 0 \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/measurement/ventilator_setting.sql b/mimic-iv/concepts_postgres/measurement/ventilator_setting.sql index a713e977c..67d408d1f 100644 --- a/mimic-iv/concepts_postgres/measurement/ventilator_setting.sql +++ b/mimic-iv/concepts_postgres/measurement/ventilator_setting.sql @@ -1,96 +1,54 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS ventilator_setting; CREATE TABLE ventilator_setting AS +DROP TABLE IF EXISTS mimiciv_derived.ventilator_setting; CREATE TABLE mimiciv_derived.ventilator_setting AS WITH ce AS ( - SELECT - ce.subject_id - , ce.stay_id - , ce.charttime - , itemid - -- TODO: clean - , value - , CASE - -- begin fio2 cleaning - WHEN itemid = 223835 - THEN - CASE - WHEN valuenum >= 0.20 AND valuenum <= 1 - THEN valuenum * 100 - -- improperly input data - looks like O2 flow in litres - WHEN valuenum > 1 AND valuenum < 20 - THEN null - WHEN valuenum >= 20 AND valuenum <= 100 - THEN valuenum - ELSE null END - -- end of fio2 cleaning - -- begin peep cleaning - WHEN itemid IN (220339, 224700) - THEN - CASE - WHEN valuenum > 100 THEN null - WHEN valuenum < 0 THEN null - ELSE valuenum END - -- end peep cleaning - ELSE valuenum END AS valuenum - , valueuom - , storetime - FROM mimiciv_icu.chartevents ce - WHERE ce.value IS NOT NULL - AND ce.stay_id IS NOT NULL - AND ce.itemid IN - ( - 224688 -- Respiratory Rate (Set) - , 224689 -- Respiratory Rate (spontaneous) - , 224690 -- Respiratory Rate (Total) - , 224687 -- minute volume - , 224685, 224684, 224686 -- tidal volume - , 224696 -- PlateauPressure - , 220339, 224700 -- PEEP - , 223835 -- fio2 - , 223849 -- vent mode - , 229314 -- vent mode (Hamilton) - , 223848 -- vent type - , 224691 -- Flow Rate (L) - ) + SELECT + ce.subject_id, + ce.stay_id, + ce.charttime, + itemid, /* TODO: clean */ + value, + CASE + WHEN itemid = 223835 + THEN CASE + WHEN valuenum >= 0.20 AND valuenum <= 1 + THEN valuenum * 100 + WHEN valuenum > 1 AND valuenum < 20 + THEN NULL + WHEN valuenum >= 20 AND valuenum <= 100 + THEN valuenum + ELSE NULL + END + WHEN itemid IN (220339, 224700) + THEN CASE WHEN valuenum > 100 THEN NULL WHEN valuenum < 0 THEN NULL ELSE valuenum END + ELSE valuenum + END AS valuenum, + valueuom, + storetime + FROM mimiciv_icu.chartevents AS ce + WHERE + NOT ce.value IS NULL + AND NOT ce.stay_id IS NULL + AND ce.itemid IN (224688 /* Respiratory Rate (Set) */, 224689 /* Respiratory Rate (spontaneous) */, 224690 /* Respiratory Rate (Total) */, 224687 /* minute volume */, 224685, 224684, 224686 /* tidal volume */, 224696 /* PlateauPressure */, 220339, 224700 /* PEEP */, 223835 /* fio2 */, 223849 /* vent mode */, 229314 /* vent mode (Hamilton) */, 223848 /* vent type */, 224691 /* Flow Rate (L) */) ) - SELECT - subject_id - , MAX(stay_id) AS stay_id - , charttime - , MAX( - CASE WHEN itemid = 224688 THEN valuenum ELSE null END - ) AS respiratory_rate_set - , MAX( - CASE WHEN itemid = 224690 THEN valuenum ELSE null END - ) AS respiratory_rate_total - , MAX( - CASE WHEN itemid = 224689 THEN valuenum ELSE null END - ) AS respiratory_rate_spontaneous - , MAX( - CASE WHEN itemid = 224687 THEN valuenum ELSE null END - ) AS minute_volume - , MAX( - CASE WHEN itemid = 224684 THEN valuenum ELSE null END - ) AS tidal_volume_set - , MAX( - CASE WHEN itemid = 224685 THEN valuenum ELSE null END - ) AS tidal_volume_observed - , MAX( - CASE WHEN itemid = 224686 THEN valuenum ELSE null END - ) AS tidal_volume_spontaneous - , MAX( - CASE WHEN itemid = 224696 THEN valuenum ELSE null END - ) AS plateau_pressure - , MAX( - CASE WHEN itemid IN (220339, 224700) THEN valuenum ELSE null END - ) AS peep - , MAX(CASE WHEN itemid = 223835 THEN valuenum ELSE null END) AS fio2 - , MAX(CASE WHEN itemid = 224691 THEN valuenum ELSE null END) AS flow_rate - , MAX(CASE WHEN itemid = 223849 THEN value ELSE null END) AS ventilator_mode - , MAX( - CASE WHEN itemid = 229314 THEN value ELSE null END - ) AS ventilator_mode_hamilton - , MAX(CASE WHEN itemid = 223848 THEN value ELSE null END) AS ventilator_type + subject_id, + MAX(stay_id) AS stay_id, + charttime, + MAX(CASE WHEN itemid = 224688 THEN valuenum ELSE NULL END) AS respiratory_rate_set, + MAX(CASE WHEN itemid = 224690 THEN valuenum ELSE NULL END) AS respiratory_rate_total, + MAX(CASE WHEN itemid = 224689 THEN valuenum ELSE NULL END) AS respiratory_rate_spontaneous, + MAX(CASE WHEN itemid = 224687 THEN valuenum ELSE NULL END) AS minute_volume, + MAX(CASE WHEN itemid = 224684 THEN valuenum ELSE NULL END) AS tidal_volume_set, + MAX(CASE WHEN itemid = 224685 THEN valuenum ELSE NULL END) AS tidal_volume_observed, + MAX(CASE WHEN itemid = 224686 THEN valuenum ELSE NULL END) AS tidal_volume_spontaneous, + MAX(CASE WHEN itemid = 224696 THEN valuenum ELSE NULL END) AS plateau_pressure, + MAX(CASE WHEN itemid IN (220339, 224700) THEN valuenum ELSE NULL END) AS peep, + MAX(CASE WHEN itemid = 223835 THEN valuenum ELSE NULL END) AS fio2, + MAX(CASE WHEN itemid = 224691 THEN valuenum ELSE NULL END) AS flow_rate, + MAX(CASE WHEN itemid = 223849 THEN value ELSE NULL END) AS ventilator_mode, + MAX(CASE WHEN itemid = 229314 THEN value ELSE NULL END) AS ventilator_mode_hamilton, + MAX(CASE WHEN itemid = 223848 THEN value ELSE NULL END) AS ventilator_type FROM ce -GROUP BY subject_id, charttime -; +GROUP BY + subject_id, + charttime \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/measurement/vitalsign.sql b/mimic-iv/concepts_postgres/measurement/vitalsign.sql index fa6f1853f..986ac8f15 100644 --- a/mimic-iv/concepts_postgres/measurement/vitalsign.sql +++ b/mimic-iv/concepts_postgres/measurement/vitalsign.sql @@ -1,102 +1,63 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS vitalsign; CREATE TABLE vitalsign AS --- This query pivots the vital signs for the entire patient stay. --- The result is a tabler with stay_id, charttime, and various --- vital signs, with one row per charted time. +DROP TABLE IF EXISTS mimiciv_derived.vitalsign; CREATE TABLE mimiciv_derived.vitalsign AS +/* This query pivots the vital signs for the entire patient stay. */ /* The result is a tabler with stay_id, charttime, and various */ /* vital signs, with one row per charted time. */ SELECT - ce.subject_id - , ce.stay_id - , ce.charttime - , AVG(CASE WHEN itemid IN (220045) - AND valuenum > 0 - AND valuenum < 300 - THEN valuenum END - ) AS heart_rate - , AVG(CASE WHEN itemid IN (220179, 220050, 225309) - AND valuenum > 0 - AND valuenum < 400 - THEN valuenum END - ) AS sbp - , AVG(CASE WHEN itemid IN (220180, 220051, 225310) - AND valuenum > 0 - AND valuenum < 300 - THEN valuenum END - ) AS dbp - , AVG(CASE WHEN itemid IN (220052, 220181, 225312) - AND valuenum > 0 - AND valuenum < 300 - THEN valuenum END - ) AS mbp - , AVG(CASE WHEN itemid = 220179 - AND valuenum > 0 - AND valuenum < 400 - THEN valuenum END - ) AS sbp_ni - , AVG(CASE WHEN itemid = 220180 - AND valuenum > 0 - AND valuenum < 300 - THEN valuenum END - ) AS dbp_ni - , AVG(CASE WHEN itemid = 220181 - AND valuenum > 0 - AND valuenum < 300 - THEN valuenum END - ) AS mbp_ni - , AVG(CASE WHEN itemid IN (220210, 224690) - AND valuenum > 0 - AND valuenum < 70 - THEN valuenum END - ) AS resp_rate - , ROUND(CAST( - AVG(CASE - -- converted to degC in valuenum call - WHEN itemid IN (223761) - AND valuenum > 70 - AND valuenum < 120 - THEN (valuenum - 32) / 1.8 - -- already in degC, no conversion necessary - WHEN itemid IN (223762) - AND valuenum > 10 - AND valuenum < 50 - THEN valuenum END) - AS NUMERIC), 2) AS temperature - , MAX(CASE WHEN itemid = 224642 THEN value END - ) AS temperature_site - , AVG(CASE WHEN itemid IN (220277) - AND valuenum > 0 - AND valuenum <= 100 - THEN valuenum END - ) AS spo2 - , AVG(CASE WHEN itemid IN (225664, 220621, 226537) - AND valuenum > 0 - THEN valuenum END - ) AS glucose -FROM mimiciv_icu.chartevents ce -WHERE ce.stay_id IS NOT NULL - AND ce.itemid IN - ( - 220045 -- Heart Rate - , 225309 -- ART BP Systolic - , 225310 -- ART BP Diastolic - , 225312 -- ART BP Mean - , 220050 -- Arterial Blood Pressure systolic - , 220051 -- Arterial Blood Pressure diastolic - , 220052 -- Arterial Blood Pressure mean - , 220179 -- Non Invasive Blood Pressure systolic - , 220180 -- Non Invasive Blood Pressure diastolic - , 220181 -- Non Invasive Blood Pressure mean - , 220210 -- Respiratory Rate - , 224690 -- Respiratory Rate (Total) - , 220277 -- SPO2, peripheral - -- GLUCOSE, both lab and fingerstick - , 225664 -- Glucose finger stick - , 220621 -- Glucose (serum) - , 226537 -- Glucose (whole blood) - -- TEMPERATURE - -- 226329 -- Blood Temperature CCO (C) - , 223762 -- "Temperature Celsius" - , 223761 -- "Temperature Fahrenheit" - , 224642 -- Temperature Site - ) -GROUP BY ce.subject_id, ce.stay_id, ce.charttime -; + ce.subject_id, + ce.stay_id, + ce.charttime, + AVG( + CASE WHEN itemid IN (220045) AND valuenum > 0 AND valuenum < 300 THEN valuenum END + ) AS heart_rate, + AVG( + CASE + WHEN itemid IN (220179, 220050, 225309) AND valuenum > 0 AND valuenum < 400 + THEN valuenum + END + ) AS sbp, + AVG( + CASE + WHEN itemid IN (220180, 220051, 225310) AND valuenum > 0 AND valuenum < 300 + THEN valuenum + END + ) AS dbp, + AVG( + CASE + WHEN itemid IN (220052, 220181, 225312) AND valuenum > 0 AND valuenum < 300 + THEN valuenum + END + ) AS mbp, + AVG(CASE WHEN itemid = 220179 AND valuenum > 0 AND valuenum < 400 THEN valuenum END) AS sbp_ni, + AVG(CASE WHEN itemid = 220180 AND valuenum > 0 AND valuenum < 300 THEN valuenum END) AS dbp_ni, + AVG(CASE WHEN itemid = 220181 AND valuenum > 0 AND valuenum < 300 THEN valuenum END) AS mbp_ni, + AVG( + CASE + WHEN itemid IN (220210, 224690) AND valuenum > 0 AND valuenum < 70 + THEN valuenum + END + ) AS resp_rate, + ROUND( + CAST(AVG( + CASE + WHEN itemid IN (223761) AND valuenum > 70 AND valuenum < 120 + THEN CAST(( + valuenum - 32 + ) AS DOUBLE PRECISION) / 1.8 + WHEN itemid IN (223762) AND valuenum > 10 AND valuenum < 50 + THEN valuenum + END + ) AS DECIMAL), + 2 + ) AS temperature, + MAX(CASE WHEN itemid = 224642 THEN value END) AS temperature_site, + AVG( + CASE WHEN itemid IN (220277) AND valuenum > 0 AND valuenum <= 100 THEN valuenum END + ) AS spo2, + AVG(CASE WHEN itemid IN (225664, 220621, 226537) AND valuenum > 0 THEN valuenum END) AS glucose +FROM mimiciv_icu.chartevents AS ce +WHERE + NOT ce.stay_id IS NULL + AND ce.itemid IN (220045 /* Heart Rate */, 225309 /* ART BP Systolic */, 225310 /* ART BP Diastolic */, 225312 /* ART BP Mean */, 220050 /* Arterial Blood Pressure systolic */, 220051 /* Arterial Blood Pressure diastolic */, 220052 /* Arterial Blood Pressure mean */, 220179 /* Non Invasive Blood Pressure systolic */, 220180 /* Non Invasive Blood Pressure diastolic */, 220181 /* Non Invasive Blood Pressure mean */, 220210 /* Respiratory Rate */, 224690 /* Respiratory Rate (Total) */, 220277 /* SPO2, peripheral */ /* GLUCOSE, both lab and fingerstick */, 225664 /* Glucose finger stick */, 220621 /* Glucose (serum) */, 226537 /* Glucose (whole blood) */ /* TEMPERATURE */ /* 226329 -- Blood Temperature CCO (C) */, 223762 /* "Temperature Celsius" */, 223761 /* "Temperature Fahrenheit" */, 224642 /* Temperature Site */) +GROUP BY + ce.subject_id, + ce.stay_id, + ce.charttime \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/medication/acei.sql b/mimic-iv/concepts_postgres/medication/acei.sql new file mode 100644 index 000000000..d9e2a9ff3 --- /dev/null +++ b/mimic-iv/concepts_postgres/medication/acei.sql @@ -0,0 +1,41 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.acei; CREATE TABLE mimiciv_derived.acei AS +WITH acei_drug AS ( + SELECT DISTINCT + drug, + CASE + WHEN UPPER(drug) LIKE '%BENAZEPRIL%' + THEN 1 + WHEN UPPER(drug) LIKE '%CAPTOPRIL%' + THEN 1 + WHEN UPPER(drug) LIKE '%ENALAPRIL%' + THEN 1 + WHEN UPPER(drug) LIKE '%FOSINOPRIL%' + THEN 1 + WHEN UPPER(drug) LIKE '%LISINOPRIL%' + THEN 1 + WHEN UPPER(drug) LIKE '%MOEXIPRIL%' + THEN 1 + WHEN UPPER(drug) LIKE '%PERINDOPRIL%' + THEN 1 + WHEN UPPER(drug) LIKE '%QUINAPRIL%' + THEN 1 + WHEN UPPER(drug) LIKE '%RAMIPRIL%' + THEN 1 + WHEN UPPER(drug) LIKE '%TRANDOLAPRIL%' + THEN 1 + ELSE 0 + END AS acei + FROM mimiciv_hosp.prescriptions +) +SELECT + pr.subject_id, + pr.hadm_id, + pr.drug AS acei, + pr.starttime, + pr.stoptime +FROM mimiciv_hosp.prescriptions AS pr +INNER JOIN acei_drug + ON pr.drug = acei_drug.drug +WHERE + acei_drug.acei = 1 \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/medication/antibiotic.sql b/mimic-iv/concepts_postgres/medication/antibiotic.sql index ccd9a38a8..4c54327fa 100644 --- a/mimic-iv/concepts_postgres/medication/antibiotic.sql +++ b/mimic-iv/concepts_postgres/medication/antibiotic.sql @@ -1,205 +1,346 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS antibiotic; CREATE TABLE antibiotic AS +DROP TABLE IF EXISTS mimiciv_derived.antibiotic; CREATE TABLE mimiciv_derived.antibiotic AS WITH abx AS ( - SELECT DISTINCT - drug - , route - , CASE - WHEN LOWER(drug) LIKE '%adoxa%' THEN 1 - WHEN LOWER(drug) LIKE '%ala-tet%' THEN 1 - WHEN LOWER(drug) LIKE '%alodox%' THEN 1 - WHEN LOWER(drug) LIKE '%amikacin%' THEN 1 - WHEN LOWER(drug) LIKE '%amikin%' THEN 1 - WHEN LOWER(drug) LIKE '%amoxicill%' THEN 1 - WHEN LOWER(drug) LIKE '%amphotericin%' THEN 1 - WHEN LOWER(drug) LIKE '%anidulafungin%' THEN 1 - WHEN LOWER(drug) LIKE '%ancef%' THEN 1 - WHEN LOWER(drug) LIKE '%clavulanate%' THEN 1 - WHEN LOWER(drug) LIKE '%ampicillin%' THEN 1 - WHEN LOWER(drug) LIKE '%augmentin%' THEN 1 - WHEN LOWER(drug) LIKE '%avelox%' THEN 1 - WHEN LOWER(drug) LIKE '%avidoxy%' THEN 1 - WHEN LOWER(drug) LIKE '%azactam%' THEN 1 - WHEN LOWER(drug) LIKE '%azithromycin%' THEN 1 - WHEN LOWER(drug) LIKE '%aztreonam%' THEN 1 - WHEN LOWER(drug) LIKE '%axetil%' THEN 1 - WHEN LOWER(drug) LIKE '%bactocill%' THEN 1 - WHEN LOWER(drug) LIKE '%bactrim%' THEN 1 - WHEN LOWER(drug) LIKE '%bactroban%' THEN 1 - WHEN LOWER(drug) LIKE '%bethkis%' THEN 1 - WHEN LOWER(drug) LIKE '%biaxin%' THEN 1 - WHEN LOWER(drug) LIKE '%bicillin l-a%' THEN 1 - WHEN LOWER(drug) LIKE '%cayston%' THEN 1 - WHEN LOWER(drug) LIKE '%cefazolin%' THEN 1 - WHEN LOWER(drug) LIKE '%cedax%' THEN 1 - WHEN LOWER(drug) LIKE '%cefoxitin%' THEN 1 - WHEN LOWER(drug) LIKE '%ceftazidime%' THEN 1 - WHEN LOWER(drug) LIKE '%cefaclor%' THEN 1 - WHEN LOWER(drug) LIKE '%cefadroxil%' THEN 1 - WHEN LOWER(drug) LIKE '%cefdinir%' THEN 1 - WHEN LOWER(drug) LIKE '%cefditoren%' THEN 1 - WHEN LOWER(drug) LIKE '%cefepime%' THEN 1 - WHEN LOWER(drug) LIKE '%cefotan%' THEN 1 - WHEN LOWER(drug) LIKE '%cefotetan%' THEN 1 - WHEN LOWER(drug) LIKE '%cefotaxime%' THEN 1 - WHEN LOWER(drug) LIKE '%ceftaroline%' THEN 1 - WHEN LOWER(drug) LIKE '%cefpodoxime%' THEN 1 - WHEN LOWER(drug) LIKE '%cefpirome%' THEN 1 - WHEN LOWER(drug) LIKE '%cefprozil%' THEN 1 - WHEN LOWER(drug) LIKE '%ceftibuten%' THEN 1 - WHEN LOWER(drug) LIKE '%ceftin%' THEN 1 - WHEN LOWER(drug) LIKE '%ceftriaxone%' THEN 1 - WHEN LOWER(drug) LIKE '%cefuroxime%' THEN 1 - WHEN LOWER(drug) LIKE '%cephalexin%' THEN 1 - WHEN LOWER(drug) LIKE '%cephalothin%' THEN 1 - WHEN LOWER(drug) LIKE '%cephapririn%' THEN 1 - WHEN LOWER(drug) LIKE '%chloramphenicol%' THEN 1 - WHEN LOWER(drug) LIKE '%cipro%' THEN 1 - WHEN LOWER(drug) LIKE '%ciprofloxacin%' THEN 1 - WHEN LOWER(drug) LIKE '%claforan%' THEN 1 - WHEN LOWER(drug) LIKE '%clarithromycin%' THEN 1 - WHEN LOWER(drug) LIKE '%cleocin%' THEN 1 - WHEN LOWER(drug) LIKE '%clindamycin%' THEN 1 - WHEN LOWER(drug) LIKE '%cubicin%' THEN 1 - WHEN LOWER(drug) LIKE '%dicloxacillin%' THEN 1 - WHEN LOWER(drug) LIKE '%dirithromycin%' THEN 1 - WHEN LOWER(drug) LIKE '%doryx%' THEN 1 - WHEN LOWER(drug) LIKE '%doxycy%' THEN 1 - WHEN LOWER(drug) LIKE '%duricef%' THEN 1 - WHEN LOWER(drug) LIKE '%dynacin%' THEN 1 - WHEN LOWER(drug) LIKE '%ery-tab%' THEN 1 - WHEN LOWER(drug) LIKE '%eryped%' THEN 1 - WHEN LOWER(drug) LIKE '%eryc%' THEN 1 - WHEN LOWER(drug) LIKE '%erythrocin%' THEN 1 - WHEN LOWER(drug) LIKE '%erythromycin%' THEN 1 - WHEN LOWER(drug) LIKE '%factive%' THEN 1 - WHEN LOWER(drug) LIKE '%flagyl%' THEN 1 - WHEN LOWER(drug) LIKE '%fortaz%' THEN 1 - WHEN LOWER(drug) LIKE '%furadantin%' THEN 1 - WHEN LOWER(drug) LIKE '%garamycin%' THEN 1 - WHEN LOWER(drug) LIKE '%gentamicin%' THEN 1 - WHEN LOWER(drug) LIKE '%kanamycin%' THEN 1 - WHEN LOWER(drug) LIKE '%keflex%' THEN 1 - WHEN LOWER(drug) LIKE '%kefzol%' THEN 1 - WHEN LOWER(drug) LIKE '%ketek%' THEN 1 - WHEN LOWER(drug) LIKE '%levaquin%' THEN 1 - WHEN LOWER(drug) LIKE '%levofloxacin%' THEN 1 - WHEN LOWER(drug) LIKE '%lincocin%' THEN 1 - WHEN LOWER(drug) LIKE '%linezolid%' THEN 1 - WHEN LOWER(drug) LIKE '%macrobid%' THEN 1 - WHEN LOWER(drug) LIKE '%macrodantin%' THEN 1 - WHEN LOWER(drug) LIKE '%maxipime%' THEN 1 - WHEN LOWER(drug) LIKE '%mefoxin%' THEN 1 - WHEN LOWER(drug) LIKE '%metronidazole%' THEN 1 - WHEN LOWER(drug) LIKE '%meropenem%' THEN 1 - WHEN LOWER(drug) LIKE '%methicillin%' THEN 1 - WHEN LOWER(drug) LIKE '%minocin%' THEN 1 - WHEN LOWER(drug) LIKE '%minocycline%' THEN 1 - WHEN LOWER(drug) LIKE '%monodox%' THEN 1 - WHEN LOWER(drug) LIKE '%monurol%' THEN 1 - WHEN LOWER(drug) LIKE '%morgidox%' THEN 1 - WHEN LOWER(drug) LIKE '%moxatag%' THEN 1 - WHEN LOWER(drug) LIKE '%moxifloxacin%' THEN 1 - WHEN LOWER(drug) LIKE '%mupirocin%' THEN 1 - WHEN LOWER(drug) LIKE '%myrac%' THEN 1 - WHEN LOWER(drug) LIKE '%nafcillin%' THEN 1 - WHEN LOWER(drug) LIKE '%neomycin%' THEN 1 - WHEN LOWER(drug) LIKE '%nicazel doxy 30%' THEN 1 - WHEN LOWER(drug) LIKE '%nitrofurantoin%' THEN 1 - WHEN LOWER(drug) LIKE '%norfloxacin%' THEN 1 - WHEN LOWER(drug) LIKE '%noroxin%' THEN 1 - WHEN LOWER(drug) LIKE '%ocudox%' THEN 1 - WHEN LOWER(drug) LIKE '%ofloxacin%' THEN 1 - WHEN LOWER(drug) LIKE '%omnicef%' THEN 1 - WHEN LOWER(drug) LIKE '%oracea%' THEN 1 - WHEN LOWER(drug) LIKE '%oraxyl%' THEN 1 - WHEN LOWER(drug) LIKE '%oxacillin%' THEN 1 - WHEN LOWER(drug) LIKE '%pc pen vk%' THEN 1 - WHEN LOWER(drug) LIKE '%pce dispertab%' THEN 1 - WHEN LOWER(drug) LIKE '%panixine%' THEN 1 - WHEN LOWER(drug) LIKE '%pediazole%' THEN 1 - WHEN LOWER(drug) LIKE '%penicillin%' THEN 1 - WHEN LOWER(drug) LIKE '%periostat%' THEN 1 - WHEN LOWER(drug) LIKE '%pfizerpen%' THEN 1 - WHEN LOWER(drug) LIKE '%piperacillin%' THEN 1 - WHEN LOWER(drug) LIKE '%tazobactam%' THEN 1 - WHEN LOWER(drug) LIKE '%primsol%' THEN 1 - WHEN LOWER(drug) LIKE '%proquin%' THEN 1 - WHEN LOWER(drug) LIKE '%raniclor%' THEN 1 - WHEN LOWER(drug) LIKE '%rifadin%' THEN 1 - WHEN LOWER(drug) LIKE '%rifampin%' THEN 1 - WHEN LOWER(drug) LIKE '%rocephin%' THEN 1 - WHEN LOWER(drug) LIKE '%smz-tmp%' THEN 1 - WHEN LOWER(drug) LIKE '%septra%' THEN 1 - WHEN LOWER(drug) LIKE '%septra ds%' THEN 1 - WHEN LOWER(drug) LIKE '%septra%' THEN 1 - WHEN LOWER(drug) LIKE '%solodyn%' THEN 1 - WHEN LOWER(drug) LIKE '%spectracef%' THEN 1 - WHEN LOWER(drug) LIKE '%streptomycin%' THEN 1 - WHEN LOWER(drug) LIKE '%sulfadiazine%' THEN 1 - WHEN LOWER(drug) LIKE '%sulfamethoxazole%' THEN 1 - WHEN LOWER(drug) LIKE '%trimethoprim%' THEN 1 - WHEN LOWER(drug) LIKE '%sulfatrim%' THEN 1 - WHEN LOWER(drug) LIKE '%sulfisoxazole%' THEN 1 - WHEN LOWER(drug) LIKE '%suprax%' THEN 1 - WHEN LOWER(drug) LIKE '%synercid%' THEN 1 - WHEN LOWER(drug) LIKE '%tazicef%' THEN 1 - WHEN LOWER(drug) LIKE '%tetracycline%' THEN 1 - WHEN LOWER(drug) LIKE '%timentin%' THEN 1 - WHEN LOWER(drug) LIKE '%tobramycin%' THEN 1 - WHEN LOWER(drug) LIKE '%trimethoprim%' THEN 1 - WHEN LOWER(drug) LIKE '%unasyn%' THEN 1 - WHEN LOWER(drug) LIKE '%vancocin%' THEN 1 - WHEN LOWER(drug) LIKE '%vancomycin%' THEN 1 - WHEN LOWER(drug) LIKE '%vantin%' THEN 1 - WHEN LOWER(drug) LIKE '%vibativ%' THEN 1 - WHEN LOWER(drug) LIKE '%vibra-tabs%' THEN 1 - WHEN LOWER(drug) LIKE '%vibramycin%' THEN 1 - WHEN LOWER(drug) LIKE '%zinacef%' THEN 1 - WHEN LOWER(drug) LIKE '%zithromax%' THEN 1 - WHEN LOWER(drug) LIKE '%zosyn%' THEN 1 - WHEN LOWER(drug) LIKE '%zyvox%' THEN 1 - ELSE 0 - END AS antibiotic - FROM mimiciv_hosp.prescriptions - -- excludes vials/syringe/normal saline, etc - WHERE drug_type NOT IN ('BASE') - -- we exclude routes via the eye, ears, or topically - AND route NOT IN ('OU', 'OS', 'OD', 'AU', 'AS', 'AD', 'TP') - AND LOWER(route) NOT LIKE '%ear%' - AND LOWER(route) NOT LIKE '%eye%' - -- we exclude certain types of antibiotics: topical creams, - -- gels, desens, etc - AND LOWER(drug) NOT LIKE '%cream%' - AND LOWER(drug) NOT LIKE '%desensitization%' - AND LOWER(drug) NOT LIKE '%ophth oint%' - AND LOWER(drug) NOT LIKE '%gel%' --- other routes not sure about... --- for sure keep: ('IV','PO','PO/NG','ORAL', 'IV DRIP', 'IV BOLUS') --- ? VT, PB, PR, PL, NS, NG, NEB, NAS, LOCK, J TUBE, IVT --- ? IT, IRR, IP, IO, INHALATION, IN, IM --- ? IJ, IH, G TUBE, DIALYS --- ?? enemas?? -) - + SELECT DISTINCT + drug, + route, + CASE + WHEN LOWER(drug) LIKE '%adoxa%' + THEN 1 + WHEN LOWER(drug) LIKE '%ala-tet%' + THEN 1 + WHEN LOWER(drug) LIKE '%alodox%' + THEN 1 + WHEN LOWER(drug) LIKE '%amikacin%' + THEN 1 + WHEN LOWER(drug) LIKE '%amikin%' + THEN 1 + WHEN LOWER(drug) LIKE '%amoxicill%' + THEN 1 + WHEN LOWER(drug) LIKE '%amphotericin%' + THEN 1 + WHEN LOWER(drug) LIKE '%anidulafungin%' + THEN 1 + WHEN LOWER(drug) LIKE '%ancef%' + THEN 1 + WHEN LOWER(drug) LIKE '%clavulanate%' + THEN 1 + WHEN LOWER(drug) LIKE '%ampicillin%' + THEN 1 + WHEN LOWER(drug) LIKE '%augmentin%' + THEN 1 + WHEN LOWER(drug) LIKE '%avelox%' + THEN 1 + WHEN LOWER(drug) LIKE '%avidoxy%' + THEN 1 + WHEN LOWER(drug) LIKE '%azactam%' + THEN 1 + WHEN LOWER(drug) LIKE '%azithromycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%aztreonam%' + THEN 1 + WHEN LOWER(drug) LIKE '%axetil%' + THEN 1 + WHEN LOWER(drug) LIKE '%bactocill%' + THEN 1 + WHEN LOWER(drug) LIKE '%bactrim%' + THEN 1 + WHEN LOWER(drug) LIKE '%bactroban%' + THEN 1 + WHEN LOWER(drug) LIKE '%bethkis%' + THEN 1 + WHEN LOWER(drug) LIKE '%biaxin%' + THEN 1 + WHEN LOWER(drug) LIKE '%bicillin l-a%' + THEN 1 + WHEN LOWER(drug) LIKE '%cayston%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefazolin%' + THEN 1 + WHEN LOWER(drug) LIKE '%cedax%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefoxitin%' + THEN 1 + WHEN LOWER(drug) LIKE '%ceftazidime%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefaclor%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefadroxil%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefdinir%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefditoren%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefepime%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefotan%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefotetan%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefotaxime%' + THEN 1 + WHEN LOWER(drug) LIKE '%ceftaroline%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefpodoxime%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefpirome%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefprozil%' + THEN 1 + WHEN LOWER(drug) LIKE '%ceftibuten%' + THEN 1 + WHEN LOWER(drug) LIKE '%ceftin%' + THEN 1 + WHEN LOWER(drug) LIKE '%ceftriaxone%' + THEN 1 + WHEN LOWER(drug) LIKE '%cefuroxime%' + THEN 1 + WHEN LOWER(drug) LIKE '%cephalexin%' + THEN 1 + WHEN LOWER(drug) LIKE '%cephalothin%' + THEN 1 + WHEN LOWER(drug) LIKE '%cephapririn%' + THEN 1 + WHEN LOWER(drug) LIKE '%chloramphenicol%' + THEN 1 + WHEN LOWER(drug) LIKE '%cipro%' + THEN 1 + WHEN LOWER(drug) LIKE '%ciprofloxacin%' + THEN 1 + WHEN LOWER(drug) LIKE '%claforan%' + THEN 1 + WHEN LOWER(drug) LIKE '%clarithromycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%cleocin%' + THEN 1 + WHEN LOWER(drug) LIKE '%clindamycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%cubicin%' + THEN 1 + WHEN LOWER(drug) LIKE '%dicloxacillin%' + THEN 1 + WHEN LOWER(drug) LIKE '%dirithromycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%doryx%' + THEN 1 + WHEN LOWER(drug) LIKE '%doxycy%' + THEN 1 + WHEN LOWER(drug) LIKE '%duricef%' + THEN 1 + WHEN LOWER(drug) LIKE '%dynacin%' + THEN 1 + WHEN LOWER(drug) LIKE '%ery-tab%' + THEN 1 + WHEN LOWER(drug) LIKE '%eryped%' + THEN 1 + WHEN LOWER(drug) LIKE '%eryc%' + THEN 1 + WHEN LOWER(drug) LIKE '%erythrocin%' + THEN 1 + WHEN LOWER(drug) LIKE '%erythromycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%factive%' + THEN 1 + WHEN LOWER(drug) LIKE '%flagyl%' + THEN 1 + WHEN LOWER(drug) LIKE '%fortaz%' + THEN 1 + WHEN LOWER(drug) LIKE '%furadantin%' + THEN 1 + WHEN LOWER(drug) LIKE '%garamycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%gentamicin%' + THEN 1 + WHEN LOWER(drug) LIKE '%kanamycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%keflex%' + THEN 1 + WHEN LOWER(drug) LIKE '%kefzol%' + THEN 1 + WHEN LOWER(drug) LIKE '%ketek%' + THEN 1 + WHEN LOWER(drug) LIKE '%levaquin%' + THEN 1 + WHEN LOWER(drug) LIKE '%levofloxacin%' + THEN 1 + WHEN LOWER(drug) LIKE '%lincocin%' + THEN 1 + WHEN LOWER(drug) LIKE '%linezolid%' + THEN 1 + WHEN LOWER(drug) LIKE '%macrobid%' + THEN 1 + WHEN LOWER(drug) LIKE '%macrodantin%' + THEN 1 + WHEN LOWER(drug) LIKE '%maxipime%' + THEN 1 + WHEN LOWER(drug) LIKE '%mefoxin%' + THEN 1 + WHEN LOWER(drug) LIKE '%metronidazole%' + THEN 1 + WHEN LOWER(drug) LIKE '%meropenem%' + THEN 1 + WHEN LOWER(drug) LIKE '%methicillin%' + THEN 1 + WHEN LOWER(drug) LIKE '%minocin%' + THEN 1 + WHEN LOWER(drug) LIKE '%minocycline%' + THEN 1 + WHEN LOWER(drug) LIKE '%monodox%' + THEN 1 + WHEN LOWER(drug) LIKE '%monurol%' + THEN 1 + WHEN LOWER(drug) LIKE '%morgidox%' + THEN 1 + WHEN LOWER(drug) LIKE '%moxatag%' + THEN 1 + WHEN LOWER(drug) LIKE '%moxifloxacin%' + THEN 1 + WHEN LOWER(drug) LIKE '%mupirocin%' + THEN 1 + WHEN LOWER(drug) LIKE '%myrac%' + THEN 1 + WHEN LOWER(drug) LIKE '%nafcillin%' + THEN 1 + WHEN LOWER(drug) LIKE '%neomycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%nicazel doxy 30%' + THEN 1 + WHEN LOWER(drug) LIKE '%nitrofurantoin%' + THEN 1 + WHEN LOWER(drug) LIKE '%norfloxacin%' + THEN 1 + WHEN LOWER(drug) LIKE '%noroxin%' + THEN 1 + WHEN LOWER(drug) LIKE '%ocudox%' + THEN 1 + WHEN LOWER(drug) LIKE '%ofloxacin%' + THEN 1 + WHEN LOWER(drug) LIKE '%omnicef%' + THEN 1 + WHEN LOWER(drug) LIKE '%oracea%' + THEN 1 + WHEN LOWER(drug) LIKE '%oraxyl%' + THEN 1 + WHEN LOWER(drug) LIKE '%oxacillin%' + THEN 1 + WHEN LOWER(drug) LIKE '%pc pen vk%' + THEN 1 + WHEN LOWER(drug) LIKE '%pce dispertab%' + THEN 1 + WHEN LOWER(drug) LIKE '%panixine%' + THEN 1 + WHEN LOWER(drug) LIKE '%pediazole%' + THEN 1 + WHEN LOWER(drug) LIKE '%penicillin%' + THEN 1 + WHEN LOWER(drug) LIKE '%periostat%' + THEN 1 + WHEN LOWER(drug) LIKE '%pfizerpen%' + THEN 1 + WHEN LOWER(drug) LIKE '%piperacillin%' + THEN 1 + WHEN LOWER(drug) LIKE '%tazobactam%' + THEN 1 + WHEN LOWER(drug) LIKE '%primsol%' + THEN 1 + WHEN LOWER(drug) LIKE '%proquin%' + THEN 1 + WHEN LOWER(drug) LIKE '%raniclor%' + THEN 1 + WHEN LOWER(drug) LIKE '%rifadin%' + THEN 1 + WHEN LOWER(drug) LIKE '%rifampin%' + THEN 1 + WHEN LOWER(drug) LIKE '%rocephin%' + THEN 1 + WHEN LOWER(drug) LIKE '%smz-tmp%' + THEN 1 + WHEN LOWER(drug) LIKE '%septra%' + THEN 1 + WHEN LOWER(drug) LIKE '%septra ds%' + THEN 1 + WHEN LOWER(drug) LIKE '%septra%' + THEN 1 + WHEN LOWER(drug) LIKE '%solodyn%' + THEN 1 + WHEN LOWER(drug) LIKE '%spectracef%' + THEN 1 + WHEN LOWER(drug) LIKE '%streptomycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%sulfadiazine%' + THEN 1 + WHEN LOWER(drug) LIKE '%sulfamethoxazole%' + THEN 1 + WHEN LOWER(drug) LIKE '%trimethoprim%' + THEN 1 + WHEN LOWER(drug) LIKE '%sulfatrim%' + THEN 1 + WHEN LOWER(drug) LIKE '%sulfisoxazole%' + THEN 1 + WHEN LOWER(drug) LIKE '%suprax%' + THEN 1 + WHEN LOWER(drug) LIKE '%synercid%' + THEN 1 + WHEN LOWER(drug) LIKE '%tazicef%' + THEN 1 + WHEN LOWER(drug) LIKE '%tetracycline%' + THEN 1 + WHEN LOWER(drug) LIKE '%timentin%' + THEN 1 + WHEN LOWER(drug) LIKE '%tobramycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%trimethoprim%' + THEN 1 + WHEN LOWER(drug) LIKE '%unasyn%' + THEN 1 + WHEN LOWER(drug) LIKE '%vancocin%' + THEN 1 + WHEN LOWER(drug) LIKE '%vancomycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%vantin%' + THEN 1 + WHEN LOWER(drug) LIKE '%vibativ%' + THEN 1 + WHEN LOWER(drug) LIKE '%vibra-tabs%' + THEN 1 + WHEN LOWER(drug) LIKE '%vibramycin%' + THEN 1 + WHEN LOWER(drug) LIKE '%zinacef%' + THEN 1 + WHEN LOWER(drug) LIKE '%zithromax%' + THEN 1 + WHEN LOWER(drug) LIKE '%zosyn%' + THEN 1 + WHEN LOWER(drug) LIKE '%zyvox%' + THEN 1 + ELSE 0 + END AS antibiotic + FROM mimiciv_hosp.prescriptions + /* excludes vials/syringe/normal saline, etc */ + WHERE + NOT drug_type IN ('BASE') /* we exclude routes via the eye, ears, or topically */ + AND NOT route IN ('OU', 'OS', 'OD', 'AU', 'AS', 'AD', 'TP') + AND NOT LOWER(route) LIKE '%ear%' + AND NOT LOWER(route) LIKE '%eye%' + AND NOT LOWER(drug) LIKE '%cream%' /* we exclude certain types of antibiotics: topical creams, */ /* gels, desens, etc */ + AND NOT LOWER(drug) LIKE '%desensitization%' + AND NOT LOWER(drug) LIKE '%ophth oint%' + AND NOT LOWER(drug) LIKE '%gel%' +) /* other routes not sure about... */ /* for sure keep: ('IV','PO','PO/NG','ORAL', 'IV DRIP', 'IV BOLUS') */ /* ? VT, PB, PR, PL, NS, NG, NEB, NAS, LOCK, J TUBE, IVT */ /* ? IT, IRR, IP, IO, INHALATION, IN, IM */ /* ? IJ, IH, G TUBE, DIALYS */ /* ?? enemas?? */ SELECT - pr.subject_id, pr.hadm_id - , ie.stay_id - , pr.drug AS antibiotic - , pr.route - , pr.starttime - , pr.stoptime -FROM mimiciv_hosp.prescriptions pr --- inner join to subselect to only antibiotic prescriptions + pr.subject_id, + pr.hadm_id, + ie.stay_id, + pr.drug AS antibiotic, + pr.route, + pr.starttime, + pr.stoptime +FROM mimiciv_hosp.prescriptions AS pr +/* inner join to subselect to only antibiotic prescriptions */ INNER JOIN abx - ON pr.drug = abx.drug - -- route is never NULL for antibiotics - -- only ~4000 null rows in prescriptions total. - AND pr.route = abx.route --- add in stay_id as we use this table for sepsis-3 -LEFT JOIN mimiciv_icu.icustays ie - ON pr.hadm_id = ie.hadm_id - AND pr.starttime >= ie.intime - AND pr.starttime < ie.outtime -WHERE abx.antibiotic = 1 -; + ON pr.drug = abx.drug AND pr.route = abx.route +/* add in stay_id as we use this table for sepsis-3 */ +LEFT JOIN mimiciv_icu.icustays AS ie + ON pr.hadm_id = ie.hadm_id AND pr.starttime >= ie.intime AND pr.starttime < ie.outtime +WHERE + abx.antibiotic = 1 \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/medication/dobutamine.sql b/mimic-iv/concepts_postgres/medication/dobutamine.sql index 8c4b19b87..67a891589 100644 --- a/mimic-iv/concepts_postgres/medication/dobutamine.sql +++ b/mimic-iv/concepts_postgres/medication/dobutamine.sql @@ -1,13 +1,13 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS dobutamine; CREATE TABLE dobutamine AS --- This query extracts dose+durations of dobutamine administration --- Local hospital dosage guidance: 2 mcg/kg/min (low) - 40 mcg/kg/min (max) +DROP TABLE IF EXISTS mimiciv_derived.dobutamine; CREATE TABLE mimiciv_derived.dobutamine AS +/* This query extracts dose+durations of dobutamine administration */ /* Local hospital dosage guidance: 2 mcg/kg/min (low) - 40 mcg/kg/min (max) */ SELECT - stay_id, linkorderid - -- all rows in mcg/kg/min - , rate AS vaso_rate - , amount AS vaso_amount - , starttime - , endtime + stay_id, + linkorderid, /* all rows in mcg/kg/min */ + rate AS vaso_rate, + amount AS vaso_amount, + starttime, + endtime FROM mimiciv_icu.inputevents -WHERE itemid = 221653 -- dobutamine +WHERE + itemid = 221653 /* dobutamine */ \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/medication/dopamine.sql b/mimic-iv/concepts_postgres/medication/dopamine.sql index e6ea842a4..63ef1c941 100644 --- a/mimic-iv/concepts_postgres/medication/dopamine.sql +++ b/mimic-iv/concepts_postgres/medication/dopamine.sql @@ -1,13 +1,13 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS dopamine; CREATE TABLE dopamine AS --- This query extracts dose+durations of dopamine administration --- Local hospital dosage guidance: 2 mcg/kg/min (low) - 10 mcg/kg/min (high) +DROP TABLE IF EXISTS mimiciv_derived.dopamine; CREATE TABLE mimiciv_derived.dopamine AS +/* This query extracts dose+durations of dopamine administration */ /* Local hospital dosage guidance: 2 mcg/kg/min (low) - 10 mcg/kg/min (high) */ SELECT - stay_id, linkorderid - -- all rows in mcg/kg/min - , rate AS vaso_rate - , amount AS vaso_amount - , starttime - , endtime + stay_id, + linkorderid, /* all rows in mcg/kg/min */ + rate AS vaso_rate, + amount AS vaso_amount, + starttime, + endtime FROM mimiciv_icu.inputevents -WHERE itemid = 221662 -- dopamine +WHERE + itemid = 221662 /* dopamine */ \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/medication/epinephrine.sql b/mimic-iv/concepts_postgres/medication/epinephrine.sql index 5e5123683..91d02facc 100644 --- a/mimic-iv/concepts_postgres/medication/epinephrine.sql +++ b/mimic-iv/concepts_postgres/medication/epinephrine.sql @@ -1,13 +1,13 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS epinephrine; CREATE TABLE epinephrine AS --- This query extracts dose+durations of epinephrine administration --- Local hospital dosage guidance: 0.2 mcg/kg/min (low) - 2 mcg/kg/min (high) +DROP TABLE IF EXISTS mimiciv_derived.epinephrine; CREATE TABLE mimiciv_derived.epinephrine AS +/* This query extracts dose+durations of epinephrine administration */ /* Local hospital dosage guidance: 0.2 mcg/kg/min (low) - 2 mcg/kg/min (high) */ SELECT - stay_id, linkorderid - -- all rows in mcg/kg/min - , rate AS vaso_rate - , amount AS vaso_amount - , starttime - , endtime + stay_id, + linkorderid, /* all rows in mcg/kg/min */ + rate AS vaso_rate, + amount AS vaso_amount, + starttime, + endtime FROM mimiciv_icu.inputevents -WHERE itemid = 221289 -- epinephrine +WHERE + itemid = 221289 /* epinephrine */ \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/medication/milrinone.sql b/mimic-iv/concepts_postgres/medication/milrinone.sql index ec03e0b68..bdb21b562 100644 --- a/mimic-iv/concepts_postgres/medication/milrinone.sql +++ b/mimic-iv/concepts_postgres/medication/milrinone.sql @@ -1,13 +1,13 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS milrinone; CREATE TABLE milrinone AS --- This query extracts dose+durations of milrinone administration --- Local hospital dosage guidance: 0.5 mcg/kg/min (usual) +DROP TABLE IF EXISTS mimiciv_derived.milrinone; CREATE TABLE mimiciv_derived.milrinone AS +/* This query extracts dose+durations of milrinone administration */ /* Local hospital dosage guidance: 0.5 mcg/kg/min (usual) */ SELECT - stay_id, linkorderid - -- all rows in mcg/kg/min - , rate AS vaso_rate - , amount AS vaso_amount - , starttime - , endtime + stay_id, + linkorderid, /* all rows in mcg/kg/min */ + rate AS vaso_rate, + amount AS vaso_amount, + starttime, + endtime FROM mimiciv_icu.inputevents -WHERE itemid = 221986 -- milrinone +WHERE + itemid = 221986 /* milrinone */ \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/medication/neuroblock.sql b/mimic-iv/concepts_postgres/medication/neuroblock.sql index ad5ac2716..12ba0dc3b 100644 --- a/mimic-iv/concepts_postgres/medication/neuroblock.sql +++ b/mimic-iv/concepts_postgres/medication/neuroblock.sql @@ -1,16 +1,14 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS neuroblock; CREATE TABLE neuroblock AS --- This query extracts dose+durations of neuromuscular blocking agents +DROP TABLE IF EXISTS mimiciv_derived.neuroblock; CREATE TABLE mimiciv_derived.neuroblock AS +/* This query extracts dose+durations of neuromuscular blocking agents */ SELECT - stay_id, orderid - , rate AS drug_rate - , amount AS drug_amount - , starttime - , endtime + stay_id, + orderid, + rate AS drug_rate, + amount AS drug_amount, + starttime, + endtime FROM mimiciv_icu.inputevents -WHERE itemid IN - ( - 222062 -- Vecuronium (664 rows, 154 infusion rows) - , 221555 -- Cisatracurium (9334 rows, 8970 infusion rows) - ) - AND rate IS NOT NULL -- only continuous infusions +WHERE + itemid IN (222062 /* Vecuronium (664 rows, 154 infusion rows) */, 221555 /* Cisatracurium (9334 rows, 8970 infusion rows) */) + AND NOT rate IS NULL /* only continuous infusions */ \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/medication/norepinephrine.sql b/mimic-iv/concepts_postgres/medication/norepinephrine.sql index 09b1e4dcf..623b6d952 100644 --- a/mimic-iv/concepts_postgres/medication/norepinephrine.sql +++ b/mimic-iv/concepts_postgres/medication/norepinephrine.sql @@ -1,18 +1,19 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS norepinephrine; CREATE TABLE norepinephrine AS --- This query extracts dose+durations of norepinephrine administration --- Local hospital dosage guidance: 0.03 mcg/kg/min (low), 0.5 mcg/kg/min (high) +DROP TABLE IF EXISTS mimiciv_derived.norepinephrine; CREATE TABLE mimiciv_derived.norepinephrine AS +/* This query extracts dose+durations of norepinephrine administration */ /* Local hospital dosage guidance: 0.03 mcg/kg/min (low), 0.5 mcg/kg/min (high) */ SELECT - stay_id, linkorderid - -- two rows in mg/kg/min... rest in mcg/kg/min - -- the rows in mg/kg/min are documented incorrectly - -- all rows converted into mcg/kg/min (equiv to ug/kg/min) - , CASE WHEN rateuom = 'mg/kg/min' AND patientweight = 1 THEN rate - -- below row is written for completion, but doesn't impact rows - WHEN rateuom = 'mg/kg/min' THEN rate * 1000.0 - ELSE rate END AS vaso_rate - , amount AS vaso_amount - , starttime - , endtime + stay_id, + linkorderid, /* two rows in mg/kg/min... rest in mcg/kg/min */ /* the rows in mg/kg/min are documented incorrectly */ /* all rows converted into mcg/kg/min (equiv to ug/kg/min) */ + CASE + WHEN rateuom = 'mg/kg/min' AND patientweight = 1 + THEN rate + WHEN rateuom = 'mg/kg/min' + THEN rate * 1000.0 + ELSE rate + END AS vaso_rate, + amount AS vaso_amount, + starttime, + endtime FROM mimiciv_icu.inputevents -WHERE itemid = 221906 -- norepinephrine +WHERE + itemid = 221906 /* norepinephrine */ \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/medication/norepinephrine_equivalent_dose.sql b/mimic-iv/concepts_postgres/medication/norepinephrine_equivalent_dose.sql index 5ed4bc5da..b63a0ebec 100644 --- a/mimic-iv/concepts_postgres/medication/norepinephrine_equivalent_dose.sql +++ b/mimic-iv/concepts_postgres/medication/norepinephrine_equivalent_dose.sql @@ -1,35 +1,18 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS norepinephrine_equivalent_dose; CREATE TABLE norepinephrine_equivalent_dose AS --- This query calculates norepinephrine equivalent dose for vasopressors. --- Based on "Vasopressor dose equivalence: A scoping review and --- suggested formula" by Goradia et al. 2020. - --- The relevant table makes the following equivalences: --- Norepinephrine - 1:1 - comparison dose of 0.1 ug/kg/min --- Epinephrine - 1:1 [0.7, 1.4] - 0.1 ug/kg/min --- Dopamine - 1:100 [75.2, 144.4] - 10 ug/kg/min --- Metaraminol - 1:8 [8.3] - 0.8 ug/kg/min --- Phenylephrine - 1:10 [1.1, 16.3] - 1 ug/kg/min --- Vasopressin - 1:0.4 [0.3, 0.4] - 0.04 units/min --- Angiotensin II - 1:0.1 [0.07, 0.13] - 0.01 ug/kg/min - -SELECT stay_id, starttime, endtime - -- calculate the dose - -- all sources are in mcg/kg/min, - -- except vasopressin which is in units/hour - , ROUND(CAST( - COALESCE(norepinephrine, 0) - + COALESCE(epinephrine, 0) - + COALESCE(phenylephrine / 10, 0) - + COALESCE(dopamine / 100, 0) - -- + metaraminol/8 -- metaraminol not used in BIDMC - + COALESCE(vasopressin * 2.5 / 60, 0) - -- angiotensin_ii*10 -- angiotensin ii rarely used, though - -- it could be included due to norepinephrine sparing effects - AS NUMERIC), 4) AS norepinephrine_equivalent_dose +DROP TABLE IF EXISTS mimiciv_derived.norepinephrine_equivalent_dose; CREATE TABLE mimiciv_derived.norepinephrine_equivalent_dose AS +/* This query calculates norepinephrine equivalent dose for vasopressors. */ /* Based on "Vasopressor dose equivalence: A scoping review and */ /* suggested formula" by Goradia et al. 2020. */ /* The relevant table makes the following equivalences: */ /* Norepinephrine - 1:1 - comparison dose of 0.1 ug/kg/min */ /* Epinephrine - 1:1 [0.7, 1.4] - 0.1 ug/kg/min */ /* Dopamine - 1:100 [75.2, 144.4] - 10 ug/kg/min */ /* Metaraminol - 1:8 [8.3] - 0.8 ug/kg/min */ /* Phenylephrine - 1:10 [1.1, 16.3] - 1 ug/kg/min */ /* Vasopressin - 1:0.4 [0.3, 0.4] - 0.04 units/min */ /* Angiotensin II - 1:0.1 [0.07, 0.13] - 0.01 ug/kg/min */ +SELECT + stay_id, + starttime, + endtime, /* calculate the dose */ /* all sources are in mcg/kg/min, */ /* except vasopressin which is in units/hour */ + ROUND( + CAST(COALESCE(norepinephrine, 0) + COALESCE(epinephrine, 0) + COALESCE(CAST(phenylephrine AS DOUBLE PRECISION) / 10, 0) + COALESCE(CAST(dopamine AS DOUBLE PRECISION) / 100, 0) + /* + metaraminol/8 -- metaraminol not used in BIDMC */ COALESCE(CAST(vasopressin * 2.5 AS DOUBLE PRECISION) / 60, 0) AS DECIMAL), + 4 + ) AS norepinephrine_equivalent_dose FROM mimiciv_derived.vasoactive_agent -WHERE norepinephrine IS NOT NULL - OR epinephrine IS NOT NULL - OR phenylephrine IS NOT NULL - OR dopamine IS NOT NULL - OR vasopressin IS NOT NULL; +WHERE + NOT norepinephrine IS NULL + OR NOT epinephrine IS NULL + OR NOT phenylephrine IS NULL + OR NOT dopamine IS NULL + OR NOT vasopressin IS NULL \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/medication/nsaid.sql b/mimic-iv/concepts_postgres/medication/nsaid.sql new file mode 100644 index 000000000..146e278d3 --- /dev/null +++ b/mimic-iv/concepts_postgres/medication/nsaid.sql @@ -0,0 +1,61 @@ +-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. +DROP TABLE IF EXISTS mimiciv_derived.nsaid; CREATE TABLE mimiciv_derived.nsaid AS +WITH nsaid_drug AS ( + SELECT DISTINCT + drug, + CASE + WHEN UPPER(drug) LIKE '%ASPIRIN%' + THEN 1 + WHEN UPPER(drug) LIKE '%BROMFENAC%' + THEN 1 + WHEN UPPER(drug) LIKE '%CELECOXIB%' + THEN 1 + WHEN UPPER(drug) LIKE '%DICLOFENAC%' + THEN 1 + WHEN UPPER(drug) LIKE '%DIFLUNISAL%' + THEN 1 + WHEN UPPER(drug) LIKE '%ETODOLAC%' + THEN 1 + WHEN UPPER(drug) LIKE '%FENOPROFEN%' + THEN 1 + WHEN UPPER(drug) LIKE '%FLURBIPROFEN%' + THEN 1 + WHEN UPPER(drug) LIKE '%IBUPROFEN%' + THEN 1 + WHEN UPPER(drug) LIKE '%INDOMETHACIN%' + THEN 1 + WHEN UPPER(drug) LIKE '%KETOPROFEN%' + THEN 1 + WHEN UPPER(drug) LIKE '%MEFENAMIC ACID%' + THEN 1 + WHEN UPPER(drug) LIKE '%MELOXICAM%' + THEN 1 + WHEN UPPER(drug) LIKE '%NABUMETONE%' + THEN 1 + WHEN UPPER(drug) LIKE '%NAPROXEN%' + THEN 1 + WHEN UPPER(drug) LIKE '%NEPAFENAC%' + THEN 1 + WHEN UPPER(drug) LIKE '%OXAPROZIN%' + THEN 1 + WHEN UPPER(drug) LIKE '%PIROXICAM%' + THEN 1 + WHEN UPPER(drug) LIKE '%SULINDAC%' + THEN 1 + WHEN UPPER(drug) LIKE '%TOLMETIN%' + THEN 1 + ELSE 0 + END AS nsaid + FROM mimiciv_hosp.prescriptions +) +SELECT + pr.subject_id, + pr.hadm_id, + pr.drug AS nsaid, + pr.starttime, + pr.stoptime +FROM mimiciv_hosp.prescriptions AS pr +INNER JOIN nsaid_drug + ON pr.drug = nsaid_drug.drug +WHERE + nsaid_drug.nsaid = 1 \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/medication/phenylephrine.sql b/mimic-iv/concepts_postgres/medication/phenylephrine.sql index af4d846c5..bd2666520 100644 --- a/mimic-iv/concepts_postgres/medication/phenylephrine.sql +++ b/mimic-iv/concepts_postgres/medication/phenylephrine.sql @@ -1,14 +1,17 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS phenylephrine; CREATE TABLE phenylephrine AS --- This query extracts dose+durations of phenylephrine administration --- Local hospital dosage guidance: 0.5 mcg/kg/min (low) - 5 mcg/kg/min (high) +DROP TABLE IF EXISTS mimiciv_derived.phenylephrine; CREATE TABLE mimiciv_derived.phenylephrine AS +/* This query extracts dose+durations of phenylephrine administration */ /* Local hospital dosage guidance: 0.5 mcg/kg/min (low) - 5 mcg/kg/min (high) */ SELECT - stay_id, linkorderid - -- one row in mcg/min, the rest in mcg/kg/min - , CASE WHEN rateuom = 'mcg/min' THEN rate / patientweight - ELSE rate END AS vaso_rate - , amount AS vaso_amount - , starttime - , endtime + stay_id, + linkorderid, /* one row in mcg/min, the rest in mcg/kg/min */ + CASE + WHEN rateuom = 'mcg/min' + THEN CAST(rate AS DOUBLE PRECISION) / patientweight + ELSE rate + END AS vaso_rate, + amount AS vaso_amount, + starttime, + endtime FROM mimiciv_icu.inputevents -WHERE itemid = 221749 -- phenylephrine +WHERE + itemid = 221749 /* phenylephrine */ \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/medication/vasoactive_agent.sql b/mimic-iv/concepts_postgres/medication/vasoactive_agent.sql index 43c0fb5ce..dfc1bbced 100644 --- a/mimic-iv/concepts_postgres/medication/vasoactive_agent.sql +++ b/mimic-iv/concepts_postgres/medication/vasoactive_agent.sql @@ -1,129 +1,112 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS vasoactive_agent; CREATE TABLE vasoactive_agent AS --- This query creates a single table with ongoing doses of vasoactive agents. --- TBD: rarely angiotensin II, methylene blue, and --- isoprenaline/isoproterenol are used. These are not in the query currently --- as they are not documented in MetaVision. However, they could --- be documented in other hospital wide systems. - --- collect all vasopressor administration times --- create a single table with these as start/stop times +DROP TABLE IF EXISTS mimiciv_derived.vasoactive_agent; CREATE TABLE mimiciv_derived.vasoactive_agent AS +/* left join to raw data tables to combine doses */ +/* This query creates a single table with ongoing doses of vasoactive agents. */ /* TBD: rarely angiotensin II, methylene blue, and */ /* isoprenaline/isoproterenol are used. These are not in the query currently */ /* as they are not documented in MetaVision. However, they could */ /* be documented in other hospital wide systems. */ /* collect all vasopressor administration times */ /* create a single table with these as start/stop times */ WITH tm AS ( - SELECT - stay_id, starttime AS vasotime - FROM mimiciv_derived.dobutamine - UNION DISTINCT - SELECT - stay_id, starttime AS vasotime - FROM mimiciv_derived.dopamine - UNION DISTINCT - SELECT - stay_id, starttime AS vasotime - FROM mimiciv_derived.epinephrine - UNION DISTINCT - SELECT - stay_id, starttime AS vasotime - FROM mimiciv_derived.norepinephrine - UNION DISTINCT - SELECT - stay_id, starttime AS vasotime - FROM mimiciv_derived.phenylephrine - UNION DISTINCT - SELECT - stay_id, starttime AS vasotime - FROM mimiciv_derived.vasopressin - UNION DISTINCT - SELECT - stay_id, starttime AS vasotime - FROM mimiciv_derived.milrinone - UNION DISTINCT - -- combine end times from the same tables - SELECT - stay_id, endtime AS vasotime - FROM mimiciv_derived.dobutamine - UNION DISTINCT - SELECT - stay_id, endtime AS vasotime - FROM mimiciv_derived.dopamine - UNION DISTINCT - SELECT - stay_id, endtime AS vasotime - FROM mimiciv_derived.epinephrine - UNION DISTINCT - SELECT - stay_id, endtime AS vasotime - FROM mimiciv_derived.norepinephrine - UNION DISTINCT - SELECT - stay_id, endtime AS vasotime - FROM mimiciv_derived.phenylephrine - UNION DISTINCT - SELECT - stay_id, endtime AS vasotime - FROM mimiciv_derived.vasopressin - UNION DISTINCT - SELECT - stay_id, endtime AS vasotime - FROM mimiciv_derived.milrinone + SELECT + stay_id, + starttime AS vasotime + FROM mimiciv_derived.dobutamine + UNION + SELECT + stay_id, + starttime AS vasotime + FROM mimiciv_derived.dopamine + UNION + SELECT + stay_id, + starttime AS vasotime + FROM mimiciv_derived.epinephrine + UNION + SELECT + stay_id, + starttime AS vasotime + FROM mimiciv_derived.norepinephrine + UNION + SELECT + stay_id, + starttime AS vasotime + FROM mimiciv_derived.phenylephrine + UNION + SELECT + stay_id, + starttime AS vasotime + FROM mimiciv_derived.vasopressin + UNION + SELECT + stay_id, + starttime AS vasotime + FROM mimiciv_derived.milrinone + UNION + /* combine end times from the same tables */ + SELECT + stay_id, + endtime AS vasotime + FROM mimiciv_derived.dobutamine + UNION + SELECT + stay_id, + endtime AS vasotime + FROM mimiciv_derived.dopamine + UNION + SELECT + stay_id, + endtime AS vasotime + FROM mimiciv_derived.epinephrine + UNION + SELECT + stay_id, + endtime AS vasotime + FROM mimiciv_derived.norepinephrine + UNION + SELECT + stay_id, + endtime AS vasotime + FROM mimiciv_derived.phenylephrine + UNION + SELECT + stay_id, + endtime AS vasotime + FROM mimiciv_derived.vasopressin + UNION + SELECT + stay_id, + endtime AS vasotime + FROM mimiciv_derived.milrinone +), tm_lag AS ( + SELECT + stay_id, + vasotime AS starttime, /* note: the last row for each partition (stay_id) will have */ /* a NULL endtime. we can drop this row later, as we know that no */ /* vasopressor will start at this time (otherwise, we would have */ /* a later end time, which would mean it's not the last row!) */ + LEAD(vasotime, 1) OVER (PARTITION BY stay_id ORDER BY vasotime NULLS FIRST) AS endtime + FROM tm ) - --- create starttime/endtime from all possible times collected -, tm_lag AS ( - SELECT stay_id - , vasotime AS starttime - -- note: the last row for each partition (stay_id) will have - -- a NULL endtime. we can drop this row later, as we know that no - -- vasopressor will start at this time (otherwise, we would have - -- a later end time, which would mean it's not the last row!) - , LEAD( - vasotime, 1 - ) OVER (PARTITION BY stay_id ORDER BY vasotime) AS endtime - FROM tm -) - --- left join to raw data tables to combine doses -SELECT t.stay_id, t.starttime, t.endtime - -- inopressors/vasopressors - , dop.vaso_rate AS dopamine -- mcg/kg/min - , epi.vaso_rate AS epinephrine -- mcg/kg/min - , nor.vaso_rate AS norepinephrine -- mcg/kg/min - , phe.vaso_rate AS phenylephrine -- mcg/kg/min - , vas.vaso_rate AS vasopressin -- units/hour - -- inodialators - , dob.vaso_rate AS dobutamine -- mcg/kg/min - , mil.vaso_rate AS milrinone -- mcg/kg/min --- isoproterenol is used in CCU/CVICU but not in metavision --- other drugs not included here but (rarely) used in the BIDMC: --- angiotensin II, methylene blue -FROM tm_lag t -LEFT JOIN mimiciv_derived.dobutamine dob - ON t.stay_id = dob.stay_id - AND t.starttime >= dob.starttime - AND t.endtime <= dob.endtime -LEFT JOIN mimiciv_derived.dopamine dop - ON t.stay_id = dop.stay_id - AND t.starttime >= dop.starttime - AND t.endtime <= dop.endtime -LEFT JOIN mimiciv_derived.epinephrine epi - ON t.stay_id = epi.stay_id - AND t.starttime >= epi.starttime - AND t.endtime <= epi.endtime -LEFT JOIN mimiciv_derived.norepinephrine nor - ON t.stay_id = nor.stay_id - AND t.starttime >= nor.starttime - AND t.endtime <= nor.endtime -LEFT JOIN mimiciv_derived.phenylephrine phe - ON t.stay_id = phe.stay_id - AND t.starttime >= phe.starttime - AND t.endtime <= phe.endtime -LEFT JOIN mimiciv_derived.vasopressin vas - ON t.stay_id = vas.stay_id - AND t.starttime >= vas.starttime - AND t.endtime <= vas.endtime -LEFT JOIN mimiciv_derived.milrinone mil - ON t.stay_id = mil.stay_id - AND t.starttime >= mil.starttime - AND t.endtime <= mil.endtime --- remove the final row for each stay_id --- it will not have any infusions associated with it -WHERE t.endtime IS NOT NULL; +SELECT + t.stay_id, + t.starttime, + t.endtime, /* inopressors/vasopressors */ + dop.vaso_rate AS dopamine, /* mcg/kg/min */ + epi.vaso_rate AS epinephrine, /* mcg/kg/min */ + nor.vaso_rate AS norepinephrine, /* mcg/kg/min */ + phe.vaso_rate AS phenylephrine, /* mcg/kg/min */ + vas.vaso_rate AS vasopressin, /* units/hour */ /* inodialators */ + dob.vaso_rate AS dobutamine, /* mcg/kg/min */ + mil.vaso_rate AS milrinone /* mcg/kg/min */ +/* isoproterenol is used in CCU/CVICU but not in metavision */ /* other drugs not included here but (rarely) used in the BIDMC: */ /* angiotensin II, methylene blue */ +FROM tm_lag AS t +LEFT JOIN mimiciv_derived.dobutamine AS dob + ON t.stay_id = dob.stay_id AND t.starttime >= dob.starttime AND t.endtime <= dob.endtime +LEFT JOIN mimiciv_derived.dopamine AS dop + ON t.stay_id = dop.stay_id AND t.starttime >= dop.starttime AND t.endtime <= dop.endtime +LEFT JOIN mimiciv_derived.epinephrine AS epi + ON t.stay_id = epi.stay_id AND t.starttime >= epi.starttime AND t.endtime <= epi.endtime +LEFT JOIN mimiciv_derived.norepinephrine AS nor + ON t.stay_id = nor.stay_id AND t.starttime >= nor.starttime AND t.endtime <= nor.endtime +LEFT JOIN mimiciv_derived.phenylephrine AS phe + ON t.stay_id = phe.stay_id AND t.starttime >= phe.starttime AND t.endtime <= phe.endtime +LEFT JOIN mimiciv_derived.vasopressin AS vas + ON t.stay_id = vas.stay_id AND t.starttime >= vas.starttime AND t.endtime <= vas.endtime +LEFT JOIN mimiciv_derived.milrinone AS mil + ON t.stay_id = mil.stay_id AND t.starttime >= mil.starttime AND t.endtime <= mil.endtime +/* remove the final row for each stay_id */ /* it will not have any infusions associated with it */ +WHERE + NOT t.endtime IS NULL \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/medication/vasopressin.sql b/mimic-iv/concepts_postgres/medication/vasopressin.sql index 9879968d6..a0a1d13f8 100644 --- a/mimic-iv/concepts_postgres/medication/vasopressin.sql +++ b/mimic-iv/concepts_postgres/medication/vasopressin.sql @@ -1,18 +1,13 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS vasopressin; CREATE TABLE vasopressin AS --- This query extracts dose+durations of vasopressin administration --- Local hospital dosage guidance: 1.2 units/hour (low) - 2.4 units/hour (high) +DROP TABLE IF EXISTS mimiciv_derived.vasopressin; CREATE TABLE mimiciv_derived.vasopressin AS +/* This query extracts dose+durations of vasopressin administration */ /* Local hospital dosage guidance: 1.2 units/hour (low) - 2.4 units/hour (high) */ SELECT - stay_id, linkorderid - -- three rows in units/min, rest in units/hour - -- the three rows in units/min look reasonable and - -- fit with the patient course - - -- convert all rows to units/hour - , CASE WHEN rateuom = 'units/min' THEN rate * 60.0 - ELSE rate END AS vaso_rate - , amount AS vaso_amount - , starttime - , endtime + stay_id, + linkorderid, /* three rows in units/min, rest in units/hour */ /* the three rows in units/min look reasonable and */ /* fit with the patient course */ /* convert all rows to units/hour */ + CASE WHEN rateuom = 'units/min' THEN rate * 60.0 ELSE rate END AS vaso_rate, + amount AS vaso_amount, + starttime, + endtime FROM mimiciv_icu.inputevents -WHERE itemid = 222315 -- vasopressin +WHERE + itemid = 222315 /* vasopressin */ \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/organfailure/kdigo_creatinine.sql b/mimic-iv/concepts_postgres/organfailure/kdigo_creatinine.sql index 22e9e73aa..ce72682f4 100644 --- a/mimic-iv/concepts_postgres/organfailure/kdigo_creatinine.sql +++ b/mimic-iv/concepts_postgres/organfailure/kdigo_creatinine.sql @@ -1,65 +1,64 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS kdigo_creatinine; CREATE TABLE kdigo_creatinine AS --- Extract all creatinine values from labevents around patient's ICU stay +DROP TABLE IF EXISTS mimiciv_derived.kdigo_creatinine; CREATE TABLE mimiciv_derived.kdigo_creatinine AS +/* Extract all creatinine values from labevents around patient's ICU stay */ WITH cr AS ( - SELECT - ie.hadm_id - , ie.stay_id - , le.charttime - , AVG(le.valuenum) AS creat - FROM mimiciv_icu.icustays ie - LEFT JOIN mimiciv_hosp.labevents le - ON ie.subject_id = le.subject_id - AND le.itemid = 50912 - AND le.valuenum IS NOT NULL - AND le.valuenum <= 150 - AND le.charttime >= DATETIME_SUB(ie.intime, INTERVAL '7' DAY) - AND le.charttime <= ie.outtime - GROUP BY ie.hadm_id, ie.stay_id, le.charttime -) - -, cr48 AS ( - -- add in the lowest value in the previous 48 hours - SELECT - cr.stay_id - , cr.charttime - , MIN(cr48.creat) AS creat_low_past_48hr - FROM cr - -- add in all creatinine values in the last 48 hours - LEFT JOIN cr cr48 - ON cr.stay_id = cr48.stay_id - AND cr48.charttime < cr.charttime - AND cr48.charttime >= DATETIME_SUB(cr.charttime, INTERVAL '48' HOUR) - GROUP BY cr.stay_id, cr.charttime -) - -, cr7 AS ( - -- add in the lowest value in the previous 7 days - SELECT - cr.stay_id - , cr.charttime - , MIN(cr7.creat) AS creat_low_past_7day - FROM cr - -- add in all creatinine values in the last 7 days - LEFT JOIN cr cr7 - ON cr.stay_id = cr7.stay_id - AND cr7.charttime < cr.charttime - AND cr7.charttime >= DATETIME_SUB(cr.charttime, INTERVAL '7' DAY) - GROUP BY cr.stay_id, cr.charttime + SELECT + ie.hadm_id, + ie.stay_id, + le.charttime, + AVG(le.valuenum) AS creat + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_hosp.labevents AS le + ON ie.subject_id = le.subject_id + AND le.itemid = 50912 + AND NOT le.valuenum IS NULL + AND le.valuenum <= 150 + AND le.charttime >= ie.intime - INTERVAL '7 DAY' + AND le.charttime <= ie.outtime + GROUP BY + ie.hadm_id, + ie.stay_id, + le.charttime +), cr48 AS ( + /* add in the lowest value in the previous 48 hours */ + SELECT + cr.stay_id, + cr.charttime, + MIN(cr48.creat) AS creat_low_past_48hr + FROM cr + /* add in all creatinine values in the last 48 hours */ + LEFT JOIN cr AS cr48 + ON cr.stay_id = cr48.stay_id + AND cr48.charttime < cr.charttime + AND cr48.charttime >= cr.charttime - INTERVAL '48 HOUR' + GROUP BY + cr.stay_id, + cr.charttime +), cr7 AS ( + /* add in the lowest value in the previous 7 days */ + SELECT + cr.stay_id, + cr.charttime, + MIN(cr7.creat) AS creat_low_past_7day + FROM cr + /* add in all creatinine values in the last 7 days */ + LEFT JOIN cr AS cr7 + ON cr.stay_id = cr7.stay_id + AND cr7.charttime < cr.charttime + AND cr7.charttime >= cr.charttime - INTERVAL '7 DAY' + GROUP BY + cr.stay_id, + cr.charttime ) - SELECT - cr.hadm_id - , cr.stay_id - , cr.charttime - , cr.creat - , cr48.creat_low_past_48hr - , cr7.creat_low_past_7day + cr.hadm_id, + cr.stay_id, + cr.charttime, + cr.creat, + cr48.creat_low_past_48hr, + cr7.creat_low_past_7day FROM cr LEFT JOIN cr48 - ON cr.stay_id = cr48.stay_id - AND cr.charttime = cr48.charttime + ON cr.stay_id = cr48.stay_id AND cr.charttime = cr48.charttime LEFT JOIN cr7 - ON cr.stay_id = cr7.stay_id - AND cr.charttime = cr7.charttime -; + ON cr.stay_id = cr7.stay_id AND cr.charttime = cr7.charttime \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/organfailure/kdigo_stages.sql b/mimic-iv/concepts_postgres/organfailure/kdigo_stages.sql index 187a0f982..4f7947d0b 100644 --- a/mimic-iv/concepts_postgres/organfailure/kdigo_stages.sql +++ b/mimic-iv/concepts_postgres/organfailure/kdigo_stages.sql @@ -1,155 +1,123 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS kdigo_stages; CREATE TABLE kdigo_stages AS --- This query checks if the patient had AKI according to KDIGO. --- AKI is calculated every time a creatinine or urine output measurement occurs. --- Baseline creatinine is defined as the lowest creatinine in the past 7 days. - --- get creatinine stages +DROP TABLE IF EXISTS mimiciv_derived.kdigo_stages; CREATE TABLE mimiciv_derived.kdigo_stages AS +/* This query checks if the patient had AKI according to KDIGO. */ /* AKI is calculated every time a creatinine or urine output measurement occurs. */ /* Baseline creatinine is defined as the lowest creatinine in the past 7 days. */ /* get creatinine stages */ WITH cr_stg AS ( - SELECT - cr.stay_id - , cr.charttime - , cr.creat_low_past_7day - , cr.creat_low_past_48hr - , cr.creat - , CASE - -- 3x baseline - WHEN cr.creat >= (cr.creat_low_past_7day * 3.0) THEN 3 - -- *OR* cr >= 4.0 with associated increase - WHEN cr.creat >= 4 - -- For patients reaching Stage 3 by SCr >4.0 mg/dl - -- require that the patient first achieve ... - -- an acute increase >= 0.3 within 48 hr - -- *or* an increase of >= 1.5 times baseline - AND ( - cr.creat_low_past_48hr <= 3.7 OR cr.creat >= ( - 1.5 * cr.creat_low_past_7day - ) - ) - THEN 3 - -- TODO: initiation of RRT - WHEN cr.creat >= (cr.creat_low_past_7day * 2.0) THEN 2 - WHEN cr.creat >= (cr.creat_low_past_48hr + 0.3) THEN 1 - WHEN cr.creat >= (cr.creat_low_past_7day * 1.5) THEN 1 - ELSE 0 END AS aki_stage_creat - FROM mimiciv_derived.kdigo_creatinine cr -) - --- stages for UO / creat -, uo_stg AS ( - SELECT - uo.stay_id - , uo.charttime - , uo.weight - , uo.uo_rt_6hr - , uo.uo_rt_12hr - , uo.uo_rt_24hr - -- AKI stages according to urine output - , CASE - WHEN uo.uo_rt_6hr IS NULL THEN NULL - -- require patient to be in ICU for at least 6 hours to stage UO - WHEN uo.charttime <= DATETIME_ADD(ie.intime, INTERVAL '6' HOUR) - THEN 0 - -- require the UO rate to be calculated over the - -- duration specified in KDIGO - -- Stage 3: <0.3 ml/kg/h for >=24 hours - WHEN uo.uo_tm_24hr >= 24 AND uo.uo_rt_24hr < 0.3 THEN 3 - -- *or* anuria for >= 12 hours - WHEN uo.uo_tm_12hr >= 12 AND uo.uo_rt_12hr = 0 THEN 3 - -- Stage 2: <0.5 ml/kg/h for >= 12 hours - WHEN uo.uo_tm_12hr >= 12 AND uo.uo_rt_12hr < 0.5 THEN 2 - -- Stage 1: <0.5 ml/kg/h for 6–12 hours - WHEN uo.uo_tm_6hr >= 6 AND uo.uo_rt_6hr < 0.5 THEN 1 - ELSE 0 END AS aki_stage_uo - FROM mimiciv_derived.kdigo_uo uo - INNER JOIN mimiciv_icu.icustays ie - ON uo.stay_id = ie.stay_id -) - --- get CRRT data -, crrt_stg AS ( - SELECT - stay_id - , charttime - , CASE - WHEN charttime IS NOT NULL THEN 3 - ELSE NULL END AS aki_stage_crrt - FROM mimiciv_derived.crrt - WHERE crrt_mode IS NOT NULL -) - --- get all charttimes documented -, tm_stg AS ( - SELECT - stay_id, charttime - FROM cr_stg - UNION DISTINCT - SELECT - stay_id, charttime - FROM uo_stg - UNION DISTINCT - SELECT - stay_id, charttime - FROM crrt_stg + SELECT + cr.stay_id, + cr.charttime, + cr.creat_low_past_7day, + cr.creat_low_past_48hr, + cr.creat, + CASE + WHEN cr.creat >= ( + cr.creat_low_past_7day * 3.0 + ) + THEN 3 + WHEN cr.creat >= 4 + AND ( + cr.creat_low_past_48hr <= 3.7 OR cr.creat >= ( + 1.5 * cr.creat_low_past_7day + ) + ) + THEN 3 + WHEN cr.creat >= ( + cr.creat_low_past_7day * 2.0 + ) + THEN 2 + WHEN cr.creat >= ( + cr.creat_low_past_48hr + 0.3 + ) + THEN 1 + WHEN cr.creat >= ( + cr.creat_low_past_7day * 1.5 + ) + THEN 1 + ELSE 0 + END AS aki_stage_creat + FROM mimiciv_derived.kdigo_creatinine AS cr +), uo_stg AS ( + SELECT + uo.stay_id, + uo.charttime, + uo.weight, + uo.uo_rt_6hr, + uo.uo_rt_12hr, + uo.uo_rt_24hr, /* AKI stages according to urine output */ + CASE + WHEN uo.uo_rt_6hr IS NULL + THEN NULL + WHEN uo.charttime <= ie.intime + INTERVAL '6 HOUR' + THEN 0 + WHEN uo.uo_tm_24hr >= 24 AND uo.uo_rt_24hr < 0.3 + THEN 3 + WHEN uo.uo_tm_12hr >= 12 AND uo.uo_rt_12hr = 0 + THEN 3 + WHEN uo.uo_tm_12hr >= 12 AND uo.uo_rt_12hr < 0.5 + THEN 2 + WHEN uo.uo_tm_6hr >= 6 AND uo.uo_rt_6hr < 0.5 + THEN 1 + ELSE 0 + END AS aki_stage_uo + FROM mimiciv_derived.kdigo_uo AS uo + INNER JOIN mimiciv_icu.icustays AS ie + ON uo.stay_id = ie.stay_id +), crrt_stg AS ( + SELECT + stay_id, + charttime, + CASE WHEN NOT charttime IS NULL THEN 3 ELSE NULL END AS aki_stage_crrt + FROM mimiciv_derived.crrt + WHERE + NOT crrt_mode IS NULL +), tm_stg AS ( + SELECT + stay_id, + charttime + FROM cr_stg + UNION + SELECT + stay_id, + charttime + FROM uo_stg + UNION + SELECT + stay_id, + charttime + FROM crrt_stg ) - SELECT - ie.subject_id - , ie.hadm_id - , ie.stay_id - , tm.charttime - , cr.creat_low_past_7day - , cr.creat_low_past_48hr - , cr.creat - , cr.aki_stage_creat - , uo.uo_rt_6hr - , uo.uo_rt_12hr - , uo.uo_rt_24hr - , uo.aki_stage_uo - , crrt.aki_stage_crrt - -- Classify AKI using both creatinine/urine output criteria - , GREATEST( - COALESCE(cr.aki_stage_creat, 0) - , COALESCE(uo.aki_stage_uo, 0) - , COALESCE(crrt.aki_stage_crrt, 0) - ) AS aki_stage - - -- We intend to combine together the scores from creatinine/UO by left - -- joining from the above temporary table which has all possible charttime. - -- This will guarantee we include all creatinine/UO measurements. - -- However, we have times where UO is measured, but not creatinine. - -- Thus we end up with NULLs for the creatinine column(s). Calculating - -- the highest stage across the columns will often only consider one stage. - -- For example, consider the following rows: - -- stay_id=123, time=10:00, cr_low_7day=4.0, uo_rt_6hr=NULL -> stage 3 - -- stay_id=123, time=10:30, cr_low_7day=NULL, uo_rt_6hr=0.3 -> stage 1 - -- This results in the stage alternating from low/high across rows. - -- To overcome this, we create a new column which carries forward the - -- highest KDIGO stage from the last 6 hours. In most cases, this smooths - -- out any discontinuity. - , MAX( - GREATEST( - COALESCE(cr.aki_stage_creat, 0) - , COALESCE(uo.aki_stage_uo, 0) - , COALESCE(crrt.aki_stage_crrt, 0) - ) - ) OVER - ( - PARTITION BY ie.subject_id - ORDER BY DATETIME_DIFF(tm.charttime, ie.intime, 'SECOND') - RANGE BETWEEN 21600 PRECEDING AND CURRENT ROW - ) AS aki_stage_smoothed -FROM mimiciv_icu.icustays ie --- get all possible charttimes as listed in tm_stg -LEFT JOIN tm_stg tm - ON ie.stay_id = tm.stay_id -LEFT JOIN cr_stg cr - ON ie.stay_id = cr.stay_id - AND tm.charttime = cr.charttime -LEFT JOIN uo_stg uo - ON ie.stay_id = uo.stay_id - AND tm.charttime = uo.charttime -LEFT JOIN crrt_stg crrt - ON ie.stay_id = crrt.stay_id - AND tm.charttime = crrt.charttime -; + ie.subject_id, + ie.hadm_id, + ie.stay_id, + tm.charttime, + cr.creat_low_past_7day, + cr.creat_low_past_48hr, + cr.creat, + cr.aki_stage_creat, + uo.uo_rt_6hr, + uo.uo_rt_12hr, + uo.uo_rt_24hr, + uo.aki_stage_uo, + crrt.aki_stage_crrt, /* Classify AKI using both creatinine/urine output criteria */ + GREATEST( + COALESCE(cr.aki_stage_creat, 0), + COALESCE(uo.aki_stage_uo, 0), + COALESCE(crrt.aki_stage_crrt, 0) + ) AS aki_stage, /* We intend to combine together the scores from creatinine/UO by left */ /* joining from the above temporary table which has all possible charttime. */ /* This will guarantee we include all creatinine/UO measurements. */ /* However, we have times where UO is measured, but not creatinine. */ /* Thus we end up with NULLs for the creatinine column(s). Calculating */ /* the highest stage across the columns will often only consider one stage. */ /* For example, consider the following rows: */ /* stay_id=123, time=10:00, cr_low_7day=4.0, uo_rt_6hr=NULL -> stage 3 */ /* stay_id=123, time=10:30, cr_low_7day=NULL, uo_rt_6hr=0.3 -> stage 1 */ /* This results in the stage alternating from low/high across rows. */ /* To overcome this, we create a new column which carries forward the */ /* highest KDIGO stage from the last 6 hours. In most cases, this smooths */ /* out any discontinuity. */ + MAX( + GREATEST( + COALESCE(cr.aki_stage_creat, 0), + COALESCE(uo.aki_stage_uo, 0), + COALESCE(crrt.aki_stage_crrt, 0) + ) + ) OVER (PARTITION BY ie.subject_id ORDER BY EXTRACT(EPOCH FROM tm.charttime - ie.intime) / 1.0 NULLS FIRST RANGE BETWEEN 21600 PRECEDING AND CURRENT ROW) AS aki_stage_smoothed +FROM mimiciv_icu.icustays AS ie +/* get all possible charttimes as listed in tm_stg */ +LEFT JOIN tm_stg AS tm + ON ie.stay_id = tm.stay_id +LEFT JOIN cr_stg AS cr + ON ie.stay_id = cr.stay_id AND tm.charttime = cr.charttime +LEFT JOIN uo_stg AS uo + ON ie.stay_id = uo.stay_id AND tm.charttime = uo.charttime +LEFT JOIN crrt_stg AS crrt + ON ie.stay_id = crrt.stay_id AND tm.charttime = crrt.charttime \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/organfailure/kdigo_uo.sql b/mimic-iv/concepts_postgres/organfailure/kdigo_uo.sql index e250d74e6..7114fdd8a 100644 --- a/mimic-iv/concepts_postgres/organfailure/kdigo_uo.sql +++ b/mimic-iv/concepts_postgres/organfailure/kdigo_uo.sql @@ -1,112 +1,72 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS kdigo_uo; CREATE TABLE kdigo_uo AS +DROP TABLE IF EXISTS mimiciv_derived.kdigo_uo; CREATE TABLE mimiciv_derived.kdigo_uo AS WITH uo_stg1 AS ( - SELECT ie.stay_id, uo.charttime - , DATETIME_DIFF(charttime, intime, 'SECOND') AS seconds_since_admit - , COALESCE( - DATETIME_DIFF(charttime, LAG(charttime) OVER (PARTITION BY ie.stay_id ORDER BY charttime), 'SECOND') / 3600.0 -- noqa: L016 - , 1 - ) AS hours_since_previous_row - , urineoutput - FROM mimiciv_icu.icustays ie - INNER JOIN mimiciv_derived.urine_output uo - ON ie.stay_id = uo.stay_id + SELECT + ie.stay_id, + uo.charttime, + CAST(EXTRACT(EPOCH FROM charttime - intime) / 1.0 AS INT) AS seconds_since_admit, + COALESCE( + CAST(EXTRACT(EPOCH FROM charttime - LAG(charttime) OVER (PARTITION BY ie.stay_id ORDER BY charttime NULLS FIRST)) / 1.0 AS DOUBLE PRECISION) / 3600.0 /* noqa: L016 */, + 1 + ) AS hours_since_previous_row, + urineoutput + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_derived.urine_output AS uo + ON ie.stay_id = uo.stay_id +), uo_stg2 AS ( + SELECT + stay_id, + charttime, + hours_since_previous_row, + urineoutput, /* Use the RANGE partition to limit the summation to the last X hours. */ /* RANGE operates using numeric, so we convert the charttime into */ /* seconds since admission, and then filter to X seconds prior to the */ /* current row, where X can be 21600 (6 hours), 43200 (12 hours), */ /* or 86400 (24 hours). */ + SUM(urineoutput) OVER (PARTITION BY stay_id ORDER BY seconds_since_admit NULLS FIRST RANGE BETWEEN 21600 PRECEDING AND CURRENT ROW) AS urineoutput_6hr, + SUM(urineoutput) OVER (PARTITION BY stay_id ORDER BY seconds_since_admit NULLS FIRST RANGE BETWEEN 43200 PRECEDING AND CURRENT ROW) AS urineoutput_12hr, + SUM(urineoutput) OVER (PARTITION BY stay_id ORDER BY seconds_since_admit NULLS FIRST RANGE BETWEEN 86400 PRECEDING AND CURRENT ROW) AS urineoutput_24hr, /* repeat the summations using the hours_since_previous_row column */ /* this gives us the amount of time the UO was calculated over */ + SUM(hours_since_previous_row) OVER (PARTITION BY stay_id ORDER BY seconds_since_admit NULLS FIRST RANGE BETWEEN 21600 PRECEDING AND CURRENT ROW) AS uo_tm_6hr, + SUM(hours_since_previous_row) OVER (PARTITION BY stay_id ORDER BY seconds_since_admit NULLS FIRST RANGE BETWEEN 43200 PRECEDING AND CURRENT ROW) AS uo_tm_12hr, + SUM(hours_since_previous_row) OVER (PARTITION BY stay_id ORDER BY seconds_since_admit NULLS FIRST RANGE BETWEEN 86400 PRECEDING AND CURRENT ROW) AS uo_tm_24hr + FROM uo_stg1 ) - -, uo_stg2 AS ( - SELECT stay_id, charttime - , hours_since_previous_row - , urineoutput - -- Use the RANGE partition to limit the summation to the last X hours. - -- RANGE operates using numeric, so we convert the charttime into - -- seconds since admission, and then filter to X seconds prior to the - -- current row, where X can be 21600 (6 hours), 43200 (12 hours), - -- or 86400 (24 hours). - , SUM(urineoutput) OVER - ( - PARTITION BY stay_id - ORDER BY seconds_since_admit - RANGE BETWEEN 21600 PRECEDING AND CURRENT ROW - ) AS urineoutput_6hr - - , SUM(urineoutput) OVER - ( - PARTITION BY stay_id - ORDER BY seconds_since_admit - RANGE BETWEEN 43200 PRECEDING AND CURRENT ROW - ) AS urineoutput_12hr - - , SUM(urineoutput) OVER - ( - PARTITION BY stay_id - ORDER BY seconds_since_admit - RANGE BETWEEN 86400 PRECEDING AND CURRENT ROW - ) AS urineoutput_24hr - - -- repeat the summations using the hours_since_previous_row column - -- this gives us the amount of time the UO was calculated over - , SUM(hours_since_previous_row) OVER - ( - PARTITION BY stay_id - ORDER BY seconds_since_admit - RANGE BETWEEN 21600 PRECEDING AND CURRENT ROW - ) AS uo_tm_6hr - - , SUM(hours_since_previous_row) OVER - ( - PARTITION BY stay_id - ORDER BY seconds_since_admit - RANGE BETWEEN 43200 PRECEDING AND CURRENT ROW - ) AS uo_tm_12hr - - , SUM(hours_since_previous_row) OVER - ( - PARTITION BY stay_id - ORDER BY seconds_since_admit - RANGE BETWEEN 86400 PRECEDING AND CURRENT ROW - ) AS uo_tm_24hr - FROM uo_stg1 -) - SELECT - ur.stay_id - , ur.charttime - , wd.weight - , ur.urineoutput_6hr - , ur.urineoutput_12hr - , ur.urineoutput_24hr - - -- calculate rates while requiring UO documentation over at least N hours - -- as specified in KDIGO guidelines 2012 pg19 - , CASE - WHEN uo_tm_6hr >= 6 AND uo_tm_6hr < 12 - THEN ROUND( - CAST((ur.urineoutput_6hr / wd.weight / uo_tm_6hr) AS NUMERIC), 4 - ) - ELSE NULL END AS uo_rt_6hr - , CASE - WHEN uo_tm_12hr >= 12 - THEN ROUND( - CAST((ur.urineoutput_12hr / wd.weight / uo_tm_12hr) AS NUMERIC) - , 4 - ) - ELSE NULL END AS uo_rt_12hr - , CASE - WHEN uo_tm_24hr >= 24 - THEN ROUND( - CAST((ur.urineoutput_24hr / wd.weight / uo_tm_24hr) AS NUMERIC) - , 4 - ) - ELSE NULL END AS uo_rt_24hr - - -- number of hours between current UO time and earliest charted UO - -- within the X hour window - , uo_tm_6hr - , uo_tm_12hr - , uo_tm_24hr -FROM uo_stg2 ur -LEFT JOIN mimiciv_derived.weight_durations wd - ON ur.stay_id = wd.stay_id - AND ur.charttime >= wd.starttime - AND ur.charttime < wd.endtime -; + ur.stay_id, + ur.charttime, + wd.weight, + ur.urineoutput_6hr, + ur.urineoutput_12hr, + ur.urineoutput_24hr, /* calculate rates while requiring UO documentation over at least N hours */ /* as specified in KDIGO guidelines 2012 pg19 */ + CASE + WHEN uo_tm_6hr >= 6 AND uo_tm_6hr < 12 + THEN ROUND( + CAST(( + CAST(CAST(ur.urineoutput_6hr AS DOUBLE PRECISION) / wd.weight AS DOUBLE PRECISION) / uo_tm_6hr + ) AS DECIMAL), + 4 + ) + ELSE NULL + END AS uo_rt_6hr, + CASE + WHEN uo_tm_12hr >= 12 + THEN ROUND( + CAST(( + CAST(CAST(ur.urineoutput_12hr AS DOUBLE PRECISION) / wd.weight AS DOUBLE PRECISION) / uo_tm_12hr + ) AS DECIMAL), + 4 + ) + ELSE NULL + END AS uo_rt_12hr, + CASE + WHEN uo_tm_24hr >= 24 + THEN ROUND( + CAST(( + CAST(CAST(ur.urineoutput_24hr AS DOUBLE PRECISION) / wd.weight AS DOUBLE PRECISION) / uo_tm_24hr + ) AS DECIMAL), + 4 + ) + ELSE NULL + END AS uo_rt_24hr, /* number of hours between current UO time and earliest charted UO */ /* within the X hour window */ + uo_tm_6hr, + uo_tm_12hr, + uo_tm_24hr +FROM uo_stg2 AS ur +LEFT JOIN mimiciv_derived.weight_durations AS wd + ON ur.stay_id = wd.stay_id AND ur.charttime >= wd.starttime AND ur.charttime < wd.endtime \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/organfailure/meld.sql b/mimic-iv/concepts_postgres/organfailure/meld.sql index a19a4e8db..9d2f51303 100644 --- a/mimic-iv/concepts_postgres/organfailure/meld.sql +++ b/mimic-iv/concepts_postgres/organfailure/meld.sql @@ -1,187 +1,105 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS meld; CREATE TABLE meld AS --- Model for end-stage liver disease (MELD) --- This model is used to determine prognosis and receipt of --- liver transplantation. - --- Reference: --- Kamath PS, Wiesner RH, Malinchoc M, Kremers W, Therneau TM, --- Kosberg CL, D'Amico G, Dickson ER, Kim WR. --- A model to predict survival in patients with end-stage liver disease. --- Hepatology. 2001 Feb;33(2):464-70. - - --- Updated January 2016 to include serum sodium, see: --- https://optn.transplant.hrsa.gov/news/meld-serum-sodium-policy-changes/ - --- Here is the relevant portion of the policy note: --- 9.1.D MELD Score --- Candidates who are at least 12 years old receive an initial MELD(i) score --- equal to: --- 0.957 x ln(creatinine mg/dL) --- + 0.378 x ln(bilirubin mg/dL) --- + 1.120 x ln(INR) --- + 0.643 - --- Laboratory values less than 1.0 will be set to 1.0 when calculating a --- candidate’s MELD score. - --- The following candidates will receive a creatinine value of 4.0 mg/dL: --- - Candidates with a creatinine value greater than 4.0 mg/dL --- - Candidates who received two or more dialysis treatments within --- the prior week --- - Candidates who received 24 hours of continuous veno-venous hemodialysis --- (CVVHD) within the prior week - --- The maximum MELD score is 40. The MELD score derived from this calculation --- will be rounded to the tenth decimal place and then multiplied by 10. - --- For candidates with an initial MELD score greater than 11, The MELD score --- is then recalculated as follows: --- MELD = MELD(i) + 1.32*(137-Na) – [0.033*MELD(i)*(137-Na)] --- Sodium values less than 125 mmol/L will be set to 125, and values greater --- than 137 mmol/L will be set to 137. - - - --- TODO needed in this code: --- 1. identify 2x dialysis in the past week, or 24 hours of CVVH --- at the moment it just checks for any dialysis on the first day --- 2. identify cholestatic or alcoholic liver disease --- 0.957 x ln(creatinine mg/dL) --- + 0.378 x ln(bilirubin mg/dL) --- + 1.120 x ln(INR) --- + 0.643 x etiology --- (0 if cholestatic or alcoholic, 1 otherwise) --- 3. adjust the serum sodium using the corresponding glucose measurement --- Measured sodium + 0.024 * (Serum glucose - 100) (Hiller, 1999) +DROP TABLE IF EXISTS mimiciv_derived.meld; CREATE TABLE mimiciv_derived.meld AS +/* Model for end-stage liver disease (MELD) */ /* This model is used to determine prognosis and receipt of */ /* liver transplantation. */ /* Reference: */ /* Kamath PS, Wiesner RH, Malinchoc M, Kremers W, Therneau TM, */ /* Kosberg CL, D'Amico G, Dickson ER, Kim WR. */ /* A model to predict survival in patients with end-stage liver disease. */ /* Hepatology. 2001 Feb;33(2):464-70. */ /* Updated January 2016 to include serum sodium, see: */ /* https://optn.transplant.hrsa.gov/news/meld-serum-sodium-policy-changes/ */ /* Here is the relevant portion of the policy note: */ /* 9.1.D MELD Score */ /* Candidates who are at least 12 years old receive an initial MELD(i) score */ /* equal to: */ /* 0.957 x ln(creatinine mg/dL) */ /* + 0.378 x ln(bilirubin mg/dL) */ /* + 1.120 x ln(INR) */ /* + 0.643 */ /* Laboratory values less than 1.0 will be set to 1.0 when calculating a */ /* candidate’s MELD score. */ /* The following candidates will receive a creatinine value of 4.0 mg/dL: */ /* - Candidates with a creatinine value greater than 4.0 mg/dL */ /* - Candidates who received two or more dialysis treatments within */ /* the prior week */ /* - Candidates who received 24 hours of continuous veno-venous hemodialysis */ /* (CVVHD) within the prior week */ /* The maximum MELD score is 40. The MELD score derived from this calculation */ /* will be rounded to the tenth decimal place and then multiplied by 10. */ /* For candidates with an initial MELD score greater than 11, The MELD score */ /* is then recalculated as follows: */ /* MELD = MELD(i) + 1.32*(137-Na) – [0.033*MELD(i)*(137-Na)] */ /* Sodium values less than 125 mmol/L will be set to 125, and values greater */ /* than 137 mmol/L will be set to 137. */ /* TODO needed in this code: */ /* 1. identify 2x dialysis in the past week, or 24 hours of CVVH */ /* at the moment it just checks for any dialysis on the first day */ /* 2. identify cholestatic or alcoholic liver disease */ /* 0.957 x ln(creatinine mg/dL) */ /* + 0.378 x ln(bilirubin mg/dL) */ /* + 1.120 x ln(INR) */ /* + 0.643 x etiology */ /* (0 if cholestatic or alcoholic, 1 otherwise) */ /* 3. adjust the serum sodium using the corresponding glucose measurement */ /* Measured sodium + 0.024 * (Serum glucose - 100) (Hiller, 1999) */ WITH cohort AS ( - SELECT - ie.subject_id - , ie.hadm_id - , ie.stay_id - , ie.intime - , ie.outtime - - , labs.creatinine_max - , labs.bilirubin_total_max - , labs.inr_max - , labs.sodium_min - - , r.dialysis_present AS rrt - - FROM mimiciv_icu.icustays ie - -- join to custom tables to get more data.... - LEFT JOIN mimiciv_derived.first_day_lab labs - ON ie.stay_id = labs.stay_id - LEFT JOIN mimiciv_derived.first_day_rrt r - ON ie.stay_id = r.stay_id + SELECT + ie.subject_id, + ie.hadm_id, + ie.stay_id, + ie.intime, + ie.outtime, + labs.creatinine_max, + labs.bilirubin_total_max, + labs.inr_max, + labs.sodium_min, + r.dialysis_present AS rrt + FROM mimiciv_icu.icustays AS ie + /* join to custom tables to get more data.... */ + LEFT JOIN mimiciv_derived.first_day_lab AS labs + ON ie.stay_id = labs.stay_id + LEFT JOIN mimiciv_derived.first_day_rrt AS r + ON ie.stay_id = r.stay_id +), score AS ( + SELECT + subject_id, + hadm_id, + stay_id, + rrt, + creatinine_max, + bilirubin_total_max, + inr_max, + sodium_min, /* TODO: Corrected Sodium */ + CASE + WHEN sodium_min IS NULL + THEN 0.0 + WHEN sodium_min > 137 + THEN 0.0 + WHEN sodium_min < 125 + THEN 12.0 /* 137 - 125 = 12 */ + ELSE 137.0 - sodium_min + END AS sodium_score, /* if hemodialysis, value for Creatinine is automatically set to 4.0 */ + CASE + WHEN rrt = 1 OR creatinine_max > 4.0 + THEN ( + 0.957 * LN(4) + ) + WHEN creatinine_max < 1 + THEN ( + 0.957 * LN(1) + ) + ELSE 0.957 * COALESCE(LN(creatinine_max), LN(1)) + END AS creatinine_score, + CASE + WHEN bilirubin_total_max < 1 + THEN 0.378 * LN(1) + ELSE 0.378 * COALESCE(LN(bilirubin_total_max), LN(1)) + END AS bilirubin_score, + CASE + WHEN inr_max < 1 + THEN ( + 1.120 * LN(1) + 0.643 + ) + ELSE ( + 1.120 * COALESCE(LN(inr_max), LN(1)) + 0.643 + ) + END AS inr_score + FROM cohort +), score2 AS ( + SELECT + subject_id, + hadm_id, + stay_id, + rrt, + creatinine_max, + bilirubin_total_max, + inr_max, + sodium_min, + creatinine_score, + sodium_score, + bilirubin_score, + inr_score, + CASE + WHEN ( + creatinine_score + bilirubin_score + inr_score + ) > 4 + THEN 40.0 + ELSE ROUND(CAST(creatinine_score + bilirubin_score + inr_score AS DECIMAL), 1) * 10 + END AS meld_initial + FROM score ) - -, score AS ( - SELECT - subject_id - , hadm_id - , stay_id - , rrt - , creatinine_max - , bilirubin_total_max - , inr_max - , sodium_min - - -- TODO: Corrected Sodium - , CASE - WHEN sodium_min IS NULL - THEN 0.0 - WHEN sodium_min > 137 - THEN 0.0 - WHEN sodium_min < 125 - THEN 12.0 -- 137 - 125 = 12 - ELSE 137.0 - sodium_min - END AS sodium_score - - -- if hemodialysis, value for Creatinine is automatically set to 4.0 - , CASE - WHEN rrt = 1 OR creatinine_max > 4.0 - THEN (0.957 * LN(4)) - -- if creatinine < 1, score is 1 - WHEN creatinine_max < 1 - THEN (0.957 * LN(1)) - ELSE 0.957 * COALESCE(LN(creatinine_max), LN(1)) - END AS creatinine_score - - , CASE - -- if value < 1, score is 1 - WHEN bilirubin_total_max < 1 - THEN 0.378 * LN(1) - ELSE 0.378 * COALESCE(LN(bilirubin_total_max), LN(1)) - END AS bilirubin_score - - , CASE - WHEN inr_max < 1 - THEN (1.120 * LN(1) + 0.643) - ELSE (1.120 * COALESCE(LN(inr_max), LN(1)) + 0.643) - END AS inr_score - - FROM cohort -) - -, score2 AS ( - SELECT - subject_id - , hadm_id - , stay_id - , rrt - , creatinine_max - , bilirubin_total_max - , inr_max - , sodium_min - - , creatinine_score - , sodium_score - , bilirubin_score - , inr_score - - , CASE - WHEN (creatinine_score + bilirubin_score + inr_score) > 4 - THEN 40.0 - ELSE - ROUND( - CAST( - creatinine_score - + bilirubin_score - + inr_score - AS NUMERIC) - , 1 - ) * 10 - END AS meld_initial - FROM score -) - SELECT - subject_id - , hadm_id - , stay_id - - -- MELD Score without sodium change - , meld_initial - - -- MELD Score (2016) = MELD*10 + 1.32*(137-Na) – [0.033*MELD*10*(137-Na)] - , CASE - WHEN meld_initial > 11 - THEN - meld_initial + 1.32 * sodium_score - - 0.033 * meld_initial * sodium_score - ELSE - meld_initial - END AS meld - - -- original variables - , rrt - , creatinine_max - , bilirubin_total_max - , inr_max - , sodium_min - -FROM score2 -; + subject_id, + hadm_id, + stay_id, /* MELD Score without sodium change */ + meld_initial, /* MELD Score (2016) = MELD*10 + 1.32*(137-Na) – [0.033*MELD*10*(137-Na)] */ + CASE + WHEN meld_initial > 11 + THEN meld_initial + 1.32 * sodium_score - 0.033 * meld_initial * sodium_score + ELSE meld_initial + END AS meld, /* original variables */ + rrt, + creatinine_max, + bilirubin_total_max, + inr_max, + sodium_min +FROM score2 \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/postgres-make-concepts.sql b/mimic-iv/concepts_postgres/postgres-make-concepts.sql index 9c8b99fed..3bbed1e3f 100644 --- a/mimic-iv/concepts_postgres/postgres-make-concepts.sql +++ b/mimic-iv/concepts_postgres/postgres-make-concepts.sql @@ -47,6 +47,7 @@ SET search_path TO mimiciv_derived, mimiciv_hosp, mimiciv_icu, mimiciv_ed; \i comorbidity/charlson.sql -- medication +\i medication/acei.sql \i medication/antibiotic.sql \i medication/dobutamine.sql \i medication/dopamine.sql @@ -54,6 +55,7 @@ SET search_path TO mimiciv_derived, mimiciv_hosp, mimiciv_icu, mimiciv_ed; \i medication/milrinone.sql \i medication/neuroblock.sql \i medication/norepinephrine.sql +\i medication/nsaid.sql \i medication/phenylephrine.sql \i medication/vasopressin.sql diff --git a/mimic-iv/concepts_postgres/score/apsiii.sql b/mimic-iv/concepts_postgres/score/apsiii.sql index daf62ca08..484121034 100644 --- a/mimic-iv/concepts_postgres/score/apsiii.sql +++ b/mimic-iv/concepts_postgres/score/apsiii.sql @@ -1,896 +1,871 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS apsiii; CREATE TABLE apsiii AS --- ------------------------------------------------------------------ --- Title: Acute Physiology Score III (APS III) --- This query extracts the acute physiology score III. --- This score is a measure of patient severity of illness. --- The score is calculated on the first day of each ICU patients' stay. --- ------------------------------------------------------------------ - --- Reference for APS III: --- Knaus WA, Wagner DP, Draper EA, Zimmerman JE, Bergner M, --- Bastos PG, Sirio CA, Murphy DJ, Lotring T, Damiano A. --- The APACHE III prognostic system. Risk prediction of hospital --- mortality for critically ill hospitalized adults. Chest Journal. --- 1991 Dec 1;100(6):1619-36. - --- Reference for the equation for calibrating APS III: --- Johnson, A. E. W. (2015). Mortality prediction and acuity assessment --- in critical care. University of Oxford, Oxford, UK. - --- Variables used in APS III: --- GCS --- VITALS: Heart rate, mean blood pressure, temperature, respiration rate --- FLAGS: ventilation/cpap, chronic dialysis --- IO: urine output --- LABS: pao2, A-aDO2, hematocrit, WBC, creatinine --- , blood urea nitrogen, sodium, albumin, bilirubin, glucose, pH, pCO2 - --- Note: --- The score is calculated for *all* ICU patients, with the assumption that --- the user will subselect appropriate stay_ids. - --- List of TODO: --- The site of temperature is not incorporated. Axillary measurements --- should be increased by 1 degree. - +DROP TABLE IF EXISTS mimiciv_derived.apsiii; CREATE TABLE mimiciv_derived.apsiii AS +/* ------------------------------------------------------------------ */ /* Title: Acute Physiology Score III (APS III) */ /* This query extracts the acute physiology score III. */ /* This score is a measure of patient severity of illness. */ /* The score is calculated on the first day of each ICU patients' stay. */ /* ------------------------------------------------------------------ */ /* Reference for APS III: */ /* Knaus WA, Wagner DP, Draper EA, Zimmerman JE, Bergner M, */ /* Bastos PG, Sirio CA, Murphy DJ, Lotring T, Damiano A. */ /* The APACHE III prognostic system. Risk prediction of hospital */ /* mortality for critically ill hospitalized adults. Chest Journal. */ /* 1991 Dec 1;100(6):1619-36. */ /* Reference for the equation for calibrating APS III: */ /* Johnson, A. E. W. (2015). Mortality prediction and acuity assessment */ /* in critical care. University of Oxford, Oxford, UK. */ /* Variables used in APS III: */ /* GCS */ /* VITALS: Heart rate, mean blood pressure, temperature, respiration rate */ /* FLAGS: ventilation/cpap, chronic dialysis */ /* IO: urine output */ /* LABS: pao2, A-aDO2, hematocrit, WBC, creatinine */ /* , blood urea nitrogen, sodium, albumin, bilirubin, glucose, pH, pCO2 */ /* Note: */ /* The score is calculated for *all* ICU patients, with the assumption that */ /* the user will subselect appropriate stay_ids. */ /* List of TODO: */ /* The site of temperature is not incorporated. Axillary measurements */ /* should be increased by 1 degree. */ WITH pa AS ( - SELECT ie.stay_id, bg.charttime - , po2 AS pao2 - , ROW_NUMBER() OVER (PARTITION BY ie.stay_id ORDER BY bg.po2 DESC) AS rn - FROM mimiciv_derived.bg bg - INNER JOIN mimiciv_icu.icustays ie - ON bg.hadm_id = ie.hadm_id - AND bg.charttime >= ie.intime AND bg.charttime < ie.outtime - LEFT JOIN mimiciv_derived.ventilation vd - ON ie.stay_id = vd.stay_id - AND bg.charttime >= vd.starttime - AND bg.charttime <= vd.endtime - AND vd.ventilation_status = 'InvasiveVent' - WHERE vd.stay_id IS NULL -- patient is *not* ventilated - -- and fio2 < 50, or if no fio2, assume room air - AND COALESCE(fio2, fio2_chartevents, 21) < 50 - AND bg.po2 IS NOT NULL - AND bg.specimen = 'ART.' + SELECT + ie.stay_id, + bg.charttime, + po2 AS pao2, + ROW_NUMBER() OVER (PARTITION BY ie.stay_id ORDER BY bg.po2 DESC NULLS LAST) AS rn + FROM mimiciv_derived.bg AS bg + INNER JOIN mimiciv_icu.icustays AS ie + ON bg.hadm_id = ie.hadm_id AND bg.charttime >= ie.intime AND bg.charttime < ie.outtime + LEFT JOIN mimiciv_derived.ventilation AS vd + ON ie.stay_id = vd.stay_id + AND bg.charttime >= vd.starttime + AND bg.charttime <= vd.endtime + AND vd.ventilation_status = 'InvasiveVent' + WHERE + vd.stay_id IS NULL /* patient is *not* ventilated */ + AND COALESCE(fio2, fio2_chartevents, 21) < 50 + AND NOT bg.po2 IS NULL + AND bg.specimen = 'ART.' +), aa AS ( + /* join blood gas to ventilation durations to determine if patient was vent */ /* also join to cpap table for the same purpose */ + SELECT + ie.stay_id, + bg.charttime, + bg.aado2, + ROW_NUMBER() OVER (PARTITION BY ie.stay_id ORDER BY bg.aado2 DESC NULLS LAST) AS rn + /* row number indicating the highest AaDO2 */ + FROM mimiciv_derived.bg AS bg + INNER JOIN mimiciv_icu.icustays AS ie + ON bg.hadm_id = ie.hadm_id AND bg.charttime >= ie.intime AND bg.charttime < ie.outtime + INNER JOIN mimiciv_derived.ventilation AS vd + ON ie.stay_id = vd.stay_id + AND bg.charttime >= vd.starttime + AND bg.charttime <= vd.endtime + AND vd.ventilation_status = 'InvasiveVent' + WHERE + NOT vd.stay_id IS NULL /* patient is ventilated */ + AND COALESCE(fio2, fio2_chartevents) >= 50 + AND NOT bg.aado2 IS NULL + AND bg.specimen = 'ART.' +), acidbase AS ( + SELECT + ie.stay_id, + ph, + pco2 AS paco2, + CASE + WHEN ph IS NULL OR pco2 IS NULL + THEN NULL + WHEN ph < 7.20 + THEN CASE WHEN pco2 < 50 THEN 12 ELSE 4 END + WHEN ph < 7.30 + THEN CASE WHEN pco2 < 30 THEN 9 WHEN pco2 < 40 THEN 6 WHEN pco2 < 50 THEN 3 ELSE 2 END + WHEN ph < 7.35 + THEN CASE WHEN pco2 < 30 THEN 9 WHEN pco2 < 45 THEN 0 ELSE 1 END + WHEN ph < 7.45 + THEN CASE WHEN pco2 < 30 THEN 5 WHEN pco2 < 45 THEN 0 ELSE 1 END + WHEN ph < 7.50 + THEN CASE WHEN pco2 < 30 THEN 5 WHEN pco2 < 35 THEN 0 WHEN pco2 < 45 THEN 2 ELSE 12 END + WHEN ph < 7.60 + THEN CASE WHEN pco2 < 40 THEN 3 ELSE 12 END + ELSE CASE WHEN pco2 < 25 THEN 0 WHEN pco2 < 40 THEN 3 ELSE 12 END + END AS acidbase_score + FROM mimiciv_derived.bg AS bg + INNER JOIN mimiciv_icu.icustays AS ie + ON bg.hadm_id = ie.hadm_id AND bg.charttime >= ie.intime AND bg.charttime < ie.outtime + WHERE + NOT ph IS NULL AND NOT pco2 IS NULL AND bg.specimen = 'ART.' +), acidbase_max AS ( + SELECT + stay_id, + acidbase_score, + ph, + paco2, /* create integer which indexes maximum value of score with 1 */ + ROW_NUMBER() OVER (PARTITION BY stay_id ORDER BY acidbase_score DESC NULLS LAST) AS acidbase_rn + FROM acidbase +), arf AS ( + SELECT + ie.stay_id, + CASE + WHEN labs.creatinine_max >= 1.5 AND uo.urineoutput < 410 AND icd.ckd = 0 + THEN 1 + ELSE 0 + END AS arf + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.first_day_urine_output AS uo + ON ie.stay_id = uo.stay_id + LEFT JOIN mimiciv_derived.first_day_lab AS labs + ON ie.stay_id = labs.stay_id + LEFT JOIN ( + SELECT + hadm_id, + MAX( + CASE + WHEN icd_version = 9 AND SUBSTR(icd_code, 1, 4) IN ('5854', '5855', '5856') + THEN 1 + WHEN icd_version = 10 AND SUBSTR(icd_code, 1, 4) IN ('N184', 'N185', 'N186') + THEN 1 + ELSE 0 + END + ) AS ckd + FROM mimiciv_hosp.diagnoses_icd + GROUP BY + hadm_id + ) AS icd + ON ie.hadm_id = icd.hadm_id +), vent AS ( + SELECT + ie.stay_id, + MAX(CASE WHEN NOT v.stay_id IS NULL THEN 1 ELSE 0 END) AS vent + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.ventilation AS v + ON ie.stay_id = v.stay_id + AND v.ventilation_status = 'InvasiveVent' + AND ( + ( + v.starttime >= ie.intime AND v.starttime <= ie.intime + INTERVAL '1 DAY' + ) + OR ( + v.endtime >= ie.intime AND v.endtime <= ie.intime + INTERVAL '1 DAY' + ) + OR ( + v.starttime <= ie.intime AND v.endtime >= ie.intime + INTERVAL '1 DAY' + ) + ) + GROUP BY + ie.stay_id +), cohort AS ( + SELECT + ie.subject_id, + ie.hadm_id, + ie.stay_id, + ie.intime, + ie.outtime, + vital.heart_rate_min, + vital.heart_rate_max, + vital.mbp_min, + vital.mbp_max, + vital.temperature_min, + vital.temperature_max, + vital.resp_rate_min, + vital.resp_rate_max, + pa.pao2, + aa.aado2, + ab.ph, + ab.paco2, + ab.acidbase_score, + labs.hematocrit_min, + labs.hematocrit_max, + labs.wbc_min, + labs.wbc_max, + labs.creatinine_min, + labs.creatinine_max, + labs.bun_min, + labs.bun_max, + labs.sodium_min, + labs.sodium_max, + labs.albumin_min, + labs.albumin_max, + labs.bilirubin_total_min AS bilirubin_min, + labs.bilirubin_total_max AS bilirubin_max, + CASE + WHEN labs.glucose_max IS NULL AND vital.glucose_max IS NULL + THEN NULL + WHEN labs.glucose_max IS NULL OR vital.glucose_max > labs.glucose_max + THEN vital.glucose_max + WHEN vital.glucose_max IS NULL OR labs.glucose_max > vital.glucose_max + THEN labs.glucose_max + ELSE labs.glucose_max /* if equal, just pick labs */ + END AS glucose_max, + CASE + WHEN labs.glucose_min IS NULL AND vital.glucose_min IS NULL + THEN NULL + WHEN labs.glucose_min IS NULL OR vital.glucose_min < labs.glucose_min + THEN vital.glucose_min + WHEN vital.glucose_min IS NULL OR labs.glucose_min < vital.glucose_min + THEN labs.glucose_min + ELSE labs.glucose_min /* if equal, just pick labs */ + END AS glucose_min, /* , labs.bicarbonate_min */ /* , labs.bicarbonate_max */ + vent.vent, + uo.urineoutput, /* gcs and its components */ + gcs.gcs_min AS mingcs, + gcs.gcs_motor, + gcs.gcs_verbal, + gcs.gcs_eyes, + gcs.gcs_unable, /* acute renal failure */ + arf.arf AS arf + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_hosp.admissions AS adm + ON ie.hadm_id = adm.hadm_id + INNER JOIN mimiciv_hosp.patients AS pat + ON ie.subject_id = pat.subject_id + /* join to above views - the row number filters to 1 row per stay_id */ + LEFT JOIN pa + ON ie.stay_id = pa.stay_id AND pa.rn = 1 + LEFT JOIN aa + ON ie.stay_id = aa.stay_id AND aa.rn = 1 + LEFT JOIN acidbase_max AS ab + ON ie.stay_id = ab.stay_id AND ab.acidbase_rn = 1 + LEFT JOIN arf + ON ie.stay_id = arf.stay_id + /* join to custom tables to get more data.... */ + LEFT JOIN vent + ON ie.stay_id = vent.stay_id + LEFT JOIN mimiciv_derived.first_day_gcs AS gcs + ON ie.stay_id = gcs.stay_id + LEFT JOIN mimiciv_derived.first_day_vitalsign AS vital + ON ie.stay_id = vital.stay_id + LEFT JOIN mimiciv_derived.first_day_urine_output AS uo + ON ie.stay_id = uo.stay_id + LEFT JOIN mimiciv_derived.first_day_lab AS labs + ON ie.stay_id = labs.stay_id +), score_min AS ( + SELECT + cohort.subject_id, + cohort.hadm_id, + cohort.stay_id, + CASE + WHEN heart_rate_min IS NULL + THEN NULL + WHEN heart_rate_min < 40 + THEN 8 + WHEN heart_rate_min < 50 + THEN 5 + WHEN heart_rate_min < 100 + THEN 0 + WHEN heart_rate_min < 110 + THEN 1 + WHEN heart_rate_min < 120 + THEN 5 + WHEN heart_rate_min < 140 + THEN 7 + WHEN heart_rate_min < 155 + THEN 13 + WHEN heart_rate_min >= 155 + THEN 17 + END AS hr_score, + CASE + WHEN mbp_min IS NULL + THEN NULL + WHEN mbp_min < 40 + THEN 23 + WHEN mbp_min < 60 + THEN 15 + WHEN mbp_min < 70 + THEN 7 + WHEN mbp_min < 80 + THEN 6 + WHEN mbp_min < 100 + THEN 0 + WHEN mbp_min < 120 + THEN 4 + WHEN mbp_min < 130 + THEN 7 + WHEN mbp_min < 140 + THEN 9 + WHEN mbp_min >= 140 + THEN 10 + END AS mbp_score, /* TODO: add 1 degree to axillary measurements */ + CASE + WHEN temperature_min IS NULL + THEN NULL + WHEN temperature_min < 33.0 + THEN 20 + WHEN temperature_min < 33.5 + THEN 16 + WHEN temperature_min < 34.0 + THEN 13 + WHEN temperature_min < 35.0 + THEN 8 + WHEN temperature_min < 36.0 + THEN 2 + WHEN temperature_min < 40.0 + THEN 0 + WHEN temperature_min >= 40.0 + THEN 4 + END AS temp_score, + CASE + WHEN resp_rate_min IS NULL + THEN NULL + WHEN vent = 1 AND resp_rate_min < 14 + THEN 0 + WHEN resp_rate_min < 6 + THEN 17 + WHEN resp_rate_min < 12 + THEN 8 + WHEN resp_rate_min < 14 + THEN 7 + WHEN resp_rate_min < 25 + THEN 0 + WHEN resp_rate_min < 35 + THEN 6 + WHEN resp_rate_min < 40 + THEN 9 + WHEN resp_rate_min < 50 + THEN 11 + WHEN resp_rate_min >= 50 + THEN 18 + END AS resp_rate_score, + CASE + WHEN hematocrit_min IS NULL + THEN NULL + WHEN hematocrit_min < 41.0 + THEN 3 + WHEN hematocrit_min < 50.0 + THEN 0 + WHEN hematocrit_min >= 50.0 + THEN 3 + END AS hematocrit_score, + CASE + WHEN wbc_min IS NULL + THEN NULL + WHEN wbc_min < 1.0 + THEN 19 + WHEN wbc_min < 3.0 + THEN 5 + WHEN wbc_min < 20.0 + THEN 0 + WHEN wbc_min < 25.0 + THEN 1 + WHEN wbc_min >= 25.0 + THEN 5 + END AS wbc_score, + CASE + WHEN creatinine_min IS NULL + THEN NULL + WHEN arf = 1 AND creatinine_min < 1.5 + THEN 0 + WHEN arf = 1 AND creatinine_min >= 1.5 + THEN 10 + WHEN creatinine_min < 0.5 + THEN 3 + WHEN creatinine_min < 1.5 + THEN 0 + WHEN creatinine_min < 1.95 + THEN 4 + WHEN creatinine_min >= 1.95 + THEN 7 + END AS creatinine_score, + CASE + WHEN bun_min IS NULL + THEN NULL + WHEN bun_min < 17.0 + THEN 0 + WHEN bun_min < 20.0 + THEN 2 + WHEN bun_min < 40.0 + THEN 7 + WHEN bun_min < 80.0 + THEN 11 + WHEN bun_min >= 80.0 + THEN 12 + END AS bun_score, + CASE + WHEN sodium_min IS NULL + THEN NULL + WHEN sodium_min < 120 + THEN 3 + WHEN sodium_min < 135 + THEN 2 + WHEN sodium_min < 155 + THEN 0 + WHEN sodium_min >= 155 + THEN 4 + END AS sodium_score, + CASE + WHEN albumin_min IS NULL + THEN NULL + WHEN albumin_min < 2.0 + THEN 11 + WHEN albumin_min < 2.5 + THEN 6 + WHEN albumin_min < 4.5 + THEN 0 + WHEN albumin_min >= 4.5 + THEN 4 + END AS albumin_score, + CASE + WHEN bilirubin_min IS NULL + THEN NULL + WHEN bilirubin_min < 2.0 + THEN 0 + WHEN bilirubin_min < 3.0 + THEN 5 + WHEN bilirubin_min < 5.0 + THEN 6 + WHEN bilirubin_min < 8.0 + THEN 8 + WHEN bilirubin_min >= 8.0 + THEN 16 + END AS bilirubin_score, + CASE + WHEN glucose_min IS NULL + THEN NULL + WHEN glucose_min < 40 + THEN 8 + WHEN glucose_min < 60 + THEN 9 + WHEN glucose_min < 200 + THEN 0 + WHEN glucose_min < 350 + THEN 3 + WHEN glucose_min >= 350 + THEN 5 + END AS glucose_score + FROM cohort +), score_max AS ( + SELECT + cohort.subject_id, + cohort.hadm_id, + cohort.stay_id, + CASE + WHEN heart_rate_max IS NULL + THEN NULL + WHEN heart_rate_max < 40 + THEN 8 + WHEN heart_rate_max < 50 + THEN 5 + WHEN heart_rate_max < 100 + THEN 0 + WHEN heart_rate_max < 110 + THEN 1 + WHEN heart_rate_max < 120 + THEN 5 + WHEN heart_rate_max < 140 + THEN 7 + WHEN heart_rate_max < 155 + THEN 13 + WHEN heart_rate_max >= 155 + THEN 17 + END AS hr_score, + CASE + WHEN mbp_max IS NULL + THEN NULL + WHEN mbp_max < 40 + THEN 23 + WHEN mbp_max < 60 + THEN 15 + WHEN mbp_max < 70 + THEN 7 + WHEN mbp_max < 80 + THEN 6 + WHEN mbp_max < 100 + THEN 0 + WHEN mbp_max < 120 + THEN 4 + WHEN mbp_max < 130 + THEN 7 + WHEN mbp_max < 140 + THEN 9 + WHEN mbp_max >= 140 + THEN 10 + END AS mbp_score, /* TODO: add 1 degree to axillary measurements */ + CASE + WHEN temperature_max IS NULL + THEN NULL + WHEN temperature_max < 33.0 + THEN 20 + WHEN temperature_max < 33.5 + THEN 16 + WHEN temperature_max < 34.0 + THEN 13 + WHEN temperature_max < 35.0 + THEN 8 + WHEN temperature_max < 36.0 + THEN 2 + WHEN temperature_max < 40.0 + THEN 0 + WHEN temperature_max >= 40.0 + THEN 4 + END AS temp_score, + CASE + WHEN resp_rate_max IS NULL + THEN NULL + WHEN vent = 1 AND resp_rate_max < 14 + THEN 0 + WHEN resp_rate_max < 6 + THEN 17 + WHEN resp_rate_max < 12 + THEN 8 + WHEN resp_rate_max < 14 + THEN 7 + WHEN resp_rate_max < 25 + THEN 0 + WHEN resp_rate_max < 35 + THEN 6 + WHEN resp_rate_max < 40 + THEN 9 + WHEN resp_rate_max < 50 + THEN 11 + WHEN resp_rate_max >= 50 + THEN 18 + END AS resp_rate_score, + CASE + WHEN hematocrit_max IS NULL + THEN NULL + WHEN hematocrit_max < 41.0 + THEN 3 + WHEN hematocrit_max < 50.0 + THEN 0 + WHEN hematocrit_max >= 50.0 + THEN 3 + END AS hematocrit_score, + CASE + WHEN wbc_max IS NULL + THEN NULL + WHEN wbc_max < 1.0 + THEN 19 + WHEN wbc_max < 3.0 + THEN 5 + WHEN wbc_max < 20.0 + THEN 0 + WHEN wbc_max < 25.0 + THEN 1 + WHEN wbc_max >= 25.0 + THEN 5 + END AS wbc_score, + CASE + WHEN creatinine_max IS NULL + THEN NULL + WHEN arf = 1 AND creatinine_max < 1.5 + THEN 0 + WHEN arf = 1 AND creatinine_max >= 1.5 + THEN 10 + WHEN creatinine_max < 0.5 + THEN 3 + WHEN creatinine_max < 1.5 + THEN 0 + WHEN creatinine_max < 1.95 + THEN 4 + WHEN creatinine_max >= 1.95 + THEN 7 + END AS creatinine_score, + CASE + WHEN bun_max IS NULL + THEN NULL + WHEN bun_max < 17.0 + THEN 0 + WHEN bun_max < 20.0 + THEN 2 + WHEN bun_max < 40.0 + THEN 7 + WHEN bun_max < 80.0 + THEN 11 + WHEN bun_max >= 80.0 + THEN 12 + END AS bun_score, + CASE + WHEN sodium_max IS NULL + THEN NULL + WHEN sodium_max < 120 + THEN 3 + WHEN sodium_max < 135 + THEN 2 + WHEN sodium_max < 155 + THEN 0 + WHEN sodium_max >= 155 + THEN 4 + END AS sodium_score, + CASE + WHEN albumin_max IS NULL + THEN NULL + WHEN albumin_max < 2.0 + THEN 11 + WHEN albumin_max < 2.5 + THEN 6 + WHEN albumin_max < 4.5 + THEN 0 + WHEN albumin_max >= 4.5 + THEN 4 + END AS albumin_score, + CASE + WHEN bilirubin_max IS NULL + THEN NULL + WHEN bilirubin_max < 2.0 + THEN 0 + WHEN bilirubin_max < 3.0 + THEN 5 + WHEN bilirubin_max < 5.0 + THEN 6 + WHEN bilirubin_max < 8.0 + THEN 8 + WHEN bilirubin_max >= 8.0 + THEN 16 + END AS bilirubin_score, + CASE + WHEN glucose_max IS NULL + THEN NULL + WHEN glucose_max < 40 + THEN 8 + WHEN glucose_max < 60 + THEN 9 + WHEN glucose_max < 200 + THEN 0 + WHEN glucose_max < 350 + THEN 3 + WHEN glucose_max >= 350 + THEN 5 + END AS glucose_score + FROM cohort +), scorecomp AS ( + SELECT + co.*, /* The rules for APS III require the definition of a "worst" value */ /* This value is defined as whatever value is furthest from a */ /* predefined normal e.g., for heart rate, worst is defined */ /* as furthest from 75 */ + CASE + WHEN heart_rate_max IS NULL + THEN NULL + WHEN ABS(heart_rate_max - 75) > ABS(heart_rate_min - 75) + THEN smax.hr_score + WHEN ABS(heart_rate_max - 75) < ABS(heart_rate_min - 75) + THEN smin.hr_score + WHEN ABS(heart_rate_max - 75) = ABS(heart_rate_min - 75) + AND smax.hr_score >= smin.hr_score + THEN smax.hr_score + WHEN ABS(heart_rate_max - 75) = ABS(heart_rate_min - 75) AND smax.hr_score < smin.hr_score + THEN smin.hr_score + END AS hr_score, + CASE + WHEN mbp_max IS NULL + THEN NULL + WHEN ABS(mbp_max - 90) > ABS(mbp_min - 90) + THEN smax.mbp_score + WHEN ABS(mbp_max - 90) < ABS(mbp_min - 90) + THEN smin.mbp_score + WHEN ABS(mbp_max - 90) = ABS(mbp_min - 90) AND smax.mbp_score >= smin.mbp_score + THEN smax.mbp_score + WHEN ABS(mbp_max - 90) = ABS(mbp_min - 90) AND smax.mbp_score < smin.mbp_score + THEN smin.mbp_score + END AS mbp_score, + CASE + WHEN temperature_max IS NULL + THEN NULL + WHEN ABS(temperature_max - 38) > ABS(temperature_min - 38) + THEN smax.temp_score + WHEN ABS(temperature_max - 38) < ABS(temperature_min - 38) + THEN smin.temp_score + WHEN ABS(temperature_max - 38) = ABS(temperature_min - 38) + AND smax.temp_score >= smin.temp_score + THEN smax.temp_score + WHEN ABS(temperature_max - 38) = ABS(temperature_min - 38) + AND smax.temp_score < smin.temp_score + THEN smin.temp_score + END AS temp_score, + CASE + WHEN resp_rate_max IS NULL + THEN NULL + WHEN ABS(resp_rate_max - 19) > ABS(resp_rate_min - 19) + THEN smax.resp_rate_score + WHEN ABS(resp_rate_max - 19) < ABS(resp_rate_min - 19) + THEN smin.resp_rate_score + WHEN ABS(resp_rate_max - 19) = ABS(resp_rate_max - 19) + AND smax.resp_rate_score >= smin.resp_rate_score + THEN smax.resp_rate_score + WHEN ABS(resp_rate_max - 19) = ABS(resp_rate_max - 19) + AND smax.resp_rate_score < smin.resp_rate_score + THEN smin.resp_rate_score + END AS resp_rate_score, + CASE + WHEN hematocrit_max IS NULL + THEN NULL + WHEN ABS(hematocrit_max - 45.5) > ABS(hematocrit_min - 45.5) + THEN smax.hematocrit_score + WHEN ABS(hematocrit_max - 45.5) < ABS(hematocrit_min - 45.5) + THEN smin.hematocrit_score + WHEN ABS(hematocrit_max - 45.5) = ABS(hematocrit_max - 45.5) + AND smax.hematocrit_score >= smin.hematocrit_score + THEN smax.hematocrit_score + WHEN ABS(hematocrit_max - 45.5) = ABS(hematocrit_max - 45.5) + AND smax.hematocrit_score < smin.hematocrit_score + THEN smin.hematocrit_score + END AS hematocrit_score, + CASE + WHEN wbc_max IS NULL + THEN NULL + WHEN ABS(wbc_max - 11.5) > ABS(wbc_min - 11.5) + THEN smax.wbc_score + WHEN ABS(wbc_max - 11.5) < ABS(wbc_min - 11.5) + THEN smin.wbc_score + WHEN ABS(wbc_max - 11.5) = ABS(wbc_max - 11.5) AND smax.wbc_score >= smin.wbc_score + THEN smax.wbc_score + WHEN ABS(wbc_max - 11.5) = ABS(wbc_max - 11.5) AND smax.wbc_score < smin.wbc_score + THEN smin.wbc_score + END AS wbc_score, /* For some labs, "furthest from normal" doesn't make sense */ /* e.g. creatinine w/ ARF, the minimum could be 0.3, */ /* and the max 1.6 while the minimum of 0.3 is */ /* "further from 1", seems like the max should */ /* be scored */ + CASE + WHEN creatinine_max IS NULL + THEN NULL + WHEN arf = 1 + THEN smax.creatinine_score + WHEN ABS(creatinine_max - 1) > ABS(creatinine_min - 1) + THEN smax.creatinine_score + WHEN ABS(creatinine_max - 1) < ABS(creatinine_min - 1) + THEN smin.creatinine_score + WHEN smax.creatinine_score >= smin.creatinine_score + THEN smax.creatinine_score + WHEN smax.creatinine_score < smin.creatinine_score + THEN smin.creatinine_score + END AS creatinine_score, /* the rule for BUN is the furthest from 0.. equivalent to the max value */ + CASE WHEN bun_max IS NULL THEN NULL ELSE smax.bun_score END AS bun_score, + CASE + WHEN sodium_max IS NULL + THEN NULL + WHEN ABS(sodium_max - 145.5) > ABS(sodium_min - 145.5) + THEN smax.sodium_score + WHEN ABS(sodium_max - 145.5) < ABS(sodium_min - 145.5) + THEN smin.sodium_score + WHEN ABS(sodium_max - 145.5) = ABS(sodium_max - 145.5) + AND smax.sodium_score >= smin.sodium_score + THEN smax.sodium_score + WHEN ABS(sodium_max - 145.5) = ABS(sodium_max - 145.5) + AND smax.sodium_score < smin.sodium_score + THEN smin.sodium_score + END AS sodium_score, + CASE + WHEN albumin_max IS NULL + THEN NULL + WHEN ABS(albumin_max - 3.5) > ABS(albumin_min - 3.5) + THEN smax.albumin_score + WHEN ABS(albumin_max - 3.5) < ABS(albumin_min - 3.5) + THEN smin.albumin_score + WHEN ABS(albumin_max - 3.5) = ABS(albumin_max - 3.5) + AND smax.albumin_score >= smin.albumin_score + THEN smax.albumin_score + WHEN ABS(albumin_max - 3.5) = ABS(albumin_max - 3.5) + AND smax.albumin_score < smin.albumin_score + THEN smin.albumin_score + END AS albumin_score, + CASE WHEN bilirubin_max IS NULL THEN NULL ELSE smax.bilirubin_score END AS bilirubin_score, + CASE + WHEN glucose_max IS NULL + THEN NULL + WHEN ABS(glucose_max - 130) > ABS(glucose_min - 130) + THEN smax.glucose_score + WHEN ABS(glucose_max - 130) < ABS(glucose_min - 130) + THEN smin.glucose_score + WHEN ABS(glucose_max - 130) = ABS(glucose_max - 130) + AND smax.glucose_score >= smin.glucose_score + THEN smax.glucose_score + WHEN ABS(glucose_max - 130) = ABS(glucose_max - 130) + AND smax.glucose_score < smin.glucose_score + THEN smin.glucose_score + END AS glucose_score, /* Below are interactions/special cases where only 1 value is important */ + CASE + WHEN urineoutput IS NULL + THEN NULL + WHEN urineoutput < 400 + THEN 15 + WHEN urineoutput < 600 + THEN 8 + WHEN urineoutput < 900 + THEN 7 + WHEN urineoutput < 1500 + THEN 5 + WHEN urineoutput < 2000 + THEN 4 + WHEN urineoutput < 4000 + THEN 0 + WHEN urineoutput >= 4000 + THEN 1 + END AS uo_score, + CASE + WHEN gcs_unable = 1 + THEN 0 + WHEN gcs_eyes = 1 + THEN CASE + WHEN gcs_verbal = 1 AND gcs_motor IN (1, 2) + THEN 48 + WHEN gcs_verbal = 1 AND gcs_motor IN (3, 4) + THEN 33 + WHEN gcs_verbal = 1 AND gcs_motor IN (5, 6) + THEN 16 + WHEN gcs_verbal IN (2, 3) AND gcs_motor IN (1, 2) + THEN 29 + WHEN gcs_verbal IN (2, 3) AND gcs_motor IN (3, 4) + THEN 24 + WHEN gcs_verbal IN (2, 3) AND gcs_motor >= 5 + THEN NULL + WHEN gcs_verbal >= 4 + THEN NULL + END + WHEN gcs_eyes > 1 + THEN CASE + WHEN gcs_verbal = 1 AND gcs_motor IN (1, 2) + THEN 29 + WHEN gcs_verbal = 1 AND gcs_motor IN (3, 4) + THEN 24 + WHEN gcs_verbal = 1 AND gcs_motor IN (5, 6) + THEN 15 + WHEN gcs_verbal IN (2, 3) AND gcs_motor IN (1, 2) + THEN 29 + WHEN gcs_verbal IN (2, 3) AND gcs_motor IN (3, 4) + THEN 24 + WHEN gcs_verbal IN (2, 3) AND gcs_motor = 5 + THEN 13 + WHEN gcs_verbal IN (2, 3) AND gcs_motor = 6 + THEN 10 + WHEN gcs_verbal = 4 AND gcs_motor IN (1, 2, 3, 4) + THEN 13 + WHEN gcs_verbal = 4 AND gcs_motor = 5 + THEN 8 + WHEN gcs_verbal = 4 AND gcs_motor = 6 + THEN 3 + WHEN gcs_verbal = 5 AND gcs_motor IN (1, 2, 3, 4, 5) + THEN 3 + WHEN gcs_verbal = 5 AND gcs_motor = 6 + THEN 0 + END + ELSE NULL + END AS gcs_score, + CASE + WHEN pao2 IS NULL AND aado2 IS NULL + THEN NULL + WHEN NOT pao2 IS NULL + THEN CASE WHEN pao2 < 50 THEN 15 WHEN pao2 < 70 THEN 5 WHEN pao2 < 80 THEN 2 ELSE 0 END + WHEN NOT aado2 IS NULL + THEN CASE + WHEN aado2 < 100 + THEN 0 + WHEN aado2 < 250 + THEN 7 + WHEN aado2 < 350 + THEN 9 + WHEN aado2 < 500 + THEN 11 + WHEN aado2 >= 500 + THEN 14 + ELSE 0 + END + END AS pao2_aado2_score + FROM cohort AS co + LEFT JOIN score_min AS smin + ON co.stay_id = smin.stay_id + LEFT JOIN score_max AS smax + ON co.stay_id = smax.stay_id +), score AS ( + SELECT + s.*, /* coalesce statements impute normal score of zero */ /* if data element is missing */ + COALESCE(hr_score, 0) + COALESCE(mbp_score, 0) + COALESCE(temp_score, 0) + COALESCE(resp_rate_score, 0) + COALESCE(pao2_aado2_score, 0) + COALESCE(hematocrit_score, 0) + COALESCE(wbc_score, 0) + COALESCE(creatinine_score, 0) + COALESCE(uo_score, 0) + COALESCE(bun_score, 0) + COALESCE(sodium_score, 0) + COALESCE(albumin_score, 0) + COALESCE(bilirubin_score, 0) + COALESCE(glucose_score, 0) + COALESCE(acidbase_score, 0) + COALESCE(gcs_score, 0) AS apsiii + FROM scorecomp AS s ) - -, aa AS ( - -- join blood gas to ventilation durations to determine if patient was vent - -- also join to cpap table for the same purpose - SELECT ie.stay_id, bg.charttime - , bg.aado2 - , ROW_NUMBER() OVER ( - PARTITION BY ie.stay_id ORDER BY bg.aado2 DESC - ) AS rn - -- row number indicating the highest AaDO2 - FROM mimiciv_derived.bg bg - INNER JOIN mimiciv_icu.icustays ie - ON bg.hadm_id = ie.hadm_id - AND bg.charttime >= ie.intime AND bg.charttime < ie.outtime - INNER JOIN mimiciv_derived.ventilation vd - ON ie.stay_id = vd.stay_id - AND bg.charttime >= vd.starttime - AND bg.charttime <= vd.endtime - AND vd.ventilation_status = 'InvasiveVent' - WHERE vd.stay_id IS NOT NULL -- patient is ventilated - AND COALESCE(fio2, fio2_chartevents) >= 50 - AND bg.aado2 IS NOT NULL - AND bg.specimen = 'ART.' -) - --- because ph/pco2 rules are an interaction *within* a blood gas, --- we calculate them here --- the worse score is then taken for the final calculation -, acidbase AS ( - SELECT ie.stay_id - , ph, pco2 AS paco2 - , CASE - WHEN ph IS NULL OR pco2 IS NULL THEN null - WHEN ph < 7.20 THEN - CASE - WHEN pco2 < 50 THEN 12 - ELSE 4 - END - WHEN ph < 7.30 THEN - CASE - WHEN pco2 < 30 THEN 9 - WHEN pco2 < 40 THEN 6 - WHEN pco2 < 50 THEN 3 - ELSE 2 - END - WHEN ph < 7.35 THEN - CASE - WHEN pco2 < 30 THEN 9 - WHEN pco2 < 45 THEN 0 - ELSE 1 - END - WHEN ph < 7.45 THEN - CASE - WHEN pco2 < 30 THEN 5 - WHEN pco2 < 45 THEN 0 - ELSE 1 - END - WHEN ph < 7.50 THEN - CASE - WHEN pco2 < 30 THEN 5 - WHEN pco2 < 35 THEN 0 - WHEN pco2 < 45 THEN 2 - ELSE 12 - END - WHEN ph < 7.60 THEN - CASE - WHEN pco2 < 40 THEN 3 - ELSE 12 - END - ELSE -- ph >= 7.60 - CASE - WHEN pco2 < 25 THEN 0 - WHEN pco2 < 40 THEN 3 - ELSE 12 - END - END AS acidbase_score - FROM mimiciv_derived.bg bg - INNER JOIN mimiciv_icu.icustays ie - ON bg.hadm_id = ie.hadm_id - AND bg.charttime >= ie.intime AND bg.charttime < ie.outtime - WHERE ph IS NOT NULL AND pco2 IS NOT NULL - AND bg.specimen = 'ART.' -) - -, acidbase_max AS ( - SELECT stay_id, acidbase_score, ph, paco2 - -- create integer which indexes maximum value of score with 1 - , ROW_NUMBER() OVER ( - PARTITION BY stay_id ORDER BY acidbase_score DESC - ) AS acidbase_rn - FROM acidbase -) - --- define acute renal failure (ARF) as: --- creatinine >=1.5 mg/dl --- and urine output <410 cc/day --- and no chronic dialysis -, arf AS ( - SELECT ie.stay_id - , CASE - WHEN labs.creatinine_max >= 1.5 - AND uo.urineoutput < 410 - -- acute renal failure is only coded if the patient - -- is not on chronic dialysis - -- we use ICD-9 coding of ESRD as a proxy for chronic dialysis - AND icd.ckd = 0 - THEN 1 - ELSE 0 END AS arf - FROM mimiciv_icu.icustays ie - LEFT JOIN mimiciv_derived.first_day_urine_output uo - ON ie.stay_id = uo.stay_id - LEFT JOIN mimiciv_derived.first_day_lab labs - ON ie.stay_id = labs.stay_id - LEFT JOIN - ( - SELECT hadm_id - , MAX(CASE - -- severe kidney failure requiring use of dialysis - WHEN - icd_version = 9 AND SUBSTR( - icd_code, 1, 4 - ) IN ('5854', '5855', '5856') THEN 1 - WHEN - icd_version = 10 AND SUBSTR( - icd_code, 1, 4 - ) IN ('N184', 'N185', 'N186') THEN 1 - -- we do not include 5859 as that is sometimes coded - -- for acute-on-chronic ARF - ELSE 0 END) - AS ckd - FROM mimiciv_hosp.diagnoses_icd - GROUP BY hadm_id - ) icd - ON ie.hadm_id = icd.hadm_id -) - --- first day mechanical ventilation -, vent AS ( - SELECT ie.stay_id - , MAX( - CASE WHEN v.stay_id IS NOT NULL THEN 1 ELSE 0 END - ) AS vent - FROM mimiciv_icu.icustays ie - LEFT JOIN mimiciv_derived.ventilation v - ON ie.stay_id = v.stay_id - AND v.ventilation_status = 'InvasiveVent' - AND ( - ( - v.starttime >= ie.intime - AND v.starttime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) - ) - OR ( - v.endtime >= ie.intime - AND v.endtime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) - ) - OR ( - v.starttime <= ie.intime - AND v.endtime >= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) - ) - ) - GROUP BY ie.stay_id -) - -, cohort AS ( - SELECT ie.subject_id, ie.hadm_id, ie.stay_id - , ie.intime - , ie.outtime - - , vital.heart_rate_min - , vital.heart_rate_max - , vital.mbp_min - , vital.mbp_max - , vital.temperature_min - , vital.temperature_max - , vital.resp_rate_min - , vital.resp_rate_max - - , pa.pao2 - , aa.aado2 - - , ab.ph - , ab.paco2 - , ab.acidbase_score - - , labs.hematocrit_min - , labs.hematocrit_max - , labs.wbc_min - , labs.wbc_max - , labs.creatinine_min - , labs.creatinine_max - , labs.bun_min - , labs.bun_max - , labs.sodium_min - , labs.sodium_max - , labs.albumin_min - , labs.albumin_max - , labs.bilirubin_total_min AS bilirubin_min - , labs.bilirubin_total_max AS bilirubin_max - - , CASE - WHEN labs.glucose_max IS NULL AND vital.glucose_max IS NULL - THEN null - WHEN labs.glucose_max IS NULL - OR vital.glucose_max > labs.glucose_max - THEN vital.glucose_max - WHEN vital.glucose_max IS NULL - OR labs.glucose_max > vital.glucose_max - THEN labs.glucose_max - ELSE labs.glucose_max -- if equal, just pick labs - END AS glucose_max - - , CASE - WHEN labs.glucose_min IS NULL - AND vital.glucose_min IS NULL - THEN null - WHEN labs.glucose_min IS NULL - OR vital.glucose_min < labs.glucose_min - THEN vital.glucose_min - WHEN vital.glucose_min IS NULL - OR labs.glucose_min < vital.glucose_min - THEN labs.glucose_min - ELSE labs.glucose_min -- if equal, just pick labs - END AS glucose_min - - -- , labs.bicarbonate_min - -- , labs.bicarbonate_max - , vent.vent - , uo.urineoutput - -- gcs and its components - , gcs.gcs_min AS mingcs - , gcs.gcs_motor, gcs.gcs_verbal, gcs.gcs_eyes, gcs.gcs_unable - -- acute renal failure - , arf.arf AS arf - - FROM mimiciv_icu.icustays ie - INNER JOIN mimiciv_hosp.admissions adm - ON ie.hadm_id = adm.hadm_id - INNER JOIN mimiciv_hosp.patients pat - ON ie.subject_id = pat.subject_id - - -- join to above views - the row number filters to 1 row per stay_id - LEFT JOIN pa - ON ie.stay_id = pa.stay_id - AND pa.rn = 1 - LEFT JOIN aa - ON ie.stay_id = aa.stay_id - AND aa.rn = 1 - LEFT JOIN acidbase_max ab - ON ie.stay_id = ab.stay_id - AND ab.acidbase_rn = 1 - LEFT JOIN arf - ON ie.stay_id = arf.stay_id - - -- join to custom tables to get more data.... - LEFT JOIN vent - ON ie.stay_id = vent.stay_id - LEFT JOIN mimiciv_derived.first_day_gcs gcs - ON ie.stay_id = gcs.stay_id - LEFT JOIN mimiciv_derived.first_day_vitalsign vital - ON ie.stay_id = vital.stay_id - LEFT JOIN mimiciv_derived.first_day_urine_output uo - ON ie.stay_id = uo.stay_id - LEFT JOIN mimiciv_derived.first_day_lab labs - ON ie.stay_id = labs.stay_id -) - --- First, we calculate the score for the minimum values -, score_min AS ( - SELECT cohort.subject_id, cohort.hadm_id, cohort.stay_id - , CASE - WHEN heart_rate_min IS NULL THEN null - WHEN heart_rate_min < 40 THEN 8 - WHEN heart_rate_min < 50 THEN 5 - WHEN heart_rate_min < 100 THEN 0 - WHEN heart_rate_min < 110 THEN 1 - WHEN heart_rate_min < 120 THEN 5 - WHEN heart_rate_min < 140 THEN 7 - WHEN heart_rate_min < 155 THEN 13 - WHEN heart_rate_min >= 155 THEN 17 - END AS hr_score - - , CASE - WHEN mbp_min IS NULL THEN null - WHEN mbp_min < 40 THEN 23 - WHEN mbp_min < 60 THEN 15 - WHEN mbp_min < 70 THEN 7 - WHEN mbp_min < 80 THEN 6 - WHEN mbp_min < 100 THEN 0 - WHEN mbp_min < 120 THEN 4 - WHEN mbp_min < 130 THEN 7 - WHEN mbp_min < 140 THEN 9 - WHEN mbp_min >= 140 THEN 10 - END AS mbp_score - - -- TODO: add 1 degree to axillary measurements - , CASE - WHEN temperature_min IS NULL THEN null - WHEN temperature_min < 33.0 THEN 20 - WHEN temperature_min < 33.5 THEN 16 - WHEN temperature_min < 34.0 THEN 13 - WHEN temperature_min < 35.0 THEN 8 - WHEN temperature_min < 36.0 THEN 2 - WHEN temperature_min < 40.0 THEN 0 - WHEN temperature_min >= 40.0 THEN 4 - END AS temp_score - - , CASE - WHEN resp_rate_min IS NULL THEN null - -- special case for ventilated patients - WHEN vent = 1 AND resp_rate_min < 14 THEN 0 - WHEN resp_rate_min < 6 THEN 17 - WHEN resp_rate_min < 12 THEN 8 - WHEN resp_rate_min < 14 THEN 7 - WHEN resp_rate_min < 25 THEN 0 - WHEN resp_rate_min < 35 THEN 6 - WHEN resp_rate_min < 40 THEN 9 - WHEN resp_rate_min < 50 THEN 11 - WHEN resp_rate_min >= 50 THEN 18 - END AS resp_rate_score - - , CASE - WHEN hematocrit_min IS NULL THEN null - WHEN hematocrit_min < 41.0 THEN 3 - WHEN hematocrit_min < 50.0 THEN 0 - WHEN hematocrit_min >= 50.0 THEN 3 - END AS hematocrit_score - - , CASE - WHEN wbc_min IS NULL THEN null - WHEN wbc_min < 1.0 THEN 19 - WHEN wbc_min < 3.0 THEN 5 - WHEN wbc_min < 20.0 THEN 0 - WHEN wbc_min < 25.0 THEN 1 - WHEN wbc_min >= 25.0 THEN 5 - END AS wbc_score - - , CASE - WHEN creatinine_min IS NULL THEN null - WHEN arf = 1 AND creatinine_min < 1.5 THEN 0 - WHEN arf = 1 AND creatinine_min >= 1.5 THEN 10 - WHEN creatinine_min < 0.5 THEN 3 - WHEN creatinine_min < 1.5 THEN 0 - WHEN creatinine_min < 1.95 THEN 4 - WHEN creatinine_min >= 1.95 THEN 7 - END AS creatinine_score - - , CASE - WHEN bun_min IS NULL THEN null - WHEN bun_min < 17.0 THEN 0 - WHEN bun_min < 20.0 THEN 2 - WHEN bun_min < 40.0 THEN 7 - WHEN bun_min < 80.0 THEN 11 - WHEN bun_min >= 80.0 THEN 12 - END AS bun_score - - , CASE - WHEN sodium_min IS NULL THEN null - WHEN sodium_min < 120 THEN 3 - WHEN sodium_min < 135 THEN 2 - WHEN sodium_min < 155 THEN 0 - WHEN sodium_min >= 155 THEN 4 - END AS sodium_score - - , CASE - WHEN albumin_min IS NULL THEN null - WHEN albumin_min < 2.0 THEN 11 - WHEN albumin_min < 2.5 THEN 6 - WHEN albumin_min < 4.5 THEN 0 - WHEN albumin_min >= 4.5 THEN 4 - END AS albumin_score - - , CASE - WHEN bilirubin_min IS NULL THEN null - WHEN bilirubin_min < 2.0 THEN 0 - WHEN bilirubin_min < 3.0 THEN 5 - WHEN bilirubin_min < 5.0 THEN 6 - WHEN bilirubin_min < 8.0 THEN 8 - WHEN bilirubin_min >= 8.0 THEN 16 - END AS bilirubin_score - - , CASE - WHEN glucose_min IS NULL THEN null - WHEN glucose_min < 40 THEN 8 - WHEN glucose_min < 60 THEN 9 - WHEN glucose_min < 200 THEN 0 - WHEN glucose_min < 350 THEN 3 - WHEN glucose_min >= 350 THEN 5 - END AS glucose_score - - FROM cohort -) - -, score_max AS ( - SELECT cohort.subject_id, cohort.hadm_id, cohort.stay_id - , CASE - WHEN heart_rate_max IS NULL THEN null - WHEN heart_rate_max < 40 THEN 8 - WHEN heart_rate_max < 50 THEN 5 - WHEN heart_rate_max < 100 THEN 0 - WHEN heart_rate_max < 110 THEN 1 - WHEN heart_rate_max < 120 THEN 5 - WHEN heart_rate_max < 140 THEN 7 - WHEN heart_rate_max < 155 THEN 13 - WHEN heart_rate_max >= 155 THEN 17 - END AS hr_score - - , CASE - WHEN mbp_max IS NULL THEN null - WHEN mbp_max < 40 THEN 23 - WHEN mbp_max < 60 THEN 15 - WHEN mbp_max < 70 THEN 7 - WHEN mbp_max < 80 THEN 6 - WHEN mbp_max < 100 THEN 0 - WHEN mbp_max < 120 THEN 4 - WHEN mbp_max < 130 THEN 7 - WHEN mbp_max < 140 THEN 9 - WHEN mbp_max >= 140 THEN 10 - END AS mbp_score - - -- TODO: add 1 degree to axillary measurements - , CASE - WHEN temperature_max IS NULL THEN null - WHEN temperature_max < 33.0 THEN 20 - WHEN temperature_max < 33.5 THEN 16 - WHEN temperature_max < 34.0 THEN 13 - WHEN temperature_max < 35.0 THEN 8 - WHEN temperature_max < 36.0 THEN 2 - WHEN temperature_max < 40.0 THEN 0 - WHEN temperature_max >= 40.0 THEN 4 - END AS temp_score - - , CASE - WHEN resp_rate_max IS NULL THEN null - -- special case for ventilated patients - WHEN vent = 1 AND resp_rate_max < 14 THEN 0 - WHEN resp_rate_max < 6 THEN 17 - WHEN resp_rate_max < 12 THEN 8 - WHEN resp_rate_max < 14 THEN 7 - WHEN resp_rate_max < 25 THEN 0 - WHEN resp_rate_max < 35 THEN 6 - WHEN resp_rate_max < 40 THEN 9 - WHEN resp_rate_max < 50 THEN 11 - WHEN resp_rate_max >= 50 THEN 18 - END AS resp_rate_score - - , CASE - WHEN hematocrit_max IS NULL THEN null - WHEN hematocrit_max < 41.0 THEN 3 - WHEN hematocrit_max < 50.0 THEN 0 - WHEN hematocrit_max >= 50.0 THEN 3 - END AS hematocrit_score - - , CASE - WHEN wbc_max IS NULL THEN null - WHEN wbc_max < 1.0 THEN 19 - WHEN wbc_max < 3.0 THEN 5 - WHEN wbc_max < 20.0 THEN 0 - WHEN wbc_max < 25.0 THEN 1 - WHEN wbc_max >= 25.0 THEN 5 - END AS wbc_score - - , CASE - WHEN creatinine_max IS NULL THEN null - WHEN arf = 1 AND creatinine_max < 1.5 THEN 0 - WHEN arf = 1 AND creatinine_max >= 1.5 THEN 10 - WHEN creatinine_max < 0.5 THEN 3 - WHEN creatinine_max < 1.5 THEN 0 - WHEN creatinine_max < 1.95 THEN 4 - WHEN creatinine_max >= 1.95 THEN 7 - END AS creatinine_score - - , CASE - WHEN bun_max IS NULL THEN null - WHEN bun_max < 17.0 THEN 0 - WHEN bun_max < 20.0 THEN 2 - WHEN bun_max < 40.0 THEN 7 - WHEN bun_max < 80.0 THEN 11 - WHEN bun_max >= 80.0 THEN 12 - END AS bun_score - - , CASE - WHEN sodium_max IS NULL THEN null - WHEN sodium_max < 120 THEN 3 - WHEN sodium_max < 135 THEN 2 - WHEN sodium_max < 155 THEN 0 - WHEN sodium_max >= 155 THEN 4 - END AS sodium_score - - , CASE - WHEN albumin_max IS NULL THEN null - WHEN albumin_max < 2.0 THEN 11 - WHEN albumin_max < 2.5 THEN 6 - WHEN albumin_max < 4.5 THEN 0 - WHEN albumin_max >= 4.5 THEN 4 - END AS albumin_score - - , CASE - WHEN bilirubin_max IS NULL THEN null - WHEN bilirubin_max < 2.0 THEN 0 - WHEN bilirubin_max < 3.0 THEN 5 - WHEN bilirubin_max < 5.0 THEN 6 - WHEN bilirubin_max < 8.0 THEN 8 - WHEN bilirubin_max >= 8.0 THEN 16 - END AS bilirubin_score - - , CASE - WHEN glucose_max IS NULL THEN null - WHEN glucose_max < 40 THEN 8 - WHEN glucose_max < 60 THEN 9 - WHEN glucose_max < 200 THEN 0 - WHEN glucose_max < 350 THEN 3 - WHEN glucose_max >= 350 THEN 5 - END AS glucose_score - - FROM cohort -) - --- Combine together the scores for min/max, using the following rules: --- 1) select the value furthest from a predefined normal value --- 2) if both equidistant, choose the one which gives a worse score --- 3) calculate score for acid-base abnormalities as it requires interactions --- sometimes the code is a bit redundant, i.e. we know the max would always --- be furthest from 0 -, scorecomp AS ( - SELECT co.* - -- The rules for APS III require the definition of a "worst" value - -- This value is defined as whatever value is furthest from a - -- predefined normal e.g., for heart rate, worst is defined - -- as furthest from 75 - , CASE - WHEN heart_rate_max IS NULL THEN null - WHEN ABS(heart_rate_max - 75) > ABS(heart_rate_min - 75) - THEN smax.hr_score - WHEN ABS(heart_rate_max - 75) < ABS(heart_rate_min - 75) - THEN smin.hr_score - WHEN ABS(heart_rate_max - 75) = ABS(heart_rate_min - 75) - AND smax.hr_score >= smin.hr_score - THEN smax.hr_score - WHEN ABS(heart_rate_max - 75) = ABS(heart_rate_min - 75) - AND smax.hr_score < smin.hr_score - THEN smin.hr_score - END AS hr_score - - , CASE - WHEN mbp_max IS NULL THEN null - WHEN ABS(mbp_max - 90) > ABS(mbp_min - 90) - THEN smax.mbp_score - WHEN ABS(mbp_max - 90) < ABS(mbp_min - 90) - THEN smin.mbp_score - -- values are equidistant - pick the larger score - WHEN ABS(mbp_max - 90) = ABS(mbp_min - 90) - AND smax.mbp_score >= smin.mbp_score - THEN smax.mbp_score - WHEN ABS(mbp_max - 90) = ABS(mbp_min - 90) - AND smax.mbp_score < smin.mbp_score - THEN smin.mbp_score - END AS mbp_score - - , CASE - WHEN temperature_max IS NULL THEN null - WHEN ABS(temperature_max - 38) > ABS(temperature_min - 38) - THEN smax.temp_score - WHEN ABS(temperature_max - 38) < ABS(temperature_min - 38) - THEN smin.temp_score - -- values are equidistant - pick the larger score - WHEN ABS(temperature_max - 38) = ABS(temperature_min - 38) - AND smax.temp_score >= smin.temp_score - THEN smax.temp_score - WHEN ABS(temperature_max - 38) = ABS(temperature_min - 38) - AND smax.temp_score < smin.temp_score - THEN smin.temp_score - END AS temp_score - - , CASE - WHEN resp_rate_max IS NULL THEN null - WHEN ABS(resp_rate_max - 19) > ABS(resp_rate_min - 19) - THEN smax.resp_rate_score - WHEN ABS(resp_rate_max - 19) < ABS(resp_rate_min - 19) - THEN smin.resp_rate_score - -- values are equidistant - pick the larger score - WHEN ABS(resp_rate_max - 19) = ABS(resp_rate_max - 19) - AND smax.resp_rate_score >= smin.resp_rate_score - THEN smax.resp_rate_score - WHEN ABS(resp_rate_max - 19) = ABS(resp_rate_max - 19) - AND smax.resp_rate_score < smin.resp_rate_score - THEN smin.resp_rate_score - END AS resp_rate_score - - , CASE - WHEN hematocrit_max IS NULL THEN null - WHEN ABS(hematocrit_max - 45.5) > ABS(hematocrit_min - 45.5) - THEN smax.hematocrit_score - WHEN ABS(hematocrit_max - 45.5) < ABS(hematocrit_min - 45.5) - THEN smin.hematocrit_score - -- values are equidistant - pick the larger score - WHEN ABS(hematocrit_max - 45.5) = ABS(hematocrit_max - 45.5) - AND smax.hematocrit_score >= smin.hematocrit_score - THEN smax.hematocrit_score - WHEN ABS(hematocrit_max - 45.5) = ABS(hematocrit_max - 45.5) - AND smax.hematocrit_score < smin.hematocrit_score - THEN smin.hematocrit_score - END AS hematocrit_score - - , CASE - WHEN wbc_max IS NULL THEN null - WHEN ABS(wbc_max - 11.5) > ABS(wbc_min - 11.5) - THEN smax.wbc_score - WHEN ABS(wbc_max - 11.5) < ABS(wbc_min - 11.5) - THEN smin.wbc_score - -- values are equidistant - pick the larger score - WHEN ABS(wbc_max - 11.5) = ABS(wbc_max - 11.5) - AND smax.wbc_score >= smin.wbc_score - THEN smax.wbc_score - WHEN ABS(wbc_max - 11.5) = ABS(wbc_max - 11.5) - AND smax.wbc_score < smin.wbc_score - THEN smin.wbc_score - END AS wbc_score - - - -- For some labs, "furthest from normal" doesn't make sense - -- e.g. creatinine w/ ARF, the minimum could be 0.3, - -- and the max 1.6 while the minimum of 0.3 is - -- "further from 1", seems like the max should - -- be scored - , CASE - WHEN creatinine_max IS NULL THEN null - -- if they have arf then use the max to score - WHEN arf = 1 THEN smax.creatinine_score - -- otherwise furthest from 1 - WHEN ABS(creatinine_max - 1) > ABS(creatinine_min - 1) - THEN smax.creatinine_score - WHEN ABS(creatinine_max - 1) < ABS(creatinine_min - 1) - THEN smin.creatinine_score - -- values are equidistant - WHEN smax.creatinine_score >= smin.creatinine_score - THEN smax.creatinine_score - WHEN smax.creatinine_score < smin.creatinine_score - THEN smin.creatinine_score - END AS creatinine_score - - -- the rule for BUN is the furthest from 0.. equivalent to the max value - , CASE - WHEN bun_max IS NULL THEN null - ELSE smax.bun_score - END AS bun_score - - , CASE - WHEN sodium_max IS NULL THEN null - WHEN ABS(sodium_max - 145.5) > ABS(sodium_min - 145.5) - THEN smax.sodium_score - WHEN ABS(sodium_max - 145.5) < ABS(sodium_min - 145.5) - THEN smin.sodium_score - -- values are equidistant - pick the larger score - WHEN ABS(sodium_max - 145.5) = ABS(sodium_max - 145.5) - AND smax.sodium_score >= smin.sodium_score - THEN smax.sodium_score - WHEN ABS(sodium_max - 145.5) = ABS(sodium_max - 145.5) - AND smax.sodium_score < smin.sodium_score - THEN smin.sodium_score - END AS sodium_score - - , CASE - WHEN albumin_max IS NULL THEN null - WHEN ABS(albumin_max - 3.5) > ABS(albumin_min - 3.5) - THEN smax.albumin_score - WHEN ABS(albumin_max - 3.5) < ABS(albumin_min - 3.5) - THEN smin.albumin_score - -- values are equidistant - pick the larger score - WHEN ABS(albumin_max - 3.5) = ABS(albumin_max - 3.5) - AND smax.albumin_score >= smin.albumin_score - THEN smax.albumin_score - WHEN ABS(albumin_max - 3.5) = ABS(albumin_max - 3.5) - AND smax.albumin_score < smin.albumin_score - THEN smin.albumin_score - END AS albumin_score - - , CASE - WHEN bilirubin_max IS NULL THEN null - ELSE smax.bilirubin_score - END AS bilirubin_score - - , CASE - WHEN glucose_max IS NULL THEN null - WHEN ABS(glucose_max - 130) > ABS(glucose_min - 130) - THEN smax.glucose_score - WHEN ABS(glucose_max - 130) < ABS(glucose_min - 130) - THEN smin.glucose_score - -- values are equidistant - pick the larger score - WHEN ABS(glucose_max - 130) = ABS(glucose_max - 130) - AND smax.glucose_score >= smin.glucose_score - THEN smax.glucose_score - WHEN ABS(glucose_max - 130) = ABS(glucose_max - 130) - AND smax.glucose_score < smin.glucose_score - THEN smin.glucose_score - END AS glucose_score - - - -- Below are interactions/special cases where only 1 value is important - , CASE - WHEN urineoutput IS NULL THEN null - WHEN urineoutput < 400 THEN 15 - WHEN urineoutput < 600 THEN 8 - WHEN urineoutput < 900 THEN 7 - WHEN urineoutput < 1500 THEN 5 - WHEN urineoutput < 2000 THEN 4 - WHEN urineoutput < 4000 THEN 0 - WHEN urineoutput >= 4000 THEN 1 - END AS uo_score - - , CASE - WHEN gcs_unable = 1 - -- here they are intubated, so their verbal score - -- is inappropriate - -- normally you are supposed to use "clinical judgement" - -- we don't have that, so we just assume normal - -- (as was done in the original study) - THEN 0 - WHEN gcs_eyes = 1 - THEN CASE - WHEN gcs_verbal = 1 AND gcs_motor IN (1, 2) - THEN 48 - WHEN gcs_verbal = 1 AND gcs_motor IN (3, 4) - THEN 33 - WHEN gcs_verbal = 1 AND gcs_motor IN (5, 6) - THEN 16 - WHEN gcs_verbal IN (2, 3) AND gcs_motor IN (1, 2) - THEN 29 - WHEN gcs_verbal IN (2, 3) AND gcs_motor IN (3, 4) - THEN 24 - WHEN gcs_verbal IN (2, 3) AND gcs_motor >= 5 - -- highly unlikely clinical combination - THEN null - WHEN gcs_verbal >= 4 - THEN null - END - WHEN gcs_eyes > 1 - THEN CASE - WHEN gcs_verbal = 1 AND gcs_motor IN (1, 2) - THEN 29 - WHEN gcs_verbal = 1 AND gcs_motor IN (3, 4) - THEN 24 - WHEN gcs_verbal = 1 AND gcs_motor IN (5, 6) - THEN 15 - WHEN gcs_verbal IN (2, 3) AND gcs_motor IN (1, 2) - THEN 29 - WHEN gcs_verbal IN (2, 3) AND gcs_motor IN (3, 4) - THEN 24 - WHEN gcs_verbal IN (2, 3) AND gcs_motor = 5 - THEN 13 - WHEN gcs_verbal IN (2, 3) AND gcs_motor = 6 - THEN 10 - WHEN gcs_verbal = 4 AND gcs_motor IN (1, 2, 3, 4) - THEN 13 - WHEN gcs_verbal = 4 AND gcs_motor = 5 - THEN 8 - WHEN gcs_verbal = 4 AND gcs_motor = 6 - THEN 3 - WHEN gcs_verbal = 5 AND gcs_motor IN (1, 2, 3, 4, 5) - THEN 3 - WHEN gcs_verbal = 5 AND gcs_motor = 6 - THEN 0 - END - ELSE null - END AS gcs_score - - , CASE - WHEN pao2 IS NULL AND aado2 IS NULL - THEN null - WHEN pao2 IS NOT NULL THEN - CASE - WHEN pao2 < 50 THEN 15 - WHEN pao2 < 70 THEN 5 - WHEN pao2 < 80 THEN 2 - ELSE 0 END - WHEN aado2 IS NOT NULL THEN - CASE - WHEN aado2 < 100 THEN 0 - WHEN aado2 < 250 THEN 7 - WHEN aado2 < 350 THEN 9 - WHEN aado2 < 500 THEN 11 - WHEN aado2 >= 500 THEN 14 - ELSE 0 END - END AS pao2_aado2_score - - FROM cohort co - LEFT JOIN score_min smin - ON co.stay_id = smin.stay_id - LEFT JOIN score_max smax - ON co.stay_id = smax.stay_id -) - --- tabulate the APS III using the scores from the worst values -, score AS ( - SELECT s.* - -- coalesce statements impute normal score of zero - -- if data element is missing - , COALESCE(hr_score, 0) - + COALESCE(mbp_score, 0) - + COALESCE(temp_score, 0) - + COALESCE(resp_rate_score, 0) - + COALESCE(pao2_aado2_score, 0) - + COALESCE(hematocrit_score, 0) - + COALESCE(wbc_score, 0) - + COALESCE(creatinine_score, 0) - + COALESCE(uo_score, 0) - + COALESCE(bun_score, 0) - + COALESCE(sodium_score, 0) - + COALESCE(albumin_score, 0) - + COALESCE(bilirubin_score, 0) - + COALESCE(glucose_score, 0) - + COALESCE(acidbase_score, 0) - + COALESCE(gcs_score, 0) - AS apsiii - FROM scorecomp s -) - -SELECT ie.subject_id, ie.hadm_id, ie.stay_id - , apsiii - -- Calculate probability of hospital mortality using - -- equation from Johnson 2014. - , 1 / (1 + EXP(- (-4.4360 + 0.04726 * (apsiii)))) AS apsiii_prob - , hr_score - , mbp_score - , temp_score - , resp_rate_score - , pao2_aado2_score - , hematocrit_score - , wbc_score - , creatinine_score - , uo_score - , bun_score - , sodium_score - , albumin_score - , bilirubin_score - , glucose_score - , acidbase_score - , gcs_score -FROM mimiciv_icu.icustays ie -LEFT JOIN score s - ON ie.stay_id = s.stay_id -; +SELECT + ie.subject_id, + ie.hadm_id, + ie.stay_id, + apsiii, /* Calculate probability of hospital mortality using */ /* equation from Johnson 2014. */ + CAST(1 AS DOUBLE PRECISION) / ( + 1 + EXP(-( + -4.4360 + 0.04726 * ( + apsiii + ) + )) + ) AS apsiii_prob, + hr_score, + mbp_score, + temp_score, + resp_rate_score, + pao2_aado2_score, + hematocrit_score, + wbc_score, + creatinine_score, + uo_score, + bun_score, + sodium_score, + albumin_score, + bilirubin_score, + glucose_score, + acidbase_score, + gcs_score +FROM mimiciv_icu.icustays AS ie +LEFT JOIN score AS s + ON ie.stay_id = s.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/score/lods.sql b/mimic-iv/concepts_postgres/score/lods.sql index 62e3568e6..a38a16fff 100644 --- a/mimic-iv/concepts_postgres/score/lods.sql +++ b/mimic-iv/concepts_postgres/score/lods.sql @@ -1,232 +1,208 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS lods; CREATE TABLE lods AS --- ------------------------------------------------------------------ --- Title: Logistic Organ Dysfunction Score (LODS) --- This query extracts the logistic organ dysfunction system. --- This score is a measure of organ failure in a patient. --- The score is calculated on the first day of each ICU patients' stay. --- ------------------------------------------------------------------ - --- Reference for LODS: --- Le Gall, J. R., Klar, J., Lemeshow, S., Saulnier, F., Alberti, C., --- Artigas, A., & Teres, D. --- The Logistic Organ Dysfunction system: a new way to assess organ --- dysfunction in the intensive care unit. JAMA 276.10 (1996): 802-810. - --- Variables used in LODS: --- GCS --- VITALS: Heart rate, systolic blood pressure --- FLAGS: ventilation/cpap --- IO: urine output --- LABS: blood urea nitrogen, WBC, bilirubin, creatinine, --- prothrombin time (PT), platelets --- ABG: PaO2 with associated FiO2 - --- Note: --- The score is calculated for *all* ICU patients, with the assumption --- that the user will subselect appropriate stay_ids. - --- extract CPAP from the "Oxygen Delivery Device" fields +DROP TABLE IF EXISTS mimiciv_derived.lods; CREATE TABLE mimiciv_derived.lods AS +/* ------------------------------------------------------------------ */ /* Title: Logistic Organ Dysfunction Score (LODS) */ /* This query extracts the logistic organ dysfunction system. */ /* This score is a measure of organ failure in a patient. */ /* The score is calculated on the first day of each ICU patients' stay. */ /* ------------------------------------------------------------------ */ /* Reference for LODS: */ /* Le Gall, J. R., Klar, J., Lemeshow, S., Saulnier, F., Alberti, C., */ /* Artigas, A., & Teres, D. */ /* The Logistic Organ Dysfunction system: a new way to assess organ */ /* dysfunction in the intensive care unit. JAMA 276.10 (1996): 802-810. */ /* Variables used in LODS: */ /* GCS */ /* VITALS: Heart rate, systolic blood pressure */ /* FLAGS: ventilation/cpap */ /* IO: urine output */ /* LABS: blood urea nitrogen, WBC, bilirubin, creatinine, */ /* prothrombin time (PT), platelets */ /* ABG: PaO2 with associated FiO2 */ /* Note: */ /* The score is calculated for *all* ICU patients, with the assumption */ /* that the user will subselect appropriate stay_ids. */ /* extract CPAP from the "Oxygen Delivery Device" fields */ WITH cpap AS ( - SELECT ie.stay_id - , MIN(DATETIME_SUB(charttime, INTERVAL '1' HOUR)) AS starttime - , MAX(DATETIME_ADD(charttime, INTERVAL '4' HOUR)) AS endtime - , MAX(CASE - WHEN LOWER(ce.value) LIKE '%cpap%' THEN 1 - WHEN LOWER(ce.value) LIKE '%bipap mask%' THEN 1 - ELSE 0 END) AS cpap - FROM mimiciv_icu.icustays ie - INNER JOIN mimiciv_icu.chartevents ce - ON ie.stay_id = ce.stay_id - AND ce.charttime >= ie.intime - AND ce.charttime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) - WHERE itemid = 226732 - AND ( - LOWER(ce.value) LIKE '%cpap%' OR LOWER(ce.value) LIKE '%bipap mask%' - ) - GROUP BY ie.stay_id + SELECT + ie.stay_id, + MIN(charttime - INTERVAL '1 HOUR') AS starttime, + MAX(charttime + INTERVAL '4 HOUR') AS endtime, + MAX( + CASE + WHEN LOWER(ce.value) LIKE '%cpap%' + THEN 1 + WHEN LOWER(ce.value) LIKE '%bipap mask%' + THEN 1 + ELSE 0 + END + ) AS cpap + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_icu.chartevents AS ce + ON ie.stay_id = ce.stay_id + AND ce.charttime >= ie.intime + AND ce.charttime <= ie.intime + INTERVAL '1 DAY' + WHERE + itemid = 226732 + AND ( + LOWER(ce.value) LIKE '%cpap%' OR LOWER(ce.value) LIKE '%bipap mask%' + ) + GROUP BY + ie.stay_id +), pafi1 AS ( + /* join blood gas to ventilation durations to determine if patient was vent */ /* also join to cpap table for the same purpose */ + SELECT + ie.stay_id, + bg.charttime, + pao2fio2ratio, + CASE WHEN NOT vd.stay_id IS NULL THEN 1 ELSE 0 END AS vent, + CASE WHEN NOT cp.stay_id IS NULL THEN 1 ELSE 0 END AS cpap + FROM mimiciv_derived.bg AS bg + INNER JOIN mimiciv_icu.icustays AS ie + ON bg.hadm_id = ie.hadm_id AND bg.charttime >= ie.intime AND bg.charttime < ie.outtime + LEFT JOIN mimiciv_derived.ventilation AS vd + ON ie.stay_id = vd.stay_id + AND bg.charttime >= vd.starttime + AND bg.charttime <= vd.endtime + AND vd.ventilation_status = 'InvasiveVent' + LEFT JOIN cpap AS cp + ON ie.stay_id = cp.stay_id AND bg.charttime >= cp.starttime AND bg.charttime <= cp.endtime +), pafi2 AS ( + /* get the minimum PaO2/FiO2 ratio *only for ventilated/cpap patients* */ + SELECT + stay_id, + MIN(pao2fio2ratio) AS pao2fio2_vent_min + FROM pafi1 + WHERE + vent = 1 OR cpap = 1 + GROUP BY + stay_id +), cohort AS ( + SELECT + ie.subject_id, + ie.hadm_id, + ie.stay_id, + ie.intime, + ie.outtime, + gcs.gcs_min, + vital.heart_rate_max, + vital.heart_rate_min, + vital.sbp_max, + vital.sbp_min, /* this value is non-null iff the patient is on vent/cpap */ + pf.pao2fio2_vent_min, + labs.bun_max, + labs.bun_min, + labs.wbc_max, + labs.wbc_min, + labs.bilirubin_total_max AS bilirubin_max, + labs.creatinine_max, + labs.pt_min, + labs.pt_max, + labs.platelets_min AS platelet_min, + uo.urineoutput + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_hosp.admissions AS adm + ON ie.hadm_id = adm.hadm_id + INNER JOIN mimiciv_hosp.patients AS pat + ON ie.subject_id = pat.subject_id + /* join to above view to get pao2/fio2 ratio */ + LEFT JOIN pafi2 AS pf + ON ie.stay_id = pf.stay_id + /* join to custom tables to get more data.... */ + LEFT JOIN mimiciv_derived.first_day_gcs AS gcs + ON ie.stay_id = gcs.stay_id + LEFT JOIN mimiciv_derived.first_day_vitalsign AS vital + ON ie.stay_id = vital.stay_id + LEFT JOIN mimiciv_derived.first_day_urine_output AS uo + ON ie.stay_id = uo.stay_id + LEFT JOIN mimiciv_derived.first_day_lab AS labs + ON ie.stay_id = labs.stay_id +), scorecomp AS ( + SELECT + cohort.*, /* Below code calculates the component scores needed for SAPS */ /* neurologic */ + CASE + WHEN gcs_min IS NULL + THEN NULL + WHEN gcs_min < 3 + THEN NULL /* erroneous value/on trach */ + WHEN gcs_min <= 5 + THEN 5 + WHEN gcs_min <= 8 + THEN 3 + WHEN gcs_min <= 13 + THEN 1 + ELSE 0 + END AS neurologic, /* cardiovascular */ + CASE + WHEN heart_rate_max IS NULL AND sbp_min IS NULL + THEN NULL + WHEN heart_rate_min < 30 + THEN 5 + WHEN sbp_min < 40 + THEN 5 + WHEN sbp_min < 70 + THEN 3 + WHEN sbp_max >= 270 + THEN 3 + WHEN heart_rate_max >= 140 + THEN 1 + WHEN sbp_max >= 240 + THEN 1 + WHEN sbp_min < 90 + THEN 1 + ELSE 0 + END AS cardiovascular, /* renal */ + CASE + WHEN bun_max IS NULL OR urineoutput IS NULL OR creatinine_max IS NULL + THEN NULL + WHEN urineoutput < 500.0 + THEN 5 + WHEN bun_max >= 56.0 + THEN 5 + WHEN creatinine_max >= 1.60 + THEN 3 + WHEN urineoutput < 750.0 + THEN 3 + WHEN bun_max >= 28.0 + THEN 3 + WHEN urineoutput >= 10000.0 + THEN 3 + WHEN creatinine_max >= 1.20 + THEN 1 + WHEN bun_max >= 17.0 + THEN 1 + WHEN bun_max >= 7.50 + THEN 1 + ELSE 0 + END AS renal, /* pulmonary */ + CASE + WHEN pao2fio2_vent_min IS NULL + THEN 0 + WHEN pao2fio2_vent_min >= 150 + THEN 1 + WHEN pao2fio2_vent_min < 150 + THEN 3 + ELSE NULL + END AS pulmonary, /* hematologic */ + CASE + WHEN wbc_max IS NULL AND platelet_min IS NULL + THEN NULL + WHEN wbc_min < 1.0 + THEN 3 + WHEN wbc_min < 2.5 + THEN 1 + WHEN platelet_min < 50.0 + THEN 1 + WHEN wbc_max >= 50.0 + THEN 1 + ELSE 0 + END AS hematologic, /* hepatic */ /* We have defined the "standard" PT as 12 seconds. */ /* This is an assumption and subsequent analyses may be */ /* affected by this assumption. */ + CASE + WHEN pt_max IS NULL AND bilirubin_max IS NULL + THEN NULL + WHEN bilirubin_max >= 2.0 + THEN 1 + WHEN pt_max > ( + 12 + 3 + ) + THEN 1 + WHEN pt_min < ( + 12 * 0.25 + ) + THEN 1 + ELSE 0 + END AS hepatic + FROM cohort ) - -, pafi1 AS ( - -- join blood gas to ventilation durations to determine if patient was vent - -- also join to cpap table for the same purpose - SELECT ie.stay_id, bg.charttime - , pao2fio2ratio - , CASE WHEN vd.stay_id IS NOT NULL THEN 1 ELSE 0 END AS vent - , CASE WHEN cp.stay_id IS NOT NULL THEN 1 ELSE 0 END AS cpap - FROM mimiciv_derived.bg bg - INNER JOIN mimiciv_icu.icustays ie - ON bg.hadm_id = ie.hadm_id - AND bg.charttime >= ie.intime AND bg.charttime < ie.outtime - LEFT JOIN mimiciv_derived.ventilation vd - ON ie.stay_id = vd.stay_id - AND bg.charttime >= vd.starttime - AND bg.charttime <= vd.endtime - AND vd.ventilation_status = 'InvasiveVent' - LEFT JOIN cpap cp - ON ie.stay_id = cp.stay_id - AND bg.charttime >= cp.starttime - AND bg.charttime <= cp.endtime -) - -, pafi2 AS ( - -- get the minimum PaO2/FiO2 ratio *only for ventilated/cpap patients* - SELECT stay_id - , MIN(pao2fio2ratio) AS pao2fio2_vent_min - FROM pafi1 - WHERE vent = 1 OR cpap = 1 - GROUP BY stay_id -) - -, cohort AS ( - SELECT ie.subject_id - , ie.hadm_id - , ie.stay_id - , ie.intime - , ie.outtime - - , gcs.gcs_min - , vital.heart_rate_max - , vital.heart_rate_min - , vital.sbp_max - , vital.sbp_min - - -- this value is non-null iff the patient is on vent/cpap - , pf.pao2fio2_vent_min - - , labs.bun_max - , labs.bun_min - , labs.wbc_max - , labs.wbc_min - , labs.bilirubin_total_max AS bilirubin_max - , labs.creatinine_max - , labs.pt_min - , labs.pt_max - , labs.platelets_min AS platelet_min - - , uo.urineoutput - - FROM mimiciv_icu.icustays ie - INNER JOIN mimiciv_hosp.admissions adm - ON ie.hadm_id = adm.hadm_id - INNER JOIN mimiciv_hosp.patients pat - ON ie.subject_id = pat.subject_id - - -- join to above view to get pao2/fio2 ratio - LEFT JOIN pafi2 pf - ON ie.stay_id = pf.stay_id - - -- join to custom tables to get more data.... - LEFT JOIN mimiciv_derived.first_day_gcs gcs - ON ie.stay_id = gcs.stay_id - LEFT JOIN mimiciv_derived.first_day_vitalsign vital - ON ie.stay_id = vital.stay_id - LEFT JOIN mimiciv_derived.first_day_urine_output uo - ON ie.stay_id = uo.stay_id - LEFT JOIN mimiciv_derived.first_day_lab labs - ON ie.stay_id = labs.stay_id -) - -, scorecomp AS ( - SELECT - cohort.* - -- Below code calculates the component scores needed for SAPS - - -- neurologic - , CASE - WHEN gcs_min IS NULL THEN null - WHEN gcs_min < 3 THEN null -- erroneous value/on trach - WHEN gcs_min <= 5 THEN 5 - WHEN gcs_min <= 8 THEN 3 - WHEN gcs_min <= 13 THEN 1 - ELSE 0 - END AS neurologic - - -- cardiovascular - , CASE - WHEN heart_rate_max IS NULL - AND sbp_min IS NULL THEN null - WHEN heart_rate_min < 30 THEN 5 - WHEN sbp_min < 40 THEN 5 - WHEN sbp_min < 70 THEN 3 - WHEN sbp_max >= 270 THEN 3 - WHEN heart_rate_max >= 140 THEN 1 - WHEN sbp_max >= 240 THEN 1 - WHEN sbp_min < 90 THEN 1 - ELSE 0 - END AS cardiovascular - - -- renal - , CASE - WHEN bun_max IS NULL - OR urineoutput IS NULL - OR creatinine_max IS NULL - THEN null - WHEN urineoutput < 500.0 THEN 5 - WHEN bun_max >= 56.0 THEN 5 - WHEN creatinine_max >= 1.60 THEN 3 - WHEN urineoutput < 750.0 THEN 3 - WHEN bun_max >= 28.0 THEN 3 - WHEN urineoutput >= 10000.0 THEN 3 - WHEN creatinine_max >= 1.20 THEN 1 - WHEN bun_max >= 17.0 THEN 1 - WHEN bun_max >= 7.50 THEN 1 - ELSE 0 - END AS renal - - -- pulmonary - , CASE - WHEN pao2fio2_vent_min IS NULL THEN 0 - WHEN pao2fio2_vent_min >= 150 THEN 1 - WHEN pao2fio2_vent_min < 150 THEN 3 - ELSE null - END AS pulmonary - - -- hematologic - , CASE - WHEN wbc_max IS NULL - AND platelet_min IS NULL - THEN null - WHEN wbc_min < 1.0 THEN 3 - WHEN wbc_min < 2.5 THEN 1 - WHEN platelet_min < 50.0 THEN 1 - WHEN wbc_max >= 50.0 THEN 1 - ELSE 0 - END AS hematologic - - -- hepatic - -- We have defined the "standard" PT as 12 seconds. - -- This is an assumption and subsequent analyses may be - -- affected by this assumption. - , CASE - WHEN pt_max IS NULL - AND bilirubin_max IS NULL - THEN null - WHEN bilirubin_max >= 2.0 THEN 1 - WHEN pt_max > (12 + 3) THEN 1 - WHEN pt_min < (12 * 0.25) THEN 1 - ELSE 0 - END AS hepatic - - FROM cohort -) - -SELECT ie.subject_id, ie.hadm_id, ie.stay_id - -- coalesce statements impute normal score of zero if NULL - , COALESCE(neurologic, 0) - + COALESCE(cardiovascular, 0) - + COALESCE(renal, 0) - + COALESCE(pulmonary, 0) - + COALESCE(hematologic, 0) - + COALESCE(hepatic, 0) - AS lods - , neurologic - , cardiovascular - , renal - , pulmonary - , hematologic - , hepatic -FROM mimiciv_icu.icustays ie -LEFT JOIN scorecomp s - ON ie.stay_id = s.stay_id -; +SELECT + ie.subject_id, + ie.hadm_id, + ie.stay_id, /* coalesce statements impute normal score of zero if NULL */ + COALESCE(neurologic, 0) + COALESCE(cardiovascular, 0) + COALESCE(renal, 0) + COALESCE(pulmonary, 0) + COALESCE(hematologic, 0) + COALESCE(hepatic, 0) AS lods, + neurologic, + cardiovascular, + renal, + pulmonary, + hematologic, + hepatic +FROM mimiciv_icu.icustays AS ie +LEFT JOIN scorecomp AS s + ON ie.stay_id = s.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/score/oasis.sql b/mimic-iv/concepts_postgres/score/oasis.sql index 3fcd8b8e6..75bf5bd02 100644 --- a/mimic-iv/concepts_postgres/score/oasis.sql +++ b/mimic-iv/concepts_postgres/score/oasis.sql @@ -1,289 +1,328 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS oasis; CREATE TABLE oasis AS --- ------------------------------------------------------------------ --- Title: Oxford Acute Severity of Illness Score (oasis) --- This query extracts the Oxford acute severity of illness score. --- This score is a measure of severity of illness for patients in the ICU. --- The score is calculated on the first day of each ICU patients' stay. --- ------------------------------------------------------------------ - --- Reference for OASIS: --- Johnson, Alistair EW, Andrew A. Kramer, and Gari D. Clifford. --- A new severity of illness scale using a subset of acute physiology --- and chronic health evaluation data elements shows comparable --- predictive accuracy*. --- Critical care medicine 41, no. 7 (2013): 1711-1718. - --- Variables used in OASIS: --- Heart rate, GCS, MAP, Temperature, Respiratory rate, Ventilation status --- (from chartevents) --- Urine output (from outputevents) --- Elective surgery (from admissions and services) --- Pre-ICU in-hospital length of stay (from admissions and icustays) --- Age (from patients) - --- Regarding missing values: --- The ventilation flag is always 0/1. It cannot be missing, --- since VENT=0 if no data is found for vent settings. - --- Note: --- The score is calculated for *all* ICU patients, with the assumption --- that the user will subselect appropriate stay_ids. - - +DROP TABLE IF EXISTS mimiciv_derived.oasis; CREATE TABLE mimiciv_derived.oasis AS +/* ------------------------------------------------------------------ */ /* Title: Oxford Acute Severity of Illness Score (oasis) */ /* This query extracts the Oxford acute severity of illness score. */ /* This score is a measure of severity of illness for patients in the ICU. */ /* The score is calculated on the first day of each ICU patients' stay. */ /* ------------------------------------------------------------------ */ /* Reference for OASIS: */ /* Johnson, Alistair EW, Andrew A. Kramer, and Gari D. Clifford. */ /* A new severity of illness scale using a subset of acute physiology */ /* and chronic health evaluation data elements shows comparable */ /* predictive accuracy*. */ /* Critical care medicine 41, no. 7 (2013): 1711-1718. */ /* Variables used in OASIS: */ /* Heart rate, GCS, MAP, Temperature, Respiratory rate, Ventilation status */ /* (from chartevents) */ /* Urine output (from outputevents) */ /* Elective surgery (from admissions and services) */ /* Pre-ICU in-hospital length of stay (from admissions and icustays) */ /* Age (from patients) */ /* Regarding missing values: */ /* The ventilation flag is always 0/1. It cannot be missing, */ /* since VENT=0 if no data is found for vent settings. */ /* Note: */ /* The score is calculated for *all* ICU patients, with the assumption */ /* that the user will subselect appropriate stay_ids. */ WITH surgflag AS ( - SELECT ie.stay_id - , MAX(CASE - WHEN LOWER(curr_service) LIKE '%surg%' THEN 1 - WHEN curr_service = 'ORTHO' THEN 1 - ELSE 0 END) AS surgical - FROM mimiciv_icu.icustays ie - LEFT JOIN mimiciv_hosp.services se - ON ie.hadm_id = se.hadm_id - AND se.transfertime < DATETIME_ADD(ie.intime, INTERVAL '1' DAY) - GROUP BY ie.stay_id + SELECT + ie.stay_id, + MAX( + CASE + WHEN LOWER(curr_service) LIKE '%surg%' + THEN 1 + WHEN curr_service = 'ORTHO' + THEN 1 + ELSE 0 + END + ) AS surgical + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_hosp.services AS se + ON ie.hadm_id = se.hadm_id AND se.transfertime < ie.intime + INTERVAL '1 DAY' + GROUP BY + ie.stay_id +), vent AS ( + SELECT + ie.stay_id, + MAX(CASE WHEN NOT v.stay_id IS NULL THEN 1 ELSE 0 END) AS vent + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.ventilation AS v + ON ie.stay_id = v.stay_id + AND v.ventilation_status = 'InvasiveVent' + AND ( + ( + v.starttime >= ie.intime AND v.starttime <= ie.intime + INTERVAL '1 DAY' + ) + OR ( + v.endtime >= ie.intime AND v.endtime <= ie.intime + INTERVAL '1 DAY' + ) + OR ( + v.starttime <= ie.intime AND v.endtime >= ie.intime + INTERVAL '1 DAY' + ) + ) + GROUP BY + ie.stay_id +), cohort AS ( + SELECT + ie.subject_id, + ie.hadm_id, + ie.stay_id, + ie.intime, + ie.outtime, + adm.deathtime, + EXTRACT(EPOCH FROM ie.intime - adm.admittime) / 60.0 AS preiculos, + ag.age, + gcs.gcs_min, + vital.heart_rate_max, + vital.heart_rate_min, + vital.mbp_max, + vital.mbp_min, + vital.resp_rate_max, + vital.resp_rate_min, + vital.temperature_max, + vital.temperature_min, + vent.vent AS mechvent, + uo.urineoutput, + CASE + WHEN adm.admission_type = 'ELECTIVE' AND sf.surgical = 1 + THEN 1 + WHEN adm.admission_type IS NULL OR sf.surgical IS NULL + THEN NULL + ELSE 0 + END AS electivesurgery, /* mortality flags */ + CASE + WHEN adm.deathtime BETWEEN ie.intime AND ie.outtime + THEN 1 + WHEN adm.deathtime <= ie.intime + THEN 1 + WHEN adm.dischtime <= ie.outtime AND adm.discharge_location = 'DEAD/EXPIRED' + THEN 1 + ELSE 0 + END AS icustay_expire_flag, + adm.hospital_expire_flag + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_hosp.admissions AS adm + ON ie.hadm_id = adm.hadm_id + INNER JOIN mimiciv_hosp.patients AS pat + ON ie.subject_id = pat.subject_id + LEFT JOIN mimiciv_derived.age AS ag + ON ie.hadm_id = ag.hadm_id + LEFT JOIN surgflag AS sf + ON ie.stay_id = sf.stay_id + /* join to custom tables to get more data.... */ + LEFT JOIN mimiciv_derived.first_day_gcs AS gcs + ON ie.stay_id = gcs.stay_id + LEFT JOIN mimiciv_derived.first_day_vitalsign AS vital + ON ie.stay_id = vital.stay_id + LEFT JOIN mimiciv_derived.first_day_urine_output AS uo + ON ie.stay_id = uo.stay_id + LEFT JOIN vent + ON ie.stay_id = vent.stay_id +), scorecomp AS ( + SELECT + co.subject_id, + co.hadm_id, + co.stay_id, + co.icustay_expire_flag, + co.hospital_expire_flag, /* Below code calculates the component scores needed for oasis */ + CASE + WHEN preiculos IS NULL + THEN NULL + WHEN preiculos < 10.2 + THEN 5 + WHEN preiculos < 297 + THEN 3 + WHEN preiculos < 1440 + THEN 0 + WHEN preiculos < 18708 + THEN 2 + ELSE 1 + END AS preiculos_score, + CASE + WHEN age IS NULL + THEN NULL + WHEN age < 24 + THEN 0 + WHEN age <= 53 + THEN 3 + WHEN age <= 77 + THEN 6 + WHEN age <= 89 + THEN 9 + WHEN age >= 90 + THEN 7 + ELSE 0 + END AS age_score, + CASE + WHEN gcs_min IS NULL + THEN NULL + WHEN gcs_min <= 7 + THEN 10 + WHEN gcs_min < 14 + THEN 4 + WHEN gcs_min = 14 + THEN 3 + ELSE 0 + END AS gcs_score, + CASE + WHEN heart_rate_max IS NULL + THEN NULL + WHEN heart_rate_max > 125 + THEN 6 + WHEN heart_rate_min < 33 + THEN 4 + WHEN heart_rate_max >= 107 AND heart_rate_max <= 125 + THEN 3 + WHEN heart_rate_max >= 89 AND heart_rate_max <= 106 + THEN 1 + ELSE 0 + END AS heart_rate_score, + CASE + WHEN mbp_min IS NULL + THEN NULL + WHEN mbp_min < 20.65 + THEN 4 + WHEN mbp_min < 51 + THEN 3 + WHEN mbp_max > 143.44 + THEN 3 + WHEN mbp_min >= 51 AND mbp_min < 61.33 + THEN 2 + ELSE 0 + END AS mbp_score, + CASE + WHEN resp_rate_min IS NULL + THEN NULL + WHEN resp_rate_min < 6 + THEN 10 + WHEN resp_rate_max > 44 + THEN 9 + WHEN resp_rate_max > 30 + THEN 6 + WHEN resp_rate_max > 22 + THEN 1 + WHEN resp_rate_min < 13 + THEN 1 + ELSE 0 + END AS resp_rate_score, + CASE + WHEN temperature_max IS NULL + THEN NULL + WHEN temperature_max > 39.88 + THEN 6 + WHEN temperature_min >= 33.22 AND temperature_min <= 35.93 + THEN 4 + WHEN temperature_max >= 33.22 AND temperature_max <= 35.93 + THEN 4 + WHEN temperature_min < 33.22 + THEN 3 + WHEN temperature_min > 35.93 AND temperature_min <= 36.39 + THEN 2 + WHEN temperature_max >= 36.89 AND temperature_max <= 39.88 + THEN 2 + ELSE 0 + END AS temp_score, + CASE + WHEN urineoutput IS NULL + THEN NULL + WHEN urineoutput < 671.09 + THEN 10 + WHEN urineoutput > 6896.80 + THEN 8 + WHEN urineoutput >= 671.09 AND urineoutput <= 1426.99 + THEN 5 + WHEN urineoutput >= 1427.00 AND urineoutput <= 2544.14 + THEN 1 + ELSE 0 + END AS urineoutput_score, + CASE WHEN mechvent IS NULL THEN NULL WHEN mechvent = 1 THEN 9 ELSE 0 END AS mechvent_score, + CASE WHEN electivesurgery IS NULL THEN NULL WHEN electivesurgery = 1 THEN 0 ELSE 6 END AS electivesurgery_score, /* The below code gives the component associated with each score */ /* This is not needed to calculate oasis, but provided for */ /* user convenience. If both the min/max are in the normal range */ /* (score of 0), then the average value is stored. */ + preiculos, + age, + gcs_min AS gcs, + CASE + WHEN heart_rate_max IS NULL + THEN NULL + WHEN heart_rate_max > 125 + THEN heart_rate_max + WHEN heart_rate_min < 33 + THEN heart_rate_min + WHEN heart_rate_max >= 107 AND heart_rate_max <= 125 + THEN heart_rate_max + WHEN heart_rate_max >= 89 AND heart_rate_max <= 106 + THEN heart_rate_max + ELSE CAST(( + heart_rate_min + heart_rate_max + ) AS DOUBLE PRECISION) / 2 + END AS heartrate, + CASE + WHEN mbp_min IS NULL + THEN NULL + WHEN mbp_min < 20.65 + THEN mbp_min + WHEN mbp_min < 51 + THEN mbp_min + WHEN mbp_max > 143.44 + THEN mbp_max + WHEN mbp_min >= 51 AND mbp_min < 61.33 + THEN mbp_min + ELSE CAST(( + mbp_min + mbp_max + ) AS DOUBLE PRECISION) / 2 + END AS meanbp, + CASE + WHEN resp_rate_min IS NULL + THEN NULL + WHEN resp_rate_min < 6 + THEN resp_rate_min + WHEN resp_rate_max > 44 + THEN resp_rate_max + WHEN resp_rate_max > 30 + THEN resp_rate_max + WHEN resp_rate_max > 22 + THEN resp_rate_max + WHEN resp_rate_min < 13 + THEN resp_rate_min + ELSE CAST(( + resp_rate_min + resp_rate_max + ) AS DOUBLE PRECISION) / 2 + END AS resprate, + CASE + WHEN temperature_max IS NULL + THEN NULL + WHEN temperature_max > 39.88 + THEN temperature_max + WHEN temperature_min >= 33.22 AND temperature_min <= 35.93 + THEN temperature_min + WHEN temperature_max >= 33.22 AND temperature_max <= 35.93 + THEN temperature_max + WHEN temperature_min < 33.22 + THEN temperature_min + WHEN temperature_min > 35.93 AND temperature_min <= 36.39 + THEN temperature_min + WHEN temperature_max >= 36.89 AND temperature_max <= 39.88 + THEN temperature_max + ELSE CAST(( + temperature_min + temperature_max + ) AS DOUBLE PRECISION) / 2 + END AS temp, + urineoutput, + mechvent, + electivesurgery + FROM cohort AS co +), score AS ( + SELECT + s.*, + COALESCE(age_score, 0) + COALESCE(preiculos_score, 0) + COALESCE(gcs_score, 0) + COALESCE(heart_rate_score, 0) + COALESCE(mbp_score, 0) + COALESCE(resp_rate_score, 0) + COALESCE(temp_score, 0) + COALESCE(urineoutput_score, 0) + COALESCE(mechvent_score, 0) + COALESCE(electivesurgery_score, 0) AS oasis + FROM scorecomp AS s ) - --- first day ventilation -, vent AS ( - SELECT ie.stay_id - , MAX( - CASE WHEN v.stay_id IS NOT NULL THEN 1 ELSE 0 END - ) AS vent - FROM mimiciv_icu.icustays ie - LEFT JOIN mimiciv_derived.ventilation v - ON ie.stay_id = v.stay_id - AND v.ventilation_status = 'InvasiveVent' - AND ( - ( - v.starttime >= ie.intime - AND v.starttime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) - ) - OR ( - v.endtime >= ie.intime - AND v.endtime <= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) - ) - OR ( - v.starttime <= ie.intime - AND v.endtime >= DATETIME_ADD(ie.intime, INTERVAL '1' DAY) - ) - ) - GROUP BY ie.stay_id -) - -, cohort AS ( - SELECT ie.subject_id, ie.hadm_id, ie.stay_id - , ie.intime - , ie.outtime - , adm.deathtime - , DATETIME_DIFF(ie.intime, adm.admittime, 'MINUTE') AS preiculos - , ag.age - , gcs.gcs_min - , vital.heart_rate_max - , vital.heart_rate_min - , vital.mbp_max - , vital.mbp_min - , vital.resp_rate_max - , vital.resp_rate_min - , vital.temperature_max - , vital.temperature_min - , vent.vent AS mechvent - , uo.urineoutput - - , CASE - WHEN adm.admission_type = 'ELECTIVE' AND sf.surgical = 1 - THEN 1 - WHEN adm.admission_type IS NULL OR sf.surgical IS NULL - THEN null - ELSE 0 - END AS electivesurgery - - -- mortality flags - , CASE - WHEN adm.deathtime BETWEEN ie.intime AND ie.outtime - THEN 1 - -- sometimes there are typographical errors in the death date - WHEN adm.deathtime <= ie.intime - THEN 1 - WHEN adm.dischtime <= ie.outtime - AND adm.discharge_location = 'DEAD/EXPIRED' - THEN 1 - ELSE 0 END - AS icustay_expire_flag - , adm.hospital_expire_flag - FROM mimiciv_icu.icustays ie - INNER JOIN mimiciv_hosp.admissions adm - ON ie.hadm_id = adm.hadm_id - INNER JOIN mimiciv_hosp.patients pat - ON ie.subject_id = pat.subject_id - LEFT JOIN mimiciv_derived.age ag - ON ie.hadm_id = ag.hadm_id - LEFT JOIN surgflag sf - ON ie.stay_id = sf.stay_id - -- join to custom tables to get more data.... - LEFT JOIN mimiciv_derived.first_day_gcs gcs - ON ie.stay_id = gcs.stay_id - LEFT JOIN mimiciv_derived.first_day_vitalsign vital - ON ie.stay_id = vital.stay_id - LEFT JOIN mimiciv_derived.first_day_urine_output uo - ON ie.stay_id = uo.stay_id - LEFT JOIN vent - ON ie.stay_id = vent.stay_id -) - -, scorecomp AS ( - SELECT co.subject_id, co.hadm_id, co.stay_id - , co.icustay_expire_flag - , co.hospital_expire_flag - - -- Below code calculates the component scores needed for oasis - , CASE WHEN preiculos IS NULL THEN null - WHEN preiculos < 10.2 THEN 5 - WHEN preiculos < 297 THEN 3 - WHEN preiculos < 1440 THEN 0 - WHEN preiculos < 18708 THEN 1 - ELSE 2 END AS preiculos_score - , CASE WHEN age IS NULL THEN null - WHEN age < 24 THEN 0 - WHEN age <= 53 THEN 3 - WHEN age <= 77 THEN 6 - WHEN age <= 89 THEN 9 - WHEN age >= 90 THEN 7 - ELSE 0 END AS age_score - , CASE WHEN gcs_min IS NULL THEN null - WHEN gcs_min <= 7 THEN 10 - WHEN gcs_min < 14 THEN 4 - WHEN gcs_min = 14 THEN 3 - ELSE 0 END AS gcs_score - , CASE WHEN heart_rate_max IS NULL THEN null - WHEN heart_rate_max > 125 THEN 6 - WHEN heart_rate_min < 33 THEN 4 - WHEN heart_rate_max >= 107 AND heart_rate_max <= 125 THEN 3 - WHEN heart_rate_max >= 89 AND heart_rate_max <= 106 THEN 1 - ELSE 0 END AS heart_rate_score - , CASE WHEN mbp_min IS NULL THEN null - WHEN mbp_min < 20.65 THEN 4 - WHEN mbp_min < 51 THEN 3 - WHEN mbp_max > 143.44 THEN 3 - WHEN mbp_min >= 51 AND mbp_min < 61.33 THEN 2 - ELSE 0 END AS mbp_score - , CASE WHEN resp_rate_min IS NULL THEN null - WHEN resp_rate_min < 6 THEN 10 - WHEN resp_rate_max > 44 THEN 9 - WHEN resp_rate_max > 30 THEN 6 - WHEN resp_rate_max > 22 THEN 1 - WHEN resp_rate_min < 13 THEN 1 ELSE 0 - END AS resp_rate_score - , CASE WHEN temperature_max IS NULL THEN null - WHEN temperature_max > 39.88 THEN 6 - WHEN - temperature_min >= 33.22 AND temperature_min <= 35.93 THEN 4 - WHEN - temperature_max >= 33.22 AND temperature_max <= 35.93 THEN 4 - WHEN temperature_min < 33.22 THEN 3 - WHEN temperature_min > 35.93 AND temperature_min <= 36.39 THEN 2 - WHEN - temperature_max >= 36.89 AND temperature_max <= 39.88 THEN 2 - ELSE 0 END AS temp_score - , CASE WHEN urineoutput IS NULL THEN null - WHEN urineoutput < 671.09 THEN 10 - WHEN urineoutput > 6896.80 THEN 8 - WHEN urineoutput >= 671.09 - AND urineoutput <= 1426.99 THEN 5 - WHEN urineoutput >= 1427.00 - AND urineoutput <= 2544.14 THEN 1 - ELSE 0 END AS urineoutput_score - , CASE WHEN mechvent IS NULL THEN null - WHEN mechvent = 1 THEN 9 - ELSE 0 END AS mechvent_score - , CASE WHEN electivesurgery IS NULL THEN null - WHEN electivesurgery = 1 THEN 0 - ELSE 6 END AS electivesurgery_score - - - -- The below code gives the component associated with each score - -- This is not needed to calculate oasis, but provided for - -- user convenience. If both the min/max are in the normal range - -- (score of 0), then the average value is stored. - , preiculos - , age - , gcs_min AS gcs - , CASE WHEN heart_rate_max IS NULL THEN null - WHEN heart_rate_max > 125 THEN heart_rate_max - WHEN heart_rate_min < 33 THEN heart_rate_min - WHEN heart_rate_max >= 107 - AND heart_rate_max <= 125 - THEN heart_rate_max - WHEN heart_rate_max >= 89 - AND heart_rate_max <= 106 - THEN heart_rate_max - ELSE (heart_rate_min + heart_rate_max) / 2 END AS heartrate - , CASE WHEN mbp_min IS NULL THEN null - WHEN mbp_min < 20.65 THEN mbp_min - WHEN mbp_min < 51 THEN mbp_min - WHEN mbp_max > 143.44 THEN mbp_max - WHEN mbp_min >= 51 AND mbp_min < 61.33 THEN mbp_min - ELSE (mbp_min + mbp_max) / 2 END AS meanbp - , CASE WHEN resp_rate_min IS NULL THEN null - WHEN resp_rate_min < 6 THEN resp_rate_min - WHEN resp_rate_max > 44 THEN resp_rate_max - WHEN resp_rate_max > 30 THEN resp_rate_max - WHEN resp_rate_max > 22 THEN resp_rate_max - WHEN resp_rate_min < 13 THEN resp_rate_min - ELSE (resp_rate_min + resp_rate_max) / 2 END AS resprate - , CASE WHEN temperature_max IS NULL THEN null - WHEN temperature_max > 39.88 THEN temperature_max - WHEN temperature_min >= 33.22 - AND temperature_min <= 35.93 - THEN temperature_min - WHEN temperature_max >= 33.22 - AND temperature_max <= 35.93 - THEN temperature_max - WHEN temperature_min < 33.22 - THEN temperature_min - WHEN temperature_min > 35.93 - AND temperature_min <= 36.39 - THEN temperature_min - WHEN temperature_max >= 36.89 - AND temperature_max <= 39.88 - THEN temperature_max - ELSE (temperature_min + temperature_max) / 2 END AS temp - , urineoutput - , mechvent - , electivesurgery - FROM cohort co -) - -, score AS ( - SELECT s.* - , COALESCE(age_score, 0) - + COALESCE(preiculos_score, 0) - + COALESCE(gcs_score, 0) - + COALESCE(heart_rate_score, 0) - + COALESCE(mbp_score, 0) - + COALESCE(resp_rate_score, 0) - + COALESCE(temp_score, 0) - + COALESCE(urineoutput_score, 0) - + COALESCE(mechvent_score, 0) - + COALESCE(electivesurgery_score, 0) - AS oasis - FROM scorecomp s -) - SELECT - subject_id, hadm_id, stay_id - , oasis - -- Calculate the probability of in-hospital mortality - , 1 / (1 + EXP(- (-6.1746 + 0.1275 * (oasis)))) AS oasis_prob - , age, age_score - , preiculos, preiculos_score - , gcs, gcs_score - , heartrate, heart_rate_score - , meanbp, mbp_score - , resprate, resp_rate_score - , temp, temp_score - , urineoutput, urineoutput_score - , mechvent, mechvent_score - , electivesurgery, electivesurgery_score -FROM score -; + subject_id, + hadm_id, + stay_id, + oasis, /* Calculate the probability of in-hospital mortality */ + CAST(1 AS DOUBLE PRECISION) / ( + 1 + EXP(-( + -6.1746 + 0.1275 * ( + oasis + ) + )) + ) AS oasis_prob, + age, + age_score, + preiculos, + preiculos_score, + gcs, + gcs_score, + heartrate, + heart_rate_score, + meanbp, + mbp_score, + resprate, + resp_rate_score, + temp, + temp_score, + urineoutput, + urineoutput_score, + mechvent, + mechvent_score, + electivesurgery, + electivesurgery_score +FROM score \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/score/sapsii.sql b/mimic-iv/concepts_postgres/score/sapsii.sql index ee7ca2ce9..aa19ee064 100644 --- a/mimic-iv/concepts_postgres/score/sapsii.sql +++ b/mimic-iv/concepts_postgres/score/sapsii.sql @@ -1,551 +1,476 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS sapsii; CREATE TABLE sapsii AS --- ------------------------------------------------------------------ --- Title: Simplified Acute Physiology Score II (SAPS II) --- This query extracts the simplified acute physiology score II. --- This score is a measure of patient severity of illness. --- The score is calculated on the first day of each ICU patients' stay. --- ------------------------------------------------------------------ - --- Reference for SAPS II: --- Le Gall, Jean-Roger, Stanley Lemeshow, and Fabienne Saulnier. --- "A new simplified acute physiology score (SAPS II) based on --- a European/North American multicenter study." --- JAMA 270, no. 24 (1993): 2957-2963. - --- Variables used in SAPS II: --- Age, GCS --- VITALS: Heart rate, systolic blood pressure, temperature --- FLAGS: ventilation/cpap --- IO: urine output --- LABS: PaO2/FiO2 ratio, blood urea nitrogen, WBC, --- potassium, sodium, HCO3 +DROP TABLE IF EXISTS mimiciv_derived.sapsii; CREATE TABLE mimiciv_derived.sapsii AS +/* ------------------------------------------------------------------ */ /* Title: Simplified Acute Physiology Score II (SAPS II) */ /* This query extracts the simplified acute physiology score II. */ /* This score is a measure of patient severity of illness. */ /* The score is calculated on the first day of each ICU patients' stay. */ /* ------------------------------------------------------------------ */ /* Reference for SAPS II: */ /* Le Gall, Jean-Roger, Stanley Lemeshow, and Fabienne Saulnier. */ /* "A new simplified acute physiology score (SAPS II) based on */ /* a European/North American multicenter study." */ /* JAMA 270, no. 24 (1993): 2957-2963. */ /* Variables used in SAPS II: */ /* Age, GCS */ /* VITALS: Heart rate, systolic blood pressure, temperature */ /* FLAGS: ventilation/cpap */ /* IO: urine output */ /* LABS: PaO2/FiO2 ratio, blood urea nitrogen, WBC, */ /* potassium, sodium, HCO3 */ WITH co AS ( - SELECT - subject_id - , hadm_id - , stay_id - , intime AS starttime - , DATETIME_ADD(intime, INTERVAL '24' HOUR) AS endtime - FROM mimiciv_icu.icustays + SELECT + subject_id, + hadm_id, + stay_id, + intime AS starttime, + intime + INTERVAL '24 HOUR' AS endtime + FROM mimiciv_icu.icustays +), cpap AS ( + SELECT + co.subject_id, + co.stay_id, + GREATEST(MIN(charttime - INTERVAL '1 HOUR'), co.starttime) AS starttime, + LEAST(MAX(charttime + INTERVAL '4 HOUR'), co.endtime) AS endtime, + MAX(CASE WHEN LOWER(ce.value) ~ '(cpap mask|bipap)' THEN 1 ELSE 0 END) AS cpap + FROM co + INNER JOIN mimiciv_icu.chartevents AS ce + ON co.stay_id = ce.stay_id AND ce.charttime > co.starttime AND ce.charttime <= co.endtime + WHERE + ce.itemid = 226732 AND LOWER(ce.value) ~ '(cpap mask|bipap)' + GROUP BY + co.subject_id, + co.stay_id, + co.starttime, + co.endtime +), surgflag AS ( + SELECT + adm.hadm_id, + CASE WHEN LOWER(curr_service) LIKE '%surg%' THEN 1 ELSE 0 END AS surgical, + ROW_NUMBER() OVER (PARTITION BY adm.hadm_id ORDER BY transfertime NULLS FIRST) AS serviceorder + FROM mimiciv_hosp.admissions AS adm + LEFT JOIN mimiciv_hosp.services AS se + ON adm.hadm_id = se.hadm_id +), comorb AS ( + SELECT + hadm_id, /* these are slightly different than elixhauser comorbidities, */ /* but based on them they include some non-comorbid ICD-9 codes */ /* (e.g. 20302, relapse of multiple myeloma) */ + MAX( + CASE + WHEN icd_version = 9 AND SUBSTR(icd_code, 1, 3) BETWEEN '042' AND '044' + THEN 1 + WHEN icd_version = 10 AND SUBSTR(icd_code, 1, 3) BETWEEN 'B20' AND 'B22' + THEN 1 + WHEN icd_version = 10 AND SUBSTR(icd_code, 1, 3) = 'B24' + THEN 1 + ELSE 0 + END + ) AS aids, /* HIV and AIDS */ + MAX( + CASE + WHEN icd_version = 9 + THEN CASE + WHEN SUBSTR(icd_code, 1, 5) BETWEEN '20000' AND '20238' + THEN 1 + WHEN SUBSTR(icd_code, 1, 5) BETWEEN '20240' AND '20248' + THEN 1 + WHEN SUBSTR(icd_code, 1, 5) BETWEEN '20250' AND '20302' + THEN 1 + WHEN SUBSTR(icd_code, 1, 5) BETWEEN '20310' AND '20312' + THEN 1 + WHEN SUBSTR(icd_code, 1, 5) BETWEEN '20302' AND '20382' + THEN 1 + WHEN SUBSTR(icd_code, 1, 5) BETWEEN '20400' AND '20522' + THEN 1 + WHEN SUBSTR(icd_code, 1, 5) BETWEEN '20580' AND '20702' + THEN 1 + WHEN SUBSTR(icd_code, 1, 5) BETWEEN '20720' AND '20892' + THEN 1 + WHEN SUBSTR(icd_code, 1, 4) IN ('2386', '2733') + THEN 1 + ELSE 0 + END + WHEN icd_version = 10 AND SUBSTR(icd_code, 1, 3) BETWEEN 'C81' AND 'C96' + THEN 1 + ELSE 0 + END + ) AS hem, + MAX( + CASE + WHEN icd_version = 9 + THEN CASE + WHEN SUBSTR(icd_code, 1, 4) BETWEEN '1960' AND '1991' + THEN 1 + WHEN SUBSTR(icd_code, 1, 5) BETWEEN '20970' AND '20975' + THEN 1 + WHEN SUBSTR(icd_code, 1, 5) IN ('20979', '78951') + THEN 1 + ELSE 0 + END + WHEN icd_version = 10 AND SUBSTR(icd_code, 1, 3) BETWEEN 'C77' AND 'C79' + THEN 1 + WHEN icd_version = 10 AND SUBSTR(icd_code, 1, 4) = 'C800' + THEN 1 + ELSE 0 + END + ) AS mets /* Metastatic cancer */ + FROM mimiciv_hosp.diagnoses_icd + GROUP BY + hadm_id +), pafi1 AS ( + /* join blood gas to ventilation durations to determine if patient was vent */ /* also join to cpap table for the same purpose */ + SELECT + co.stay_id, + bg.charttime, + pao2fio2ratio AS pao2fio2, + CASE WHEN NOT vd.stay_id IS NULL THEN 1 ELSE 0 END AS vent, + CASE WHEN NOT cp.subject_id IS NULL THEN 1 ELSE 0 END AS cpap + FROM co + LEFT JOIN mimiciv_derived.bg AS bg + ON co.subject_id = bg.subject_id + AND bg.specimen = 'ART.' + AND bg.charttime > co.starttime + AND bg.charttime <= co.endtime + LEFT JOIN mimiciv_derived.ventilation AS vd + ON co.stay_id = vd.stay_id + AND bg.charttime > vd.starttime + AND bg.charttime <= vd.endtime + AND vd.ventilation_status = 'InvasiveVent' + LEFT JOIN cpap AS cp + ON bg.subject_id = cp.subject_id + AND bg.charttime > cp.starttime + AND bg.charttime <= cp.endtime +), pafi2 AS ( + /* get the minimum PaO2/FiO2 ratio *only for ventilated/cpap patients* */ + SELECT + stay_id, + MIN(pao2fio2) AS pao2fio2_vent_min + FROM pafi1 + WHERE + vent = 1 OR cpap = 1 + GROUP BY + stay_id +), gcs AS ( + SELECT + co.stay_id, + MIN(gcs.gcs) AS mingcs + FROM co + LEFT JOIN mimiciv_derived.gcs AS gcs + ON co.stay_id = gcs.stay_id AND co.starttime < gcs.charttime AND gcs.charttime <= co.endtime + GROUP BY + co.stay_id +), vital AS ( + SELECT + co.stay_id, + MIN(vital.heart_rate) AS heartrate_min, + MAX(vital.heart_rate) AS heartrate_max, + MIN(vital.sbp) AS sysbp_min, + MAX(vital.sbp) AS sysbp_max, + MIN(vital.temperature) AS tempc_min, + MAX(vital.temperature) AS tempc_max + FROM co + LEFT JOIN mimiciv_derived.vitalsign AS vital + ON co.subject_id = vital.subject_id + AND co.starttime < vital.charttime + AND co.endtime >= vital.charttime + GROUP BY + co.stay_id +), uo AS ( + SELECT + co.stay_id, + SUM(uo.urineoutput) AS urineoutput + FROM co + LEFT JOIN mimiciv_derived.urine_output AS uo + ON co.stay_id = uo.stay_id AND co.starttime < uo.charttime AND co.endtime >= uo.charttime + GROUP BY + co.stay_id +), labs AS ( + SELECT + co.stay_id, + MIN(labs.bun) AS bun_min, + MAX(labs.bun) AS bun_max, + MIN(labs.potassium) AS potassium_min, + MAX(labs.potassium) AS potassium_max, + MIN(labs.sodium) AS sodium_min, + MAX(labs.sodium) AS sodium_max, + MIN(labs.bicarbonate) AS bicarbonate_min, + MAX(labs.bicarbonate) AS bicarbonate_max + FROM co + LEFT JOIN mimiciv_derived.chemistry AS labs + ON co.subject_id = labs.subject_id + AND co.starttime < labs.charttime + AND co.endtime >= labs.charttime + GROUP BY + co.stay_id +), cbc AS ( + SELECT + co.stay_id, + MIN(cbc.wbc) AS wbc_min, + MAX(cbc.wbc) AS wbc_max + FROM co + LEFT JOIN mimiciv_derived.complete_blood_count AS cbc + ON co.subject_id = cbc.subject_id + AND co.starttime < cbc.charttime + AND co.endtime >= cbc.charttime + GROUP BY + co.stay_id +), enz AS ( + SELECT + co.stay_id, + MIN(enz.bilirubin_total) AS bilirubin_min, + MAX(enz.bilirubin_total) AS bilirubin_max + FROM co + LEFT JOIN mimiciv_derived.enzyme AS enz + ON co.subject_id = enz.subject_id + AND co.starttime < enz.charttime + AND co.endtime >= enz.charttime + GROUP BY + co.stay_id +), cohort AS ( + SELECT + ie.subject_id, + ie.hadm_id, + ie.stay_id, + ie.intime, + ie.outtime, + va.age, + co.starttime, + co.endtime, + vital.heartrate_max, + vital.heartrate_min, + vital.sysbp_max, + vital.sysbp_min, + vital.tempc_max, + vital.tempc_min, /* this value is non-null iff the patient is on vent/cpap */ + pf.pao2fio2_vent_min, + uo.urineoutput, + labs.bun_min, + labs.bun_max, + cbc.wbc_min, + cbc.wbc_max, + labs.potassium_min, + labs.potassium_max, + labs.sodium_min, + labs.sodium_max, + labs.bicarbonate_min, + labs.bicarbonate_max, + enz.bilirubin_min, + enz.bilirubin_max, + gcs.mingcs, + comorb.aids, + comorb.hem, + comorb.mets, + CASE + WHEN adm.admission_type = 'ELECTIVE' AND sf.surgical = 1 + THEN 'ScheduledSurgical' + WHEN adm.admission_type <> 'ELECTIVE' AND sf.surgical = 1 + THEN 'UnscheduledSurgical' + ELSE 'Medical' + END AS admissiontype + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_hosp.admissions AS adm + ON ie.hadm_id = adm.hadm_id + LEFT JOIN mimiciv_derived.age AS va + ON ie.hadm_id = va.hadm_id + INNER JOIN co + ON ie.stay_id = co.stay_id + /* join to above views */ + LEFT JOIN pafi2 AS pf + ON ie.stay_id = pf.stay_id + LEFT JOIN surgflag AS sf + ON adm.hadm_id = sf.hadm_id AND sf.serviceorder = 1 + LEFT JOIN comorb + ON ie.hadm_id = comorb.hadm_id + /* join to custom tables to get more data.... */ + LEFT JOIN gcs AS gcs + ON ie.stay_id = gcs.stay_id + LEFT JOIN vital + ON ie.stay_id = vital.stay_id + LEFT JOIN uo + ON ie.stay_id = uo.stay_id + LEFT JOIN labs + ON ie.stay_id = labs.stay_id + LEFT JOIN cbc + ON ie.stay_id = cbc.stay_id + LEFT JOIN enz + ON ie.stay_id = enz.stay_id +), scorecomp AS ( + SELECT + cohort.*, /* Below code calculates the component scores needed for SAPS */ + CASE + WHEN age IS NULL + THEN NULL + WHEN age < 40 + THEN 0 + WHEN age < 60 + THEN 7 + WHEN age < 70 + THEN 12 + WHEN age < 75 + THEN 15 + WHEN age < 80 + THEN 16 + WHEN age >= 80 + THEN 18 + END AS age_score, + CASE + WHEN heartrate_max IS NULL + THEN NULL + WHEN heartrate_min < 40 + THEN 11 + WHEN heartrate_max >= 160 + THEN 7 + WHEN heartrate_max >= 120 + THEN 4 + WHEN heartrate_min < 70 + THEN 2 + WHEN heartrate_max >= 70 AND heartrate_max < 120 AND heartrate_min >= 70 AND heartrate_min < 120 + THEN 0 + END AS hr_score, + CASE + WHEN sysbp_min IS NULL + THEN NULL + WHEN sysbp_min < 70 + THEN 13 + WHEN sysbp_min < 100 + THEN 5 + WHEN sysbp_max >= 200 + THEN 2 + WHEN sysbp_max >= 100 AND sysbp_max < 200 AND sysbp_min >= 100 AND sysbp_min < 200 + THEN 0 + END AS sysbp_score, + CASE + WHEN tempc_max IS NULL + THEN NULL + WHEN tempc_max >= 39.0 + THEN 3 + WHEN tempc_min < 39.0 + THEN 0 + END AS temp_score, + CASE + WHEN pao2fio2_vent_min IS NULL + THEN NULL + WHEN pao2fio2_vent_min < 100 + THEN 11 + WHEN pao2fio2_vent_min < 200 + THEN 9 + WHEN pao2fio2_vent_min >= 200 + THEN 6 + END AS pao2fio2_score, + CASE + WHEN urineoutput IS NULL + THEN NULL + WHEN urineoutput < 500.0 + THEN 11 + WHEN urineoutput < 1000.0 + THEN 4 + WHEN urineoutput >= 1000.0 + THEN 0 + END AS uo_score, + CASE + WHEN bun_max IS NULL + THEN NULL + WHEN bun_max < 28.0 + THEN 0 + WHEN bun_max < 84.0 + THEN 6 + WHEN bun_max >= 84.0 + THEN 10 + END AS bun_score, + CASE + WHEN wbc_max IS NULL + THEN NULL + WHEN wbc_min < 1.0 + THEN 12 + WHEN wbc_max >= 20.0 + THEN 3 + WHEN wbc_max >= 1.0 AND wbc_max < 20.0 AND wbc_min >= 1.0 AND wbc_min < 20.0 + THEN 0 + END AS wbc_score, + CASE + WHEN potassium_max IS NULL + THEN NULL + WHEN potassium_min < 3.0 + THEN 3 + WHEN potassium_max >= 5.0 + THEN 3 + WHEN potassium_max >= 3.0 AND potassium_max < 5.0 AND potassium_min >= 3.0 AND potassium_min < 5.0 + THEN 0 + END AS potassium_score, + CASE + WHEN sodium_max IS NULL + THEN NULL + WHEN sodium_min < 125 + THEN 5 + WHEN sodium_max >= 145 + THEN 1 + WHEN sodium_max >= 125 AND sodium_max < 145 AND sodium_min >= 125 AND sodium_min < 145 + THEN 0 + END AS sodium_score, + CASE + WHEN bicarbonate_max IS NULL + THEN NULL + WHEN bicarbonate_min < 15.0 + THEN 6 + WHEN bicarbonate_min < 20.0 + THEN 3 + WHEN bicarbonate_max >= 20.0 AND bicarbonate_min >= 20.0 + THEN 0 + END AS bicarbonate_score, + CASE + WHEN bilirubin_max IS NULL + THEN NULL + WHEN bilirubin_max < 4.0 + THEN 0 + WHEN bilirubin_max < 6.0 + THEN 4 + WHEN bilirubin_max >= 6.0 + THEN 9 + END AS bilirubin_score, + CASE + WHEN mingcs IS NULL + THEN NULL + WHEN mingcs < 3 + THEN NULL /* erroneous value/on trach */ + WHEN mingcs < 6 + THEN 26 + WHEN mingcs < 9 + THEN 13 + WHEN mingcs < 11 + THEN 7 + WHEN mingcs < 14 + THEN 5 + WHEN mingcs >= 14 AND mingcs <= 15 + THEN 0 + END AS gcs_score, + CASE WHEN aids = 1 THEN 17 WHEN hem = 1 THEN 10 WHEN mets = 1 THEN 9 ELSE 0 END AS comorbidity_score, + CASE + WHEN admissiontype = 'ScheduledSurgical' + THEN 0 + WHEN admissiontype = 'Medical' + THEN 6 + WHEN admissiontype = 'UnscheduledSurgical' + THEN 8 + ELSE NULL + END AS admissiontype_score + FROM cohort +), score AS ( + SELECT + s.*, /* coalesce statements impute normal score */ /* of zero if data element is missing */ + COALESCE(age_score, 0) + COALESCE(hr_score, 0) + COALESCE(sysbp_score, 0) + COALESCE(temp_score, 0) + COALESCE(pao2fio2_score, 0) + COALESCE(uo_score, 0) + COALESCE(bun_score, 0) + COALESCE(wbc_score, 0) + COALESCE(potassium_score, 0) + COALESCE(sodium_score, 0) + COALESCE(bicarbonate_score, 0) + COALESCE(bilirubin_score, 0) + COALESCE(gcs_score, 0) + COALESCE(comorbidity_score, 0) + COALESCE(admissiontype_score, 0) AS sapsii + FROM scorecomp AS s ) - -, cpap AS ( - SELECT - co.subject_id - , co.stay_id - , GREATEST( - MIN(DATETIME_SUB(charttime, INTERVAL '1' HOUR)), co.starttime - ) AS starttime - , LEAST( - MAX(DATETIME_ADD(charttime, INTERVAL '4' HOUR)), co.endtime - ) AS endtime - , MAX( - CASE - WHEN - REGEXP_CONTAINS(LOWER(ce.value), '(cpap mask|bipap)') THEN 1 - ELSE 0 - END - ) AS cpap - FROM co - INNER JOIN mimiciv_icu.chartevents ce - ON co.stay_id = ce.stay_id - AND ce.charttime > co.starttime - AND ce.charttime <= co.endtime - WHERE ce.itemid = 226732 - AND REGEXP_CONTAINS(LOWER(ce.value), '(cpap mask|bipap)') - GROUP BY co.subject_id, co.stay_id, co.starttime, co.endtime -) - --- extract a flag for surgical service --- this combined with "elective" from admissions table --- defines elective/non-elective surgery -, surgflag AS ( - SELECT adm.hadm_id - , CASE - WHEN LOWER(curr_service) LIKE '%surg%' THEN 1 ELSE 0 - END AS surgical - , ROW_NUMBER() OVER - ( - PARTITION BY adm.hadm_id - ORDER BY transfertime - ) AS serviceorder - FROM mimiciv_hosp.admissions adm - LEFT JOIN mimiciv_hosp.services se - ON adm.hadm_id = se.hadm_id -) - --- icd-9 diagnostic codes are our best source for comorbidity information --- unfortunately, they are technically a-causal --- however, this shouldn't matter too much for the SAPS II comorbidities -, comorb AS ( - SELECT hadm_id - -- these are slightly different than elixhauser comorbidities, - -- but based on them they include some non-comorbid ICD-9 codes - -- (e.g. 20302, relapse of multiple myeloma) - , MAX(CASE - WHEN - icd_version = 9 AND SUBSTR( - icd_code, 1, 3 - ) BETWEEN '042' AND '044' - THEN 1 - WHEN - icd_version = 10 AND SUBSTR( - icd_code, 1, 3 - ) BETWEEN 'B20' AND 'B22' THEN 1 - WHEN icd_version = 10 AND SUBSTR(icd_code, 1, 3) = 'B24' THEN 1 - ELSE 0 END) AS aids /* HIV and AIDS */ - , MAX( - CASE WHEN icd_version = 9 THEN - CASE - -- lymphoma - WHEN - SUBSTR( - icd_code, 1, 5 - ) BETWEEN '20000' AND '20238' THEN 1 - -- leukemia - WHEN - SUBSTR( - icd_code, 1, 5 - ) BETWEEN '20240' AND '20248' THEN 1 - -- lymphoma - WHEN - SUBSTR( - icd_code, 1, 5 - ) BETWEEN '20250' AND '20302' THEN 1 - -- leukemia - WHEN - SUBSTR( - icd_code, 1, 5 - ) BETWEEN '20310' AND '20312' THEN 1 - -- lymphoma - WHEN - SUBSTR( - icd_code, 1, 5 - ) BETWEEN '20302' AND '20382' THEN 1 - -- chronic leukemia - WHEN - SUBSTR( - icd_code, 1, 5 - ) BETWEEN '20400' AND '20522' THEN 1 - -- other myeloid leukemia - WHEN - SUBSTR( - icd_code, 1, 5 - ) BETWEEN '20580' AND '20702' THEN 1 - -- other myeloid leukemia - WHEN - SUBSTR( - icd_code, 1, 5 - ) BETWEEN '20720' AND '20892' THEN 1 - -- lymphoma - WHEN SUBSTR(icd_code, 1, 4) IN ('2386', '2733') THEN 1 - ELSE 0 END - WHEN - icd_version = 10 AND SUBSTR( - icd_code, 1, 3 - ) BETWEEN 'C81' AND 'C96' THEN 1 - ELSE 0 END) AS hem - , MAX(CASE - WHEN icd_version = 9 THEN - CASE - WHEN SUBSTR(icd_code, 1, 4) BETWEEN '1960' AND '1991' THEN 1 - WHEN - SUBSTR( - icd_code, 1, 5 - ) BETWEEN '20970' AND '20975' THEN 1 - WHEN SUBSTR(icd_code, 1, 5) IN ('20979', '78951') THEN 1 - ELSE 0 END - WHEN - icd_version = 10 AND SUBSTR( - icd_code, 1, 3 - ) BETWEEN 'C77' AND 'C79' THEN 1 - WHEN icd_version = 10 AND SUBSTR(icd_code, 1, 4) = 'C800' THEN 1 - ELSE 0 END) AS mets /* Metastatic cancer */ - FROM mimiciv_hosp.diagnoses_icd - GROUP BY hadm_id -) - -, pafi1 AS ( - -- join blood gas to ventilation durations to determine if patient was vent - -- also join to cpap table for the same purpose - SELECT - co.stay_id - , bg.charttime - , pao2fio2ratio AS pao2fio2 - , CASE WHEN vd.stay_id IS NOT NULL THEN 1 ELSE 0 END AS vent - , CASE WHEN cp.subject_id IS NOT NULL THEN 1 ELSE 0 END AS cpap - FROM co - LEFT JOIN mimiciv_derived.bg bg - ON co.subject_id = bg.subject_id - AND bg.specimen = 'ART.' - AND bg.charttime > co.starttime - AND bg.charttime <= co.endtime - LEFT JOIN mimiciv_derived.ventilation vd - ON co.stay_id = vd.stay_id - AND bg.charttime > vd.starttime - AND bg.charttime <= vd.endtime - AND vd.ventilation_status = 'InvasiveVent' - LEFT JOIN cpap cp - ON bg.subject_id = cp.subject_id - AND bg.charttime > cp.starttime - AND bg.charttime <= cp.endtime -) - -, pafi2 AS ( - -- get the minimum PaO2/FiO2 ratio *only for ventilated/cpap patients* - SELECT stay_id - , MIN(pao2fio2) AS pao2fio2_vent_min - FROM pafi1 - WHERE vent = 1 OR cpap = 1 - GROUP BY stay_id -) - -, gcs AS ( - SELECT co.stay_id - , MIN(gcs.gcs) AS mingcs - FROM co - LEFT JOIN mimiciv_derived.gcs gcs - ON co.stay_id = gcs.stay_id - AND co.starttime < gcs.charttime - AND gcs.charttime <= co.endtime - GROUP BY co.stay_id -) - -, vital AS ( - SELECT - co.stay_id - , MIN(vital.heart_rate) AS heartrate_min - , MAX(vital.heart_rate) AS heartrate_max - , MIN(vital.sbp) AS sysbp_min - , MAX(vital.sbp) AS sysbp_max - , MIN(vital.temperature) AS tempc_min - , MAX(vital.temperature) AS tempc_max - FROM co - LEFT JOIN mimiciv_derived.vitalsign vital - ON co.subject_id = vital.subject_id - AND co.starttime < vital.charttime - AND co.endtime >= vital.charttime - GROUP BY co.stay_id -) - -, uo AS ( - SELECT - co.stay_id - , SUM(uo.urineoutput) AS urineoutput - FROM co - LEFT JOIN mimiciv_derived.urine_output uo - ON co.stay_id = uo.stay_id - AND co.starttime < uo.charttime - AND co.endtime >= uo.charttime - GROUP BY co.stay_id -) - -, labs AS ( - SELECT - co.stay_id - , MIN(labs.bun) AS bun_min - , MAX(labs.bun) AS bun_max - , MIN(labs.potassium) AS potassium_min - , MAX(labs.potassium) AS potassium_max - , MIN(labs.sodium) AS sodium_min - , MAX(labs.sodium) AS sodium_max - , MIN(labs.bicarbonate) AS bicarbonate_min - , MAX(labs.bicarbonate) AS bicarbonate_max - FROM co - LEFT JOIN mimiciv_derived.chemistry labs - ON co.subject_id = labs.subject_id - AND co.starttime < labs.charttime - AND co.endtime >= labs.charttime - GROUP BY co.stay_id -) - -, cbc AS ( - SELECT - co.stay_id - , MIN(cbc.wbc) AS wbc_min - , MAX(cbc.wbc) AS wbc_max - FROM co - LEFT JOIN mimiciv_derived.complete_blood_count cbc - ON co.subject_id = cbc.subject_id - AND co.starttime < cbc.charttime - AND co.endtime >= cbc.charttime - GROUP BY co.stay_id -) - -, enz AS ( - SELECT - co.stay_id - , MIN(enz.bilirubin_total) AS bilirubin_min - , MAX(enz.bilirubin_total) AS bilirubin_max - FROM co - LEFT JOIN mimiciv_derived.enzyme enz - ON co.subject_id = enz.subject_id - AND co.starttime < enz.charttime - AND co.endtime >= enz.charttime - GROUP BY co.stay_id -) - -, cohort AS ( - SELECT - ie.subject_id, ie.hadm_id, ie.stay_id - , ie.intime - , ie.outtime - , va.age - , co.starttime - , co.endtime - - , vital.heartrate_max - , vital.heartrate_min - , vital.sysbp_max - , vital.sysbp_min - , vital.tempc_max - , vital.tempc_min - - -- this value is non-null iff the patient is on vent/cpap - , pf.pao2fio2_vent_min - - , uo.urineoutput - - , labs.bun_min - , labs.bun_max - , cbc.wbc_min - , cbc.wbc_max - , labs.potassium_min - , labs.potassium_max - , labs.sodium_min - , labs.sodium_max - , labs.bicarbonate_min - , labs.bicarbonate_max - - , enz.bilirubin_min - , enz.bilirubin_max - - , gcs.mingcs - - , comorb.aids - , comorb.hem - , comorb.mets - - , CASE - WHEN adm.admission_type = 'ELECTIVE' AND sf.surgical = 1 - THEN 'ScheduledSurgical' - WHEN adm.admission_type != 'ELECTIVE' AND sf.surgical = 1 - THEN 'UnscheduledSurgical' - ELSE 'Medical' - END AS admissiontype - - - FROM mimiciv_icu.icustays ie - INNER JOIN mimiciv_hosp.admissions adm - ON ie.hadm_id = adm.hadm_id - LEFT JOIN mimiciv_derived.age va - ON ie.hadm_id = va.hadm_id - INNER JOIN co - ON ie.stay_id = co.stay_id - - -- join to above views - LEFT JOIN pafi2 pf - ON ie.stay_id = pf.stay_id - LEFT JOIN surgflag sf - ON adm.hadm_id = sf.hadm_id AND sf.serviceorder = 1 - LEFT JOIN comorb - ON ie.hadm_id = comorb.hadm_id - - -- join to custom tables to get more data.... - LEFT JOIN gcs gcs - ON ie.stay_id = gcs.stay_id - LEFT JOIN vital - ON ie.stay_id = vital.stay_id - LEFT JOIN uo - ON ie.stay_id = uo.stay_id - LEFT JOIN labs - ON ie.stay_id = labs.stay_id - LEFT JOIN cbc - ON ie.stay_id = cbc.stay_id - LEFT JOIN enz - ON ie.stay_id = enz.stay_id -) - -, scorecomp AS ( - SELECT - cohort.* - -- Below code calculates the component scores needed for SAPS - , CASE - WHEN age IS NULL THEN null - WHEN age < 40 THEN 0 - WHEN age < 60 THEN 7 - WHEN age < 70 THEN 12 - WHEN age < 75 THEN 15 - WHEN age < 80 THEN 16 - WHEN age >= 80 THEN 18 - END AS age_score - - , CASE - WHEN heartrate_max IS NULL THEN null - WHEN heartrate_min < 40 THEN 11 - WHEN heartrate_max >= 160 THEN 7 - WHEN heartrate_max >= 120 THEN 4 - WHEN heartrate_min < 70 THEN 2 - WHEN heartrate_max >= 70 AND heartrate_max < 120 - AND heartrate_min >= 70 AND heartrate_min < 120 - THEN 0 - END AS hr_score - - , CASE - WHEN sysbp_min IS NULL THEN null - WHEN sysbp_min < 70 THEN 13 - WHEN sysbp_min < 100 THEN 5 - WHEN sysbp_max >= 200 THEN 2 - WHEN sysbp_max >= 100 AND sysbp_max < 200 - AND sysbp_min >= 100 AND sysbp_min < 200 - THEN 0 - END AS sysbp_score - - , CASE - WHEN tempc_max IS NULL THEN null - WHEN tempc_max >= 39.0 THEN 3 - WHEN tempc_min < 39.0 THEN 0 - END AS temp_score - - , CASE - WHEN pao2fio2_vent_min IS NULL THEN null - WHEN pao2fio2_vent_min < 100 THEN 11 - WHEN pao2fio2_vent_min < 200 THEN 9 - WHEN pao2fio2_vent_min >= 200 THEN 6 - END AS pao2fio2_score - - , CASE - WHEN urineoutput IS NULL THEN null - WHEN urineoutput < 500.0 THEN 11 - WHEN urineoutput < 1000.0 THEN 4 - WHEN urineoutput >= 1000.0 THEN 0 - END AS uo_score - - , CASE - WHEN bun_max IS NULL THEN null - WHEN bun_max < 28.0 THEN 0 - WHEN bun_max < 84.0 THEN 6 - WHEN bun_max >= 84.0 THEN 10 - END AS bun_score - - , CASE - WHEN wbc_max IS NULL THEN null - WHEN wbc_min < 1.0 THEN 12 - WHEN wbc_max >= 20.0 THEN 3 - WHEN wbc_max >= 1.0 AND wbc_max < 20.0 - AND wbc_min >= 1.0 AND wbc_min < 20.0 - THEN 0 - END AS wbc_score - - , CASE - WHEN potassium_max IS NULL THEN null - WHEN potassium_min < 3.0 THEN 3 - WHEN potassium_max >= 5.0 THEN 3 - WHEN potassium_max >= 3.0 AND potassium_max < 5.0 - AND potassium_min >= 3.0 AND potassium_min < 5.0 - THEN 0 - END AS potassium_score - - , CASE - WHEN sodium_max IS NULL THEN null - WHEN sodium_min < 125 THEN 5 - WHEN sodium_max >= 145 THEN 1 - WHEN sodium_max >= 125 AND sodium_max < 145 - AND sodium_min >= 125 AND sodium_min < 145 - THEN 0 - END AS sodium_score - - , CASE - WHEN bicarbonate_max IS NULL THEN null - WHEN bicarbonate_min < 15.0 THEN 5 - WHEN bicarbonate_min < 20.0 THEN 3 - WHEN bicarbonate_max >= 20.0 - AND bicarbonate_min >= 20.0 - THEN 0 - END AS bicarbonate_score - - , CASE - WHEN bilirubin_max IS NULL THEN null - WHEN bilirubin_max < 4.0 THEN 0 - WHEN bilirubin_max < 6.0 THEN 4 - WHEN bilirubin_max >= 6.0 THEN 9 - END AS bilirubin_score - - , CASE - WHEN mingcs IS NULL THEN null - WHEN mingcs < 3 THEN null -- erroneous value/on trach - WHEN mingcs < 6 THEN 26 - WHEN mingcs < 9 THEN 13 - WHEN mingcs < 11 THEN 7 - WHEN mingcs < 14 THEN 5 - WHEN mingcs >= 14 - AND mingcs <= 15 - THEN 0 - END AS gcs_score - - , CASE - WHEN aids = 1 THEN 17 - WHEN hem = 1 THEN 10 - WHEN mets = 1 THEN 9 - ELSE 0 - END AS comorbidity_score - - , CASE - WHEN admissiontype = 'ScheduledSurgical' THEN 0 - WHEN admissiontype = 'Medical' THEN 6 - WHEN admissiontype = 'UnscheduledSurgical' THEN 8 - ELSE null - END AS admissiontype_score - - FROM cohort -) - --- Calculate SAPS II here, later we will calculate probability -, score AS ( - SELECT s.* - -- coalesce statements impute normal score - -- of zero if data element is missing - , COALESCE(age_score, 0) - + COALESCE(hr_score, 0) - + COALESCE(sysbp_score, 0) - + COALESCE(temp_score, 0) - + COALESCE(pao2fio2_score, 0) - + COALESCE(uo_score, 0) - + COALESCE(bun_score, 0) - + COALESCE(wbc_score, 0) - + COALESCE(potassium_score, 0) - + COALESCE(sodium_score, 0) - + COALESCE(bicarbonate_score, 0) - + COALESCE(bilirubin_score, 0) - + COALESCE(gcs_score, 0) - + COALESCE(comorbidity_score, 0) - + COALESCE(admissiontype_score, 0) - AS sapsii - FROM scorecomp s -) - -SELECT s.subject_id, s.hadm_id, s.stay_id - , s.starttime - , s.endtime - , sapsii - , 1 / ( - 1 + EXP(- (-7.7631 + 0.0737 * (sapsii) + 0.9971 * (LN(sapsii + 1)))) - ) AS sapsii_prob - , age_score - , hr_score - , sysbp_score - , temp_score - , pao2fio2_score - , uo_score - , bun_score - , wbc_score - , potassium_score - , sodium_score - , bicarbonate_score - , bilirubin_score - , gcs_score - , comorbidity_score - , admissiontype_score -FROM score s -; +SELECT + s.subject_id, + s.hadm_id, + s.stay_id, + s.starttime, + s.endtime, + sapsii, + CAST(1 AS DOUBLE PRECISION) / ( + 1 + EXP(-( + -7.7631 + 0.0737 * ( + sapsii + ) + 0.9971 * ( + LN(sapsii + 1) + ) + )) + ) AS sapsii_prob, + age_score, + hr_score, + sysbp_score, + temp_score, + pao2fio2_score, + uo_score, + bun_score, + wbc_score, + potassium_score, + sodium_score, + bicarbonate_score, + bilirubin_score, + gcs_score, + comorbidity_score, + admissiontype_score +FROM score AS s \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/score/sirs.sql b/mimic-iv/concepts_postgres/score/sirs.sql index 794388629..b1b28667a 100644 --- a/mimic-iv/concepts_postgres/score/sirs.sql +++ b/mimic-iv/concepts_postgres/score/sirs.sql @@ -1,102 +1,75 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS sirs; CREATE TABLE sirs AS --- ------------------------------------------------------------------ --- Title: Systemic inflammatory response syndrome (SIRS) criteria --- This query extracts the Systemic inflammatory response syndrome --- (SIRS) criteria. The criteria quantify the level of inflammatory --- response of the body. The score is calculated on the first day --- of each ICU patients' stay. --- ------------------------------------------------------------------ - --- Reference for SIRS: --- American College of Chest Physicians/Society of Critical Care --- Medicine Consensus Conference: definitions for sepsis and organ --- failure and guidelines for the use of innovative therapies in --- sepsis". Crit. Care Med. 20 (6): 864–74. 1992. --- doi:10.1097/00003246-199206000-00025. PMID 1597042. - --- Variables used in SIRS: --- Body temperature (min and max) --- Heart rate (max) --- Respiratory rate (max) --- PaCO2 (min) --- White blood cell count (min and max) --- the presence of greater than 10% immature neutrophils (band forms) - --- Note: --- The score is calculated for *all* ICU patients, with the assumption --- that the user will subselect appropriate stay_ids. - --- Aggregate the components for the score +DROP TABLE IF EXISTS mimiciv_derived.sirs; CREATE TABLE mimiciv_derived.sirs AS +/* ------------------------------------------------------------------ */ /* Title: Systemic inflammatory response syndrome (SIRS) criteria */ /* This query extracts the Systemic inflammatory response syndrome */ /* (SIRS) criteria. The criteria quantify the level of inflammatory */ /* response of the body. The score is calculated on the first day */ /* of each ICU patients' stay. */ /* ------------------------------------------------------------------ */ /* Reference for SIRS: */ /* American College of Chest Physicians/Society of Critical Care */ /* Medicine Consensus Conference: definitions for sepsis and organ */ /* failure and guidelines for the use of innovative therapies in */ /* sepsis". Crit. Care Med. 20 (6): 864–74. 1992. */ /* doi:10.1097/00003246-199206000-00025. PMID 1597042. */ /* Variables used in SIRS: */ /* Body temperature (min and max) */ /* Heart rate (max) */ /* Respiratory rate (max) */ /* PaCO2 (min) */ /* White blood cell count (min and max) */ /* the presence of greater than 10% immature neutrophils (band forms) */ /* Note: */ /* The score is calculated for *all* ICU patients, with the assumption */ /* that the user will subselect appropriate stay_ids. */ /* Aggregate the components for the score */ WITH scorecomp AS ( - SELECT ie.stay_id - , v.temperature_min - , v.temperature_max - , v.heart_rate_max - , v.resp_rate_max - , bg.pco2_min AS paco2_min - , l.wbc_min - , l.wbc_max - , l.bands_max - FROM mimiciv_icu.icustays ie - LEFT JOIN mimiciv_derived.first_day_bg_art bg - ON ie.stay_id = bg.stay_id - LEFT JOIN mimiciv_derived.first_day_vitalsign v - ON ie.stay_id = v.stay_id - LEFT JOIN mimiciv_derived.first_day_lab l - ON ie.stay_id = l.stay_id + SELECT + ie.stay_id, + v.temperature_min, + v.temperature_max, + v.heart_rate_max, + v.resp_rate_max, + bg.pco2_min AS paco2_min, + l.wbc_min, + l.wbc_max, + l.bands_max + FROM mimiciv_icu.icustays AS ie + LEFT JOIN mimiciv_derived.first_day_bg_art AS bg + ON ie.stay_id = bg.stay_id + LEFT JOIN mimiciv_derived.first_day_vitalsign AS v + ON ie.stay_id = v.stay_id + LEFT JOIN mimiciv_derived.first_day_lab AS l + ON ie.stay_id = l.stay_id +), scorecalc AS ( + /* Calculate the final score */ /* note that if the underlying data is missing, the component is null */ /* eventually these are treated as 0 (normal), but knowing when */ /* data is missing is useful for debugging */ + SELECT + stay_id, + CASE + WHEN temperature_min < 36.0 + THEN 1 + WHEN temperature_max > 38.0 + THEN 1 + WHEN temperature_min IS NULL + THEN NULL + ELSE 0 + END AS temp_score, + CASE + WHEN heart_rate_max > 90.0 + THEN 1 + WHEN heart_rate_max IS NULL + THEN NULL + ELSE 0 + END AS heart_rate_score, + CASE + WHEN resp_rate_max > 20.0 + THEN 1 + WHEN paco2_min < 32.0 + THEN 1 + WHEN COALESCE(resp_rate_max, paco2_min) IS NULL + THEN NULL + ELSE 0 + END AS resp_score, + CASE + WHEN wbc_min < 4.0 + THEN 1 + WHEN wbc_max > 12.0 + THEN 1 + WHEN bands_max > 10 + THEN 1 /* > 10% immature neurophils (band forms) */ + WHEN COALESCE(wbc_min, bands_max) IS NULL + THEN NULL + ELSE 0 + END AS wbc_score + FROM scorecomp ) - -, scorecalc AS ( - -- Calculate the final score - -- note that if the underlying data is missing, the component is null - -- eventually these are treated as 0 (normal), but knowing when - -- data is missing is useful for debugging - SELECT stay_id - - , CASE - WHEN temperature_min < 36.0 THEN 1 - WHEN temperature_max > 38.0 THEN 1 - WHEN temperature_min IS NULL THEN null - ELSE 0 - END AS temp_score - - - , CASE - WHEN heart_rate_max > 90.0 THEN 1 - WHEN heart_rate_max IS NULL THEN null - ELSE 0 - END AS heart_rate_score - - , CASE - WHEN resp_rate_max > 20.0 THEN 1 - WHEN paco2_min < 32.0 THEN 1 - WHEN COALESCE(resp_rate_max, paco2_min) IS NULL THEN null - ELSE 0 - END AS resp_score - - , CASE - WHEN wbc_min < 4.0 THEN 1 - WHEN wbc_max > 12.0 THEN 1 - WHEN bands_max > 10 THEN 1-- > 10% immature neurophils (band forms) - WHEN COALESCE(wbc_min, bands_max) IS NULL THEN null - ELSE 0 - END AS wbc_score - - FROM scorecomp -) - SELECT - ie.subject_id, ie.hadm_id, ie.stay_id - -- Combine all the scores to get SOFA - -- Impute 0 if the score is missing - , COALESCE(temp_score, 0) - + COALESCE(heart_rate_score, 0) - + COALESCE(resp_score, 0) - + COALESCE(wbc_score, 0) - AS sirs - , temp_score, heart_rate_score, resp_score, wbc_score -FROM mimiciv_icu.icustays ie -LEFT JOIN scorecalc s - ON ie.stay_id = s.stay_id -; + ie.subject_id, + ie.hadm_id, + ie.stay_id, /* Combine all the scores to get SOFA */ /* Impute 0 if the score is missing */ + COALESCE(temp_score, 0) + COALESCE(heart_rate_score, 0) + COALESCE(resp_score, 0) + COALESCE(wbc_score, 0) AS sirs, + temp_score, + heart_rate_score, + resp_score, + wbc_score +FROM mimiciv_icu.icustays AS ie +LEFT JOIN scorecalc AS s + ON ie.stay_id = s.stay_id \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/score/sofa.sql b/mimic-iv/concepts_postgres/score/sofa.sql index bbbc06554..3bcd891b1 100644 --- a/mimic-iv/concepts_postgres/score/sofa.sql +++ b/mimic-iv/concepts_postgres/score/sofa.sql @@ -1,381 +1,301 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS sofa; CREATE TABLE sofa AS --- ------------------------------------------------------------------ --- Title: Sequential Organ Failure Assessment (SOFA) --- This query extracts the sequential organ failure assessment --- (formally: sepsis-related organ failure assessment). --- This score is a measure of organ failure for patients in the ICU. --- The score is calculated for **every hour** of the patient's ICU stay. --- However, as the calculation window is 24 hours, care should be --- taken when using the score before the end of the first day, --- as the data window is limited. --- ------------------------------------------------------------------ - --- Reference for SOFA: --- Jean-Louis Vincent, Rui Moreno, Jukka Takala, Sheila Willatts, --- Arnaldo De Mendonça, Hajo Bruining, C. K. Reinhart, --- Peter M Suter, and L. G. Thijs. --- "The SOFA (Sepsis-related Organ Failure Assessment) score to --- describe organ dysfunction/failure." --- Intensive care medicine 22, no. 7 (1996): 707-710. - --- Variables used in SOFA: --- GCS, MAP, FiO2, Ventilation status (chartevents) --- Creatinine, Bilirubin, FiO2, PaO2, Platelets (labevents) --- Dopamine, Dobutamine, Epinephrine, Norepinephrine (inputevents) --- Urine output (outputevents) - --- use icustay_hourly to get a row for every hour the patient was in the ICU --- all of our joins to data will use these times --- to extract data pertinent to only that hour +DROP TABLE IF EXISTS mimiciv_derived.sofa; CREATE TABLE mimiciv_derived.sofa AS +/* ------------------------------------------------------------------ */ /* Title: Sequential Organ Failure Assessment (SOFA) */ /* This query extracts the sequential organ failure assessment */ /* (formally: sepsis-related organ failure assessment). */ /* This score is a measure of organ failure for patients in the ICU. */ /* The score is calculated for **every hour** of the patient's ICU stay. */ /* However, as the calculation window is 24 hours, care should be */ /* taken when using the score before the end of the first day, */ /* as the data window is limited. */ /* ------------------------------------------------------------------ */ /* Reference for SOFA: */ /* Jean-Louis Vincent, Rui Moreno, Jukka Takala, Sheila Willatts, */ /* Arnaldo De Mendonça, Hajo Bruining, C. K. Reinhart, */ /* Peter M Suter, and L. G. Thijs. */ /* "The SOFA (Sepsis-related Organ Failure Assessment) score to */ /* describe organ dysfunction/failure." */ /* Intensive care medicine 22, no. 7 (1996): 707-710. */ /* Variables used in SOFA: */ /* GCS, MAP, FiO2, Ventilation status (chartevents) */ /* Creatinine, Bilirubin, FiO2, PaO2, Platelets (labevents) */ /* Dopamine, Dobutamine, Epinephrine, Norepinephrine (inputevents) */ /* Urine output (outputevents) */ /* use icustay_hourly to get a row for every hour the patient was in the ICU */ /* all of our joins to data will use these times */ /* to extract data pertinent to only that hour */ WITH co AS ( - SELECT ih.stay_id, ie.hadm_id - , hr - -- start/endtime can be used to filter to values within this hour - , DATETIME_SUB(ih.endtime, INTERVAL '1' HOUR) AS starttime - , ih.endtime - FROM mimiciv_derived.icustay_hourly ih - INNER JOIN mimiciv_icu.icustays ie - ON ih.stay_id = ie.stay_id + SELECT + ih.stay_id, + ie.hadm_id, + hr, /* start/endtime can be used to filter to values within this hour */ + ih.endtime - INTERVAL '1 HOUR' AS starttime, + ih.endtime + FROM mimiciv_derived.icustay_hourly AS ih + INNER JOIN mimiciv_icu.icustays AS ie + ON ih.stay_id = ie.stay_id +), pafi AS ( + /* join blood gas to ventilation durations to determine if patient was vent */ + SELECT + ie.stay_id, + bg.charttime, /* because pafi has an interaction between vent/PaO2:FiO2, */ /* we need two columns for the score */ /* it can happen that the lowest unventilated PaO2/FiO2 is 68, */ /* but the lowest ventilated PaO2/FiO2 is 120 */ /* in this case, the SOFA score is 3, *not* 4. */ + CASE WHEN vd.stay_id IS NULL THEN pao2fio2ratio ELSE NULL END AS pao2fio2ratio_novent, + CASE WHEN NOT vd.stay_id IS NULL THEN pao2fio2ratio ELSE NULL END AS pao2fio2ratio_vent + FROM mimiciv_icu.icustays AS ie + INNER JOIN mimiciv_derived.bg AS bg + ON ie.subject_id = bg.subject_id + LEFT JOIN mimiciv_derived.ventilation AS vd + ON ie.stay_id = vd.stay_id + AND bg.charttime >= vd.starttime + AND bg.charttime <= vd.endtime + AND vd.ventilation_status = 'InvasiveVent' + WHERE + specimen = 'ART.' +), vs AS ( + SELECT + co.stay_id, + co.hr, /* vitals */ + MIN(vs.mbp) AS meanbp_min + FROM co + LEFT JOIN mimiciv_derived.vitalsign AS vs + ON co.stay_id = vs.stay_id AND co.starttime < vs.charttime AND co.endtime >= vs.charttime + GROUP BY + co.stay_id, + co.hr +), gcs AS ( + SELECT + co.stay_id, + co.hr, /* gcs */ + MIN(gcs.gcs) AS gcs_min + FROM co + LEFT JOIN mimiciv_derived.gcs AS gcs + ON co.stay_id = gcs.stay_id AND co.starttime < gcs.charttime AND co.endtime >= gcs.charttime + GROUP BY + co.stay_id, + co.hr +), bili AS ( + SELECT + co.stay_id, + co.hr, + MAX(enz.bilirubin_total) AS bilirubin_max + FROM co + LEFT JOIN mimiciv_derived.enzyme AS enz + ON co.hadm_id = enz.hadm_id AND co.starttime < enz.charttime AND co.endtime >= enz.charttime + GROUP BY + co.stay_id, + co.hr +), cr AS ( + SELECT + co.stay_id, + co.hr, + MAX(chem.creatinine) AS creatinine_max + FROM co + LEFT JOIN mimiciv_derived.chemistry AS chem + ON co.hadm_id = chem.hadm_id + AND co.starttime < chem.charttime + AND co.endtime >= chem.charttime + GROUP BY + co.stay_id, + co.hr +), plt AS ( + SELECT + co.stay_id, + co.hr, + MIN(cbc.platelet) AS platelet_min + FROM co + LEFT JOIN mimiciv_derived.complete_blood_count AS cbc + ON co.hadm_id = cbc.hadm_id AND co.starttime < cbc.charttime AND co.endtime >= cbc.charttime + GROUP BY + co.stay_id, + co.hr +), pf AS ( + SELECT + co.stay_id, + co.hr, + MIN(pafi.pao2fio2ratio_novent) AS pao2fio2ratio_novent, + MIN(pafi.pao2fio2ratio_vent) AS pao2fio2ratio_vent + FROM co + /* bring in blood gases that occurred during this hour */ + LEFT JOIN pafi + ON co.stay_id = pafi.stay_id + AND co.starttime < pafi.charttime + AND co.endtime >= pafi.charttime + GROUP BY + co.stay_id, + co.hr +), uo AS ( + SELECT + co.stay_id, + co.hr, /* uo */ + MAX( + CASE + WHEN uo.uo_tm_24hr >= 22 AND uo.uo_tm_24hr <= 30 + THEN CAST(uo.urineoutput_24hr AS DOUBLE PRECISION) / uo.uo_tm_24hr * 24 + END + ) AS uo_24hr + FROM co + LEFT JOIN mimiciv_derived.urine_output_rate AS uo + ON co.stay_id = uo.stay_id AND co.starttime < uo.charttime AND co.endtime >= uo.charttime + GROUP BY + co.stay_id, + co.hr +), vaso AS ( + SELECT + co.stay_id, + co.hr, + MAX(epi.vaso_rate) AS rate_epinephrine, + MAX(nor.vaso_rate) AS rate_norepinephrine, + MAX(dop.vaso_rate) AS rate_dopamine, + MAX(dob.vaso_rate) AS rate_dobutamine + FROM co + LEFT JOIN mimiciv_derived.epinephrine AS epi + ON co.stay_id = epi.stay_id AND co.endtime > epi.starttime AND co.endtime <= epi.endtime + LEFT JOIN mimiciv_derived.norepinephrine AS nor + ON co.stay_id = nor.stay_id AND co.endtime > nor.starttime AND co.endtime <= nor.endtime + LEFT JOIN mimiciv_derived.dopamine AS dop + ON co.stay_id = dop.stay_id AND co.endtime > dop.starttime AND co.endtime <= dop.endtime + LEFT JOIN mimiciv_derived.dobutamine AS dob + ON co.stay_id = dob.stay_id AND co.endtime > dob.starttime AND co.endtime <= dob.endtime + WHERE + NOT epi.stay_id IS NULL + OR NOT nor.stay_id IS NULL + OR NOT dop.stay_id IS NULL + OR NOT dob.stay_id IS NULL + GROUP BY + co.stay_id, + co.hr +), scorecomp AS ( + SELECT + co.stay_id, + co.hr, + co.starttime, + co.endtime, + pf.pao2fio2ratio_novent, + pf.pao2fio2ratio_vent, + vaso.rate_epinephrine, + vaso.rate_norepinephrine, + vaso.rate_dopamine, + vaso.rate_dobutamine, + vs.meanbp_min, + gcs.gcs_min, /* uo */ + uo.uo_24hr, /* labs */ + bili.bilirubin_max, + cr.creatinine_max, + plt.platelet_min + FROM co + LEFT JOIN vs + ON co.stay_id = vs.stay_id AND co.hr = vs.hr + LEFT JOIN gcs + ON co.stay_id = gcs.stay_id AND co.hr = gcs.hr + LEFT JOIN bili + ON co.stay_id = bili.stay_id AND co.hr = bili.hr + LEFT JOIN cr + ON co.stay_id = cr.stay_id AND co.hr = cr.hr + LEFT JOIN plt + ON co.stay_id = plt.stay_id AND co.hr = plt.hr + LEFT JOIN pf + ON co.stay_id = pf.stay_id AND co.hr = pf.hr + LEFT JOIN uo + ON co.stay_id = uo.stay_id AND co.hr = uo.hr + LEFT JOIN vaso + ON co.stay_id = vaso.stay_id AND co.hr = vaso.hr +), scorecalc AS ( + /* Calculate the final score */ /* note that if the underlying data is missing, */ /* the component is null */ /* eventually these are treated as 0 (normal), */ /* but knowing when data is missing is useful for debugging */ + SELECT + scorecomp.*, /* Respiration */ + CASE + WHEN pao2fio2ratio_vent < 100 + THEN 4 + WHEN pao2fio2ratio_vent < 200 + THEN 3 + WHEN pao2fio2ratio_novent < 300 + THEN 2 + WHEN pao2fio2ratio_vent < 300 + THEN 2 + WHEN pao2fio2ratio_novent < 400 + THEN 1 + WHEN pao2fio2ratio_vent < 400 + THEN 1 + WHEN COALESCE(pao2fio2ratio_vent, pao2fio2ratio_novent) IS NULL + THEN NULL + ELSE 0 + END AS respiration, /* Coagulation */ + CASE + WHEN platelet_min < 20 + THEN 4 + WHEN platelet_min < 50 + THEN 3 + WHEN platelet_min < 100 + THEN 2 + WHEN platelet_min < 150 + THEN 1 + WHEN platelet_min IS NULL + THEN NULL + ELSE 0 + END AS coagulation, /* Liver */ + CASE + WHEN bilirubin_max >= 12.0 + THEN 4 + WHEN bilirubin_max >= 6.0 + THEN 3 + WHEN bilirubin_max >= 2.0 + THEN 2 + WHEN bilirubin_max >= 1.2 + THEN 1 + WHEN bilirubin_max IS NULL + THEN NULL + ELSE 0 + END AS liver, /* Cardiovascular */ + CASE + WHEN rate_dopamine > 15 OR rate_epinephrine > 0.1 OR rate_norepinephrine > 0.1 + THEN 4 + WHEN rate_dopamine > 5 OR rate_epinephrine <= 0.1 OR rate_norepinephrine <= 0.1 + THEN 3 + WHEN rate_dopamine > 0 OR rate_dobutamine > 0 + THEN 2 + WHEN meanbp_min < 70 + THEN 1 + WHEN COALESCE(meanbp_min, rate_dopamine, rate_dobutamine, rate_epinephrine, rate_norepinephrine) IS NULL + THEN NULL + ELSE 0 + END AS cardiovascular, /* Neurological failure (GCS) */ + CASE + WHEN ( + gcs_min >= 13 AND gcs_min <= 14 + ) + THEN 1 + WHEN ( + gcs_min >= 10 AND gcs_min <= 12 + ) + THEN 2 + WHEN ( + gcs_min >= 6 AND gcs_min <= 9 + ) + THEN 3 + WHEN gcs_min < 6 + THEN 4 + WHEN gcs_min IS NULL + THEN NULL + ELSE 0 + END AS cns, /* Renal failure - high creatinine or low urine output */ + CASE + WHEN ( + creatinine_max >= 5.0 + ) + THEN 4 + WHEN uo_24hr < 200 + THEN 4 + WHEN ( + creatinine_max >= 3.5 AND creatinine_max < 5.0 + ) + THEN 3 + WHEN uo_24hr < 500 + THEN 3 + WHEN ( + creatinine_max >= 2.0 AND creatinine_max < 3.5 + ) + THEN 2 + WHEN ( + creatinine_max >= 1.2 AND creatinine_max < 2.0 + ) + THEN 1 + WHEN COALESCE(uo_24hr, creatinine_max) IS NULL + THEN NULL + ELSE 0 + END AS renal + FROM scorecomp +), score_final AS ( + SELECT + s.*, /* Combine all the scores to get SOFA */ /* Impute 0 if the score is missing */ /* the window function takes the max over the last 24 hours */ + COALESCE(MAX(respiration) OVER w, 0) AS respiration_24hours, + COALESCE(MAX(coagulation) OVER w, 0) AS coagulation_24hours, + COALESCE(MAX(liver) OVER w, 0) AS liver_24hours, + COALESCE(MAX(cardiovascular) OVER w, 0) AS cardiovascular_24hours, + COALESCE(MAX(cns) OVER w, 0) AS cns_24hours, + COALESCE(MAX(renal) OVER w, 0) AS renal_24hours, /* sum together data for final SOFA */ + COALESCE(MAX(respiration) OVER w, 0) + COALESCE(MAX(coagulation) OVER w, 0) + COALESCE(MAX(liver) OVER w, 0) + COALESCE(MAX(cardiovascular) OVER w, 0) + COALESCE(MAX(cns) OVER w, 0) + COALESCE(MAX(renal) OVER w, 0) AS sofa_24hours + FROM scorecalc AS s + WINDOW w AS (PARTITION BY stay_id ORDER BY hr NULLS FIRST ROWS BETWEEN 23 PRECEDING AND 0 FOLLOWING) ) - -, pafi AS ( - -- join blood gas to ventilation durations to determine if patient was vent - SELECT ie.stay_id - , bg.charttime - -- because pafi has an interaction between vent/PaO2:FiO2, - -- we need two columns for the score - -- it can happen that the lowest unventilated PaO2/FiO2 is 68, - -- but the lowest ventilated PaO2/FiO2 is 120 - -- in this case, the SOFA score is 3, *not* 4. - , CASE - WHEN vd.stay_id IS NULL THEN pao2fio2ratio ELSE null - END AS pao2fio2ratio_novent - , CASE - WHEN vd.stay_id IS NOT NULL THEN pao2fio2ratio ELSE null - END AS pao2fio2ratio_vent - FROM mimiciv_icu.icustays ie - INNER JOIN mimiciv_derived.bg bg - ON ie.subject_id = bg.subject_id - LEFT JOIN mimiciv_derived.ventilation vd - ON ie.stay_id = vd.stay_id - AND bg.charttime >= vd.starttime - AND bg.charttime <= vd.endtime - AND vd.ventilation_status = 'InvasiveVent' - WHERE specimen = 'ART.' -) - -, vs AS ( - - SELECT co.stay_id, co.hr - -- vitals - , MIN(vs.mbp) AS meanbp_min - FROM co - LEFT JOIN mimiciv_derived.vitalsign vs - ON co.stay_id = vs.stay_id - AND co.starttime < vs.charttime - AND co.endtime >= vs.charttime - GROUP BY co.stay_id, co.hr -) - -, gcs AS ( - SELECT co.stay_id, co.hr - -- gcs - , MIN(gcs.gcs) AS gcs_min - FROM co - LEFT JOIN mimiciv_derived.gcs gcs - ON co.stay_id = gcs.stay_id - AND co.starttime < gcs.charttime - AND co.endtime >= gcs.charttime - GROUP BY co.stay_id, co.hr -) - -, bili AS ( - SELECT co.stay_id, co.hr - , MAX(enz.bilirubin_total) AS bilirubin_max - FROM co - LEFT JOIN mimiciv_derived.enzyme enz - ON co.hadm_id = enz.hadm_id - AND co.starttime < enz.charttime - AND co.endtime >= enz.charttime - GROUP BY co.stay_id, co.hr -) - -, cr AS ( - SELECT co.stay_id, co.hr - , MAX(chem.creatinine) AS creatinine_max - FROM co - LEFT JOIN mimiciv_derived.chemistry chem - ON co.hadm_id = chem.hadm_id - AND co.starttime < chem.charttime - AND co.endtime >= chem.charttime - GROUP BY co.stay_id, co.hr -) - -, plt AS ( - SELECT co.stay_id, co.hr - , MIN(cbc.platelet) AS platelet_min - FROM co - LEFT JOIN mimiciv_derived.complete_blood_count cbc - ON co.hadm_id = cbc.hadm_id - AND co.starttime < cbc.charttime - AND co.endtime >= cbc.charttime - GROUP BY co.stay_id, co.hr -) - -, pf AS ( - SELECT co.stay_id, co.hr - , MIN(pafi.pao2fio2ratio_novent) AS pao2fio2ratio_novent - , MIN(pafi.pao2fio2ratio_vent) AS pao2fio2ratio_vent - FROM co - -- bring in blood gases that occurred during this hour - LEFT JOIN pafi - ON co.stay_id = pafi.stay_id - AND co.starttime < pafi.charttime - AND co.endtime >= pafi.charttime - GROUP BY co.stay_id, co.hr -) - --- sum uo separately to prevent duplicating values -, uo AS ( - SELECT co.stay_id, co.hr - -- uo - , MAX( - CASE WHEN uo.uo_tm_24hr >= 22 AND uo.uo_tm_24hr <= 30 - THEN uo.urineoutput_24hr / uo.uo_tm_24hr * 24 - END) AS uo_24hr - FROM co - LEFT JOIN mimiciv_derived.urine_output_rate uo - ON co.stay_id = uo.stay_id - AND co.starttime < uo.charttime - AND co.endtime >= uo.charttime - GROUP BY co.stay_id, co.hr -) - --- collapse vasopressors into 1 row per hour --- also ensures only 1 row per chart time -, vaso AS ( - SELECT - co.stay_id - , co.hr - , MAX(epi.vaso_rate) AS rate_epinephrine - , MAX(nor.vaso_rate) AS rate_norepinephrine - , MAX(dop.vaso_rate) AS rate_dopamine - , MAX(dob.vaso_rate) AS rate_dobutamine - FROM co - LEFT JOIN mimiciv_derived.epinephrine epi - ON co.stay_id = epi.stay_id - AND co.endtime > epi.starttime - AND co.endtime <= epi.endtime - LEFT JOIN mimiciv_derived.norepinephrine nor - ON co.stay_id = nor.stay_id - AND co.endtime > nor.starttime - AND co.endtime <= nor.endtime - LEFT JOIN mimiciv_derived.dopamine dop - ON co.stay_id = dop.stay_id - AND co.endtime > dop.starttime - AND co.endtime <= dop.endtime - LEFT JOIN mimiciv_derived.dobutamine dob - ON co.stay_id = dob.stay_id - AND co.endtime > dob.starttime - AND co.endtime <= dob.endtime - WHERE epi.stay_id IS NOT NULL - OR nor.stay_id IS NOT NULL - OR dop.stay_id IS NOT NULL - OR dob.stay_id IS NOT NULL - GROUP BY co.stay_id, co.hr -) - -, scorecomp AS ( - SELECT - co.stay_id - , co.hr - , co.starttime, co.endtime - , pf.pao2fio2ratio_novent - , pf.pao2fio2ratio_vent - , vaso.rate_epinephrine - , vaso.rate_norepinephrine - , vaso.rate_dopamine - , vaso.rate_dobutamine - , vs.meanbp_min - , gcs.gcs_min - -- uo - , uo.uo_24hr - -- labs - , bili.bilirubin_max - , cr.creatinine_max - , plt.platelet_min - FROM co - LEFT JOIN vs - ON co.stay_id = vs.stay_id - AND co.hr = vs.hr - LEFT JOIN gcs - ON co.stay_id = gcs.stay_id - AND co.hr = gcs.hr - LEFT JOIN bili - ON co.stay_id = bili.stay_id - AND co.hr = bili.hr - LEFT JOIN cr - ON co.stay_id = cr.stay_id - AND co.hr = cr.hr - LEFT JOIN plt - ON co.stay_id = plt.stay_id - AND co.hr = plt.hr - LEFT JOIN pf - ON co.stay_id = pf.stay_id - AND co.hr = pf.hr - LEFT JOIN uo - ON co.stay_id = uo.stay_id - AND co.hr = uo.hr - LEFT JOIN vaso - ON co.stay_id = vaso.stay_id - AND co.hr = vaso.hr -) - -, scorecalc AS ( - -- Calculate the final score - -- note that if the underlying data is missing, - -- the component is null - -- eventually these are treated as 0 (normal), - -- but knowing when data is missing is useful for debugging - SELECT scorecomp.* - -- Respiration - , CASE - WHEN pao2fio2ratio_vent < 100 THEN 4 - WHEN pao2fio2ratio_vent < 200 THEN 3 - WHEN pao2fio2ratio_novent < 300 THEN 2 - WHEN pao2fio2ratio_vent < 300 THEN 2 - WHEN pao2fio2ratio_novent < 400 THEN 1 - WHEN pao2fio2ratio_vent < 400 THEN 1 - WHEN - COALESCE( - pao2fio2ratio_vent, pao2fio2ratio_novent - ) IS NULL THEN null - ELSE 0 - END AS respiration - - -- Coagulation - , CASE - WHEN platelet_min < 20 THEN 4 - WHEN platelet_min < 50 THEN 3 - WHEN platelet_min < 100 THEN 2 - WHEN platelet_min < 150 THEN 1 - WHEN platelet_min IS NULL THEN null - ELSE 0 - END AS coagulation - - -- Liver - , CASE - -- Bilirubin checks in mg/dL - WHEN bilirubin_max >= 12.0 THEN 4 - WHEN bilirubin_max >= 6.0 THEN 3 - WHEN bilirubin_max >= 2.0 THEN 2 - WHEN bilirubin_max >= 1.2 THEN 1 - WHEN bilirubin_max IS NULL THEN null - ELSE 0 - END AS liver - - -- Cardiovascular - , CASE - WHEN rate_dopamine > 15 - OR rate_epinephrine > 0.1 - OR rate_norepinephrine > 0.1 - THEN 4 - WHEN rate_dopamine > 5 - OR rate_epinephrine <= 0.1 - OR rate_norepinephrine <= 0.1 - THEN 3 - WHEN rate_dopamine > 0 - OR rate_dobutamine > 0 - THEN 2 - WHEN meanbp_min < 70 THEN 1 - WHEN - COALESCE( - meanbp_min - , rate_dopamine - , rate_dobutamine - , rate_epinephrine - , rate_norepinephrine - ) IS NULL THEN null - ELSE 0 - END AS cardiovascular - - -- Neurological failure (GCS) - , CASE - WHEN (gcs_min >= 13 AND gcs_min <= 14) THEN 1 - WHEN (gcs_min >= 10 AND gcs_min <= 12) THEN 2 - WHEN (gcs_min >= 6 AND gcs_min <= 9) THEN 3 - WHEN gcs_min < 6 THEN 4 - WHEN gcs_min IS NULL THEN null - ELSE 0 - END AS cns - - -- Renal failure - high creatinine or low urine output - , CASE - WHEN (creatinine_max >= 5.0) THEN 4 - WHEN uo_24hr < 200 THEN 4 - WHEN (creatinine_max >= 3.5 AND creatinine_max < 5.0) THEN 3 - WHEN uo_24hr < 500 THEN 3 - WHEN (creatinine_max >= 2.0 AND creatinine_max < 3.5) THEN 2 - WHEN (creatinine_max >= 1.2 AND creatinine_max < 2.0) THEN 1 - WHEN COALESCE(uo_24hr, creatinine_max) IS NULL THEN null - ELSE 0 - END AS renal - FROM scorecomp -) - -, score_final AS ( - SELECT s.* - -- Combine all the scores to get SOFA - -- Impute 0 if the score is missing - -- the window function takes the max over the last 24 hours - , COALESCE( - MAX(respiration) OVER w - , 0) AS respiration_24hours - , COALESCE( - MAX(coagulation) OVER w - , 0) AS coagulation_24hours - , COALESCE( - MAX(liver) OVER w - , 0) AS liver_24hours - , COALESCE( - MAX(cardiovascular) OVER w - , 0) AS cardiovascular_24hours - , COALESCE( - MAX(cns) OVER w - , 0) AS cns_24hours - , COALESCE( - MAX(renal) OVER w - , 0) AS renal_24hours - - -- sum together data for final SOFA - , COALESCE( - MAX(respiration) OVER w - , 0) - + COALESCE( - MAX(coagulation) OVER w - , 0) - + COALESCE( - MAX(liver) OVER w - , 0) - + COALESCE( - MAX(cardiovascular) OVER w - , 0) - + COALESCE( - MAX(cns) OVER w - , 0) - + COALESCE( - MAX(renal) OVER w - , 0) - AS sofa_24hours - FROM scorecalc s - WINDOW w AS - ( - PARTITION BY stay_id - ORDER BY hr - ROWS BETWEEN 23 PRECEDING AND 0 FOLLOWING - ) -) - -SELECT * FROM score_final -WHERE hr >= 0; +SELECT + * +FROM score_final +WHERE + hr >= 0 \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/sepsis/sepsis3.sql b/mimic-iv/concepts_postgres/sepsis/sepsis3.sql index 4214b68fe..315c551da 100644 --- a/mimic-iv/concepts_postgres/sepsis/sepsis3.sql +++ b/mimic-iv/concepts_postgres/sepsis/sepsis3.sql @@ -1,82 +1,68 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS sepsis3; CREATE TABLE sepsis3 AS --- Creates a table with "onset" time of Sepsis-3 in the ICU. --- That is, the earliest time at which a patient had SOFA >= 2 --- and suspicion of infection. --- As many variables used in SOFA are only collected in the ICU, --- this query can only define sepsis-3 onset within the ICU. - --- extract rows with SOFA >= 2 --- implicitly this assumes baseline SOFA was 0 before ICU admission. +DROP TABLE IF EXISTS mimiciv_derived.sepsis3; CREATE TABLE mimiciv_derived.sepsis3 AS +/* Creates a table with "onset" time of Sepsis-3 in the ICU. */ /* That is, the earliest time at which a patient had SOFA >= 2 */ /* and suspicion of infection. */ /* As many variables used in SOFA are only collected in the ICU, */ /* this query can only define sepsis-3 onset within the ICU. */ /* extract rows with SOFA >= 2 */ /* implicitly this assumes baseline SOFA was 0 before ICU admission. */ WITH sofa AS ( - SELECT stay_id - , starttime, endtime - , respiration_24hours AS respiration - , coagulation_24hours AS coagulation - , liver_24hours AS liver - , cardiovascular_24hours AS cardiovascular - , cns_24hours AS cns - , renal_24hours AS renal - , sofa_24hours AS sofa_score - FROM mimiciv_derived.sofa - WHERE sofa_24hours >= 2 + SELECT + stay_id, + starttime, + endtime, + respiration_24hours AS respiration, + coagulation_24hours AS coagulation, + liver_24hours AS liver, + cardiovascular_24hours AS cardiovascular, + cns_24hours AS cns, + renal_24hours AS renal, + sofa_24hours AS sofa_score + FROM mimiciv_derived.sofa + WHERE + sofa_24hours >= 2 +), s1 AS ( + SELECT + soi.subject_id, + soi.stay_id, /* suspicion columns */ + soi.ab_id, + soi.antibiotic, + soi.antibiotic_time, + soi.culture_time, + soi.suspected_infection, + soi.suspected_infection_time, + soi.specimen, + soi.positive_culture, /* sofa columns */ + starttime, + endtime, + respiration, + coagulation, + liver, + cardiovascular, + cns, + renal, + sofa_score, /* All rows have an associated suspicion of infection event */ /* Therefore, Sepsis-3 is defined as SOFA >= 2. */ /* Implicitly, the baseline SOFA score is assumed to be zero, */ /* as we do not know if the patient has preexisting */ /* (acute or chronic) organ dysfunction before the onset */ /* of infection. */ + sofa_score >= 2 AND suspected_infection = 1 AS sepsis3, /* subselect to the earliest suspicion/antibiotic/SOFA row */ + ROW_NUMBER() OVER (PARTITION BY soi.stay_id ORDER BY suspected_infection_time NULLS FIRST, antibiotic_time NULLS FIRST, culture_time NULLS FIRST, endtime NULLS FIRST) AS rn_sus + FROM mimiciv_derived.suspicion_of_infection AS soi + INNER JOIN sofa + ON soi.stay_id = sofa.stay_id + AND sofa.endtime >= soi.suspected_infection_time - INTERVAL '48 HOUR' + AND sofa.endtime <= soi.suspected_infection_time + INTERVAL '24 HOUR' + /* only include in-ICU rows */ + WHERE + NOT soi.stay_id IS NULL ) - -, s1 AS ( - SELECT - soi.subject_id - , soi.stay_id - -- suspicion columns - , soi.ab_id - , soi.antibiotic - , soi.antibiotic_time - , soi.culture_time - , soi.suspected_infection - , soi.suspected_infection_time - , soi.specimen - , soi.positive_culture - -- sofa columns - , starttime, endtime - , respiration, coagulation, liver, cardiovascular, cns, renal - , sofa_score - -- All rows have an associated suspicion of infection event - -- Therefore, Sepsis-3 is defined as SOFA >= 2. - -- Implicitly, the baseline SOFA score is assumed to be zero, - -- as we do not know if the patient has preexisting - -- (acute or chronic) organ dysfunction before the onset - -- of infection. - , sofa_score >= 2 AND suspected_infection = 1 AS sepsis3 - -- subselect to the earliest suspicion/antibiotic/SOFA row - , ROW_NUMBER() OVER - ( - PARTITION BY soi.stay_id - ORDER BY - suspected_infection_time, antibiotic_time, culture_time, endtime - ) AS rn_sus - FROM mimiciv_derived.suspicion_of_infection AS soi - INNER JOIN sofa - ON soi.stay_id = sofa.stay_id - AND sofa.endtime >= DATETIME_SUB( - soi.suspected_infection_time, INTERVAL '48' HOUR - ) - AND sofa.endtime <= DATETIME_ADD( - soi.suspected_infection_time, INTERVAL '24' HOUR - ) - -- only include in-ICU rows - WHERE soi.stay_id IS NOT NULL -) - SELECT - subject_id, stay_id - -- note: there may be more than one antibiotic given at this time - , antibiotic_time - -- culture times may be dates, rather than times - , culture_time - , suspected_infection_time - -- endtime is latest time at which the SOFA score is valid - , endtime AS sofa_time - , sofa_score - , respiration, coagulation, liver, cardiovascular, cns, renal - , sepsis3 + subject_id, + stay_id, /* note: there may be more than one antibiotic given at this time */ + antibiotic_time, /* culture times may be dates, rather than times */ + culture_time, + suspected_infection_time, /* endtime is latest time at which the SOFA score is valid */ + endtime AS sofa_time, + sofa_score, + respiration, + coagulation, + liver, + cardiovascular, + cns, + renal, + sepsis3 FROM s1 -WHERE rn_sus = 1 +WHERE + rn_sus = 1 \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/sepsis/suspicion_of_infection.sql b/mimic-iv/concepts_postgres/sepsis/suspicion_of_infection.sql index cf783b427..730822fc7 100644 --- a/mimic-iv/concepts_postgres/sepsis/suspicion_of_infection.sql +++ b/mimic-iv/concepts_postgres/sepsis/suspicion_of_infection.sql @@ -1,177 +1,112 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS suspicion_of_infection; CREATE TABLE suspicion_of_infection AS --- note this duplicates prescriptions --- each ICU stay in the same hospitalization will get a copy of --- all prescriptions for that hospitalization +DROP TABLE IF EXISTS mimiciv_derived.suspicion_of_infection; CREATE TABLE mimiciv_derived.suspicion_of_infection AS +/* note this duplicates prescriptions */ /* each ICU stay in the same hospitalization will get a copy of */ /* all prescriptions for that hospitalization */ WITH ab_tbl AS ( - SELECT - abx.subject_id, abx.hadm_id, abx.stay_id - , abx.antibiotic - , abx.starttime AS antibiotic_time - -- date is used to match microbiology cultures with only date available - , DATE_TRUNC('DAY', abx.starttime) AS antibiotic_date - , abx.stoptime AS antibiotic_stoptime - -- create a unique identifier for each patient antibiotic - , ROW_NUMBER() OVER - ( - PARTITION BY subject_id - ORDER BY starttime, stoptime, antibiotic - ) AS ab_id - FROM mimiciv_derived.antibiotic abx + SELECT + abx.subject_id, + abx.hadm_id, + abx.stay_id, + abx.antibiotic, + abx.starttime AS antibiotic_time, /* date is used to match microbiology cultures with only date available */ + DATE_TRUNC('DAY', abx.starttime) AS antibiotic_date, + abx.stoptime AS antibiotic_stoptime, /* create a unique identifier for each patient antibiotic */ + ROW_NUMBER() OVER (PARTITION BY subject_id ORDER BY starttime NULLS FIRST, stoptime NULLS FIRST, antibiotic NULLS FIRST) AS ab_id + FROM mimiciv_derived.antibiotic AS abx +), me AS ( + SELECT + micro_specimen_id, /* the following columns are identical for all rows */ /* of the same micro_specimen_id */ /* these aggregates simply collapse duplicates down to 1 row */ + MAX(subject_id) AS subject_id, + MAX(hadm_id) AS hadm_id, + CAST(MAX(chartdate) AS DATE) AS chartdate, + MAX(charttime) AS charttime, + MAX(spec_type_desc) AS spec_type_desc, /* identify negative cultures as NULL organism */ /* or a specific itemid saying "NEGATIVE" */ + MAX( + CASE + WHEN NOT org_name IS NULL AND org_itemid <> 90856 AND org_name <> '' + THEN 1 + ELSE 0 + END + ) AS positiveculture + FROM mimiciv_hosp.microbiologyevents + GROUP BY + micro_specimen_id +), me_then_ab AS ( + SELECT + ab_tbl.subject_id, + ab_tbl.hadm_id, + ab_tbl.stay_id, + ab_tbl.ab_id, + me72.micro_specimen_id, + COALESCE(me72.charttime, CAST(me72.chartdate AS TIMESTAMP)) AS last72_charttime, + me72.positiveculture AS last72_positiveculture, + me72.spec_type_desc AS last72_specimen, /* we will use this partition to select the earliest culture */ /* before this abx */ /* this ensures each antibiotic is only matched to a single culture */ /* and consequently we have 1 row per antibiotic */ + ROW_NUMBER() OVER (PARTITION BY ab_tbl.subject_id, ab_tbl.ab_id ORDER BY me72.chartdate NULLS FIRST, me72.charttime) AS micro_seq + FROM ab_tbl + /* abx taken after culture, but no more than 72 hours after */ + LEFT JOIN me AS me72 + ON ab_tbl.subject_id = me72.subject_id + AND ( + ( + NOT me72.charttime IS NULL + AND ab_tbl.antibiotic_time > me72.charttime + AND ab_tbl.antibiotic_time <= me72.charttime + INTERVAL '72 HOUR' + ) + OR ( + me72.charttime IS NULL + AND antibiotic_date >= me72.chartdate + AND antibiotic_date <= me72.chartdate + INTERVAL '3 DAY' + ) + ) +), ab_then_me AS ( + SELECT + ab_tbl.subject_id, + ab_tbl.hadm_id, + ab_tbl.stay_id, + ab_tbl.ab_id, + me24.micro_specimen_id, + COALESCE(me24.charttime, CAST(me24.chartdate AS TIMESTAMP)) AS next24_charttime, + me24.positiveculture AS next24_positiveculture, + me24.spec_type_desc AS next24_specimen, /* we will use this partition to select the earliest culture */ /* before this abx */ /* this ensures each antibiotic is only matched to a single culture */ /* and consequently we have 1 row per antibiotic */ + ROW_NUMBER() OVER (PARTITION BY ab_tbl.subject_id, ab_tbl.ab_id ORDER BY me24.chartdate NULLS FIRST, me24.charttime) AS micro_seq + FROM ab_tbl + /* culture in subsequent 24 hours */ + LEFT JOIN me AS me24 + ON ab_tbl.subject_id = me24.subject_id + AND ( + ( + NOT me24.charttime IS NULL + AND ab_tbl.antibiotic_time >= me24.charttime - INTERVAL '24 HOUR' /* noqa: L016 */ + AND ab_tbl.antibiotic_time < me24.charttime + ) + OR ( + me24.charttime IS NULL + AND ab_tbl.antibiotic_date >= me24.chartdate - INTERVAL '1 DAY' /* noqa: L016 */ + AND ab_tbl.antibiotic_date <= me24.chartdate + ) + ) ) - -, me AS ( - SELECT micro_specimen_id - -- the following columns are identical for all rows - -- of the same micro_specimen_id - -- these aggregates simply collapse duplicates down to 1 row - , MAX(subject_id) AS subject_id - , MAX(hadm_id) AS hadm_id - , CAST(MAX(chartdate) AS DATE) AS chartdate - , MAX(charttime) AS charttime - , MAX(spec_type_desc) AS spec_type_desc - -- identify negative cultures as NULL organism - -- or a specific itemid saying "NEGATIVE" - , MAX( - CASE WHEN org_name IS NOT NULL - AND org_itemid != 90856 - AND org_name != '' - THEN 1 ELSE 0 - END) AS positiveculture - FROM mimiciv_hosp.microbiologyevents - GROUP BY micro_specimen_id -) - --- culture followed by an antibiotic -, me_then_ab AS ( - SELECT - ab_tbl.subject_id - , ab_tbl.hadm_id - , ab_tbl.stay_id - , ab_tbl.ab_id - - , me72.micro_specimen_id - , COALESCE(me72.charttime, DATETIME(me72.chartdate)) AS last72_charttime - , me72.positiveculture AS last72_positiveculture - , me72.spec_type_desc AS last72_specimen - - -- we will use this partition to select the earliest culture - -- before this abx - -- this ensures each antibiotic is only matched to a single culture - -- and consequently we have 1 row per antibiotic - , ROW_NUMBER() OVER - ( - PARTITION BY ab_tbl.subject_id, ab_tbl.ab_id - ORDER BY me72.chartdate, me72.charttime NULLS LAST - ) AS micro_seq - FROM ab_tbl - -- abx taken after culture, but no more than 72 hours after - LEFT JOIN me me72 - ON ab_tbl.subject_id = me72.subject_id - AND - ( - ( - -- if charttime is available, use it - me72.charttime IS NOT NULL - AND ab_tbl.antibiotic_time > me72.charttime - AND ab_tbl.antibiotic_time <= DATETIME_ADD( - me72.charttime, INTERVAL '72' HOUR - ) - ) - OR - ( - -- if charttime is not available, use chartdate - me72.charttime IS NULL - AND antibiotic_date >= me72.chartdate - AND antibiotic_date <= DATE_ADD( - me72.chartdate, INTERVAL '3' DAY - ) - ) - ) -) - -, ab_then_me AS ( - SELECT - ab_tbl.subject_id - , ab_tbl.hadm_id - , ab_tbl.stay_id - , ab_tbl.ab_id - - , me24.micro_specimen_id - , COALESCE(me24.charttime, DATETIME(me24.chartdate)) AS next24_charttime - , me24.positiveculture AS next24_positiveculture - , me24.spec_type_desc AS next24_specimen - - -- we will use this partition to select the earliest culture - -- before this abx - -- this ensures each antibiotic is only matched to a single culture - -- and consequently we have 1 row per antibiotic - , ROW_NUMBER() OVER - ( - PARTITION BY ab_tbl.subject_id, ab_tbl.ab_id - ORDER BY me24.chartdate, me24.charttime NULLS LAST - ) AS micro_seq - FROM ab_tbl - -- culture in subsequent 24 hours - LEFT JOIN me me24 - ON ab_tbl.subject_id = me24.subject_id - AND - ( - ( - -- if charttime is available, use it - me24.charttime IS NOT NULL - AND ab_tbl.antibiotic_time >= DATETIME_SUB(me24.charttime, INTERVAL '24' HOUR) -- noqa: L016 - AND ab_tbl.antibiotic_time < me24.charttime - ) - OR - ( - -- if charttime is not available, use chartdate - me24.charttime IS NULL - AND ab_tbl.antibiotic_date >= DATE_SUB(me24.chartdate, INTERVAL '1' DAY) -- noqa: L016 - AND ab_tbl.antibiotic_date <= me24.chartdate - ) - ) -) - SELECT - ab_tbl.subject_id - , ab_tbl.stay_id - , ab_tbl.hadm_id - , ab_tbl.ab_id - , ab_tbl.antibiotic - , ab_tbl.antibiotic_time - - , CASE - WHEN last72_specimen IS NULL AND next24_specimen IS NULL - THEN 0 - ELSE 1 - END AS suspected_infection - -- time of suspected infection: - -- (1) the culture time (if before antibiotic) - -- (2) or the antibiotic time (if before culture) - , CASE - WHEN last72_specimen IS NULL AND next24_specimen IS NULL - THEN NULL - ELSE COALESCE(last72_charttime, antibiotic_time) - END AS suspected_infection_time - - , COALESCE(last72_charttime, next24_charttime) AS culture_time - - -- the specimen that was cultured - , COALESCE(last72_specimen, next24_specimen) AS specimen - - -- whether the cultured specimen ended up being positive or not - , COALESCE( - last72_positiveculture, next24_positiveculture - ) AS positive_culture - + ab_tbl.subject_id, + ab_tbl.stay_id, + ab_tbl.hadm_id, + ab_tbl.ab_id, + ab_tbl.antibiotic, + ab_tbl.antibiotic_time, + CASE WHEN last72_specimen IS NULL AND next24_specimen IS NULL THEN 0 ELSE 1 END AS suspected_infection, /* time of suspected infection: */ /* (1) the culture time (if before antibiotic) */ /* (2) or the antibiotic time (if before culture) */ + CASE + WHEN last72_specimen IS NULL AND next24_specimen IS NULL + THEN NULL + ELSE COALESCE(last72_charttime, antibiotic_time) + END AS suspected_infection_time, + COALESCE(last72_charttime, next24_charttime) AS culture_time, /* the specimen that was cultured */ + COALESCE(last72_specimen, next24_specimen) AS specimen, /* whether the cultured specimen ended up being positive or not */ + COALESCE(last72_positiveculture, next24_positiveculture) AS positive_culture FROM ab_tbl -LEFT JOIN ab_then_me ab2me - ON ab_tbl.subject_id = ab2me.subject_id - AND ab_tbl.ab_id = ab2me.ab_id - AND ab2me.micro_seq = 1 -LEFT JOIN me_then_ab me2ab - ON ab_tbl.subject_id = me2ab.subject_id - AND ab_tbl.ab_id = me2ab.ab_id - AND me2ab.micro_seq = 1 -; +LEFT JOIN ab_then_me AS ab2me + ON ab_tbl.subject_id = ab2me.subject_id + AND ab_tbl.ab_id = ab2me.ab_id + AND ab2me.micro_seq = 1 +LEFT JOIN me_then_ab AS me2ab + ON ab_tbl.subject_id = me2ab.subject_id + AND ab_tbl.ab_id = me2ab.ab_id + AND me2ab.micro_seq = 1 \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/treatment/crrt.sql b/mimic-iv/concepts_postgres/treatment/crrt.sql index 39010f82b..101f2cce7 100644 --- a/mimic-iv/concepts_postgres/treatment/crrt.sql +++ b/mimic-iv/concepts_postgres/treatment/crrt.sql @@ -1,150 +1,80 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS crrt; CREATE TABLE crrt AS +DROP TABLE IF EXISTS mimiciv_derived.crrt; CREATE TABLE mimiciv_derived.crrt AS +/* use MAX() to collapse to a single row */ /* there is only ever 1 row for unique combinations of stay_id/charttime/itemid */ WITH crrt_settings AS ( - SELECT ce.stay_id, ce.charttime - , CASE WHEN ce.itemid = 227290 THEN ce.value END AS crrt_mode - , CASE - WHEN ce.itemid = 224149 THEN ce.valuenum ELSE NULL - END AS accesspressure - -- (ml/min) - , CASE - WHEN ce.itemid = 224144 THEN ce.valuenum ELSE NULL - END AS bloodflow - -- (ACD-A) - , CASE WHEN ce.itemid = 228004 THEN ce.valuenum ELSE NULL END AS citrate - , CASE - WHEN ce.itemid = 225183 THEN ce.valuenum ELSE NULL - END AS currentgoal - , CASE - WHEN ce.itemid = 225977 THEN ce.value ELSE NULL - END AS dialysatefluid - , CASE - WHEN ce.itemid = 224154 THEN ce.valuenum ELSE NULL - END AS dialysaterate - , CASE - WHEN ce.itemid = 224151 THEN ce.valuenum ELSE NULL - END AS effluentpressure - , CASE - WHEN ce.itemid = 224150 THEN ce.valuenum ELSE NULL - END AS filterpressure - -- (units/mL) - , CASE - WHEN ce.itemid = 225958 THEN ce.value ELSE NULL - END AS heparinconcentration - -- (per hour) - , CASE - WHEN ce.itemid = 224145 THEN ce.valuenum ELSE NULL - END AS heparindose - -- below may not account for drug infusion, - -- hyperalimentation, and/or anticoagulants infused - , CASE - WHEN ce.itemid = 224191 THEN ce.valuenum ELSE NULL - END AS hourlypatientfluidremoval - , CASE - WHEN ce.itemid = 228005 THEN ce.valuenum ELSE NULL - END AS prefilterreplacementrate - , CASE - WHEN ce.itemid = 228006 THEN ce.valuenum ELSE NULL - END AS postfilterreplacementrate - , CASE - WHEN ce.itemid = 225976 THEN ce.value ELSE NULL - END AS replacementfluid - , CASE - WHEN ce.itemid = 224153 THEN ce.valuenum ELSE NULL - END AS replacementrate - , CASE - WHEN ce.itemid = 224152 THEN ce.valuenum ELSE NULL - END AS returnpressure - , CASE - WHEN ce.itemid = 226457 THEN ce.valuenum - END AS ultrafiltrateoutput - -- separate system integrity into sub components - -- need to do this as 224146 has multiple unique values - -- for a single charttime - -- e.g. "Clots Present" and "Active" at same time - , CASE - WHEN ce.itemid = 224146 - AND ce.value IN ( - 'Active', 'Initiated', 'Reinitiated', 'New Filter' - ) - THEN 1 - WHEN ce.itemid = 224146 - AND ce.value IN ('Recirculating', 'Discontinued') - THEN 0 - ELSE NULL END AS system_active - , CASE - WHEN ce.itemid = 224146 - AND ce.value IN ('Clots Present', 'Clots Present') - THEN 1 - WHEN ce.itemid = 224146 - AND ce.value IN ('No Clot Present', 'No Clot Present') - THEN 0 - ELSE NULL END AS clots - , CASE - WHEN ce.itemid = 224146 - AND ce.value IN ('Clots Increasing', 'Clot Increasing') - THEN 1 - ELSE NULL END AS clots_increasing - , CASE - WHEN ce.itemid = 224146 - AND ce.value IN ('Clotted') - THEN 1 - ELSE NULL END AS clotted - FROM mimiciv_icu.chartevents ce - WHERE ce.itemid IN - ( - -- MetaVision ITEMIDs - 227290 -- CRRT Mode - , 224146 -- System Integrity - -- 225956, -- Reason for CRRT Filter Change - -- above itemid is one of: Clotted, Line Changed, Procedure - -- only ~200 rows, not super useful - , 224149 -- Access Pressure - , 224144 -- Blood Flow (ml/min) - , 228004 -- Citrate (ACD-A) - , 225183 -- Current Goal - , 225977 -- Dialysate Fluid - , 224154 -- Dialysate Rate - , 224151 -- Effluent Pressure - , 224150 -- Filter Pressure - , 225958 -- Heparin Concentration (units/mL) - , 224145 -- Heparin Dose (per hour) - , 224191 -- Hourly Patient Fluid Removal - , 228005 -- PBP (Prefilter) Replacement Rate - , 228006 -- Post Filter Replacement Rate - , 225976 -- Replacement Fluid - , 224153 -- Replacement Rate - , 224152 -- Return Pressure - , 226457 -- Ultrafiltrate Output - ) - AND ce.value IS NOT NULL + SELECT + ce.stay_id, + ce.charttime, + CASE WHEN ce.itemid = 227290 THEN ce.value END AS crrt_mode, + CASE WHEN ce.itemid = 224149 THEN ce.valuenum ELSE NULL END AS accesspressure, /* (ml/min) */ + CASE WHEN ce.itemid = 224144 THEN ce.valuenum ELSE NULL END AS bloodflow, /* (ACD-A) */ + CASE WHEN ce.itemid = 228004 THEN ce.valuenum ELSE NULL END AS citrate, + CASE WHEN ce.itemid = 225183 THEN ce.valuenum ELSE NULL END AS currentgoal, + CASE WHEN ce.itemid = 225977 THEN ce.value ELSE NULL END AS dialysatefluid, + CASE WHEN ce.itemid = 224154 THEN ce.valuenum ELSE NULL END AS dialysaterate, + CASE WHEN ce.itemid = 224151 THEN ce.valuenum ELSE NULL END AS effluentpressure, + CASE WHEN ce.itemid = 224150 THEN ce.valuenum ELSE NULL END AS filterpressure, /* (units/mL) */ + CASE WHEN ce.itemid = 225958 THEN ce.value ELSE NULL END AS heparinconcentration, /* (per hour) */ + CASE WHEN ce.itemid = 224145 THEN ce.valuenum ELSE NULL END AS heparindose, /* below may not account for drug infusion, */ /* hyperalimentation, and/or anticoagulants infused */ + CASE WHEN ce.itemid = 224191 THEN ce.valuenum ELSE NULL END AS hourlypatientfluidremoval, + CASE WHEN ce.itemid = 228005 THEN ce.valuenum ELSE NULL END AS prefilterreplacementrate, + CASE WHEN ce.itemid = 228006 THEN ce.valuenum ELSE NULL END AS postfilterreplacementrate, + CASE WHEN ce.itemid = 225976 THEN ce.value ELSE NULL END AS replacementfluid, + CASE WHEN ce.itemid = 224153 THEN ce.valuenum ELSE NULL END AS replacementrate, + CASE WHEN ce.itemid = 224152 THEN ce.valuenum ELSE NULL END AS returnpressure, + CASE WHEN ce.itemid = 226457 THEN ce.valuenum END AS ultrafiltrateoutput, /* separate system integrity into sub components */ /* need to do this as 224146 has multiple unique values */ /* for a single charttime */ /* e.g. "Clots Present" and "Active" at same time */ + CASE + WHEN ce.itemid = 224146 + AND ce.value IN ('Active', 'Initiated', 'Reinitiated', 'New Filter') + THEN 1 + WHEN ce.itemid = 224146 AND ce.value IN ('Recirculating', 'Discontinued') + THEN 0 + ELSE NULL + END AS system_active, + CASE + WHEN ce.itemid = 224146 AND ce.value IN ('Clots Present', 'Clots Present') + THEN 1 + WHEN ce.itemid = 224146 AND ce.value IN ('No Clot Present', 'No Clot Present') + THEN 0 + ELSE NULL + END AS clots, + CASE + WHEN ce.itemid = 224146 AND ce.value IN ('Clots Increasing', 'Clot Increasing') + THEN 1 + ELSE NULL + END AS clots_increasing, + CASE WHEN ce.itemid = 224146 AND ce.value IN ('Clotted') THEN 1 ELSE NULL END AS clotted + FROM mimiciv_icu.chartevents AS ce + WHERE + ce.itemid IN (227290 /* MetaVision ITEMIDs */ /* CRRT Mode */, 224146 /* System Integrity */ /* 225956, -- Reason for CRRT Filter Change */ /* above itemid is one of: Clotted, Line Changed, Procedure */ /* only ~200 rows, not super useful */, 224149 /* Access Pressure */, 224144 /* Blood Flow (ml/min) */, 228004 /* Citrate (ACD-A) */, 225183 /* Current Goal */, 225977 /* Dialysate Fluid */, 224154 /* Dialysate Rate */, 224151 /* Effluent Pressure */, 224150 /* Filter Pressure */, 225958 /* Heparin Concentration (units/mL) */, 224145 /* Heparin Dose (per hour) */, 224191 /* Hourly Patient Fluid Removal */, 228005 /* PBP (Prefilter) Replacement Rate */, 228006 /* Post Filter Replacement Rate */, 225976 /* Replacement Fluid */, 224153 /* Replacement Rate */, 224152 /* Return Pressure */, 226457 /* Ultrafiltrate Output */) + AND NOT ce.value IS NULL ) - --- use MAX() to collapse to a single row --- there is only ever 1 row for unique combinations of stay_id/charttime/itemid -SELECT stay_id - , charttime - , MAX(crrt_mode) AS crrt_mode - , MAX(accesspressure) AS access_pressure - , MAX(bloodflow) AS blood_flow - , MAX(citrate) AS citrate - , MAX(currentgoal) AS current_goal - , MAX(dialysatefluid) AS dialysate_fluid - , MAX(dialysaterate) AS dialysate_rate - , MAX(effluentpressure) AS effluent_pressure - , MAX(filterpressure) AS filter_pressure - , MAX(heparinconcentration) AS heparin_concentration - , MAX(heparindose) AS heparin_dose - , MAX(hourlypatientfluidremoval) AS hourly_patient_fluid_removal - , MAX(prefilterreplacementrate) AS prefilter_replacement_rate - , MAX(postfilterreplacementrate) AS postfilter_replacement_rate - , MAX(replacementfluid) AS replacement_fluid - , MAX(replacementrate) AS replacement_rate - , MAX(returnpressure) AS return_pressure - , MAX(ultrafiltrateoutput) AS ultrafiltrate_output - , MAX(system_active) AS system_active - , MAX(clots) AS clots - , MAX(clots_increasing) AS clots_increasing - , MAX(clotted) AS clotted +SELECT + stay_id, + charttime, + MAX(crrt_mode) AS crrt_mode, + MAX(accesspressure) AS access_pressure, + MAX(bloodflow) AS blood_flow, + MAX(citrate) AS citrate, + MAX(currentgoal) AS current_goal, + MAX(dialysatefluid) AS dialysate_fluid, + MAX(dialysaterate) AS dialysate_rate, + MAX(effluentpressure) AS effluent_pressure, + MAX(filterpressure) AS filter_pressure, + MAX(heparinconcentration) AS heparin_concentration, + MAX(heparindose) AS heparin_dose, + MAX(hourlypatientfluidremoval) AS hourly_patient_fluid_removal, + MAX(prefilterreplacementrate) AS prefilter_replacement_rate, + MAX(postfilterreplacementrate) AS postfilter_replacement_rate, + MAX(replacementfluid) AS replacement_fluid, + MAX(replacementrate) AS replacement_rate, + MAX(returnpressure) AS return_pressure, + MAX(ultrafiltrateoutput) AS ultrafiltrate_output, + MAX(system_active) AS system_active, + MAX(clots) AS clots, + MAX(clots_increasing) AS clots_increasing, + MAX(clotted) AS clotted FROM crrt_settings -GROUP BY stay_id, charttime +GROUP BY + stay_id, + charttime \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/treatment/invasive_line.sql b/mimic-iv/concepts_postgres/treatment/invasive_line.sql index 134adf3d6..8bddbdfc3 100644 --- a/mimic-iv/concepts_postgres/treatment/invasive_line.sql +++ b/mimic-iv/concepts_postgres/treatment/invasive_line.sql @@ -1,133 +1,74 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS invasive_line; CREATE TABLE invasive_line AS - --- metavision +DROP TABLE IF EXISTS mimiciv_derived.invasive_line; CREATE TABLE mimiciv_derived.invasive_line AS +/* as a final step, combine any similar terms together */ +/* metavision */ WITH mv AS ( - SELECT - stay_id - -- since metavision separates lines using itemid, - -- we can use it as the line number - , mv.itemid AS line_number - , di.label AS line_type - , mv.location AS line_site - , starttime, endtime - FROM mimiciv_icu.procedureevents mv - INNER JOIN mimiciv_icu.d_items di - ON mv.itemid = di.itemid - WHERE mv.itemid IN - ( - 227719 -- AVA Line - , 225752 -- Arterial Line - , 224269 -- CCO PAC - , 224267 -- Cordis/Introducer - , 224270 -- Dialysis Catheter - , 224272 -- IABP line - , 226124 -- ICP Catheter - , 228169 -- Impella Line - , 225202 -- Indwelling Port (PortaCath) - , 228286 -- Intraosseous Device - , 225204 -- Midline - , 224263 -- Multi Lumen - , 224560 -- PA Catheter - , 224264 -- PICC Line - , 225203 -- Pheresis Catheter - , 224273 -- Presep Catheter - , 225789 -- Sheath - , 225761 -- Sheath Insertion - , 228201 -- Tandem Heart Access Line - , 228202 -- Tandem Heart Return Line - , 224268 -- Trauma line - , 225199 -- Triple Introducer - , 225315 -- Tunneled (Hickman) Line - , 225205 -- RIC - ) + SELECT + stay_id, /* since metavision separates lines using itemid, */ /* we can use it as the line number */ + mv.itemid AS line_number, + di.label AS line_type, + mv.location AS line_site, + starttime, + endtime + FROM mimiciv_icu.procedureevents AS mv + INNER JOIN mimiciv_icu.d_items AS di + ON mv.itemid = di.itemid + WHERE + mv.itemid IN (227719 /* AVA Line */, 225752 /* Arterial Line */, 224269 /* CCO PAC */, 224267 /* Cordis/Introducer */, 224270 /* Dialysis Catheter */, 224272 /* IABP line */, 226124 /* ICP Catheter */, 228169 /* Impella Line */, 225202 /* Indwelling Port (PortaCath) */, 228286 /* Intraosseous Device */, 225204 /* Midline */, 224263 /* Multi Lumen */, 224560 /* PA Catheter */, 224264 /* PICC Line */, 225203 /* Pheresis Catheter */, 224273 /* Presep Catheter */, 225789 /* Sheath */, 225761 /* Sheath Insertion */, 228201 /* Tandem Heart Access Line */, 228202 /* Tandem Heart Return Line */, 224268 /* Trauma line */, 225199 /* Triple Introducer */, 225315 /* Tunneled (Hickman) Line */, 225205 /* RIC */) ) - --- as a final step, combine any similar terms together SELECT - stay_id - , CASE - WHEN line_type IN ('Arterial Line', 'A-Line') THEN 'Arterial' - WHEN - line_type IN ( - 'CCO PA Line', 'CCO PAC' - ) THEN 'Continuous Cardiac Output PA' - WHEN line_type IN ('Dialysis Catheter', 'Dialysis Line') THEN 'Dialysis' - WHEN line_type IN ('Hickman', 'Tunneled (Hickman) Line') THEN 'Hickman' - WHEN line_type IN ('IABP', 'IABP line') THEN 'IABP' - WHEN line_type IN ('Multi Lumen', 'Multi-lumen') THEN 'Multi Lumen' - WHEN line_type IN ('PA Catheter', 'PA line') THEN 'PA' - WHEN line_type IN ('PICC Line', 'PICC line') THEN 'PICC' - WHEN line_type IN ('Pre-Sep Catheter', 'Presep Catheter') THEN 'Pre-Sep' - WHEN line_type IN ('Trauma Line', 'Trauma line') THEN 'Trauma' - WHEN - line_type IN ( - 'Triple Introducer', 'TripleIntroducer' - ) THEN 'Triple Introducer' - WHEN - line_type IN ( - 'Portacath', 'Indwelling Port (PortaCath)' - ) THEN 'Portacath' - -- the following lines were not merged with another line: - -- AVA Line - -- Camino Bolt - -- Cordis/Introducer - -- ICP Catheter - -- Impella Line - -- Intraosseous Device - -- Introducer - -- Lumbar Drain - -- Midline - -- Other/Remarks - -- PacerIntroducer - -- PermaCath - -- Pheresis Catheter - -- RIC - -- Sheath - -- Tandem Heart Access Line - -- Tandem Heart Return Line - -- Venous Access - -- Ventriculostomy - ELSE line_type END AS line_type - , CASE - WHEN line_site IN ('Left Antecub', 'Left Antecube') THEN 'Left Antecube' - WHEN line_site IN ('Left Axilla', 'Left Axilla.') THEN 'Left Axilla' - WHEN - line_site IN ( - 'Left Brachial', 'Left Brachial.' - ) THEN 'Left Brachial' - WHEN line_site IN ('Left Femoral', 'Left Femoral.') THEN 'Left Femoral' - WHEN - line_site IN ( - 'Right Antecub', 'Right Antecube' - ) THEN 'Right Antecube' - WHEN line_site IN ('Right Axilla', 'Right Axilla.') THEN 'Right Axilla' - WHEN - line_site IN ( - 'Right Brachial', 'Right Brachial.' - ) THEN 'Right Brachial' - WHEN - line_site IN ( - 'Right Femoral', 'Right Femoral.' - ) THEN 'Right Femoral' - -- the following sites were not merged with other sites: - -- 'Left Foot' - -- 'Left IJ' - -- 'Left Radial' - -- 'Left Subclavian' - -- 'Left Ulnar' - -- 'Left Upper Arm' - -- 'Right Foot' - -- 'Right IJ' - -- 'Right Radial' - -- 'Right Side Head' - -- 'Right Subclavian' - -- 'Right Ulnar' - -- 'Right Upper Arm' - -- 'Transthoracic' - -- 'Other/Remarks' - ELSE line_site END AS line_site - , starttime - , endtime + stay_id, + CASE + WHEN line_type IN ('Arterial Line', 'A-Line') + THEN 'Arterial' + WHEN line_type IN ('CCO PA Line', 'CCO PAC') + THEN 'Continuous Cardiac Output PA' + WHEN line_type IN ('Dialysis Catheter', 'Dialysis Line') + THEN 'Dialysis' + WHEN line_type IN ('Hickman', 'Tunneled (Hickman) Line') + THEN 'Hickman' + WHEN line_type IN ('IABP', 'IABP line') + THEN 'IABP' + WHEN line_type IN ('Multi Lumen', 'Multi-lumen') + THEN 'Multi Lumen' + WHEN line_type IN ('PA Catheter', 'PA line') + THEN 'PA' + WHEN line_type IN ('PICC Line', 'PICC line') + THEN 'PICC' + WHEN line_type IN ('Pre-Sep Catheter', 'Presep Catheter') + THEN 'Pre-Sep' + WHEN line_type IN ('Trauma Line', 'Trauma line') + THEN 'Trauma' + WHEN line_type IN ('Triple Introducer', 'TripleIntroducer') + THEN 'Triple Introducer' + WHEN line_type IN ('Portacath', 'Indwelling Port (PortaCath)') + THEN 'Portacath' + ELSE line_type + END AS line_type, + CASE + WHEN line_site IN ('Left Antecub', 'Left Antecube') + THEN 'Left Antecube' + WHEN line_site IN ('Left Axilla', 'Left Axilla.') + THEN 'Left Axilla' + WHEN line_site IN ('Left Brachial', 'Left Brachial.') + THEN 'Left Brachial' + WHEN line_site IN ('Left Femoral', 'Left Femoral.') + THEN 'Left Femoral' + WHEN line_site IN ('Right Antecub', 'Right Antecube') + THEN 'Right Antecube' + WHEN line_site IN ('Right Axilla', 'Right Axilla.') + THEN 'Right Axilla' + WHEN line_site IN ('Right Brachial', 'Right Brachial.') + THEN 'Right Brachial' + WHEN line_site IN ('Right Femoral', 'Right Femoral.') + THEN 'Right Femoral' + ELSE line_site + END AS line_site, + starttime, + endtime FROM mv -ORDER BY stay_id, starttime, line_type, line_site; +ORDER BY + stay_id NULLS FIRST, + starttime NULLS FIRST, + line_type NULLS FIRST, + line_site NULLS FIRST \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/treatment/rrt.sql b/mimic-iv/concepts_postgres/treatment/rrt.sql index ced0b2ca1..c010d9573 100644 --- a/mimic-iv/concepts_postgres/treatment/rrt.sql +++ b/mimic-iv/concepts_postgres/treatment/rrt.sql @@ -1,329 +1,105 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS rrt; CREATE TABLE rrt AS --- Creates a table with stay_id / time / dialysis type (if present) - +DROP TABLE IF EXISTS mimiciv_derived.rrt; CREATE TABLE mimiciv_derived.rrt AS +/* Creates a table with stay_id / time / dialysis type (if present) */ WITH ce AS ( - SELECT ce.stay_id - , ce.charttime - -- when ce.itemid in (152,148,149,146,147,151,150) - -- and value is not null then 1 - -- when ce.itemid in (229,235,241,247,253,259,265,271) - -- and value = 'Dialysis Line' then 1 - -- when ce.itemid = 466 and value = 'Dialysis RN' then 1 - -- when ce.itemid = 927 and value = 'Dialysis Solutions' then 1 - -- when ce.itemid = 6250 and value = 'dialys' then 1 - -- when ce. - -- when ce.itemid = 582 and value in ('CAVH Start','CAVH D/C', - -- 'CVVHD Start','CVVHD D/C', - -- 'Hemodialysis st','Hemodialysis end') then 1 - , CASE - -- metavision itemids - - -- checkboxes - WHEN ce.itemid IN - ( - 226118 -- | Dialysis Catheter placed in outside facility - , 227357 -- | Dialysis Catheter Dressing Occlusive - , 225725 -- | Dialysis Catheter Tip Cultured - ) THEN 1 - -- numeric data - WHEN ce.itemid IN - ( - -- | Hemodialysis Output - 226499 - -- | Dialysate Rate - , 224154 - -- | Dwell Time (Peritoneal Dialysis) - , 225810 - -- | Medication Added Amount #1 (Peritoneal Dialysis) - , 225959 - -- | Medication Added Amount #2 (Peritoneal Dialysis) - , 227639 - , 225183 -- | Current Goal - , 227438 -- | Volume not removed - , 224191 -- | Hourly Patient Fluid Removal - , 225806 -- | Volume In (PD) - , 225807 -- | Volume Out (PD) - , 228004 -- | Citrate (ACD-A) - , 228005 -- | PBP (Prefilter) Replacement Rate - , 228006 -- | Post Filter Replacement Rate - , 224144 -- | Blood Flow (ml/min) - , 224145 -- | Heparin Dose (per hour) - , 224149 -- | Access Pressure - , 224150 -- | Filter Pressure - , 224151 -- | Effluent Pressure - , 224152 -- | Return Pressure - , 224153 -- | Replacement Rate - , 224404 -- | ART Lumen Volume - , 224406 -- | VEN Lumen Volume - , 226457 -- | Ultrafiltrate Output - ) THEN 1 - - -- text fields - WHEN ce.itemid IN - ( - 224135 -- | Dialysis Access Site - , 224139 -- | Dialysis Site Appearance - , 224146 -- | System Integrity - -- | Dialysis Catheter Site Appear - , 225323 - -- | Dialysis Catheter Discontinued - , 225740 - -- | Dialysis Catheter Dressing Type - , 225776 - -- | Peritoneal Dialysis Fluid Appearance - , 225951 - -- | Medication Added #1 (Peritoneal Dialysis) - , 225952 - , 225953 -- | Solution (Peritoneal Dialysis) - , 225954 -- | Dialysis Access Type - , 225956 -- | Reason for CRRT Filter Change - , 225958 -- | Heparin Concentration (units/mL) - -- | Medication Added Units #1 (Peritoneal Dialysis) - , 225961 - , 225963 -- | Peritoneal Dialysis Catheter Type - , 225965 -- | Peritoneal Dialysis Catheter Status - , 225976 -- | Replacement Fluid - , 225977 -- | Dialysate Fluid - -- | Dialysis Catheter Type | Access Lines - Invasive - , 227124 - , 227290 -- | CRRT mode - -- | Medication Added #2 (Peritoneal Dialysis) - , 227638 - -- | Medication Added Units #2 (Peritoneal Dialysis) - , 227640 - -- | Dialysis Catheter Placement Confirmed by X-ray - , 227753 - ) THEN 1 - ELSE 0 END - AS dialysis_present - , CASE - WHEN ce.itemid = 225965 -- Peritoneal Dialysis Catheter Status - AND value = 'In use' THEN 1 - WHEN ce.itemid IN - ( - 226499 -- | Hemodialysis Output - , 224154 -- | Dialysate Rate - , 225183 -- | Current Goal - , 227438 -- | Volume not removed - , 224191 -- | Hourly Patient Fluid Removal - , 225806 -- | Volume In (PD) - , 225807 -- | Volume Out (PD) - , 228004 -- | Citrate (ACD-A) - , 228005 -- | PBP (Prefilter) Replacement Rat - , 228006 -- | Post Filter Replacement Rate - , 224144 -- | Blood Flow (ml/min) - , 224145 -- | Heparin Dose (per hour) - , 224153 -- | Replacement Rate - , 226457 -- | Ultrafiltrate Output - ) THEN 1 - ELSE 0 END - AS dialysis_active - , CASE - -- dialysis mode - -- we try to set dialysis mode to one of: - -- CVVH - -- CVVHD - -- CVVHDF - -- SCUF - -- Peritoneal - -- IHD - -- these are the modes in itemid 227290 - WHEN ce.itemid = 227290 THEN value - -- itemids which imply a certain dialysis mode - -- peritoneal dialysis - WHEN ce.itemid IN - ( - 225810 -- | Dwell Time (Peritoneal Dialysis) - , 225806 -- | Volume In (PD) - , 225807 -- | Volume Out (PD) - -- | Dwell Time (Peritoneal Dialysis) - , 225810 - -- | Medication Added Amount #2 (Peritoneal Dialysis) - , 227639 - -- | Medication Added Amount #1 (Peritoneal Dialysis) - , 225959 - -- | Peritoneal Dialysis Fluid Appearance - , 225951 - -- | Medication Added #1 (Peritoneal Dialysis) - , 225952 - -- | Medication Added Units #1 (Peritoneal Dialysis) - , 225961 - , 225953 -- | Solution (Peritoneal Dialysis) - , 225963 -- | Peritoneal Dialysis Catheter Type - , 225965 -- | Peritoneal Dialysis Catheter Status - -- | Medication Added #2 (Peritoneal Dialysis) - , 227638 - -- | Medication Added Units #2 (Peritoneal Dialysis) - , 227640 - ) - THEN 'Peritoneal' - WHEN ce.itemid = 226499 - THEN 'IHD' - ELSE NULL END AS dialysis_type - FROM mimiciv_icu.chartevents ce - WHERE ce.itemid IN - ( - -- === MetaVision itemids === -- - -- Checkboxes - 226118 -- | Dialysis Catheter placed in outside facility - , 227357 -- | Dialysis Catheter Dressing Occlusive - , 225725 -- | Dialysis Catheter Tip Cultured - - -- Numeric values - , 226499 -- | Hemodialysis Output - , 224154 -- | Dialysate Rate - , 225810 -- | Dwell Time (Peritoneal Dialysis) - , 227639 -- | Medication Added Amount #2 (Peritoneal Dialysis) - , 225183 -- | Current Goal - , 227438 -- | Volume not removed - , 224191 -- | Hourly Patient Fluid Removal - , 225806 -- | Volume In (PD) - , 225807 -- | Volume Out (PD) - , 228004 -- | Citrate (ACD-A) - , 228005 -- | PBP (Prefilter) Replacement Rate - , 228006 -- | Post Filter Replacement Rate - , 224144 -- | Blood Flow (ml/min) - , 224145 -- | Heparin Dose (per hour) - , 224149 -- | Access Pressure - , 224150 -- | Filter Pressure - , 224151 -- | Effluent Pressure - , 224152 -- | Return Pressure - , 224153 -- | Replacement Rate - , 224404 -- | ART Lumen Volume - , 224406 -- | VEN Lumen Volume - , 226457 -- | Ultrafiltrate Output - , 225959 -- | Medication Added Amount #1 (Peritoneal Dialysis) - -- Text values - , 224135 -- | Dialysis Access Site - -- | Dialysis Site Appearance - , 224139 - , 224146 -- | System Integrity - , 225323 -- | Dialysis Catheter Site Appear - , 225740 -- | Dialysis Catheter Discontinued - , 225776 -- | Dialysis Catheter Dressing Type - , 225951 -- | Peritoneal Dialysis Fluid Appearance - , 225952 -- | Medication Added #1 (Peritoneal Dialysis) - -- | Solution (Peritoneal Dialysis) - , 225953 - , 225954 -- | Dialysis Access Type - -- | Reason for CRRT Filter Change - , 225956 - -- | Heparin Concentration (units/mL) - , 225958 - , 225961 -- | Medication Added Units #1 (Peritoneal Dialysis) - -- | Peritoneal Dialysis Catheter Type - , 225963 - -- | Peritoneal Dialysis Catheter Status - , 225965 - , 225976 -- | Replacement Fluid - , 225977 -- | Dialysate Fluid - , 227124 -- | Dialysis Catheter Type - , 227290 -- | CRRT mode - , 227638 -- | Medication Added #2 (Peritoneal Dialysis) - , 227640 -- | Medication Added Units #2 (Peritoneal Dialysis) - , 227753 -- | Dialysis Catheter Placement Confirmed by X-ray - ) - AND ce.value IS NOT NULL + SELECT + ce.stay_id, + ce.charttime, /* when ce.itemid in (152,148,149,146,147,151,150) */ /* and value is not null then 1 */ /* when ce.itemid in (229,235,241,247,253,259,265,271) */ /* and value = 'Dialysis Line' then 1 */ /* when ce.itemid = 466 and value = 'Dialysis RN' then 1 */ /* when ce.itemid = 927 and value = 'Dialysis Solutions' then 1 */ /* when ce.itemid = 6250 and value = 'dialys' then 1 */ /* when ce. */ /* when ce.itemid = 582 and value in ('CAVH Start','CAVH D/C', */ /* 'CVVHD Start','CVVHD D/C', */ /* 'Hemodialysis st','Hemodialysis end') then 1 */ + CASE + WHEN ce.itemid IN (226118 /* | Dialysis Catheter placed in outside facility */, 227357 /* | Dialysis Catheter Dressing Occlusive */, 225725 /* | Dialysis Catheter Tip Cultured */) + THEN 1 + WHEN ce.itemid IN (226499 /* | Hemodialysis Output */ /* | Dialysate Rate */, 224154 /* | Dwell Time (Peritoneal Dialysis) */, 225810 /* | Medication Added Amount #1 (Peritoneal Dialysis) */, 225959 /* | Medication Added Amount #2 (Peritoneal Dialysis) */, 227639, 225183 /* | Current Goal */, 227438 /* | Volume not removed */, 224191 /* | Hourly Patient Fluid Removal */, 225806 /* | Volume In (PD) */, 225807 /* | Volume Out (PD) */, 228004 /* | Citrate (ACD-A) */, 228005 /* | PBP (Prefilter) Replacement Rate */, 228006 /* | Post Filter Replacement Rate */, 224144 /* | Blood Flow (ml/min) */, 224145 /* | Heparin Dose (per hour) */, 224149 /* | Access Pressure */, 224150 /* | Filter Pressure */, 224151 /* | Effluent Pressure */, 224152 /* | Return Pressure */, 224153 /* | Replacement Rate */, 224404 /* | ART Lumen Volume */, 224406 /* | VEN Lumen Volume */, 226457 /* | Ultrafiltrate Output */) + THEN 1 + WHEN ce.itemid IN (224135 /* | Dialysis Access Site */, 224139 /* | Dialysis Site Appearance */, 224146 /* | System Integrity */ /* | Dialysis Catheter Site Appear */, 225323 /* | Dialysis Catheter Discontinued */, 225740 /* | Dialysis Catheter Dressing Type */, 225776 /* | Peritoneal Dialysis Fluid Appearance */, 225951 /* | Medication Added #1 (Peritoneal Dialysis) */, 225952, 225953 /* | Solution (Peritoneal Dialysis) */, 225954 /* | Dialysis Access Type */, 225956 /* | Reason for CRRT Filter Change */, 225958 /* | Heparin Concentration (units/mL) */ /* | Medication Added Units #1 (Peritoneal Dialysis) */, 225961, 225963 /* | Peritoneal Dialysis Catheter Type */, 225965 /* | Peritoneal Dialysis Catheter Status */, 225976 /* | Replacement Fluid */, 225977 /* | Dialysate Fluid */ /* | Dialysis Catheter Type | Access Lines - Invasive */, 227124, 227290 /* | CRRT mode */ /* | Medication Added #2 (Peritoneal Dialysis) */, 227638 /* | Medication Added Units #2 (Peritoneal Dialysis) */, 227640 /* | Dialysis Catheter Placement Confirmed by X-ray */, 227753) + THEN 1 + ELSE 0 + END AS dialysis_present, + CASE + WHEN ce.itemid = 225965 /* Peritoneal Dialysis Catheter Status */ AND value = 'In use' + THEN 1 + WHEN ce.itemid IN (226499 /* | Hemodialysis Output */, 224154 /* | Dialysate Rate */, 225183 /* | Current Goal */, 227438 /* | Volume not removed */, 224191 /* | Hourly Patient Fluid Removal */, 225806 /* | Volume In (PD) */, 225807 /* | Volume Out (PD) */, 228004 /* | Citrate (ACD-A) */, 228005 /* | PBP (Prefilter) Replacement Rat */, 228006 /* | Post Filter Replacement Rate */, 224144 /* | Blood Flow (ml/min) */, 224145 /* | Heparin Dose (per hour) */, 224153 /* | Replacement Rate */, 226457 /* | Ultrafiltrate Output */) + THEN 1 + ELSE 0 + END AS dialysis_active, + CASE + WHEN ce.itemid = 227290 + THEN value + WHEN ce.itemid IN (225810 /* | Dwell Time (Peritoneal Dialysis) */, 225806 /* | Volume In (PD) */, 225807 /* | Volume Out (PD) */ /* | Dwell Time (Peritoneal Dialysis) */, 225810 /* | Medication Added Amount #2 (Peritoneal Dialysis) */, 227639 /* | Medication Added Amount #1 (Peritoneal Dialysis) */, 225959 /* | Peritoneal Dialysis Fluid Appearance */, 225951 /* | Medication Added #1 (Peritoneal Dialysis) */, 225952 /* | Medication Added Units #1 (Peritoneal Dialysis) */, 225961, 225953 /* | Solution (Peritoneal Dialysis) */, 225963 /* | Peritoneal Dialysis Catheter Type */, 225965 /* | Peritoneal Dialysis Catheter Status */ /* | Medication Added #2 (Peritoneal Dialysis) */, 227638 /* | Medication Added Units #2 (Peritoneal Dialysis) */, 227640) + THEN 'Peritoneal' + WHEN ce.itemid = 226499 + THEN 'IHD' + ELSE NULL + END AS dialysis_type + FROM mimiciv_icu.chartevents AS ce + WHERE + ce.itemid IN (226118 /* === MetaVision itemids === -- */ /* Checkboxes */ /* | Dialysis Catheter placed in outside facility */, 227357 /* | Dialysis Catheter Dressing Occlusive */, 225725 /* | Dialysis Catheter Tip Cultured */ /* Numeric values */, 226499 /* | Hemodialysis Output */, 224154 /* | Dialysate Rate */, 225810 /* | Dwell Time (Peritoneal Dialysis) */, 227639 /* | Medication Added Amount #2 (Peritoneal Dialysis) */, 225183 /* | Current Goal */, 227438 /* | Volume not removed */, 224191 /* | Hourly Patient Fluid Removal */, 225806 /* | Volume In (PD) */, 225807 /* | Volume Out (PD) */, 228004 /* | Citrate (ACD-A) */, 228005 /* | PBP (Prefilter) Replacement Rate */, 228006 /* | Post Filter Replacement Rate */, 224144 /* | Blood Flow (ml/min) */, 224145 /* | Heparin Dose (per hour) */, 224149 /* | Access Pressure */, 224150 /* | Filter Pressure */, 224151 /* | Effluent Pressure */, 224152 /* | Return Pressure */, 224153 /* | Replacement Rate */, 224404 /* | ART Lumen Volume */, 224406 /* | VEN Lumen Volume */, 226457 /* | Ultrafiltrate Output */, 225959 /* | Medication Added Amount #1 (Peritoneal Dialysis) */ /* Text values */, 224135 /* | Dialysis Access Site */ /* | Dialysis Site Appearance */, 224139, 224146 /* | System Integrity */, 225323 /* | Dialysis Catheter Site Appear */, 225740 /* | Dialysis Catheter Discontinued */, 225776 /* | Dialysis Catheter Dressing Type */, 225951 /* | Peritoneal Dialysis Fluid Appearance */, 225952 /* | Medication Added #1 (Peritoneal Dialysis) */ /* | Solution (Peritoneal Dialysis) */, 225953, 225954 /* | Dialysis Access Type */ /* | Reason for CRRT Filter Change */, 225956 /* | Heparin Concentration (units/mL) */, 225958, 225961 /* | Medication Added Units #1 (Peritoneal Dialysis) */ /* | Peritoneal Dialysis Catheter Type */, 225963 /* | Peritoneal Dialysis Catheter Status */, 225965, 225976 /* | Replacement Fluid */, 225977 /* | Dialysate Fluid */, 227124 /* | Dialysis Catheter Type */, 227290 /* | CRRT mode */, 227638 /* | Medication Added #2 (Peritoneal Dialysis) */, 227640 /* | Medication Added Units #2 (Peritoneal Dialysis) */, 227753 /* | Dialysis Catheter Placement Confirmed by X-ray */) + AND NOT ce.value IS NULL +), mv_ranges AS ( + SELECT + stay_id, + starttime, + endtime, + 1 AS dialysis_present, + 1 AS dialysis_active, + 'CRRT' AS dialysis_type + FROM mimiciv_icu.inputevents + WHERE + itemid IN (227536 /* KCl (CRRT) Medications inputevents_mv Solution */ /* Calcium Gluconate (CRRT) Medications inputevents_mv Solution */, 227525) + AND amount > 0 /* also ensures it's not null */ + UNION + SELECT + stay_id, + starttime, + endtime, + 1 AS dialysis_present, + CASE WHEN NOT itemid IN (224270, 225436) THEN 1 ELSE 0 END AS dialysis_active, + CASE + WHEN itemid = 225441 + THEN 'IHD' + WHEN itemid = 225802 + THEN 'CRRT' + WHEN itemid = 225803 + THEN 'CVVHD' + WHEN itemid = 225805 + THEN 'Peritoneal' + WHEN itemid = 225809 + THEN 'CVVHDF' + WHEN itemid = 225955 + THEN 'SCUF' + ELSE NULL + END AS dialysis_type + FROM mimiciv_icu.procedureevents + WHERE + itemid IN (225441 /* | Hemodialysis */, 225802 /* | Dialysis - CRRT */, 225803 /* | Dialysis - CVVHD */, 225805 /* | Peritoneal Dialysis */, 224270 /* | Dialysis Catheter */, 225809 /* | Dialysis - CVVHDF */, 225955 /* | Dialysis - SCUF */, 225436 /* | CRRT Filter Change */) + AND NOT value IS NULL +), stg0 AS ( + SELECT + stay_id, + charttime, + dialysis_present, + dialysis_active, + dialysis_type + FROM ce + WHERE + dialysis_present = 1 + UNION + /* SELECT */ /* stay_id, charttime, dialysis_present, dialysis_active, dialysis_type */ /* FROM oe */ /* WHERE dialysis_present = 1 */ /* UNION DISTINCT */ + SELECT + stay_id, + starttime AS charttime, + dialysis_present, + dialysis_active, + dialysis_type + FROM mv_ranges ) - --- TODO: --- charttime + dialysis_present + dialysis_active --- for inputevents_cv, outputevents --- for procedures_mv, left join and set the dialysis_type --- , oe AS ( --- SELECT stay_id --- , charttime --- , 1 AS dialysis_present --- , 0 AS dialysis_active --- , NULL AS dialysis_type --- FROM mimiciv_icu.outputevents --- WHERE itemid IN --- ( --- 40386 -- hemodialysis --- ) --- AND value > 0 -- also ensures it's not null --- ) - -, mv_ranges AS ( - SELECT stay_id - , starttime, endtime - , 1 AS dialysis_present - , 1 AS dialysis_active - , 'CRRT' AS dialysis_type - FROM mimiciv_icu.inputevents - WHERE itemid IN - ( - 227536 -- KCl (CRRT) Medications inputevents_mv Solution - -- Calcium Gluconate (CRRT) Medications inputevents_mv Solution - , 227525 - ) - AND amount > 0 -- also ensures it's not null - UNION DISTINCT - SELECT stay_id - , starttime, endtime - , 1 AS dialysis_present - , CASE - WHEN itemid NOT IN (224270, 225436) THEN 1 ELSE 0 - END AS dialysis_active - , CASE - WHEN itemid = 225441 THEN 'IHD' - -- CVVH (Continuous venovenous hemofiltration) - WHEN itemid = 225802 THEN 'CRRT' - -- CVVHD (Continuous venovenous hemodialysis) - WHEN itemid = 225803 THEN 'CVVHD' - WHEN itemid = 225805 THEN 'Peritoneal' - -- CVVHDF (Continuous venovenous hemodiafiltration) - WHEN itemid = 225809 THEN 'CVVHDF' - -- SCUF (Slow continuous ultra filtration) - WHEN itemid = 225955 THEN 'SCUF' - ELSE NULL END AS dialysis_type - FROM mimiciv_icu.procedureevents - WHERE itemid IN - ( - 225441 -- | Hemodialysis - , 225802 -- | Dialysis - CRRT - , 225803 -- | Dialysis - CVVHD - , 225805 -- | Peritoneal Dialysis - , 224270 -- | Dialysis Catheter - , 225809 -- | Dialysis - CVVHDF - , 225955 -- | Dialysis - SCUF - , 225436 -- | CRRT Filter Change - ) - AND value IS NOT NULL -) - --- union together the charttime tables; --- append times from mv_ranges to guarantee they exist -, stg0 AS ( - SELECT - stay_id, charttime, dialysis_present, dialysis_active, dialysis_type - FROM ce - WHERE dialysis_present = 1 - UNION DISTINCT - -- SELECT - -- stay_id, charttime, dialysis_present, dialysis_active, dialysis_type - -- FROM oe - -- WHERE dialysis_present = 1 - -- UNION DISTINCT - SELECT - stay_id - , starttime AS charttime - , dialysis_present - , dialysis_active - , dialysis_type - FROM mv_ranges -) - SELECT - stg0.stay_id - , charttime - , COALESCE(mv.dialysis_present, stg0.dialysis_present) AS dialysis_present - , COALESCE(mv.dialysis_active, stg0.dialysis_active) AS dialysis_active - , COALESCE(mv.dialysis_type, stg0.dialysis_type) AS dialysis_type + stg0.stay_id, + charttime, + COALESCE(mv.dialysis_present, stg0.dialysis_present) AS dialysis_present, + COALESCE(mv.dialysis_active, stg0.dialysis_active) AS dialysis_active, + COALESCE(mv.dialysis_type, stg0.dialysis_type) AS dialysis_type FROM stg0 -LEFT JOIN mv_ranges mv - ON stg0.stay_id = mv.stay_id - AND stg0.charttime >= mv.starttime - AND stg0.charttime <= mv.endtime -; +LEFT JOIN mv_ranges AS mv + ON stg0.stay_id = mv.stay_id + AND stg0.charttime >= mv.starttime + AND stg0.charttime <= mv.endtime \ No newline at end of file diff --git a/mimic-iv/concepts_postgres/treatment/ventilation.sql b/mimic-iv/concepts_postgres/treatment/ventilation.sql index 2811b3bd1..4c253f559 100644 --- a/mimic-iv/concepts_postgres/treatment/ventilation.sql +++ b/mimic-iv/concepts_postgres/treatment/ventilation.sql @@ -1,251 +1,102 @@ -- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY. -DROP TABLE IF EXISTS ventilation; CREATE TABLE ventilation AS --- Classify oxygen devices and ventilator modes into six clinical categories. - --- Categories include.. --- Invasive oxygen delivery types: --- Tracheostomy (with or without positive pressure ventilation) --- InvasiveVent (positive pressure ventilation via endotracheal tube, --- could be oro/nasotracheal or tracheostomy) --- Non invasive oxygen delivery types (ref doi:10.1001/jama.2020.9524): --- NonInvasiveVent (non-invasive positive pressure ventilation) --- HFNC (high flow nasal oxygen / cannula) --- SupplementalOxygen (all other non-rebreather, --- facemask, face tent, nasal prongs...) --- No oxygen device: --- None - --- When conflicting settings occur (rare), the priority is: --- trach > mech vent > NIV > high flow > o2 - --- Some useful cases for debugging: --- stay_id = 30019660 has a tracheostomy placed in the ICU --- stay_id = 30000117 has explicit documentation of extubation - --- first we collect all times which have relevant documentation +DROP TABLE IF EXISTS mimiciv_derived.ventilation; CREATE TABLE mimiciv_derived.ventilation AS +/* create the durations for each ventilation instance */ +/* Classify oxygen devices and ventilator modes into six clinical categories. */ /* Categories include.. */ /* Invasive oxygen delivery types: */ /* Tracheostomy (with or without positive pressure ventilation) */ /* InvasiveVent (positive pressure ventilation via endotracheal tube, */ /* could be oro/nasotracheal or tracheostomy) */ /* Non invasive oxygen delivery types (ref doi:10.1001/jama.2020.9524): */ /* NonInvasiveVent (non-invasive positive pressure ventilation) */ /* HFNC (high flow nasal oxygen / cannula) */ /* SupplementalOxygen (all other non-rebreather, */ /* facemask, face tent, nasal prongs...) */ /* No oxygen device: */ /* None */ /* When conflicting settings occur (rare), the priority is: */ /* trach > mech vent > NIV > high flow > o2 */ /* Some useful cases for debugging: */ /* stay_id = 30019660 has a tracheostomy placed in the ICU */ /* stay_id = 30000117 has explicit documentation of extubation */ /* first we collect all times which have relevant documentation */ WITH tm AS ( - SELECT stay_id, charttime - FROM mimiciv_derived.ventilator_setting - UNION DISTINCT - SELECT stay_id, charttime - FROM mimiciv_derived.oxygen_delivery + SELECT + stay_id, + charttime + FROM mimiciv_derived.ventilator_setting + UNION + SELECT + stay_id, + charttime + FROM mimiciv_derived.oxygen_delivery +), vs AS ( + SELECT + tm.stay_id, + tm.charttime, /* source data columns, here for debug */ + o2_delivery_device_1, + COALESCE(ventilator_mode, ventilator_mode_hamilton) AS vent_mode, /* case statement determining the type of intervention */ /* done in order of priority: trach > mech vent > NIV > high flow > o2 */ + CASE + WHEN o2_delivery_device_1 IN ('Tracheostomy tube' /* 1135 observations for T-Piece */ /* could be either InvasiveVent or Tracheostomy, so omit */ /* 'T-piece', */, 'Trach mask ' /* 16435 observations */) + THEN 'Tracheostomy' + WHEN o2_delivery_device_1 IN ('Endotracheal tube') + OR ventilator_mode IN ('(S) CMV', 'APRV', 'APRV/Biphasic+ApnPress', 'APRV/Biphasic+ApnVol', 'APV (cmv)', 'Ambient', 'Apnea Ventilation', 'CMV', 'CMV/ASSIST', 'CMV/ASSIST/AutoFlow', 'CMV/AutoFlow', 'CPAP/PPS', 'CPAP/PSV', 'CPAP/PSV+Apn TCPL', 'CPAP/PSV+ApnPres', 'CPAP/PSV+ApnVol', 'MMV', 'MMV/AutoFlow', 'MMV/PSV', 'MMV/PSV/AutoFlow', 'P-CMV', 'PCV+', 'PCV+/PSV', 'PCV+Assist', 'PRES/AC', 'PRVC/AC', 'PRVC/SIMV', 'PSV/SBT', 'SIMV', 'SIMV/AutoFlow', 'SIMV/PRES', 'SIMV/PSV', 'SIMV/PSV/AutoFlow', 'SIMV/VOL', 'SYNCHRON MASTER', 'SYNCHRON SLAVE', 'VOL/AC') + OR ventilator_mode_hamilton IN ('APRV', 'APV (cmv)', 'Ambient', '(S) CMV', 'P-CMV', 'SIMV', 'APV (simv)', 'P-SIMV', 'VS', 'ASV') + THEN 'InvasiveVent' + WHEN o2_delivery_device_1 IN ('Bipap mask ' /* 8997 observations */, 'CPAP mask ' /* 5568 observations */) + OR ventilator_mode_hamilton IN ('DuoPaP', 'NIV', 'NIV-ST') + THEN 'NonInvasiveVent' + WHEN o2_delivery_device_1 IN ('High flow nasal cannula' /* 925 observations */) + THEN 'HFNC' + WHEN o2_delivery_device_1 IN ('Non-rebreather' /* 5182 observations */, 'Face tent' /* 24601 observations */, 'Aerosol-cool' /* 24560 observations */, 'Venti mask ' /* 1947 observations */, 'Medium conc mask ' /* 1888 observations */, 'Ultrasonic neb' /* 9 observations */, 'Vapomist' /* 3 observations */, 'Oxymizer' /* 1301 observations */, 'High flow neb' /* 10785 observations */, 'Nasal cannula') + THEN 'SupplementalOxygen' + WHEN o2_delivery_device_1 IN ('None') + THEN 'None' + ELSE NULL + END AS ventilation_status + FROM tm + LEFT JOIN mimiciv_derived.ventilator_setting AS vs + ON tm.stay_id = vs.stay_id AND tm.charttime = vs.charttime + LEFT JOIN mimiciv_derived.oxygen_delivery AS od + ON tm.stay_id = od.stay_id AND tm.charttime = od.charttime +), vd0 AS ( + SELECT + stay_id, + charttime, /* source data columns, here for debug */ /* , o2_delivery_device_1 */ /* , vent_mode */ /* carry over the previous charttime which had the same state */ + LAG(charttime, 1) OVER (PARTITION BY stay_id, ventilation_status ORDER BY charttime NULLS FIRST) AS charttime_lag, /* bring back the next charttime, regardless of the state */ /* this will be used as the end time for state transitions */ + LEAD(charttime, 1) OVER w AS charttime_lead, + ventilation_status, + LAG(ventilation_status, 1) OVER w AS ventilation_status_lag + FROM vs + WHERE + NOT ventilation_status IS NULL + WINDOW w AS (PARTITION BY stay_id ORDER BY charttime NULLS FIRST) +), vd1 AS ( + SELECT + stay_id, + charttime, + charttime_lag, + charttime_lead, + ventilation_status, /* source data columns, here for debug */ /* , o2_delivery_device_1 */ /* , vent_mode */ /* calculate the time since the last event */ + CAST(EXTRACT(EPOCH FROM charttime - charttime_lag) / 60.0 AS DOUBLE PRECISION) / 60 AS ventduration, /* now we determine if the current ventilation status is "new", */ /* or continuing the previous event */ + CASE + WHEN ventilation_status_lag IS NULL + THEN 1 + WHEN EXTRACT(EPOCH FROM charttime - charttime_lag) / 3600.0 >= 14 + THEN 1 + WHEN ventilation_status_lag <> ventilation_status + THEN 1 + ELSE 0 + END AS new_ventilation_event + FROM vd0 +), vd2 AS ( + SELECT + vd1.stay_id, + vd1.charttime, + vd1.charttime_lead, + vd1.ventilation_status, + ventduration, + new_ventilation_event, /* create a cumulative sum of the instances of new ventilation */ /* this results in a monotonically increasing integer assigned */ /* to each instance of ventilation */ + SUM(new_ventilation_event) OVER (PARTITION BY stay_id ORDER BY charttime NULLS FIRST) AS vent_seq + FROM vd1 ) - -, vs AS ( - SELECT tm.stay_id, tm.charttime - -- source data columns, here for debug - , o2_delivery_device_1 - , COALESCE(ventilator_mode, ventilator_mode_hamilton) AS vent_mode - -- case statement determining the type of intervention - -- done in order of priority: trach > mech vent > NIV > high flow > o2 - , CASE - -- tracheostomy - WHEN o2_delivery_device_1 IN - ( - 'Tracheostomy tube' - -- 1135 observations for T-Piece - -- could be either InvasiveVent or Tracheostomy, so omit - -- 'T-piece', - , 'Trach mask ' -- 16435 observations - ) - THEN 'Tracheostomy' - -- mechanical / invasive ventilation - WHEN o2_delivery_device_1 IN - ( - 'Endotracheal tube' - ) - OR ventilator_mode IN - ( - '(S) CMV' - , 'APRV' - , 'APRV/Biphasic+ApnPress' - , 'APRV/Biphasic+ApnVol' - , 'APV (cmv)' - , 'Ambient' - , 'Apnea Ventilation' - , 'CMV' - , 'CMV/ASSIST' - , 'CMV/ASSIST/AutoFlow' - , 'CMV/AutoFlow' - , 'CPAP/PPS' - , 'CPAP/PSV' - , 'CPAP/PSV+Apn TCPL' - , 'CPAP/PSV+ApnPres' - , 'CPAP/PSV+ApnVol' - , 'MMV' - , 'MMV/AutoFlow' - , 'MMV/PSV' - , 'MMV/PSV/AutoFlow' - , 'P-CMV' - , 'PCV+' - , 'PCV+/PSV' - , 'PCV+Assist' - , 'PRES/AC' - , 'PRVC/AC' - , 'PRVC/SIMV' - , 'PSV/SBT' - , 'SIMV' - , 'SIMV/AutoFlow' - , 'SIMV/PRES' - , 'SIMV/PSV' - , 'SIMV/PSV/AutoFlow' - , 'SIMV/VOL' - , 'SYNCHRON MASTER' - , 'SYNCHRON SLAVE' - , 'VOL/AC' - ) - OR ventilator_mode_hamilton IN - ( - 'APRV' - , 'APV (cmv)' - , 'Ambient' - , '(S) CMV' - , 'P-CMV' - , 'SIMV' - , 'APV (simv)' - , 'P-SIMV' - , 'VS' - , 'ASV' - ) - THEN 'InvasiveVent' - -- NIV - WHEN o2_delivery_device_1 IN - ( - 'Bipap mask ' -- 8997 observations - , 'CPAP mask ' -- 5568 observations - ) - OR ventilator_mode_hamilton IN - ( - 'DuoPaP' - , 'NIV' - , 'NIV-ST' - ) - THEN 'NonInvasiveVent' - -- high flow nasal cannula - WHEN o2_delivery_device_1 IN - ( - 'High flow nasal cannula' -- 925 observations - ) - THEN 'HFNC' - -- non rebreather - WHEN o2_delivery_device_1 IN - ( - 'Non-rebreather' -- 5182 observations - , 'Face tent' -- 24601 observations - , 'Aerosol-cool' -- 24560 observations - , 'Venti mask ' -- 1947 observations - , 'Medium conc mask ' -- 1888 observations - , 'Ultrasonic neb' -- 9 observations - , 'Vapomist' -- 3 observations - , 'Oxymizer' -- 1301 observations - , 'High flow neb' -- 10785 observations - , 'Nasal cannula' - ) - THEN 'SupplementalOxygen' - WHEN o2_delivery_device_1 IN - ( - 'None' - ) - THEN 'None' - -- not categorized: other - ELSE NULL END AS ventilation_status - FROM tm - LEFT JOIN mimiciv_derived.ventilator_setting vs - ON tm.stay_id = vs.stay_id - AND tm.charttime = vs.charttime - LEFT JOIN mimiciv_derived.oxygen_delivery od - ON tm.stay_id = od.stay_id - AND tm.charttime = od.charttime -) - -, vd0 AS ( - SELECT - stay_id, charttime - -- source data columns, here for debug - -- , o2_delivery_device_1 - -- , vent_mode - -- carry over the previous charttime which had the same state - , LAG( - charttime, 1 - ) OVER ( - PARTITION BY stay_id, ventilation_status ORDER BY charttime - ) AS charttime_lag - -- bring back the next charttime, regardless of the state - -- this will be used as the end time for state transitions - , LEAD(charttime, 1) OVER w AS charttime_lead - , ventilation_status - , LAG(ventilation_status, 1) OVER w AS ventilation_status_lag - FROM vs - WHERE ventilation_status IS NOT NULL - WINDOW w AS (PARTITION BY stay_id ORDER BY charttime) -) - -, vd1 AS ( - SELECT - stay_id - , charttime - , charttime_lag - , charttime_lead - , ventilation_status - - -- source data columns, here for debug - -- , o2_delivery_device_1 - -- , vent_mode - - -- calculate the time since the last event - , DATETIME_DIFF(charttime, charttime_lag, 'MINUTE') / 60 AS ventduration - - -- now we determine if the current ventilation status is "new", - -- or continuing the previous event - , CASE - -- if lag is null, this is the first event for the patient - WHEN ventilation_status_lag IS NULL THEN 1 - -- a 14 hour gap always initiates a new event - WHEN DATETIME_DIFF(charttime, charttime_lag, 'HOUR') >= 14 THEN 1 - -- not a new event if identical to the last row - WHEN ventilation_status_lag != ventilation_status THEN 1 - ELSE 0 - END AS new_ventilation_event - FROM vd0 -) - -, vd2 AS ( - SELECT vd1.stay_id, vd1.charttime - , vd1.charttime_lead, vd1.ventilation_status - , ventduration, new_ventilation_event - -- create a cumulative sum of the instances of new ventilation - -- this results in a monotonically increasing integer assigned - -- to each instance of ventilation - , SUM(new_ventilation_event) OVER - ( - PARTITION BY stay_id - ORDER BY charttime - ) AS vent_seq - FROM vd1 -) - --- create the durations for each ventilation instance SELECT - stay_id - , MIN(charttime) AS starttime - -- for the end time of the ventilation event, the time of the *next* setting - -- i.e. if we go NIV -> O2, the end time of NIV is the first row - -- with a documented O2 device - -- ... unless it's been over 14 hours, - -- in which case it's the last row with a documented NIV. - , MAX( - CASE - WHEN charttime_lead IS NULL - OR DATETIME_DIFF(charttime_lead, charttime, 'HOUR') >= 14 - THEN charttime - ELSE charttime_lead - END - ) AS endtime - -- all rows with the same vent_num will have the same ventilation_status - -- for efficiency, we use an aggregate here, - -- but we could equally well group by this column - , MAX(ventilation_status) AS ventilation_status + stay_id, + MIN(charttime) AS starttime, /* for the end time of the ventilation event, the time of the *next* setting */ /* i.e. if we go NIV -> O2, the end time of NIV is the first row */ /* with a documented O2 device */ /* ... unless it's been over 14 hours, */ /* in which case it's the last row with a documented NIV. */ + MAX( + CASE + WHEN charttime_lead IS NULL + OR EXTRACT(EPOCH FROM charttime_lead - charttime) / 3600.0 >= 14 + THEN charttime + ELSE charttime_lead + END + ) AS endtime, /* all rows with the same vent_num will have the same ventilation_status */ /* for efficiency, we use an aggregate here, */ /* but we could equally well group by this column */ + MAX(ventilation_status) AS ventilation_status FROM vd2 -GROUP BY stay_id, vent_seq -HAVING MIN(charttime) != MAX(charttime) -; +GROUP BY + stay_id, + vent_seq +HAVING + MIN(charttime) <> MAX(charttime) \ No newline at end of file diff --git a/mimic-iv/concepts/concept_map/d_labitems_to_loinc.csv b/mimic-iv/mapping/d_labitems_to_loinc.csv similarity index 100% rename from mimic-iv/concepts/concept_map/d_labitems_to_loinc.csv rename to mimic-iv/mapping/d_labitems_to_loinc.csv diff --git a/mimic-iv/concepts/concept_map/inputevents_to_rxnorm.csv b/mimic-iv/mapping/inputevents_to_rxnorm.csv similarity index 100% rename from mimic-iv/concepts/concept_map/inputevents_to_rxnorm.csv rename to mimic-iv/mapping/inputevents_to_rxnorm.csv diff --git a/mimic-iv/concepts/concept_map/lab_itemid_to_loinc.csv b/mimic-iv/mapping/lab_itemid_to_loinc.csv similarity index 100% rename from mimic-iv/concepts/concept_map/lab_itemid_to_loinc.csv rename to mimic-iv/mapping/lab_itemid_to_loinc.csv diff --git a/mimic-iv/concepts/concept_map/meas_chartevents_main.csv b/mimic-iv/mapping/meas_chartevents_main.csv similarity index 100% rename from mimic-iv/concepts/concept_map/meas_chartevents_main.csv rename to mimic-iv/mapping/meas_chartevents_main.csv diff --git a/mimic-iv/concepts/concept_map/meas_chartevents_value.csv b/mimic-iv/mapping/meas_chartevents_value.csv similarity index 100% rename from mimic-iv/concepts/concept_map/meas_chartevents_value.csv rename to mimic-iv/mapping/meas_chartevents_value.csv diff --git a/mimic-iv/concepts/concept_map/numerics-summary.csv b/mimic-iv/mapping/numerics-summary.csv similarity index 100% rename from mimic-iv/concepts/concept_map/numerics-summary.csv rename to mimic-iv/mapping/numerics-summary.csv diff --git a/mimic-iv/concepts/concept_map/outputevents_to_loinc.csv b/mimic-iv/mapping/outputevents_to_loinc.csv similarity index 100% rename from mimic-iv/concepts/concept_map/outputevents_to_loinc.csv rename to mimic-iv/mapping/outputevents_to_loinc.csv diff --git a/mimic-iv/concepts/concept_map/proc_datetimeevents.csv b/mimic-iv/mapping/proc_datetimeevents.csv similarity index 100% rename from mimic-iv/concepts/concept_map/proc_datetimeevents.csv rename to mimic-iv/mapping/proc_datetimeevents.csv diff --git a/mimic-iv/concepts/concept_map/proc_itemid.csv b/mimic-iv/mapping/proc_itemid.csv similarity index 100% rename from mimic-iv/concepts/concept_map/proc_itemid.csv rename to mimic-iv/mapping/proc_itemid.csv diff --git a/mimic-iv/concepts/concept_map/waveforms-summary.csv b/mimic-iv/mapping/waveforms-summary.csv similarity index 100% rename from mimic-iv/concepts/concept_map/waveforms-summary.csv rename to mimic-iv/mapping/waveforms-summary.csv diff --git a/pyproject.toml b/pyproject.toml new file mode 100644 index 000000000..8c887778b --- /dev/null +++ b/pyproject.toml @@ -0,0 +1,38 @@ +[build-system] +requires = ["hatchling"] +build-backend = "hatchling.build" + +[project] +name = "mimic_utils" +version = "1.0.0" +authors = [ + { name="Alistair Johnson", email="aewj@mit.edu" }, +] +description = "Utilities to support building and analyzing the MIMIC database(s)" +readme = "README_mimic_utils.md" +license = { file="LICENSE" } +requires-python = ">=3.8" +classifiers = [ + "Programming Language :: Python :: 3", + "License :: OSI Approved :: Apache Software License", + "Operating System :: OS Independent", +] +dependencies = [ + "sqlglot", + "pandas", + "numpy", +] + +[project.scripts] +mimic_utils = "mimic_utils.__main__:main" + +[project.urls] +"Homepage" = "https://github.com/MIT-LCP/mimic-code" +"Bug Tracker" = "https://github.com/MIT-LCP/mimic-code/issues" + +[tool.hatch.build.targets.sdist] +ignore-vcs = true +only-include = ["src/mimic_utils"] + +[tool.hatch.build.targets.wheel] +packages = ["src/mimic_utils"] \ No newline at end of file diff --git a/src/mimic_utils/__init__.py b/src/mimic_utils/__init__.py new file mode 100644 index 000000000..e69de29bb diff --git a/src/mimic_utils/__main__.py b/src/mimic_utils/__main__.py new file mode 100644 index 000000000..ba33954e9 --- /dev/null +++ b/src/mimic_utils/__main__.py @@ -0,0 +1,31 @@ +from argparse import ArgumentParser + +from mimic_utils.transpile import transpile_file, transpile_folder + +def main(): + parser = ArgumentParser(description="Convert SQL to different dialects.") + subparsers = parser.add_subparsers() + + file_parser = subparsers.add_parser('convert_file', help='Transpile a single SQL file.') + file_parser.add_argument("source_file", help="Source file.") + file_parser.add_argument("destination_file", help="Destination file.") + file_parser.add_argument("--source_dialect", choices=["bigquery", "postgres", "duckdb"], default='bigquery', help="SQL dialect to transpile.") + file_parser.add_argument("--destination_dialect", choices=["postgres", "duckdb"], default='postgres', help="SQL dialect to transpile.") + file_parser.set_defaults(func=transpile_file) + + folder_parser = subparsers.add_parser('convert_folder', help='Transpile all SQL files in a folder.') + folder_parser.add_argument("source_folder", help="Source folder.") + folder_parser.add_argument("destination_folder", help="Destination folder.") + folder_parser.add_argument("--source_dialect", choices=["bigquery", "postgres", "duckdb"], default='bigquery', help="SQL dialect to transpile.") + folder_parser.add_argument("--destination_dialect", choices=["bigquery", "postgres", "duckdb"], default="postgres", help="SQL dialect to transpile.") + folder_parser.set_defaults(func=transpile_folder) + + args = parser.parse_args() + # pop func from args + args = vars(args) + func = args.pop("func") + func(**args) + + +if __name__ == '__main__': + main() diff --git a/src/mimic_utils/sqlglot/__init__.py b/src/mimic_utils/sqlglot/__init__.py new file mode 100644 index 000000000..e69de29bb diff --git a/src/mimic_utils/sqlglot/bigquery.py b/src/mimic_utils/sqlglot/bigquery.py new file mode 100644 index 000000000..777344ca5 --- /dev/null +++ b/src/mimic_utils/sqlglot/bigquery.py @@ -0,0 +1,12 @@ +import sqlglot +import sqlglot.dialects.bigquery +from sqlglot import Expression, exp, select +from sqlglot.helper import seq_get + +sqlglot.dialects.bigquery.BigQuery.Parser.FUNCTIONS["PARSE_DATETIME"] = lambda args: exp.StrToTime( + this=seq_get(args, 1), format=seq_get(args, 0) +) +sqlglot.dialects.bigquery.BigQuery.Parser.FUNCTIONS["FORMAT_DATE"] = lambda args: exp.TimeToStr( + this=seq_get(args, 1), format=seq_get(args, 0) +) +sqlglot.dialects.bigquery.BigQuery.Parser.STRICT_CAST = False diff --git a/src/mimic_utils/sqlglot/duckdb.py b/src/mimic_utils/sqlglot/duckdb.py new file mode 100644 index 000000000..67d504be3 --- /dev/null +++ b/src/mimic_utils/sqlglot/duckdb.py @@ -0,0 +1,78 @@ +import sqlglot +import sqlglot.dialects.duckdb +from sqlglot.dialects.duckdb import DuckDB +from sqlglot import Expression, exp, select +from sqlglot.helper import seq_get + +# Monkey patches for duckdb +# (1) date_sub / date_add +# (2) date_diff +# (3) datetime() function +# (4) date_trunc + +# DATETIME_ADD / DATETIME_SUB -> quote the integer +def datetime_arithmetic_sql(self: Expression, expression: Expression, operator: str): + """Render DATE_ADD and DATE_SUB functions as a addition or subtraction of an interval.""" + this = self.sql(expression, "this") + unit = self.sql(expression, "unit") or "DAY" + # for psql, we need to quote the number + interval_exp = expression.expression + if isinstance(interval_exp, exp.Literal): + interval_exp = exp.Literal(this=expression.expression.this, is_string=True) + return f"{this} {operator} {self.sql(exp.Interval(this=interval_exp, unit=unit))}" + + # if the interval number is an expression, we multiply it by an interval instead + # e.g. if it is CAST(column AS INT), it becomes CAST(column AS INT) * INTERVAL '1' HOUR + one_interval = exp.Interval( + this=exp.Literal(this="1", is_string=True), + unit=unit + ) + return f"{this} {operator} {self.sql(exp.Mul(this=interval_exp, expression=one_interval))}" +sqlglot.dialects.duckdb.DuckDB.Generator.TRANSFORMS[exp.DatetimeSub] = lambda self, expression: datetime_arithmetic_sql(self, expression, "-") +sqlglot.dialects.duckdb.DuckDB.Generator.TRANSFORMS[exp.DatetimeAdd] = lambda self, expression: datetime_arithmetic_sql(self, expression, "+") + +_unit_ms_conversion_factor_map = { + 'SECOND': 1e6, + 'MINUTE': 60.0*1e6, + 'HOUR': 3600.0*1e6, + 'DAY': 24*3600.0*1e6, + 'YEAR': 365.242*24*3600.0*1e6, +} +def duckdb_date_diff_frac_sql(self, expression): + this = self.sql(expression, "this") + mfactor = _unit_ms_conversion_factor_map[self.sql(expression, "unit").upper() or "DAY"] + # DuckDB DATE_DIFF operand order is start_time, end_time--not like end_time - start_time! + return f"DATE_DIFF('microseconds', {self.sql(expression.expression)}, {this})/{mfactor:.1f}" +sqlglot.dialects.duckdb.DuckDB.Generator.TRANSFORMS[exp.DatetimeDiff] = duckdb_date_diff_frac_sql +sqlglot.dialects.duckdb.DuckDB.Generator.TRANSFORMS[exp.DateDiff] = duckdb_date_diff_frac_sql + +# DATETIME: duckdb has a similar function, but it's named make_timestamp +class DateTime(exp.Func): + arg_types = {"this": True, "expressions": False} + _sql_names = ["MAKE_TIMESTAMP", "DATETIME"] + +def datetime_sql(self: DuckDB.Generator, expression: DateTime): + # https://cloud.google.com/bigquery/docs/reference/standard-sql/datetime_functions#datetime + # BigQuery supports three overloaded arguments to DATETIME, but we will only accept + # (1) the version which accepts integer valued arguments + # (2) the version which accepts a DATE directly (no optional 2nd argument allowed) + if not isinstance(expression.expressions, list): + raise NotImplementedError("Transpile only supports DATETIME(date) OR DATETIME(year, month, day, hour, minute, second)") + if len(expression.expressions) == 1: + # handle the case where we are passing a DATE directly + return f"CAST({self.sql(expression.expressions[0])} AS TIMESTAMP)" + + if len(expression.expressions) != 6: + raise NotImplementedError("Transpile only supports DATETIME(date) OR DATETIME(year, month, day, hour, minute, second)") + + return f'MAKE_TIMESTAMP({", ".join([self.sql(arg) for arg in expression.expressions])})' +sqlglot.dialects.duckdb.DuckDB.Generator.TRANSFORMS[DateTime] = datetime_sql + + +# DATE_TRUNC -> quote the unit part +def date_trunc_sql(self: DuckDB.Generator, expression: Expression): + this = self.sql(expression, "this") + unit = self.sql(expression, "unit") or "DAY" + return f"DATE_TRUNC('{unit}', {this})" +sqlglot.dialects.duckdb.DuckDB.Generator.TRANSFORMS[exp.DateTrunc] = date_trunc_sql +sqlglot.dialects.duckdb.DuckDB.Generator.TRANSFORMS[exp.DatetimeTrunc] = date_trunc_sql diff --git a/src/mimic_utils/sqlglot/postgres.py b/src/mimic_utils/sqlglot/postgres.py new file mode 100644 index 000000000..8334f5ad5 --- /dev/null +++ b/src/mimic_utils/sqlglot/postgres.py @@ -0,0 +1,122 @@ +import sqlglot +import sqlglot.dialects.postgres +from sqlglot import Expression, exp, select + +# DATETIME: allow passing either a DATE directly, or multiple arguments +# there isn't a class for the Datetime function, so we have to create it ourself, +# and recast anonymous functions with the name "datetime" to this class +# https://cloud.google.com/bigquery/docs/reference/standard-sql/datetime_functions#datetime +class DateTime(exp.Func): + arg_types = {"this": False, "zone": False, "expressions": False} + is_var_len_args = True + + +# GENERATE_ARRAY(exp1, exp2) -> convert to ARRAY(SELECT * FROM generate_series(exp1, exp2)) +# https://cloud.google.com/bigquery/docs/reference/standard-sql/array_functions#generate_array +# https://www.postgresql.org/docs/current/functions-srf.html +class GenerateArray(exp.Func): + arg_types = {"this": False, "expressions": False} + +class GenerateSeries(exp.Func): + arg_types = {"this": False, "expressions": False} + + +# DATETIME_ADD / DATETIME_SUB -> quote the integer +def date_arithmetic_sql(self: Expression, expression: Expression, operator: str): + """Render DATE_ADD and DATE_SUB functions as a addition or subtraction of an interval.""" + this = self.sql(expression, "this") + unit = self.sql(expression, "unit") or "DAY" + # for psql, we need to quote the number + interval_exp = expression.expression + if isinstance(interval_exp, exp.Literal): + interval_exp = exp.Literal(this=expression.expression.this, is_string=True) + return f"{this} {operator} {self.sql(exp.Interval(this=interval_exp, unit=unit))}" + + # if the interval number is an expression, we multiply it by an interval instead + # e.g. if it is CAST(column AS INT), it becomes CAST(column AS INT) * INTERVAL '1' HOUR + one_interval = exp.Interval( + this=exp.Literal(this="1", is_string=True), + unit=unit + ) + return f"{this} {operator} {self.sql(exp.Mul(this=interval_exp, expression=one_interval))}" +sqlglot.dialects.postgres.Postgres.Generator.TRANSFORMS[exp.DatetimeSub] = lambda self, expression: date_arithmetic_sql(self, expression, "-") +sqlglot.dialects.postgres.Postgres.Generator.TRANSFORMS[exp.DatetimeAdd] = lambda self, expression: date_arithmetic_sql(self, expression, "+") + +# DATETIME_DIFF / DATE_DIFF -> use EXTRACT(EPOCH ...) with a custom conversion factor +_unit_second_conversion_factor_map = { + 'SECOND': 1, + 'MINUTE': 60.0, + 'HOUR': 3600.0, + 'DAY': 24*3600.0, + 'YEAR': 365.242*24*3600.0, +} +def date_diff_sql(self: Expression, expression: Expression): + this = self.sql(expression, "this") + mfactor = _unit_second_conversion_factor_map[self.sql(expression, "unit").upper() or "DAY"] + return f"EXTRACT(EPOCH FROM {this} - {self.sql(expression.expression)}) / {mfactor:.1f}" + +sqlglot.dialects.postgres.Postgres.Generator.TRANSFORMS[exp.DatetimeDiff] = date_diff_sql +sqlglot.dialects.postgres.Postgres.Generator.TRANSFORMS[exp.DateDiff] = date_diff_sql + +# DATE_TRUNC -> quote the unit part +def date_trunc_sql(self: Expression, expression: Expression): + this = self.sql(expression, "this") + unit = self.sql(expression, "unit") or "DAY" + return f"DATE_TRUNC('{unit}', {this})" +sqlglot.dialects.postgres.Postgres.Generator.TRANSFORMS[exp.DateTrunc] = date_trunc_sql +sqlglot.dialects.postgres.Postgres.Generator.TRANSFORMS[exp.DatetimeTrunc] = date_trunc_sql + +def datetime_sql(self: Expression, expression: Expression): + # https://cloud.google.com/bigquery/docs/reference/standard-sql/datetime_functions#datetime + # BigQuery supports three overloaded arguments to DATETIME, but we will only accept + # (1) the version which accepts integer valued arguments + # (2) the version which accepts a DATE directly (no optional 2nd argument allowed) + if not isinstance(expression.expressions, list): + raise NotImplementedError("Transpile only supports DATETIME(date) OR DATETIME(year, month, day, hour, minute, second)") + if len(expression.expressions) == 1: + # handle the case where we are passing a DATE directly + return f"CAST({self.sql(expression.expressions[0])} AS TIMESTAMP)" + + if len(expression.expressions) != 6: + raise NotImplementedError("Transpile only supports DATETIME(date) OR DATETIME(year, month, day, hour, minute, second)") + + # we will now map the args for passing to the TO_TIMESTAMP(string, format) PSQL function + args = [self.sql(arg) for arg in expression.expressions] + # pad the arguments with zeros + args = [f"TO_CHAR({arg}, '{'0000' if i == 0 else '00'}')" for i, arg in enumerate(args)] + # concatenate the arguments + args = " || ".join(args) + # convert the concatenated string to a timestamp + return f"TO_TIMESTAMP({args}, 'yyyymmddHH24MISS')" +sqlglot.dialects.postgres.Postgres.Generator.TRANSFORMS[DateTime] = datetime_sql + +# GENERATE_ARRAY(exp1, exp2) -> convert to ARRAY(SELECT * FROM generate_series(exp1, exp2)) +# https://cloud.google.com/bigquery/docs/reference/standard-sql/array_functions#generate_array +# https://www.postgresql.org/docs/current/functions-srf.html +def generate_array_sql(self: Expression, expression: Expression): + # first create a select statement which selects from generate_series + select_statement = select("*").from_( + GenerateSeries( + expressions=[ + expression.expressions[0], + expression.expressions[1], + ], + ) + ) + + # now convert the select statement to an array + return f"ARRAY({self.sql(select_statement)})" +sqlglot.dialects.postgres.Postgres.Generator.TRANSFORMS[GenerateArray] = generate_array_sql + +# we need to prevent the wrapping of the table alias in brackets for UNNEST +# e.g. UNNEST(array) AS (alias) -> UNNEST(array) AS alias +def unnest_sql(self: Expression, expression: Expression): + alias = self.sql(expression, "alias") + # remove the brackets + if alias.startswith("(") and alias.endswith(")"): + alias = alias[1:-1] + sql_text = expression.sql() + # substitute the alias + sql_text = sql_text.replace(f' AS {self.sql(expression, "alias")}', f' AS {alias}') + return sql_text +sqlglot.dialects.postgres.Postgres.Generator.TRANSFORMS[exp.Unnest] = unnest_sql diff --git a/src/mimic_utils/transpile.py b/src/mimic_utils/transpile.py new file mode 100644 index 000000000..365e30a0e --- /dev/null +++ b/src/mimic_utils/transpile.py @@ -0,0 +1,102 @@ +import os +from pathlib import Path +from typing import Union + +import sqlglot +import sqlglot.dialects.bigquery +import sqlglot.dialects.duckdb +import sqlglot.dialects.postgres +from sqlglot import Expression, exp, select +from sqlglot.helper import seq_get + +# Apply transformation monkey patches +# these modules are imported for their side effects +from mimic_utils.sqlglot import postgres +from mimic_utils.sqlglot import bigquery +from mimic_utils.sqlglot import duckdb + +# sqlglot has a default convention that function names are upper-case +_FUNCTION_MAPPING = { + 'bigquery': {}, + 'postgres': { + 'DATETIME': postgres.DateTime, + 'GENERATE_ARRAY': postgres.GenerateArray, + }, + 'duckdb': { + 'DATETIME': duckdb.DateTime, + }, +} + +def transpile_query(query: str, source_dialect: str="bigquery", destination_dialect: str="postgres"): + """ + Transpiles the SQL file from BigQuery to the specified dialect. + """ + sql_parsed = sqlglot.parse_one(query, read=source_dialect) + + # Remove "physionet-data" as the catalog name + catalog_to_remove = 'physionet-data' + for table in sql_parsed.find_all(exp.Table): + if table.catalog == catalog_to_remove: + table.args['catalog'] = None + elif table.this.name.startswith(catalog_to_remove): + table.args['this'].args['this'] = table.this.name.replace(catalog_to_remove + '.', '') + # sqlglot wants to output the schema/table as a single quoted identifier + # so here we remove the quoting + table.args['this'] = sqlglot.expressions.to_identifier( + name=table.args['this'].args['this'], + quoted=False + ) + + # BigQuery has a few functions which are not in sqlglot, so we have + # created classes for them, and this loop replaces the anonymous functions + # with the named functions + function_mapper = _FUNCTION_MAPPING[destination_dialect] + for anon_function in sql_parsed.find_all(exp.Anonymous): + if anon_function.this in function_mapper: + named_function = function_mapper[anon_function.this](**anon_function.args) + anon_function.replace(named_function) + + # duckdb does not support the default /* ... */ comment style + keep_comments = True + if destination_dialect == 'duckdb': + keep_comments = False + + # convert back to sql + transpiled_query = sql_parsed.sql(dialect=destination_dialect, pretty=True, comments=keep_comments) + + return transpiled_query + +def transpile_file(source_file: Union[str, os.PathLike], destination_file: Union[str, os.PathLike], source_dialect: str="bigquery", destination_dialect: str="postgres", derived_schema: str="mimiciv_derived"): + """ + Reads an SQL file in from file, transpiles it, and outputs it to file. + """ + with open(source_file, "r") as read_file: + sql_query = read_file.read() + + if derived_schema is not None: + derived_schema = derived_schema.rstrip('.') + "." + else: + derived_schema = "" + + transpiled_query = transpile_query(sql_query, source_dialect, destination_dialect) + # add "create" statement based on the file stem + transpiled_query = ( + "-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY.\n" + f"DROP TABLE IF EXISTS {derived_schema}{Path(source_file).stem}; " + f"CREATE TABLE {derived_schema}{Path(source_file).stem} AS\n" + ) + transpiled_query + + with open(destination_file, "w") as write_file: + write_file.write(transpiled_query) + +def transpile_folder(source_folder: Union[str, os.PathLike], destination_folder: Union[str, os.PathLike], source_dialect: str="bigquery", destination_dialect: str="postgres"): + """ + Transpiles each file in the folder from BigQuery to the specified dialect. + """ + source_folder = Path(source_folder).resolve() + for filename in source_folder.rglob("*.sql"): + source_file = filename + destination_file = Path(destination_folder).resolve() / filename.relative_to(source_folder) + destination_file.parent.mkdir(parents=True, exist_ok=True) + + transpile_file(source_file, destination_file, source_dialect, destination_dialect)