diff --git a/.changes/0.0.1.md b/.changes/0.0.1.md
new file mode 100644
index 0000000..faff804
--- /dev/null
+++ b/.changes/0.0.1.md
@@ -0,0 +1,7 @@
+## 0.0.1 - 2024-07-31
+### Added
+* Initial commit
+* README, CHANGELOG, LICENSE
+* Initial folder structure
+* Initial library added to `src`
+* Dockerfiles and docker-compose
diff --git a/.changes/0.0.2.md b/.changes/0.0.2.md
new file mode 100644
index 0000000..73d7316
--- /dev/null
+++ b/.changes/0.0.2.md
@@ -0,0 +1,6 @@
+## 0.0.2 - 2024-07-31
+### Added
+* Added resource limits to docker-compose
+### Changed
+* Removed comments in SQL scripts as its causing issues
+* Progressed MIMIC data version to 2.2, updated SQL scripts to match
diff --git a/.changes/0.0.3.md b/.changes/0.0.3.md
new file mode 100644
index 0000000..300f5b1
--- /dev/null
+++ b/.changes/0.0.3.md
@@ -0,0 +1,5 @@
+## 0.0.3 - 2024-07-31
+### Added
+* MIMIC-IV Postgres Functions
+### Changed
+* Allowing MIMIC-IV 2.0 backwards compatibility
diff --git a/.changes/0.0.4.md b/.changes/0.0.4.md
new file mode 100644
index 0000000..7dae9a7
--- /dev/null
+++ b/.changes/0.0.4.md
@@ -0,0 +1,7 @@
+## 0.0.4 - 2024-08-05
+### Added
+* MIMIC-ED Import Option Closes Issue #5
+### Changed
+* README to correctly reflect volume location Closes Issue #16
+* Updated `docker-compose.yaml` to use env var for data folder
+* Changed the library name to `pgmimic` Closes Issue #16
diff --git a/.changes/header.tpl.md b/.changes/header.tpl.md
new file mode 100644
index 0000000..df8faa7
--- /dev/null
+++ b/.changes/header.tpl.md
@@ -0,0 +1,6 @@
+# Changelog
+All notable changes to this project will be documented in this file.
+
+The format is based on [Keep a Changelog](https://keepachangelog.com/en/1.0.0/),
+adheres to [Semantic Versioning](https://semver.org/spec/v2.0.0.html),
+and is generated by [Changie](https://github.com/miniscruff/changie).
diff --git a/.changes/unreleased/.gitkeep b/.changes/unreleased/.gitkeep
new file mode 100644
index 0000000..e69de29
diff --git a/.changie.yaml b/.changie.yaml
new file mode 100644
index 0000000..78ab6e3
--- /dev/null
+++ b/.changie.yaml
@@ -0,0 +1,26 @@
+changesDir: .changes
+unreleasedDir: unreleased
+headerPath: header.tpl.md
+changelogPath: CHANGELOG.md
+versionExt: md
+versionFormat: '## {{.Version}} - {{.Time.Format "2006-01-02"}}'
+kindFormat: '### {{.Kind}}'
+changeFormat: '* {{.Body}}'
+kinds:
+ - label: Added
+ auto: minor
+ - label: Changed
+ auto: major
+ - label: Deprecated
+ auto: minor
+ - label: Removed
+ auto: major
+ - label: Fixed
+ auto: patch
+ - label: Security
+ auto: patch
+newlines:
+ afterChangelogHeader: 1
+ beforeChangelogVersion: 1
+ endOfVersion: 1
+envPrefix: CHANGIE_
diff --git a/.env b/.env
new file mode 100644
index 0000000..08b3d52
--- /dev/null
+++ b/.env
@@ -0,0 +1,3 @@
+POSTGRES_USER=mimic
+POSTGRES_PASSWORD=mimic123
+POSTGRES_DB=postgres
\ No newline at end of file
diff --git a/.gitignore b/.gitignore
new file mode 100644
index 0000000..4884c51
--- /dev/null
+++ b/.gitignore
@@ -0,0 +1,14 @@
+## DATA FOLDER ##
+data/
+!data/README.md
+
+## bin ##
+bin/notes.md
+
+## PYTHON ##
+__pycache__/*
+*/__pycache__/*
+__pycache__
+
+## JetBrains ##
+.idea/*
\ No newline at end of file
diff --git a/CHANGELOG.md b/CHANGELOG.md
new file mode 100644
index 0000000..dd8acb3
--- /dev/null
+++ b/CHANGELOG.md
@@ -0,0 +1,36 @@
+# Changelog
+All notable changes to this project will be documented in this file.
+
+The format is based on [Keep a Changelog](https://keepachangelog.com/en/1.0.0/),
+adheres to [Semantic Versioning](https://semver.org/spec/v2.0.0.html),
+and is generated by [Changie](https://github.com/miniscruff/changie).
+
+
+## 0.0.4 - 2024-08-05
+### Added
+* MIMIC-ED Import Option Closes Issue #5
+### Changed
+* README to correctly reflect volume location Closes Issue #16
+* Updated `docker-compose.yaml` to use env var for data folder
+* Changed the library name to `pgmimic` Closes Issue #16
+
+## 0.0.3 - 2024-07-31
+### Added
+* MIMIC-IV Postgres Functions
+### Changed
+* Allowing MIMIC-IV 2.0 backwards compatibility
+
+## 0.0.2 - 2024-07-31
+### Added
+* Added resource limits to docker-compose
+### Changed
+* Removed comments in SQL scripts as its causing issues
+* Progressed MIMIC data version to 2.2, updated SQL scripts to match
+
+## 0.0.1 - 2024-07-31
+### Added
+* Initial commit
+* README, CHANGELOG, LICENSE
+* Initial folder structure
+* Initial library added to `src`
+* Dockerfiles and docker-compose
diff --git a/CONTRIBUTING.md b/CONTRIBUTING.md
new file mode 100644
index 0000000..a2726a0
--- /dev/null
+++ b/CONTRIBUTING.md
@@ -0,0 +1,26 @@
+# How to contribute
+
+Thank you for your interest in our little project. I appreciate any support to help improve this project.
+
+## How to Contribute
+
+1. Fork the repository.
+2. Create a new branch for your feature or bug fix.
+3. Make your changes in the new branch.
+4. Submit a [pull request (PR)](https://github.com/rudolfjs/PostgresMimicImporter/pull/new/master) to the main repository.
+
+## Pull Request Guidelines
+
+When [submitting a pull request](https://github.com/rudolfjs/PostgresMimicImporter/pull/new/master) please ensure that:
+
+1. You clearly describe the problem you're solving or the feature you're adding, linking to [issue](https://github.com/rudolfjs/PostgresMimicImporter/issues).
+2. You outline the changes you've made in detail.
+3. Please make sure your code is formatted using [psf/black](https://github.com/psf/black)
+
+## Review Process
+
+Once you've submitted a pull request:
+
+1. The project maintainers will review your changes.
+2. Maintainers may ask for additional changes or clarifications.
+3. Once approved, your contribution will be merged into the project.
diff --git a/LICENSE b/LICENSE
new file mode 100644
index 0000000..92b1466
--- /dev/null
+++ b/LICENSE
@@ -0,0 +1,21 @@
+MIT License
+
+Copyright (c) 2024 Rudolf J
+
+Permission is hereby granted, free of charge, to any person obtaining a copy
+of this software and associated documentation files (the "Software"), to deal
+in the Software without restriction, including without limitation the rights
+to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
+copies of the Software, and to permit persons to whom the Software is
+furnished to do so, subject to the following conditions:
+
+The above copyright notice and this permission notice shall be included in all
+copies or substantial portions of the Software.
+
+THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
+IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
+FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
+AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
+LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
+OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
+SOFTWARE.
diff --git a/README.md b/README.md
new file mode 100644
index 0000000..c670a0d
--- /dev/null
+++ b/README.md
@@ -0,0 +1,113 @@
+# Postgres MIMIC Importer
+
+
+
+
+
+****
+
+MIMIC data importer for PostgreSQL.
+
+This repository **does not** contain **any** `MIMIC` data.
+
+## Data
+
+The location of the `MIMIC` is to be set as an environment variable before running `docker-compose`.
+
+### Data Preparation
+
+As `MIMIC-IV` and `MIMIC-IV-ED` are separate downloads, please ensure that all data is copied into a single target folder.
+
+The target folder must have the following structure:
+
+```bash
+.
+data
+└───mimiciv
+ └───
+ ├───ed
+ ├───hosp
+ └───icu
+```
+
+If you do not require `MIMIC-IV-ED` data to be imported, edit the `config.json` file to remove the import.
+
+### Set the target location
+
+Using the environment variable (default):
+
+#### Windows
+
+PowerShell:
+```PowerShell
+$env:MIMIC_DATA_PATH = "C:/absolute/path/to/mimic/data"
+```
+
+Command Prompt:
+
+```commandline
+set MIMIC_DATA_PATH=C:/absolute/path/to/mimic/data
+```
+
+#### Linux
+
+```Bash
+export MIMIC_DATA_PATH=/absolute/path/to/mimic/data
+```
+
+The `docker-compose.yaml` can be edited to hard code the location:
+
+```yaml
+version: "3"
+services:
+ mimic_import:
+ volumes:
+ - /absolute/path/to/mimic/data/:/usr/src/app/data
+```
+
+### Compatible Data Versions
+
+| MIMIC Dataset | Version Compatibility |
+|:--------------|:----------------------|
+| MIMIC-IV | 2.0 |
+| MIMIC-IV-ED | 2.0 |
+| MIMIC-IV | 2.2 |
+| MIMIC-IV-ED | 2.2 |
+
+## Build MIMIC-IV database services
+
+```bash
+docker-compose build
+```
+
+The service can be started and stopped after being built:
+
+1. Start the service: `docker-compose up`
+ * Start the service as a background daemon: `docker-compose up -d`
+2. Stop the service: `docker-compose down`
+3. Stop the service and remove data: `docker-compose down -v`
+
+## License
+```license
+MIT License
+
+Copyright (c) 2024 Rudolf J
+
+Permission is hereby granted, free of charge, to any person obtaining a copy
+of this software and associated documentation files (the "Software"), to deal
+in the Software without restriction, including without limitation the rights
+to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
+copies of the Software, and to permit persons to whom the Software is
+furnished to do so, subject to the following conditions:
+
+The above copyright notice and this permission notice shall be included in all
+copies or substantial portions of the Software.
+
+THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
+IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
+FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
+AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
+LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
+OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
+SOFTWARE.
+```
diff --git a/config.json b/config.json
new file mode 100644
index 0000000..239577f
--- /dev/null
+++ b/config.json
@@ -0,0 +1,66 @@
+{
+ "database": {
+ "type": "postgresql+asyncpg",
+ "host": "pg",
+ "port": 5432,
+ "database": "postgres",
+ "schema": "public"
+ },
+
+ "data": {
+ "location": "./data/mimiciv",
+ "version": "2.2",
+ "schemas": [
+ "mimic_hosp",
+ "mimic_icu",
+ "mimiciv_ed",
+ "mimic_derived"
+ ],
+ "tables": {
+ "mimic_hosp": [
+ "admissions",
+ "d_hcpcs",
+ "diagnoses_icd",
+ "d_icd_diagnoses",
+ "d_icd_procedures",
+ "d_labitems",
+ "emar_detail",
+ "emar",
+ "hcpcsevents",
+ "labevents",
+ "microbiologyevents",
+ "omr",
+ "patients",
+ "pharmacy",
+ "poe_detail",
+ "poe",
+ "prescriptions",
+ "procedures_icd",
+ "transfers"
+ ],
+ "mimic_icu": [
+ "chartevents",
+ "datetimeevents",
+ "d_items",
+ "icustays",
+ "ingredientevents",
+ "inputevents",
+ "outputevents",
+ "procedureevents"
+ ],
+ "mimiciv_ed": [
+ "diagnosis",
+ "edstays",
+ "medrecon",
+ "pyxis",
+ "triage",
+ "vitalsign"
+ ],
+ "mimic_derived": {
+ "demographics": [
+ "age"
+ ]
+ }
+ }
+ }
+}
\ No newline at end of file
diff --git a/docker-compose.yaml b/docker-compose.yaml
new file mode 100644
index 0000000..fb1f4fa
--- /dev/null
+++ b/docker-compose.yaml
@@ -0,0 +1,62 @@
+version: "3"
+services:
+ pg:
+ image: postgres:14.0-alpine
+ container_name: db
+ command: >
+ postgres -c max_wal_size=20GB
+ environment:
+ - POSTGRES_USER=${POSTGRES_USER}
+ - POSTGRES_PASSWORD=${POSTGRES_PASSWORD}
+ logging:
+ options:
+ max-size: 10m
+ max-file: "3"
+ ports:
+ - "5432:5432"
+ volumes:
+ - db-data:/var/lib/postgresql/data/
+ healthcheck:
+ test: ["CMD", "pg_isready", "-q", "-d", "${POSTGRES_DB}", "-U", "${POSTGRES_USER}"]
+ interval: 10s
+ timeout: 3s
+ retries: 3
+ deploy:
+ resources:
+ limits:
+ memory: 4096m # 6Gi limit, change if needed
+ mimic_import:
+ container_name: mimic_import
+ build:
+ dockerfile: ./mimic_import.dockerfile
+ context: .
+ image: mimic_import
+ environment:
+ - DB_USER=${POSTGRES_USER}
+ - DB_PASSWORD=${POSTGRES_PASSWORD}
+ - PYTHONUNBUFFERED=1
+ depends_on:
+ pg:
+ condition: service_healthy
+ links:
+ - pg
+ volumes:
+ - ${MIMIC_DATA_PATH}:/usr/src/app/data
+ - ./config.json:/usr/src/app/config.json
+ deploy:
+ resources:
+ limits:
+ memory: 1024m # 6Gi limit, change if needed
+
+# Local Storage
+volumes:
+ db-data:
+
+## NFS
+# volumes:
+# db-data:
+# driver: local
+# driver_opts:
+# type: 'none'
+# o: 'bind'
+# device: ${NFS_MOUNT}
diff --git a/mimic_import.dockerfile b/mimic_import.dockerfile
new file mode 100644
index 0000000..b42e25a
--- /dev/null
+++ b/mimic_import.dockerfile
@@ -0,0 +1,20 @@
+FROM python:3.10-slim-bullseye
+
+LABEL Maintainer="Rudolf J"
+
+WORKDIR /usr/src/app
+
+# COPY
+# COPY config.json ./config.json
+COPY requirements.txt ./requirements.txt
+COPY pgmimic/ ./
+
+## Kernel requirements
+
+RUN apt-get update && \
+ apt-get install -y zip libpq-dev python3-dev gcc postgresql-client-common postgresql-client
+
+# Install pip requirements
+RUN pip install -r requirements.txt
+
+CMD ["python","main.py"]
\ No newline at end of file
diff --git a/pgmimic/README.md b/pgmimic/README.md
new file mode 100644
index 0000000..e69de29
diff --git a/pgmimic/__init__.py b/pgmimic/__init__.py
new file mode 100644
index 0000000..e69de29
diff --git a/pgmimic/_config/__init__.py b/pgmimic/_config/__init__.py
new file mode 100644
index 0000000..e69de29
diff --git a/pgmimic/_config/_config_handler.py b/pgmimic/_config/_config_handler.py
new file mode 100644
index 0000000..c189e2f
--- /dev/null
+++ b/pgmimic/_config/_config_handler.py
@@ -0,0 +1,19 @@
+import json
+import os
+
+
+class ConfigHandler:
+ def __init__(self, location: str = None) -> None:
+ try:
+ with open(location) as config_file:
+ self.config = json.load(config_file)
+ # add ENVS
+ self.config["database"]["username"] = os.getenv("DB_USER")
+ self.config["database"]["password"] = os.getenv("DB_PASSWORD")
+ config_file.close()
+ except Exception as e:
+ print(repr(e))
+ return None
+
+ def get_config(self) -> json:
+ return self.config
diff --git a/pgmimic/_db/SQL/2.0/contraint.sql b/pgmimic/_db/SQL/2.0/contraint.sql
new file mode 100644
index 0000000..15d7902
--- /dev/null
+++ b/pgmimic/_db/SQL/2.0/contraint.sql
@@ -0,0 +1,428 @@
+ALTER TABLE mimic_hosp.admissions DROP CONSTRAINT IF EXISTS admissions_pk CASCADE;
+ALTER TABLE mimic_hosp.admissions
+ADD CONSTRAINT admissions_pk
+ PRIMARY KEY (hadm_id);
+ALTER TABLE mimic_hosp.d_hcpcs DROP CONSTRAINT IF EXISTS d_hcpcs_pk CASCADE;
+ALTER TABLE mimic_hosp.d_hcpcs
+ADD CONSTRAINT d_hcpcs_pk
+ PRIMARY KEY (code);
+ALTER TABLE mimic_hosp.diagnoses_icd DROP CONSTRAINT IF EXISTS diagnoses_icd_pk CASCADE;
+ALTER TABLE mimic_hosp.diagnoses_icd
+ADD CONSTRAINT diagnoses_icd_pk
+ PRIMARY KEY (hadm_id, seq_num, icd_code, icd_version);
+ALTER TABLE mimic_hosp.d_icd_diagnoses DROP CONSTRAINT IF EXISTS d_icd_diagnoses_pk CASCADE;
+ALTER TABLE mimic_hosp.d_icd_diagnoses
+ADD CONSTRAINT d_icd_diagnoses_pk
+ PRIMARY KEY (icd_code, icd_version);
+ALTER TABLE mimic_hosp.d_icd_procedures DROP CONSTRAINT IF EXISTS d_icd_procedures_pk CASCADE;
+ALTER TABLE mimic_hosp.d_icd_procedures
+ADD CONSTRAINT d_icd_procedures_pk
+ PRIMARY KEY (icd_code, icd_version);
+ALTER TABLE mimic_hosp.d_labitems DROP CONSTRAINT IF EXISTS d_labitems_pk CASCADE;
+ALTER TABLE mimic_hosp.d_labitems
+ADD CONSTRAINT d_labitems_pk
+ PRIMARY KEY (itemid);
+ALTER TABLE mimic_hosp.emar DROP CONSTRAINT IF EXISTS emar_pk CASCADE;
+ALTER TABLE mimic_hosp.emar
+ADD CONSTRAINT emar_pk
+ PRIMARY KEY (emar_id);
+ALTER TABLE mimic_hosp.hcpcsevents DROP CONSTRAINT IF EXISTS hcpcsevents_pk CASCADE;
+ALTER TABLE mimic_hosp.hcpcsevents
+ADD CONSTRAINT hcpcsevents_pk
+ PRIMARY KEY (hadm_id, hcpcs_cd, seq_num);
+ALTER TABLE mimic_hosp.labevents DROP CONSTRAINT IF EXISTS labevents_pk CASCADE;
+ALTER TABLE mimic_hosp.labevents
+ADD CONSTRAINT labevents_pk
+ PRIMARY KEY (labevent_id);
+ALTER TABLE mimic_hosp.microbiologyevents DROP CONSTRAINT IF EXISTS microbiologyevents_pk CASCADE;
+ALTER TABLE mimic_hosp.microbiologyevents
+ADD CONSTRAINT microbiologyevents_pk
+ PRIMARY KEY (microevent_id);
+ALTER TABLE mimic_hosp.patients DROP CONSTRAINT IF EXISTS patients_pk CASCADE;
+ALTER TABLE mimic_hosp.patients
+ADD CONSTRAINT patients_pk
+ PRIMARY KEY (subject_id);
+ALTER TABLE mimic_hosp.pharmacy DROP CONSTRAINT IF EXISTS pharmacy_pk CASCADE;
+ALTER TABLE mimic_hosp.pharmacy
+ADD CONSTRAINT pharmacy_pk
+ PRIMARY KEY (pharmacy_id);
+ALTER TABLE mimic_hosp.poe_detail DROP CONSTRAINT IF EXISTS poe_detail_pk CASCADE;
+ALTER TABLE mimic_hosp.poe_detail
+ADD CONSTRAINT poe_detail_pk
+ PRIMARY KEY (poe_id, field_name);
+ALTER TABLE mimic_hosp.poe DROP CONSTRAINT IF EXISTS poe_pk CASCADE;
+ALTER TABLE mimic_hosp.poe
+ADD CONSTRAINT poe_pk
+ PRIMARY KEY (poe_id);
+ALTER TABLE mimic_hosp.prescriptions DROP CONSTRAINT IF EXISTS prescriptions_pk CASCADE;
+ALTER TABLE mimic_hosp.prescriptions
+ADD CONSTRAINT prescriptions_pk
+ PRIMARY KEY (pharmacy_id, drug_type, drug);
+ALTER TABLE mimic_hosp.procedures_icd DROP CONSTRAINT IF EXISTS procedures_icd_pk CASCADE;
+ALTER TABLE mimic_hosp.procedures_icd
+ADD CONSTRAINT procedures_icd_pk
+ PRIMARY KEY (hadm_id, seq_num, icd_code, icd_version);
+ALTER TABLE mimic_hosp.services DROP CONSTRAINT IF EXISTS services_pk CASCADE;
+ALTER TABLE mimic_hosp.services
+ADD CONSTRAINT services_pk
+ PRIMARY KEY (hadm_id, transfertime, curr_service);
+ALTER TABLE mimic_icu.datetimeevents DROP CONSTRAINT IF EXISTS datetimeevents_pk CASCADE;
+ALTER TABLE mimic_icu.datetimeevents
+ADD CONSTRAINT datetimeevents_pk
+ PRIMARY KEY (stay_id, itemid, charttime);
+ALTER TABLE mimic_icu.d_items DROP CONSTRAINT IF EXISTS d_items_pk CASCADE;
+ALTER TABLE mimic_icu.d_items
+ADD CONSTRAINT d_items_pk
+ PRIMARY KEY (itemid);
+ALTER TABLE mimic_icu.icustays DROP CONSTRAINT IF EXISTS icustays_pk CASCADE;
+ALTER TABLE mimic_icu.icustays
+ADD CONSTRAINT icustays_pk
+ PRIMARY KEY (stay_id);
+ALTER TABLE mimic_icu.inputevents DROP CONSTRAINT IF EXISTS inputevents_pk CASCADE;
+ALTER TABLE mimic_icu.inputevents
+ADD CONSTRAINT inputevents_pk
+ PRIMARY KEY (orderid, itemid);
+ALTER TABLE mimic_icu.outputevents DROP CONSTRAINT IF EXISTS outputevents_pk CASCADE;
+ALTER TABLE mimic_icu.outputevents
+ADD CONSTRAINT outputevents_pk
+ PRIMARY KEY (stay_id, charttime, itemid);
+ALTER TABLE mimic_icu.procedureevents DROP CONSTRAINT IF EXISTS procedureevents_pk CASCADE;
+ALTER TABLE mimic_icu.procedureevents
+ADD CONSTRAINT procedureevents_pk
+ PRIMARY KEY (orderid);
+ALTER TABLE mimic_hosp.admissions DROP CONSTRAINT IF EXISTS admissions_patients_fk;
+ALTER TABLE mimic_hosp.admissions
+ADD CONSTRAINT admissions_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.diagnoses_icd DROP CONSTRAINT IF EXISTS diagnoses_icd_patients_fk;
+ALTER TABLE mimic_hosp.diagnoses_icd
+ADD CONSTRAINT diagnoses_icd_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.diagnoses_icd DROP CONSTRAINT IF EXISTS diagnoses_icd_admissions_fk;
+ALTER TABLE mimic_hosp.diagnoses_icd
+ADD CONSTRAINT diagnoses_icd_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_hosp.drgcodes DROP CONSTRAINT IF EXISTS drgcodes_patients_fk;
+ALTER TABLE mimic_hosp.drgcodes
+ADD CONSTRAINT drgcodes_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.drgcodes DROP CONSTRAINT IF EXISTS drgcodes_admissions_fk;
+ALTER TABLE mimic_hosp.drgcodes
+ADD CONSTRAINT drgcodes_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_hosp.emar_detail DROP CONSTRAINT IF EXISTS emar_detail_patients_fk;
+ALTER TABLE mimic_hosp.emar_detail
+ADD CONSTRAINT emar_detail_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.emar_detail DROP CONSTRAINT IF EXISTS emar_detail_emar_fk;
+ALTER TABLE mimic_hosp.emar_detail
+ADD CONSTRAINT emar_detail_emar_fk
+ FOREIGN KEY (emar_id)
+ REFERENCES mimic_hosp.emar (emar_id);
+ALTER TABLE mimic_hosp.emar DROP CONSTRAINT IF EXISTS emar_patients_fk;
+ALTER TABLE mimic_hosp.emar
+ADD CONSTRAINT emar_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.emar DROP CONSTRAINT IF EXISTS emar_admissions_fk;
+ALTER TABLE mimic_hosp.emar
+ADD CONSTRAINT emar_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_hosp.hcpcsevents DROP CONSTRAINT IF EXISTS hcpcsevents_patients_fk;
+ALTER TABLE mimic_hosp.hcpcsevents
+ADD CONSTRAINT hcpcsevents_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.hcpcsevents DROP CONSTRAINT IF EXISTS hcpcsevents_admissions_fk;
+ALTER TABLE mimic_hosp.hcpcsevents
+ADD CONSTRAINT hcpcsevents_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_hosp.hcpcsevents DROP CONSTRAINT IF EXISTS hcpcsevents_d_hcpcs_fk;
+ALTER TABLE mimic_hosp.hcpcsevents
+ADD CONSTRAINT hcpcsevents_d_hcpcs_fk
+ FOREIGN KEY (hcpcs_cd)
+ REFERENCES mimic_hosp.d_hcpcs (code);
+ALTER TABLE mimic_hosp.labevents DROP CONSTRAINT IF EXISTS labevents_patients_fk;
+ALTER TABLE mimic_hosp.labevents
+ADD CONSTRAINT labevents_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.labevents DROP CONSTRAINT IF EXISTS labevents_d_labitems_fk;
+ALTER TABLE mimic_hosp.labevents
+ADD CONSTRAINT labevents_d_labitems_fk
+ FOREIGN KEY (itemid)
+ REFERENCES mimic_hosp.d_labitems (itemid);
+ALTER TABLE mimic_hosp.microbiologyevents DROP CONSTRAINT IF EXISTS microbiologyevents_patients_fk;
+ALTER TABLE mimic_hosp.microbiologyevents
+ADD CONSTRAINT microbiologyevents_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.microbiologyevents DROP CONSTRAINT IF EXISTS microbiologyevents_admissions_fk;
+ALTER TABLE mimic_hosp.microbiologyevents
+ADD CONSTRAINT microbiologyevents_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_hosp.pharmacy DROP CONSTRAINT IF EXISTS pharmacy_patients_fk;
+ALTER TABLE mimic_hosp.pharmacy
+ADD CONSTRAINT pharmacy_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.pharmacy DROP CONSTRAINT IF EXISTS pharmacy_admissions_fk;
+ALTER TABLE mimic_hosp.pharmacy
+ADD CONSTRAINT pharmacy_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_hosp.poe_detail DROP CONSTRAINT IF EXISTS poe_detail_patients_fk;
+ALTER TABLE mimic_hosp.poe_detail
+ADD CONSTRAINT poe_detail_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.poe_detail DROP CONSTRAINT IF EXISTS poe_detail_poe_fk;
+ALTER TABLE mimic_hosp.poe_detail
+ADD CONSTRAINT poe_detail_poe_fk
+ FOREIGN KEY (poe_id)
+ REFERENCES mimic_hosp.poe (poe_id);
+ALTER TABLE mimic_hosp.poe DROP CONSTRAINT IF EXISTS poe_patients_fk;
+ALTER TABLE mimic_hosp.poe
+ADD CONSTRAINT poe_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.poe DROP CONSTRAINT IF EXISTS poe_admissions_fk;
+ALTER TABLE mimic_hosp.poe
+ADD CONSTRAINT poe_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_hosp.prescriptions DROP CONSTRAINT IF EXISTS prescriptions_patients_fk;
+ALTER TABLE mimic_hosp.prescriptions
+ADD CONSTRAINT prescriptions_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.prescriptions DROP CONSTRAINT IF EXISTS prescriptions_admissions_fk;
+ALTER TABLE mimic_hosp.prescriptions
+ADD CONSTRAINT prescriptions_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_hosp.procedures_icd DROP CONSTRAINT IF EXISTS procedures_icd_patients_fk;
+ALTER TABLE mimic_hosp.procedures_icd
+ADD CONSTRAINT procedures_icd_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.procedures_icd DROP CONSTRAINT IF EXISTS procedures_icd_admissions_fk;
+ALTER TABLE mimic_hosp.procedures_icd
+ADD CONSTRAINT procedures_icd_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_hosp.services DROP CONSTRAINT IF EXISTS services_patients_fk;
+ALTER TABLE mimic_hosp.services
+ADD CONSTRAINT services_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.services DROP CONSTRAINT IF EXISTS services_admissions_fk;
+ALTER TABLE mimic_hosp.services
+ADD CONSTRAINT services_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_hosp.transfers DROP CONSTRAINT IF EXISTS transfers_pk CASCADE;
+ALTER TABLE mimic_hosp.transfers
+ADD CONSTRAINT transfers_pk
+ PRIMARY KEY (transfer_id);
+ALTER TABLE mimic_hosp.transfers DROP CONSTRAINT IF EXISTS transfers_patients_fk;
+ALTER TABLE mimic_hosp.transfers
+ADD CONSTRAINT transfers_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_icu.chartevents DROP CONSTRAINT IF EXISTS chartevents_patients_fk;
+ALTER TABLE mimic_icu.chartevents
+ADD CONSTRAINT chartevents_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_icu.chartevents DROP CONSTRAINT IF EXISTS chartevents_admissions_fk;
+ALTER TABLE mimic_icu.chartevents
+ADD CONSTRAINT chartevents_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_icu.chartevents DROP CONSTRAINT IF EXISTS chartevents_icustays_fk;
+ALTER TABLE mimic_icu.chartevents
+ADD CONSTRAINT chartevents_icustays_fk
+ FOREIGN KEY (stay_id)
+ REFERENCES mimic_icu.icustays (stay_id);
+ALTER TABLE mimic_icu.chartevents DROP CONSTRAINT IF EXISTS chartevents_d_items_fk;
+ALTER TABLE mimic_icu.chartevents
+ADD CONSTRAINT chartevents_d_items_fk
+ FOREIGN KEY (itemid)
+ REFERENCES mimic_icu.d_items (itemid);
+ALTER TABLE mimic_icu.datetimeevents DROP CONSTRAINT IF EXISTS datetimeevents_patients_fk;
+ALTER TABLE mimic_icu.datetimeevents
+ADD CONSTRAINT datetimeevents_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_icu.datetimeevents DROP CONSTRAINT IF EXISTS datetimeevents_admissions_fk;
+ALTER TABLE mimic_icu.datetimeevents
+ADD CONSTRAINT datetimeevents_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_icu.datetimeevents DROP CONSTRAINT IF EXISTS datetimeevents_icustays_fk;
+ALTER TABLE mimic_icu.datetimeevents
+ADD CONSTRAINT datetimeevents_icustays_fk
+ FOREIGN KEY (stay_id)
+ REFERENCES mimic_icu.icustays (stay_id);
+ALTER TABLE mimic_icu.datetimeevents DROP CONSTRAINT IF EXISTS datetimeevents_d_items_fk;
+ALTER TABLE mimic_icu.datetimeevents
+ADD CONSTRAINT datetimeevents_d_items_fk
+ FOREIGN KEY (itemid)
+ REFERENCES mimic_icu.d_items (itemid);
+ALTER TABLE mimic_icu.icustays DROP CONSTRAINT IF EXISTS icustays_patients_fk;
+ALTER TABLE mimic_icu.icustays
+ADD CONSTRAINT icustays_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_icu.icustays DROP CONSTRAINT IF EXISTS icustays_admissions_fk;
+ALTER TABLE mimic_icu.icustays
+ADD CONSTRAINT icustays_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_icu.inputevents DROP CONSTRAINT IF EXISTS inputevents_patients_fk;
+ALTER TABLE mimic_icu.inputevents
+ADD CONSTRAINT inputevents_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_icu.inputevents DROP CONSTRAINT IF EXISTS inputevents_admissions_fk;
+ALTER TABLE mimic_icu.inputevents
+ADD CONSTRAINT inputevents_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_icu.inputevents DROP CONSTRAINT IF EXISTS inputevents_icustays_fk;
+ALTER TABLE mimic_icu.inputevents
+ADD CONSTRAINT inputevents_icustays_fk
+ FOREIGN KEY (stay_id)
+ REFERENCES mimic_icu.icustays (stay_id);
+ALTER TABLE mimic_icu.inputevents DROP CONSTRAINT IF EXISTS inputevents_d_items_fk;
+ALTER TABLE mimic_icu.inputevents
+ADD CONSTRAINT inputevents_d_items_fk
+ FOREIGN KEY (itemid)
+ REFERENCES mimic_icu.d_items (itemid);
+ALTER TABLE mimic_icu.outputevents DROP CONSTRAINT IF EXISTS outputevents_patients_fk;
+ALTER TABLE mimic_icu.outputevents
+ADD CONSTRAINT outputevents_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_icu.outputevents DROP CONSTRAINT IF EXISTS outputevents_admissions_fk;
+ALTER TABLE mimic_icu.outputevents
+ADD CONSTRAINT outputevents_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_icu.outputevents DROP CONSTRAINT IF EXISTS outputevents_icustays_fk;
+ALTER TABLE mimic_icu.outputevents
+ADD CONSTRAINT outputevents_icustays_fk
+ FOREIGN KEY (stay_id)
+ REFERENCES mimic_icu.icustays (stay_id);
+ALTER TABLE mimic_icu.outputevents DROP CONSTRAINT IF EXISTS outputevents_d_items_fk;
+ALTER TABLE mimic_icu.outputevents
+ADD CONSTRAINT outputevents_d_items_fk
+ FOREIGN KEY (itemid)
+ REFERENCES mimic_icu.d_items (itemid);
+ALTER TABLE mimic_icu.procedureevents DROP CONSTRAINT IF EXISTS procedureevents_patients_fk;
+ALTER TABLE mimic_icu.procedureevents
+ADD CONSTRAINT procedureevents_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_icu.procedureevents DROP CONSTRAINT IF EXISTS procedureevents_admissions_fk;
+ALTER TABLE mimic_icu.procedureevents
+ADD CONSTRAINT procedureevents_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_icu.procedureevents DROP CONSTRAINT IF EXISTS procedureevents_icustays_fk;
+ALTER TABLE mimic_icu.procedureevents
+ADD CONSTRAINT procedureevents_icustays_fk
+ FOREIGN KEY (stay_id)
+ REFERENCES mimic_icu.icustays (stay_id);
+ALTER TABLE mimic_icu.procedureevents DROP CONSTRAINT IF EXISTS procedureevents_d_items_fk;
+ALTER TABLE mimic_icu.procedureevents
+ADD CONSTRAINT procedureevents_d_items_fk
+ FOREIGN KEY (itemid)
+ REFERENCES mimic_icu.d_items (itemid);
+
+/******
+ ED
+ */
+
+ SET search_path TO mimic_ed;
+---------------------------
+---------------------------
+-- Creating Primary Keys --
+---------------------------
+---------------------------
+
+ALTER TABLE mimic_ed.edstays DROP CONSTRAINT IF EXISTS edstays_pk CASCADE;
+ALTER TABLE mimic_ed.edstays
+ADD CONSTRAINT edstays_pk
+ PRIMARY KEY (stay_id);
+
+ALTER TABLE mimic_ed.diagnosis DROP CONSTRAINT IF EXISTS diagnosis_pk CASCADE;
+ALTER TABLE mimic_ed.diagnosis
+ADD CONSTRAINT diagnosis_pk
+ PRIMARY KEY (stay_id, seq_num);
+
+--ALTER TABLE mimic_ed.medrecon DROP CONSTRAINT IF EXISTS medrecon_pk CASCADE;
+--ALTER TABLE mimic_ed.medrecon
+--ADD CONSTRAINT medrecon_pk
+-- PRIMARY KEY (stay_id, charttime, name);
+
+--ALTER TABLE mimic_ed.pyxis DROP CONSTRAINT IF EXISTS pyxis_pk CASCADE;
+--ALTER TABLE mimic_ed.pyxis
+--ADD CONSTRAINT pyxis_pk
+-- PRIMARY KEY (stay_id, charttime, name);
+
+ALTER TABLE mimic_ed.triage DROP CONSTRAINT IF EXISTS triage_pk CASCADE;
+ALTER TABLE mimic_ed.triage
+ADD CONSTRAINT triage_pk
+ PRIMARY KEY (stay_id);
+
+ALTER TABLE mimic_ed.vitalsign DROP CONSTRAINT IF EXISTS vitalsign_pk CASCADE;
+ALTER TABLE mimic_ed.vitalsign
+ADD CONSTRAINT vitalsign_pk
+ PRIMARY KEY (stay_id, charttime);
+
+---------------------------
+---------------------------
+-- Creating Foreign Keys --
+---------------------------
+---------------------------
+
+ALTER TABLE mimic_ed.diagnosis DROP CONSTRAINT IF EXISTS diagnosis_edstays_fk CASCADE;
+ALTER TABLE mimic_ed.diagnosis
+ADD CONSTRAINT diagnosis_edstays_fk
+ FOREIGN KEY (stay_id)
+ REFERENCES mimic_ed.edstays (stay_id);
+
+ALTER TABLE mimic_ed.medrecon DROP CONSTRAINT IF EXISTS medrecon_edstays_fk CASCADE;
+ALTER TABLE mimic_ed.medrecon
+ADD CONSTRAINT medrecon_edstays_fk
+ FOREIGN KEY (stay_id)
+ REFERENCES mimic_ed.edstays (stay_id);
+
+ALTER TABLE mimic_ed.pyxis DROP CONSTRAINT IF EXISTS pyxis_edstays_fk CASCADE;
+ALTER TABLE mimic_ed.pyxis
+ADD CONSTRAINT pyxis_edstays_fk
+ FOREIGN KEY (stay_id)
+ REFERENCES mimic_ed.edstays (stay_id);
+
+ALTER TABLE mimic_ed.triage DROP CONSTRAINT IF EXISTS triage_edstays_fk CASCADE;
+ALTER TABLE mimic_ed.triage
+ADD CONSTRAINT triage_edstays_fk
+ FOREIGN KEY (stay_id)
+ REFERENCES mimic_ed.edstays (stay_id);
+
+ALTER TABLE mimic_ed.vitalsign DROP CONSTRAINT IF EXISTS vitalsign_edstays_fk CASCADE;
+ALTER TABLE mimic_ed.vitalsign
+ADD CONSTRAINT vitalsign_edstays_fk
+ FOREIGN KEY (stay_id)
+ REFERENCES mimic_ed.edstays (stay_id);
\ No newline at end of file
diff --git a/pgmimic/_db/SQL/2.0/create.sql b/pgmimic/_db/SQL/2.0/create.sql
new file mode 100644
index 0000000..304b3e0
--- /dev/null
+++ b/pgmimic/_db/SQL/2.0/create.sql
@@ -0,0 +1,584 @@
+DROP SCHEMA IF EXISTS mimic_hosp CASCADE;
+CREATE SCHEMA mimic_hosp;
+DROP SCHEMA IF EXISTS mimic_icu CASCADE;
+CREATE SCHEMA mimic_icu;
+DROP SCHEMA IF EXISTS mimic_derived CASCADE;
+CREATE SCHEMA mimic_derived;
+DROP SCHEMA IF EXISTS mimic_ed CASCADE;
+CREATE SCHEMA mimic_ed;
+
+
+
+DROP TABLE IF EXISTS mimic_hosp.admissions;
+CREATE TABLE mimic_hosp.admissions
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ admittime TIMESTAMP NOT NULL,
+ dischtime TIMESTAMP,
+ deathtime TIMESTAMP,
+ admission_type VARCHAR(40) NOT NULL,
+ admission_location VARCHAR(60),
+ discharge_location VARCHAR(60),
+ insurance VARCHAR(255),
+ language VARCHAR(10),
+ marital_status VARCHAR(30),
+ ethnicity VARCHAR(80),
+ edregtime TIMESTAMP,
+ edouttime TIMESTAMP,
+ hospital_expire_flag SMALLINT
+);
+
+DROP TABLE IF EXISTS mimic_hosp.d_hcpcs;
+CREATE TABLE mimic_hosp.d_hcpcs
+(
+ code CHAR(5) NOT NULL,
+ category SMALLINT,
+ long_description TEXT,
+ short_description VARCHAR(180)
+);
+
+DROP TABLE IF EXISTS mimic_hosp.diagnoses_icd;
+CREATE TABLE mimic_hosp.diagnoses_icd
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ seq_num INTEGER NOT NULL,
+ icd_code CHAR(7),
+ icd_version SMALLINT
+);
+
+DROP TABLE IF EXISTS mimic_hosp.d_icd_diagnoses;
+CREATE TABLE mimic_hosp.d_icd_diagnoses
+(
+ icd_code CHAR(7) NOT NULL,
+ icd_version SMALLINT NOT NULL,
+ long_title VARCHAR(255)
+);
+
+DROP TABLE IF EXISTS mimic_hosp.d_icd_procedures;
+CREATE TABLE mimic_hosp.d_icd_procedures
+(
+ icd_code CHAR(7) NOT NULL,
+ icd_version SMALLINT NOT NULL,
+ long_title VARCHAR(222)
+);
+
+DROP TABLE IF EXISTS mimic_hosp.d_labitems;
+CREATE TABLE mimic_hosp.d_labitems
+(
+ itemid INTEGER NOT NULL,
+ label VARCHAR(50),
+ fluid VARCHAR(50),
+ category VARCHAR(50)
+);
+
+DROP TABLE IF EXISTS mimic_hosp.drgcodes;
+CREATE TABLE mimic_hosp.drgcodes
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ drg_type VARCHAR(4),
+ drg_code VARCHAR(10) NOT NULL,
+ description VARCHAR(195),
+ drg_severity SMALLINT,
+ drg_mortality SMALLINT
+);
+
+DROP TABLE IF EXISTS mimic_hosp.emar_detail;
+CREATE TABLE mimic_hosp.emar_detail
+(
+ subject_id INTEGER NOT NULL,
+ emar_id VARCHAR(25) NOT NULL,
+ emar_seq INTEGER NOT NULL,
+ parent_field_ordinal NUMERIC(3, 2),
+ administration_type VARCHAR(50),
+ pharmacy_id INTEGER,
+ barcode_type VARCHAR(4),
+ reason_for_no_barcode TEXT,
+ complete_dose_not_given VARCHAR(5),
+ dose_due VARCHAR(100),
+ dose_due_unit VARCHAR(50),
+ dose_given VARCHAR(255),
+ dose_given_unit VARCHAR(50),
+ will_remainder_of_dose_be_given VARCHAR(5),
+ product_amount_given VARCHAR(30),
+ product_unit VARCHAR(30),
+ product_code VARCHAR(30),
+ product_description VARCHAR(255),
+ product_description_other VARCHAR(255),
+ prior_infusion_rate VARCHAR(20),
+ infusion_rate VARCHAR(20),
+ infusion_rate_adjustment VARCHAR(50),
+ infusion_rate_adjustment_amount VARCHAR(30),
+ infusion_rate_unit VARCHAR(30),
+ route VARCHAR(10),
+ infusion_complete VARCHAR(1),
+ completion_interval VARCHAR(30),
+ new_iv_bag_hung VARCHAR(1),
+ continued_infusion_in_other_location VARCHAR(1),
+ restart_interval VARCHAR(2305),
+ side VARCHAR(10),
+ site VARCHAR(255),
+ non_formulary_visual_verification VARCHAR(1)
+);
+
+DROP TABLE IF EXISTS mimic_hosp.emar;
+CREATE TABLE mimic_hosp.emar
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER,
+ emar_id VARCHAR(25) NOT NULL,
+ emar_seq INTEGER NOT NULL,
+ poe_id VARCHAR(25) NOT NULL,
+ pharmacy_id INTEGER,
+ charttime TIMESTAMP NOT NULL,
+ medication TEXT,
+ event_txt VARCHAR(100),
+ scheduletime TIMESTAMP,
+ storetime TIMESTAMP NOT NULL
+);
+
+DROP TABLE IF EXISTS mimic_hosp.hcpcsevents;
+CREATE TABLE mimic_hosp.hcpcsevents
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ chartdate TIMESTAMP(0) NOT NULL,
+ hcpcs_cd CHAR(5) NOT NULL,
+ seq_num INTEGER NOT NULL,
+ short_description VARCHAR(180)
+);
+
+DROP TABLE IF EXISTS mimic_hosp.labevents;
+CREATE TABLE mimic_hosp.labevents
+(
+ labevent_id INTEGER NOT NULL,
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER,
+ specimen_id INTEGER NOT NULL,
+ itemid INTEGER NOT NULL,
+ charttime TIMESTAMP(0),
+ storetime TIMESTAMP(0),
+ value VARCHAR(200),
+ valuenum DOUBLE PRECISION,
+ valueuom VARCHAR(20),
+ ref_range_lower DOUBLE PRECISION,
+ ref_range_upper DOUBLE PRECISION,
+ flag VARCHAR(10),
+ priority VARCHAR(7),
+ comments TEXT
+);
+
+DROP TABLE IF EXISTS mimic_hosp.microbiologyevents;
+CREATE TABLE mimic_hosp.microbiologyevents
+(
+ microevent_id INTEGER NOT NULL,
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER,
+ micro_specimen_id INTEGER NOT NULL,
+ chartdate TIMESTAMP(0) NOT NULL,
+ charttime TIMESTAMP(0),
+ spec_itemid INTEGER NOT NULL,
+ spec_type_desc VARCHAR(100) NOT NULL,
+ test_seq INTEGER NOT NULL,
+ storedate TIMESTAMP(0),
+ storetime TIMESTAMP(0),
+ test_itemid INTEGER,
+ test_name VARCHAR(100),
+ org_itemid INTEGER,
+ org_name VARCHAR(100),
+ isolate_num SMALLINT,
+ quantity VARCHAR(50),
+ ab_itemid INTEGER,
+ ab_name VARCHAR(30),
+ dilution_text VARCHAR(10),
+ dilution_comparison VARCHAR(20),
+ dilution_value DOUBLE PRECISION,
+ interpretation VARCHAR(5),
+ comments TEXT
+);
+
+DROP TABLE IF EXISTS mimic_hosp.omr;
+CREATE TABLE mimic_hosp.omr(
+ subject_id INTEGER NOT NULL,
+ chartdate TIMESTAMP(0) NOT NULL,
+ seq_num INTEGER NOT NULL,
+ result_name VARCHAR(255) NOT NULL,
+ result_value VARCHAR(255) NOT NULL
+);
+
+DROP TABLE IF EXISTS mimic_hosp.patients;
+CREATE TABLE mimic_hosp.patients
+(
+ subject_id INTEGER NOT NULL,
+ gender CHAR(1) NOT NULL,
+ anchor_age SMALLINT,
+ anchor_year SMALLINT NOT NULL,
+ anchor_year_group VARCHAR(20) NOT NULL,
+ dod DATE
+);
+
+DROP TABLE IF EXISTS mimic_hosp.pharmacy;
+CREATE TABLE mimic_hosp.pharmacy
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ pharmacy_id INTEGER NOT NULL,
+ poe_id VARCHAR(25),
+ starttime TIMESTAMP(3),
+ stoptime TIMESTAMP(3),
+ medication TEXT,
+ proc_type VARCHAR(50) NOT NULL,
+ status VARCHAR(50),
+ entertime TIMESTAMP(3) NOT NULL,
+ verifiedtime TIMESTAMP(3),
+ route VARCHAR(50),
+ frequency VARCHAR(50),
+ disp_sched VARCHAR(255),
+ infusion_type VARCHAR(15),
+ sliding_scale VARCHAR(1),
+ lockout_interval VARCHAR(50),
+ basal_rate REAL,
+ one_hr_max VARCHAR(10),
+ doses_per_24_hrs REAL,
+ duration REAL,
+ duration_interval VARCHAR(50),
+ expiration_value INTEGER,
+ expiration_unit VARCHAR(50),
+ expirationdate TIMESTAMP(3),
+ dispensation VARCHAR(50),
+ fill_quantity VARCHAR(50)
+);
+
+DROP TABLE IF EXISTS mimic_hosp.poe_detail;
+CREATE TABLE mimic_hosp.poe_detail
+(
+ poe_id VARCHAR(25) NOT NULL,
+ poe_seq INTEGER NOT NULL,
+ subject_id INTEGER NOT NULL,
+ field_name VARCHAR(255) NOT NULL,
+ field_value TEXT
+);
+
+DROP TABLE IF EXISTS mimic_hosp.poe;
+CREATE TABLE mimic_hosp.poe
+(
+ poe_id VARCHAR(25) NOT NULL,
+ poe_seq INTEGER NOT NULL,
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER,
+ ordertime TIMESTAMP(0) NOT NULL,
+ order_type VARCHAR(25) NOT NULL,
+ order_subtype VARCHAR(50),
+ transaction_type VARCHAR(15),
+ discontinue_of_poe_id VARCHAR(25),
+ discontinued_by_poe_id VARCHAR(25),
+ order_status VARCHAR(15)
+);
+
+DROP TABLE IF EXISTS mimic_hosp.prescriptions;
+CREATE TABLE mimic_hosp.prescriptions
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ pharmacy_id INTEGER NOT NULL,
+ poe_id VARCHAR(25),
+ poe_seq INTEGER,
+ starttime TIMESTAMP(3),
+ stoptime TIMESTAMP(3),
+ drug_type VARCHAR(20) NOT NULL,
+ drug VARCHAR(255) NOT NULL,
+ formulary_drug_cd VARCHAR(120),
+ gsn VARCHAR(255),
+ ndc VARCHAR(25),
+ prod_strength VARCHAR(255),
+ form_rx VARCHAR(25),
+ dose_val_rx VARCHAR(100),
+ dose_unit_rx VARCHAR(50),
+ form_val_disp VARCHAR(50),
+ form_unit_disp VARCHAR(50),
+ doses_per_24_hrs REAL,
+ route VARCHAR(50)
+);
+
+DROP TABLE IF EXISTS mimic_hosp.procedures_icd;
+CREATE TABLE mimic_hosp.procedures_icd
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ seq_num INTEGER NOT NULL,
+ chartdate TIMESTAMP(0) NOT NULL,
+ icd_code VARCHAR(7),
+ icd_version SMALLINT
+);
+
+DROP TABLE IF EXISTS mimic_hosp.services;
+CREATE TABLE mimic_hosp.services
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ transfertime TIMESTAMP NOT NULL,
+ prev_service VARCHAR(10),
+ curr_service VARCHAR(10)
+);
+
+DROP TABLE IF EXISTS mimic_hosp.transfers;
+CREATE TABLE mimic_hosp.transfers
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER,
+ transfer_id INTEGER NOT NULL,
+ eventtype VARCHAR(10),
+ careunit VARCHAR(255),
+ intime TIMESTAMP,
+ outtime TIMESTAMP
+);
+DROP TABLE IF EXISTS mimic_icu.chartevents;
+CREATE TABLE mimic_icu.chartevents
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ stay_id INTEGER NOT NULL,
+ charttime TIMESTAMP NOT NULL,
+ storetime TIMESTAMP,
+ itemid INTEGER NOT NULL,
+ value VARCHAR(200),
+ valuenum FLOAT,
+ valueuom VARCHAR(20),
+ warning SMALLINT
+);
+
+DROP TABLE IF EXISTS mimic_icu.datetimeevents;
+CREATE TABLE mimic_icu.datetimeevents
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ stay_id INTEGER NOT NULL,
+ charttime TIMESTAMP NOT NULL,
+ storetime TIMESTAMP,
+ itemid INTEGER NOT NULL,
+ value TIMESTAMP NOT NULL,
+ valueuom VARCHAR(20),
+ warning SMALLINT
+);
+
+DROP TABLE IF EXISTS mimic_icu.d_items;
+CREATE TABLE mimic_icu.d_items
+(
+ itemid INTEGER NOT NULL,
+ label VARCHAR(100) NOT NULL,
+ abbreviation VARCHAR(50) NOT NULL,
+ linksto VARCHAR(30) NOT NULL,
+ category VARCHAR(50) NOT NULL,
+ unitname VARCHAR(50),
+ param_type VARCHAR(20) NOT NULL,
+ lownormalvalue FLOAT,
+ highnormalvalue FLOAT
+);
+
+DROP TABLE IF EXISTS mimic_icu.icustays;
+CREATE TABLE mimic_icu.icustays
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ stay_id INTEGER NOT NULL,
+ first_careunit VARCHAR(255),
+ last_careunit VARCHAR(255),
+ intime TIMESTAMP,
+ outtime TIMESTAMP,
+ los FLOAT
+);
+
+DROP TABLE IF EXISTS mimic_icu.ingredientevents;
+CREATE TABLE mimic_icu.ingredientevents(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ stay_id INTEGER,
+ starttime TIMESTAMP NOT NULL,
+ endtime TIMESTAMP NOT NULL,
+ storetime TIMESTAMP,
+ itemid INTEGER NOT NULL,
+ amount FLOAT,
+ amountuom VARCHAR(20),
+ rate FLOAT,
+ rateuom VARCHAR(20),
+ orderid INTEGER NOT NULL,
+ linkorderid INTEGER,
+ statusdescription VARCHAR(20),
+ originalamount FLOAT,
+ originalrate FLOAT
+);
+
+DROP TABLE IF EXISTS mimic_icu.inputevents;
+CREATE TABLE mimic_icu.inputevents
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ stay_id INTEGER,
+ starttime TIMESTAMP NOT NULL,
+ endtime TIMESTAMP NOT NULL,
+ storetime TIMESTAMP,
+ itemid INTEGER NOT NULL,
+ amount FLOAT,
+ amountuom VARCHAR(20),
+ rate FLOAT,
+ rateuom VARCHAR(20),
+ orderid INTEGER NOT NULL,
+ linkorderid INTEGER,
+ ordercategoryname VARCHAR(50),
+ secondaryordercategoryname VARCHAR(50),
+ ordercomponenttypedescription VARCHAR(100),
+ ordercategorydescription VARCHAR(30),
+ patientweight FLOAT,
+ totalamount FLOAT,
+ totalamountuom VARCHAR(50),
+ isopenbag SMALLINT,
+ continueinnextdept SMALLINT,
+ statusdescription VARCHAR(20),
+ originalamount FLOAT,
+ originalrate FLOAT
+);
+
+DROP TABLE IF EXISTS mimic_icu.outputevents;
+CREATE TABLE mimic_icu.outputevents
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ stay_id INTEGER NOT NULL,
+ charttime TIMESTAMP(3) NOT NULL,
+ storetime TIMESTAMP(3) NOT NULL,
+ itemid INTEGER NOT NULL,
+ value FLOAT NOT NULL,
+ valueuom VARCHAR(20)
+);
+
+DROP TABLE IF EXISTS mimic_icu.procedureevents;
+CREATE TABLE mimic_icu.procedureevents
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ stay_id INTEGER NOT NULL,
+ starttime TIMESTAMP NOT NULL,
+ endtime TIMESTAMP NOT NULL,
+ storetime TIMESTAMP NOT NULL,
+ itemid INTEGER NOT NULL,
+ value FLOAT,
+ valueuom VARCHAR(20),
+ location VARCHAR(100),
+ locationcategory VARCHAR(50),
+ orderid INTEGER,
+ linkorderid INTEGER,
+ ordercategoryname VARCHAR(50),
+ ordercategorydescription VARCHAR(30),
+ patientweight FLOAT,
+ isopenbag SMALLINT,
+ continueinnextdept SMALLINT,
+ statusdescription VARCHAR(20),
+ originalamount FLOAT,
+ originalrate FLOAT
+);
+
+
+DROP TABLE IF EXISTS mimic_ed.diagnosis CASCADE;
+CREATE TABLE mimic_ed.diagnosis
+(
+ subject_id INTEGER NOT NULL,
+ stay_id INTEGER NOT NULL,
+ seq_num INTEGER NOT NULL,
+ icd_code VARCHAR(8) NOT NULL,
+ icd_version SMALLINT NOT NULL,
+ icd_title TEXT NOT NULL
+) ;
+
+--------------------------------------------------------
+-- DDL for Table edstays
+--------------------------------------------------------
+
+DROP TABLE IF EXISTS mimic_ed.edstays CASCADE;
+CREATE TABLE mimic_ed.edstays
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER,
+ stay_id INTEGER NOT NULL,
+ intime TIMESTAMP(0) NOT NULL,
+ outtime TIMESTAMP(0) NOT NULL,
+ gender VARCHAR(1) NOT NULL,
+ race VARCHAR(60),
+ arrival_transport VARCHAR(50) NOT NULL,
+ disposition VARCHAR(255)
+) ;
+
+--------------------------------------------------------
+-- DDL for Table medrecon
+--------------------------------------------------------
+
+DROP TABLE IF EXISTS mimic_ed.medrecon CASCADE;
+CREATE TABLE mimic_ed.medrecon
+(
+ subject_id INTEGER NOT NULL,
+ stay_id INTEGER NOT NULL,
+ charttime TIMESTAMP(0),
+ name VARCHAR(255),
+ gsn VARCHAR(10),
+ ndc VARCHAR(12),
+ etc_rn SMALLINT,
+ etccode VARCHAR(8),
+ etcdescription VARCHAR(255)
+) ;
+
+--------------------------------------------------------
+-- DDL for Table pyxis
+--------------------------------------------------------
+
+DROP TABLE IF EXISTS mimic_ed.pyxis CASCADE;
+CREATE TABLE mimic_ed.pyxis
+(
+ subject_id INTEGER NOT NULL,
+ stay_id INTEGER NOT NULL,
+ charttime TIMESTAMP(0),
+ med_rn SMALLINT NOT NULL,
+ name VARCHAR(255),
+ gsn_rn SMALLINT NOT NULL,
+ gsn VARCHAR(10)
+) ;
+
+--------------------------------------------------------
+-- PARTITION for Table triage
+--------------------------------------------------------
+
+DROP TABLE IF EXISTS mimic_ed.triage CASCADE;
+CREATE TABLE mimic_ed.triage
+(
+ subject_id INTEGER NOT NULL,
+ stay_id INTEGER NOT NULL,
+ temperature NUMERIC,
+ heartrate NUMERIC,
+ resprate NUMERIC,
+ o2sat NUMERIC,
+ sbp NUMERIC,
+ dbp NUMERIC,
+ pain TEXT,
+ acuity NUMERIC,
+ chiefcomplaint VARCHAR(255)
+) ;
+
+--------------------------------------------------------
+-- DDL for Table vitalsign
+--------------------------------------------------------
+
+DROP TABLE IF EXISTS mimic_ed.vitalsign CASCADE;
+CREATE TABLE mimic_ed.vitalsign
+(
+ subject_id INTEGER NOT NULL,
+ stay_id INTEGER NOT NULL,
+ charttime TIMESTAMP(0),
+ temperature NUMERIC,
+ heartrate NUMERIC,
+ resprate NUMERIC(10, 4),
+ o2sat NUMERIC,
+ sbp INTEGER,
+ dbp INTEGER,
+ rhythm TEXT,
+ pain TEXT
+);
\ No newline at end of file
diff --git a/pgmimic/_db/SQL/2.0/index.sql b/pgmimic/_db/SQL/2.0/index.sql
new file mode 100644
index 0000000..9d78d77
--- /dev/null
+++ b/pgmimic/_db/SQL/2.0/index.sql
@@ -0,0 +1,169 @@
+SET search_path TO mimic_hosp;
+DROP INDEX IF EXISTS admissions_idx01;
+CREATE INDEX admissions_idx01
+ ON admissions (admittime, dischtime, deathtime);
+DROP INDEX IF EXISTS D_ICD_DIAG_idx02;
+CREATE INDEX D_ICD_DIAG_idx02
+ ON D_ICD_DIAGNOSES (LONG_TITLE);
+DROP INDEX IF EXISTS D_ICD_PROC_idx02;
+CREATE INDEX D_ICD_PROC_idx02
+ ON D_ICD_PROCEDURES (LONG_TITLE);
+DROP INDEX IF EXISTS drgcodes_idx01;
+CREATE INDEX drgcodes_idx01
+ ON drgcodes (drg_code, drg_type);
+DROP INDEX IF EXISTS drgcodes_idx02;
+CREATE INDEX drgcodes_idx02
+ ON drgcodes (description, drg_severity);
+DROP INDEX IF EXISTS d_labitems_idx01;
+CREATE INDEX d_labitems_idx01
+ ON d_labitems (label, fluid, category);
+DROP INDEX IF EXISTS emar_detail_idx01;
+CREATE INDEX emar_detail_idx01
+ ON emar_detail (pharmacy_id);
+DROP INDEX IF EXISTS emar_detail_idx02;
+CREATE INDEX emar_detail_idx02
+ ON emar_detail (product_code);
+DROP INDEX IF EXISTS emar_detail_idx03;
+CREATE INDEX emar_detail_idx03
+ ON emar_detail (route, site, side);
+DROP INDEX IF EXISTS EMAR_DET_idx04;
+CREATE INDEX EMAR_DET_idx04
+ ON EMAR_DETAIL (PRODUCT_DESCRIPTION);
+DROP INDEX IF EXISTS emar_idx01;
+CREATE INDEX emar_idx01
+ ON emar (poe_id);
+DROP INDEX IF EXISTS emar_idx02;
+CREATE INDEX emar_idx02
+ ON emar (pharmacy_id);
+DROP INDEX IF EXISTS emar_idx03;
+CREATE INDEX emar_idx03
+ ON emar (charttime, scheduletime, storetime);
+DROP INDEX IF EXISTS emar_idx04;
+CREATE INDEX emar_idx04
+ ON emar (medication);
+DROP INDEX IF EXISTS HCPCSEVENTS_idx04;
+CREATE INDEX HCPCSEVENTS_idx04
+ ON HCPCSEVENTS (SHORT_DESCRIPTION);
+DROP INDEX IF EXISTS labevents_idx01;
+CREATE INDEX labevents_idx01
+ ON labevents (charttime, storetime);
+DROP INDEX IF EXISTS labevents_idx02;
+CREATE INDEX labevents_idx02
+ ON labevents (specimen_id);
+DROP INDEX IF EXISTS microbiologyevents_idx01;
+CREATE INDEX microbiologyevents_idx01
+ ON microbiologyevents (chartdate, charttime, storedate, storetime);
+DROP INDEX IF EXISTS microbiologyevents_idx02;
+CREATE INDEX microbiologyevents_idx02
+ ON microbiologyevents (spec_itemid, test_itemid, org_itemid, ab_itemid);
+DROP INDEX IF EXISTS microbiologyevents_idx03;
+CREATE INDEX microbiologyevents_idx03
+ ON microbiologyevents (micro_specimen_id);
+DROP INDEX IF EXISTS patients_idx01;
+CREATE INDEX patients_idx01
+ ON patients (anchor_age);
+DROP INDEX IF EXISTS patients_idx02;
+CREATE INDEX patients_idx02
+ ON patients (anchor_year);
+DROP INDEX IF EXISTS pharmacy_idx01;
+CREATE INDEX pharmacy_idx01
+ ON pharmacy (poe_id);
+DROP INDEX IF EXISTS pharmacy_idx02;
+CREATE INDEX pharmacy_idx02
+ ON pharmacy (starttime, stoptime);
+DROP INDEX IF EXISTS pharmacy_idx03;
+CREATE INDEX pharmacy_idx03
+ ON pharmacy (medication);
+DROP INDEX IF EXISTS pharmacy_idx04;
+CREATE INDEX pharmacy_idx04
+ ON pharmacy (route);
+DROP INDEX IF EXISTS poe_idx01;
+CREATE INDEX poe_idx01
+ ON poe (order_type);
+DROP INDEX IF EXISTS prescriptions_idx01;
+CREATE INDEX prescriptions_idx01
+ ON prescriptions (starttime, stoptime);
+DROP INDEX IF EXISTS transfers_idx01;
+CREATE INDEX transfers_idx01
+ ON transfers (hadm_id);
+DROP INDEX IF EXISTS transfers_idx02;
+CREATE INDEX transfers_idx02
+ ON transfers (intime);
+DROP INDEX IF EXISTS transfers_idx03;
+CREATE INDEX transfers_idx03
+ ON transfers (careunit);
+SET search_path TO mimic_icu;
+DROP INDEX IF EXISTS chartevents_idx01;
+CREATE INDEX chartevents_idx01
+ ON chartevents (charttime, storetime);
+DROP INDEX IF EXISTS datetimeevents_idx01;
+CREATE INDEX datetimeevents_idx01
+ ON datetimeevents (charttime, storetime);
+DROP INDEX IF EXISTS datetimeevents_idx02;
+CREATE INDEX datetimeevents_idx02
+ ON datetimeevents (value);
+DROP INDEX IF EXISTS d_items_idx01;
+CREATE INDEX d_items_idx01
+ ON d_items (label, abbreviation);
+DROP INDEX IF EXISTS d_items_idx02;
+CREATE INDEX d_items_idx02
+ ON d_items (category);
+DROP INDEX IF EXISTS icustays_idx01;
+CREATE INDEX icustays_idx01
+ ON icustays (first_careunit, last_careunit);
+DROP INDEX IF EXISTS icustays_idx02;
+CREATE INDEX icustays_idx02
+ ON icustays (intime, outtime);
+DROP INDEX IF EXISTS inputevents_idx01;
+CREATE INDEX inputevents_idx01
+ ON inputevents (starttime, endtime);
+DROP INDEX IF EXISTS inputevents_idx02;
+CREATE INDEX inputevents_idx02
+ ON inputevents (ordercategorydescription);
+DROP INDEX IF EXISTS outputevents_idx01;
+CREATE INDEX outputevents_idx01
+ ON outputevents (charttime, storetime);
+DROP INDEX IF EXISTS procedureevents_idx01;
+CREATE INDEX procedureevents_idx01
+ ON procedureevents (starttime, endtime);
+DROP INDEX IF EXISTS procedureevents_idx02;
+CREATE INDEX procedureevents_idx02
+ ON procedureevents (ordercategoryname);
+
+/***********
+ ED
+ */
+----------------------------------------
+----------------------------------------
+-- Indexes for the MIMIC-IV-ED module --
+----------------------------------------
+----------------------------------------
+
+-- patients
+DROP INDEX IF EXISTS patients_idx01;
+CREATE INDEX patients_idx01
+ ON patients (anchor_age);
+
+DROP INDEX IF EXISTS patients_idx02;
+CREATE INDEX patients_idx02
+ ON patients (anchor_year);
+
+-- admissions
+
+DROP INDEX IF EXISTS admissions_idx01;
+CREATE INDEX admissions_idx01
+ ON admissions (admittime, dischtime, deathtime);
+
+-- transfers
+
+DROP INDEX IF EXISTS transfers_idx01;
+CREATE INDEX transfers_idx01
+ ON transfers (hadm_id);
+
+DROP INDEX IF EXISTS transfers_idx02;
+CREATE INDEX transfers_idx02
+ ON transfers (intime);
+
+DROP INDEX IF EXISTS transfers_idx03;
+CREATE INDEX transfers_idx03
+ ON transfers (careunit);
diff --git a/pgmimic/_db/SQL/2.2/README.md b/pgmimic/_db/SQL/2.2/README.md
new file mode 100644
index 0000000..e69de29
diff --git a/pgmimic/_db/SQL/2.2/constraint.sql b/pgmimic/_db/SQL/2.2/constraint.sql
new file mode 100644
index 0000000..c90c63a
--- /dev/null
+++ b/pgmimic/_db/SQL/2.2/constraint.sql
@@ -0,0 +1,428 @@
+ALTER TABLE mimic_hosp.admissions DROP CONSTRAINT IF EXISTS admissions_pk CASCADE;
+ALTER TABLE mimic_hosp.admissions
+ADD CONSTRAINT admissions_pk
+ PRIMARY KEY (hadm_id);
+ALTER TABLE mimic_hosp.d_hcpcs DROP CONSTRAINT IF EXISTS d_hcpcs_pk CASCADE;
+ALTER TABLE mimic_hosp.d_hcpcs
+ADD CONSTRAINT d_hcpcs_pk
+ PRIMARY KEY (code);
+ALTER TABLE mimic_hosp.diagnoses_icd DROP CONSTRAINT IF EXISTS diagnoses_icd_pk CASCADE;
+ALTER TABLE mimic_hosp.diagnoses_icd
+ADD CONSTRAINT diagnoses_icd_pk
+ PRIMARY KEY (hadm_id, seq_num, icd_code, icd_version);
+ALTER TABLE mimic_hosp.d_icd_diagnoses DROP CONSTRAINT IF EXISTS d_icd_diagnoses_pk CASCADE;
+ALTER TABLE mimic_hosp.d_icd_diagnoses
+ADD CONSTRAINT d_icd_diagnoses_pk
+ PRIMARY KEY (icd_code, icd_version);
+ALTER TABLE mimic_hosp.d_icd_procedures DROP CONSTRAINT IF EXISTS d_icd_procedures_pk CASCADE;
+ALTER TABLE mimic_hosp.d_icd_procedures
+ADD CONSTRAINT d_icd_procedures_pk
+ PRIMARY KEY (icd_code, icd_version);
+ALTER TABLE mimic_hosp.d_labitems DROP CONSTRAINT IF EXISTS d_labitems_pk CASCADE;
+ALTER TABLE mimic_hosp.d_labitems
+ADD CONSTRAINT d_labitems_pk
+ PRIMARY KEY (itemid);
+ALTER TABLE mimic_hosp.emar DROP CONSTRAINT IF EXISTS emar_pk CASCADE;
+ALTER TABLE mimic_hosp.emar
+ADD CONSTRAINT emar_pk
+ PRIMARY KEY (emar_id);
+ALTER TABLE mimic_hosp.hcpcsevents DROP CONSTRAINT IF EXISTS hcpcsevents_pk CASCADE;
+ALTER TABLE mimic_hosp.hcpcsevents
+ADD CONSTRAINT hcpcsevents_pk
+ PRIMARY KEY (hadm_id, hcpcs_cd, seq_num);
+ALTER TABLE mimic_hosp.labevents DROP CONSTRAINT IF EXISTS labevents_pk CASCADE;
+ALTER TABLE mimic_hosp.labevents
+ADD CONSTRAINT labevents_pk
+ PRIMARY KEY (labevent_id);
+ALTER TABLE mimic_hosp.microbiologyevents DROP CONSTRAINT IF EXISTS microbiologyevents_pk CASCADE;
+ALTER TABLE mimic_hosp.microbiologyevents
+ADD CONSTRAINT microbiologyevents_pk
+ PRIMARY KEY (microevent_id);
+ALTER TABLE mimic_hosp.patients DROP CONSTRAINT IF EXISTS patients_pk CASCADE;
+ALTER TABLE mimic_hosp.patients
+ADD CONSTRAINT patients_pk
+ PRIMARY KEY (subject_id);
+ALTER TABLE mimic_hosp.pharmacy DROP CONSTRAINT IF EXISTS pharmacy_pk CASCADE;
+ALTER TABLE mimic_hosp.pharmacy
+ADD CONSTRAINT pharmacy_pk
+ PRIMARY KEY (pharmacy_id);
+ALTER TABLE mimic_hosp.poe_detail DROP CONSTRAINT IF EXISTS poe_detail_pk CASCADE;
+ALTER TABLE mimic_hosp.poe_detail
+ADD CONSTRAINT poe_detail_pk
+ PRIMARY KEY (poe_id, field_name);
+ALTER TABLE mimic_hosp.poe DROP CONSTRAINT IF EXISTS poe_pk CASCADE;
+ALTER TABLE mimic_hosp.poe
+ADD CONSTRAINT poe_pk
+ PRIMARY KEY (poe_id);
+ALTER TABLE mimic_hosp.prescriptions DROP CONSTRAINT IF EXISTS prescriptions_pk CASCADE;
+ALTER TABLE mimic_hosp.prescriptions
+ADD CONSTRAINT prescriptions_pk
+ PRIMARY KEY (pharmacy_id, drug_type, drug);
+ALTER TABLE mimic_hosp.procedures_icd DROP CONSTRAINT IF EXISTS procedures_icd_pk CASCADE;
+ALTER TABLE mimic_hosp.procedures_icd
+ADD CONSTRAINT procedures_icd_pk
+ PRIMARY KEY (hadm_id, seq_num, icd_code, icd_version);
+ALTER TABLE mimic_hosp.services DROP CONSTRAINT IF EXISTS services_pk CASCADE;
+ALTER TABLE mimic_hosp.services
+ADD CONSTRAINT services_pk
+ PRIMARY KEY (hadm_id, transfertime, curr_service);
+ALTER TABLE mimic_icu.datetimeevents DROP CONSTRAINT IF EXISTS datetimeevents_pk CASCADE;
+ALTER TABLE mimic_icu.datetimeevents
+ADD CONSTRAINT datetimeevents_pk
+ PRIMARY KEY (stay_id, itemid, charttime);
+ALTER TABLE mimic_icu.d_items DROP CONSTRAINT IF EXISTS d_items_pk CASCADE;
+ALTER TABLE mimic_icu.d_items
+ADD CONSTRAINT d_items_pk
+ PRIMARY KEY (itemid);
+ALTER TABLE mimic_icu.icustays DROP CONSTRAINT IF EXISTS icustays_pk CASCADE;
+ALTER TABLE mimic_icu.icustays
+ADD CONSTRAINT icustays_pk
+ PRIMARY KEY (stay_id);
+ALTER TABLE mimic_icu.inputevents DROP CONSTRAINT IF EXISTS inputevents_pk CASCADE;
+ALTER TABLE mimic_icu.inputevents
+ADD CONSTRAINT inputevents_pk
+ PRIMARY KEY (orderid, itemid);
+ALTER TABLE mimic_icu.outputevents DROP CONSTRAINT IF EXISTS outputevents_pk CASCADE;
+ALTER TABLE mimic_icu.outputevents
+ADD CONSTRAINT outputevents_pk
+ PRIMARY KEY (stay_id, charttime, itemid);
+ALTER TABLE mimic_icu.procedureevents DROP CONSTRAINT IF EXISTS procedureevents_pk CASCADE;
+ALTER TABLE mimic_icu.procedureevents
+ADD CONSTRAINT procedureevents_pk
+ PRIMARY KEY (orderid);
+ALTER TABLE mimic_hosp.admissions DROP CONSTRAINT IF EXISTS admissions_patients_fk;
+ALTER TABLE mimic_hosp.admissions
+ADD CONSTRAINT admissions_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.diagnoses_icd DROP CONSTRAINT IF EXISTS diagnoses_icd_patients_fk;
+ALTER TABLE mimic_hosp.diagnoses_icd
+ADD CONSTRAINT diagnoses_icd_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.diagnoses_icd DROP CONSTRAINT IF EXISTS diagnoses_icd_admissions_fk;
+ALTER TABLE mimic_hosp.diagnoses_icd
+ADD CONSTRAINT diagnoses_icd_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_hosp.drgcodes DROP CONSTRAINT IF EXISTS drgcodes_patients_fk;
+ALTER TABLE mimic_hosp.drgcodes
+ADD CONSTRAINT drgcodes_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.drgcodes DROP CONSTRAINT IF EXISTS drgcodes_admissions_fk;
+ALTER TABLE mimic_hosp.drgcodes
+ADD CONSTRAINT drgcodes_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_hosp.emar_detail DROP CONSTRAINT IF EXISTS emar_detail_patients_fk;
+ALTER TABLE mimic_hosp.emar_detail
+ADD CONSTRAINT emar_detail_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.emar_detail DROP CONSTRAINT IF EXISTS emar_detail_emar_fk;
+ALTER TABLE mimic_hosp.emar_detail
+ADD CONSTRAINT emar_detail_emar_fk
+ FOREIGN KEY (emar_id)
+ REFERENCES mimic_hosp.emar (emar_id);
+ALTER TABLE mimic_hosp.emar DROP CONSTRAINT IF EXISTS emar_patients_fk;
+ALTER TABLE mimic_hosp.emar
+ADD CONSTRAINT emar_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.emar DROP CONSTRAINT IF EXISTS emar_admissions_fk;
+ALTER TABLE mimic_hosp.emar
+ADD CONSTRAINT emar_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_hosp.hcpcsevents DROP CONSTRAINT IF EXISTS hcpcsevents_patients_fk;
+ALTER TABLE mimic_hosp.hcpcsevents
+ADD CONSTRAINT hcpcsevents_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.hcpcsevents DROP CONSTRAINT IF EXISTS hcpcsevents_admissions_fk;
+ALTER TABLE mimic_hosp.hcpcsevents
+ADD CONSTRAINT hcpcsevents_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_hosp.hcpcsevents DROP CONSTRAINT IF EXISTS hcpcsevents_d_hcpcs_fk;
+ALTER TABLE mimic_hosp.hcpcsevents
+ADD CONSTRAINT hcpcsevents_d_hcpcs_fk
+ FOREIGN KEY (hcpcs_cd)
+ REFERENCES mimic_hosp.d_hcpcs (code);
+ALTER TABLE mimic_hosp.labevents DROP CONSTRAINT IF EXISTS labevents_patients_fk;
+ALTER TABLE mimic_hosp.labevents
+ADD CONSTRAINT labevents_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.labevents DROP CONSTRAINT IF EXISTS labevents_d_labitems_fk;
+ALTER TABLE mimic_hosp.labevents
+ADD CONSTRAINT labevents_d_labitems_fk
+ FOREIGN KEY (itemid)
+ REFERENCES mimic_hosp.d_labitems (itemid);
+ALTER TABLE mimic_hosp.microbiologyevents DROP CONSTRAINT IF EXISTS microbiologyevents_patients_fk;
+ALTER TABLE mimic_hosp.microbiologyevents
+ADD CONSTRAINT microbiologyevents_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.microbiologyevents DROP CONSTRAINT IF EXISTS microbiologyevents_admissions_fk;
+ALTER TABLE mimic_hosp.microbiologyevents
+ADD CONSTRAINT microbiologyevents_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_hosp.pharmacy DROP CONSTRAINT IF EXISTS pharmacy_patients_fk;
+ALTER TABLE mimic_hosp.pharmacy
+ADD CONSTRAINT pharmacy_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.pharmacy DROP CONSTRAINT IF EXISTS pharmacy_admissions_fk;
+ALTER TABLE mimic_hosp.pharmacy
+ADD CONSTRAINT pharmacy_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_hosp.poe_detail DROP CONSTRAINT IF EXISTS poe_detail_patients_fk;
+ALTER TABLE mimic_hosp.poe_detail
+ADD CONSTRAINT poe_detail_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.poe_detail DROP CONSTRAINT IF EXISTS poe_detail_poe_fk;
+ALTER TABLE mimic_hosp.poe_detail
+ADD CONSTRAINT poe_detail_poe_fk
+ FOREIGN KEY (poe_id)
+ REFERENCES mimic_hosp.poe (poe_id);
+ALTER TABLE mimic_hosp.poe DROP CONSTRAINT IF EXISTS poe_patients_fk;
+ALTER TABLE mimic_hosp.poe
+ADD CONSTRAINT poe_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.poe DROP CONSTRAINT IF EXISTS poe_admissions_fk;
+ALTER TABLE mimic_hosp.poe
+ADD CONSTRAINT poe_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_hosp.prescriptions DROP CONSTRAINT IF EXISTS prescriptions_patients_fk;
+ALTER TABLE mimic_hosp.prescriptions
+ADD CONSTRAINT prescriptions_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.prescriptions DROP CONSTRAINT IF EXISTS prescriptions_admissions_fk;
+ALTER TABLE mimic_hosp.prescriptions
+ADD CONSTRAINT prescriptions_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_hosp.procedures_icd DROP CONSTRAINT IF EXISTS procedures_icd_patients_fk;
+ALTER TABLE mimic_hosp.procedures_icd
+ADD CONSTRAINT procedures_icd_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.procedures_icd DROP CONSTRAINT IF EXISTS procedures_icd_admissions_fk;
+ALTER TABLE mimic_hosp.procedures_icd
+ADD CONSTRAINT procedures_icd_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_hosp.services DROP CONSTRAINT IF EXISTS services_patients_fk;
+ALTER TABLE mimic_hosp.services
+ADD CONSTRAINT services_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_hosp.services DROP CONSTRAINT IF EXISTS services_admissions_fk;
+ALTER TABLE mimic_hosp.services
+ADD CONSTRAINT services_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_hosp.transfers DROP CONSTRAINT IF EXISTS transfers_pk CASCADE;
+ALTER TABLE mimic_hosp.transfers
+ADD CONSTRAINT transfers_pk
+ PRIMARY KEY (transfer_id);
+ALTER TABLE mimic_hosp.transfers DROP CONSTRAINT IF EXISTS transfers_patients_fk;
+ALTER TABLE mimic_hosp.transfers
+ADD CONSTRAINT transfers_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_icu.chartevents DROP CONSTRAINT IF EXISTS chartevents_patients_fk;
+ALTER TABLE mimic_icu.chartevents
+ADD CONSTRAINT chartevents_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_icu.chartevents DROP CONSTRAINT IF EXISTS chartevents_admissions_fk;
+ALTER TABLE mimic_icu.chartevents
+ADD CONSTRAINT chartevents_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_icu.chartevents DROP CONSTRAINT IF EXISTS chartevents_icustays_fk;
+ALTER TABLE mimic_icu.chartevents
+ADD CONSTRAINT chartevents_icustays_fk
+ FOREIGN KEY (stay_id)
+ REFERENCES mimic_icu.icustays (stay_id);
+ALTER TABLE mimic_icu.chartevents DROP CONSTRAINT IF EXISTS chartevents_d_items_fk;
+ALTER TABLE mimic_icu.chartevents
+ADD CONSTRAINT chartevents_d_items_fk
+ FOREIGN KEY (itemid)
+ REFERENCES mimic_icu.d_items (itemid);
+ALTER TABLE mimic_icu.datetimeevents DROP CONSTRAINT IF EXISTS datetimeevents_patients_fk;
+ALTER TABLE mimic_icu.datetimeevents
+ADD CONSTRAINT datetimeevents_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_icu.datetimeevents DROP CONSTRAINT IF EXISTS datetimeevents_admissions_fk;
+ALTER TABLE mimic_icu.datetimeevents
+ADD CONSTRAINT datetimeevents_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_icu.datetimeevents DROP CONSTRAINT IF EXISTS datetimeevents_icustays_fk;
+ALTER TABLE mimic_icu.datetimeevents
+ADD CONSTRAINT datetimeevents_icustays_fk
+ FOREIGN KEY (stay_id)
+ REFERENCES mimic_icu.icustays (stay_id);
+ALTER TABLE mimic_icu.datetimeevents DROP CONSTRAINT IF EXISTS datetimeevents_d_items_fk;
+ALTER TABLE mimic_icu.datetimeevents
+ADD CONSTRAINT datetimeevents_d_items_fk
+ FOREIGN KEY (itemid)
+ REFERENCES mimic_icu.d_items (itemid);
+ALTER TABLE mimic_icu.icustays DROP CONSTRAINT IF EXISTS icustays_patients_fk;
+ALTER TABLE mimic_icu.icustays
+ADD CONSTRAINT icustays_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_icu.icustays DROP CONSTRAINT IF EXISTS icustays_admissions_fk;
+ALTER TABLE mimic_icu.icustays
+ADD CONSTRAINT icustays_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_icu.inputevents DROP CONSTRAINT IF EXISTS inputevents_patients_fk;
+ALTER TABLE mimic_icu.inputevents
+ADD CONSTRAINT inputevents_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_icu.inputevents DROP CONSTRAINT IF EXISTS inputevents_admissions_fk;
+ALTER TABLE mimic_icu.inputevents
+ADD CONSTRAINT inputevents_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_icu.inputevents DROP CONSTRAINT IF EXISTS inputevents_icustays_fk;
+ALTER TABLE mimic_icu.inputevents
+ADD CONSTRAINT inputevents_icustays_fk
+ FOREIGN KEY (stay_id)
+ REFERENCES mimic_icu.icustays (stay_id);
+ALTER TABLE mimic_icu.inputevents DROP CONSTRAINT IF EXISTS inputevents_d_items_fk;
+ALTER TABLE mimic_icu.inputevents
+ADD CONSTRAINT inputevents_d_items_fk
+ FOREIGN KEY (itemid)
+ REFERENCES mimic_icu.d_items (itemid);
+ALTER TABLE mimic_icu.outputevents DROP CONSTRAINT IF EXISTS outputevents_patients_fk;
+ALTER TABLE mimic_icu.outputevents
+ADD CONSTRAINT outputevents_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_icu.outputevents DROP CONSTRAINT IF EXISTS outputevents_admissions_fk;
+ALTER TABLE mimic_icu.outputevents
+ADD CONSTRAINT outputevents_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_icu.outputevents DROP CONSTRAINT IF EXISTS outputevents_icustays_fk;
+ALTER TABLE mimic_icu.outputevents
+ADD CONSTRAINT outputevents_icustays_fk
+ FOREIGN KEY (stay_id)
+ REFERENCES mimic_icu.icustays (stay_id);
+ALTER TABLE mimic_icu.outputevents DROP CONSTRAINT IF EXISTS outputevents_d_items_fk;
+ALTER TABLE mimic_icu.outputevents
+ADD CONSTRAINT outputevents_d_items_fk
+ FOREIGN KEY (itemid)
+ REFERENCES mimic_icu.d_items (itemid);
+ALTER TABLE mimic_icu.procedureevents DROP CONSTRAINT IF EXISTS procedureevents_patients_fk;
+ALTER TABLE mimic_icu.procedureevents
+ADD CONSTRAINT procedureevents_patients_fk
+ FOREIGN KEY (subject_id)
+ REFERENCES mimic_hosp.patients (subject_id);
+ALTER TABLE mimic_icu.procedureevents DROP CONSTRAINT IF EXISTS procedureevents_admissions_fk;
+ALTER TABLE mimic_icu.procedureevents
+ADD CONSTRAINT procedureevents_admissions_fk
+ FOREIGN KEY (hadm_id)
+ REFERENCES mimic_hosp.admissions (hadm_id);
+ALTER TABLE mimic_icu.procedureevents DROP CONSTRAINT IF EXISTS procedureevents_icustays_fk;
+ALTER TABLE mimic_icu.procedureevents
+ADD CONSTRAINT procedureevents_icustays_fk
+ FOREIGN KEY (stay_id)
+ REFERENCES mimic_icu.icustays (stay_id);
+ALTER TABLE mimic_icu.procedureevents DROP CONSTRAINT IF EXISTS procedureevents_d_items_fk;
+ALTER TABLE mimic_icu.procedureevents
+ADD CONSTRAINT procedureevents_d_items_fk
+ FOREIGN KEY (itemid)
+ REFERENCES mimic_icu.d_items (itemid);
+
+/*
+ ED CONSTRAINT
+ */
+
+ SET search_path TO mimiciv_ed;
+---------------------------
+---------------------------
+-- Creating Primary Keys --
+---------------------------
+---------------------------
+
+ALTER TABLE mimiciv_ed.edstays DROP CONSTRAINT IF EXISTS edstays_pk CASCADE;
+ALTER TABLE mimiciv_ed.edstays
+ADD CONSTRAINT edstays_pk
+ PRIMARY KEY (stay_id);
+
+ALTER TABLE mimiciv_ed.diagnosis DROP CONSTRAINT IF EXISTS diagnosis_pk CASCADE;
+ALTER TABLE mimiciv_ed.diagnosis
+ADD CONSTRAINT diagnosis_pk
+ PRIMARY KEY (stay_id, seq_num);
+
+--ALTER TABLE mimiciv_ed.medrecon DROP CONSTRAINT IF EXISTS medrecon_pk CASCADE;
+--ALTER TABLE mimiciv_ed.medrecon
+--ADD CONSTRAINT medrecon_pk
+-- PRIMARY KEY (stay_id, charttime, name);
+
+--ALTER TABLE mimiciv_ed.pyxis DROP CONSTRAINT IF EXISTS pyxis_pk CASCADE;
+--ALTER TABLE mimiciv_ed.pyxis
+--ADD CONSTRAINT pyxis_pk
+-- PRIMARY KEY (stay_id, charttime, name);
+
+ALTER TABLE mimiciv_ed.triage DROP CONSTRAINT IF EXISTS triage_pk CASCADE;
+ALTER TABLE mimiciv_ed.triage
+ADD CONSTRAINT triage_pk
+ PRIMARY KEY (stay_id);
+
+ALTER TABLE mimiciv_ed.vitalsign DROP CONSTRAINT IF EXISTS vitalsign_pk CASCADE;
+ALTER TABLE mimiciv_ed.vitalsign
+ADD CONSTRAINT vitalsign_pk
+ PRIMARY KEY (stay_id, charttime);
+
+---------------------------
+---------------------------
+-- Creating Foreign Keys --
+---------------------------
+---------------------------
+
+ALTER TABLE mimiciv_ed.diagnosis DROP CONSTRAINT IF EXISTS diagnosis_edstays_fk CASCADE;
+ALTER TABLE mimiciv_ed.diagnosis
+ADD CONSTRAINT diagnosis_edstays_fk
+ FOREIGN KEY (stay_id)
+ REFERENCES mimiciv_ed.edstays (stay_id);
+
+ALTER TABLE mimiciv_ed.medrecon DROP CONSTRAINT IF EXISTS medrecon_edstays_fk CASCADE;
+ALTER TABLE mimiciv_ed.medrecon
+ADD CONSTRAINT medrecon_edstays_fk
+ FOREIGN KEY (stay_id)
+ REFERENCES mimiciv_ed.edstays (stay_id);
+
+ALTER TABLE mimiciv_ed.pyxis DROP CONSTRAINT IF EXISTS pyxis_edstays_fk CASCADE;
+ALTER TABLE mimiciv_ed.pyxis
+ADD CONSTRAINT pyxis_edstays_fk
+ FOREIGN KEY (stay_id)
+ REFERENCES mimiciv_ed.edstays (stay_id);
+
+ALTER TABLE mimiciv_ed.triage DROP CONSTRAINT IF EXISTS triage_edstays_fk CASCADE;
+ALTER TABLE mimiciv_ed.triage
+ADD CONSTRAINT triage_edstays_fk
+ FOREIGN KEY (stay_id)
+ REFERENCES mimiciv_ed.edstays (stay_id);
+
+ALTER TABLE mimiciv_ed.vitalsign DROP CONSTRAINT IF EXISTS vitalsign_edstays_fk CASCADE;
+ALTER TABLE mimiciv_ed.vitalsign
+ADD CONSTRAINT vitalsign_edstays_fk
+ FOREIGN KEY (stay_id)
+ REFERENCES mimiciv_ed.edstays (stay_id);
\ No newline at end of file
diff --git a/pgmimic/_db/SQL/2.2/create.sql b/pgmimic/_db/SQL/2.2/create.sql
new file mode 100644
index 0000000..10ee1fc
--- /dev/null
+++ b/pgmimic/_db/SQL/2.2/create.sql
@@ -0,0 +1,619 @@
+/*
+ DROP SCHEMA IF EXISTS
+ */
+DROP SCHEMA IF EXISTS mimic_hosp CASCADE;
+CREATE SCHEMA mimic_hosp;
+DROP SCHEMA IF EXISTS mimic_icu CASCADE;
+CREATE SCHEMA mimic_icu;
+DROP SCHEMA IF EXISTS mimic_derived CASCADE;
+CREATE SCHEMA mimic_derived;
+DROP SCHEMA IF EXISTS mimic_ed CASCADE;
+CREATE SCHEMA mimiciv_ed;
+
+DROP TABLE IF EXISTS mimic_hosp.admissions;
+/*
+ CREATE TABLES
+ */
+CREATE TABLE mimic_hosp.admissions
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ admittime TIMESTAMP NOT NULL,
+ dischtime TIMESTAMP,
+ deathtime TIMESTAMP,
+ admission_type VARCHAR(40) NOT NULL,
+ admit_provider_id VARCHAR(10),
+ admission_location VARCHAR(60),
+ discharge_location VARCHAR(60),
+ insurance VARCHAR(255),
+ language VARCHAR(10),
+ marital_status VARCHAR(30),
+ race VARCHAR(80),
+ edregtime TIMESTAMP,
+ edouttime TIMESTAMP,
+ hospital_expire_flag SMALLINT
+);
+DROP TABLE IF EXISTS mimic_hosp.d_hcpcs;
+CREATE TABLE mimic_hosp.d_hcpcs
+(
+ code CHAR(5) NOT NULL,
+ category SMALLINT,
+ long_description TEXT,
+ short_description VARCHAR(180)
+);
+DROP TABLE IF EXISTS mimic_hosp.diagnoses_icd;
+CREATE TABLE mimic_hosp.diagnoses_icd
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ seq_num INTEGER NOT NULL,
+ icd_code CHAR(7),
+ icd_version SMALLINT
+);
+DROP TABLE IF EXISTS mimic_hosp.d_icd_diagnoses;
+CREATE TABLE mimic_hosp.d_icd_diagnoses
+(
+ icd_code CHAR(7) NOT NULL,
+ icd_version SMALLINT NOT NULL,
+ long_title VARCHAR(255)
+);
+DROP TABLE IF EXISTS mimic_hosp.d_icd_procedures;
+CREATE TABLE mimic_hosp.d_icd_procedures
+(
+ icd_code CHAR(7) NOT NULL,
+ icd_version SMALLINT NOT NULL,
+ long_title VARCHAR(222)
+);
+
+DROP TABLE IF EXISTS mimic_hosp.d_labitems;
+CREATE TABLE mimic_hosp.d_labitems
+(
+ itemid INTEGER NOT NULL,
+ label VARCHAR(50),
+ fluid VARCHAR(50),
+ category VARCHAR(50)
+);
+
+DROP TABLE IF EXISTS mimic_hosp.drgcodes;
+CREATE TABLE mimic_hosp.drgcodes
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ drg_type VARCHAR(4),
+ drg_code VARCHAR(10) NOT NULL,
+ description VARCHAR(195),
+ drg_severity SMALLINT,
+ drg_mortality SMALLINT
+);
+
+DROP TABLE IF EXISTS mimic_hosp.emar_detail;
+CREATE TABLE mimic_hosp.emar_detail
+(
+ subject_id INTEGER NOT NULL,
+ emar_id VARCHAR(25) NOT NULL,
+ emar_seq INTEGER NOT NULL,
+ parent_field_ordinal VARCHAR(10),
+ administration_type VARCHAR(50),
+ pharmacy_id INTEGER,
+ barcode_type VARCHAR(4),
+ reason_for_no_barcode TEXT,
+ complete_dose_not_given VARCHAR(5),
+ dose_due VARCHAR(100),
+ dose_due_unit VARCHAR(50),
+ dose_given VARCHAR(255),
+ dose_given_unit VARCHAR(50),
+ will_remainder_of_dose_be_given VARCHAR(5),
+ product_amount_given VARCHAR(30),
+ product_unit VARCHAR(30),
+ product_code VARCHAR(30),
+ product_description VARCHAR(255),
+ product_description_other VARCHAR(255),
+ prior_infusion_rate VARCHAR(40),
+ infusion_rate VARCHAR(40),
+ infusion_rate_adjustment VARCHAR(50),
+ infusion_rate_adjustment_amount VARCHAR(30),
+ infusion_rate_unit VARCHAR(30),
+ route VARCHAR(10),
+ infusion_complete VARCHAR(1),
+ completion_interval VARCHAR(50),
+ new_iv_bag_hung VARCHAR(1),
+ continued_infusion_in_other_location VARCHAR(1),
+ restart_interval VARCHAR(2305),
+ side VARCHAR(10),
+ site VARCHAR(255),
+ non_formulary_visual_verification VARCHAR(1)
+);
+
+DROP TABLE IF EXISTS mimic_hosp.emar;
+CREATE TABLE mimic_hosp.emar
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER,
+ emar_id VARCHAR(25) NOT NULL,
+ emar_seq INTEGER NOT NULL,
+ poe_id VARCHAR(25) NOT NULL,
+ pharmacy_id INTEGER,
+ enter_provider_id VARCHAR(10),
+ charttime TIMESTAMP NOT NULL,
+ medication TEXT,
+ event_txt VARCHAR(100),
+ scheduletime TIMESTAMP,
+ storetime TIMESTAMP NOT NULL
+);
+
+DROP TABLE IF EXISTS mimic_hosp.hcpcsevents;
+CREATE TABLE mimic_hosp.hcpcsevents
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ chartdate DATE,
+ hcpcs_cd CHAR(5) NOT NULL,
+ seq_num INTEGER NOT NULL,
+ short_description VARCHAR(180)
+);
+
+DROP TABLE IF EXISTS mimic_hosp.labevents;
+CREATE TABLE mimic_hosp.labevents
+(
+ labevent_id INTEGER NOT NULL,
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER,
+ specimen_id INTEGER NOT NULL,
+ itemid INTEGER NOT NULL,
+ order_provider_id VARCHAR(10),
+ charttime TIMESTAMP(0),
+ storetime TIMESTAMP(0),
+ value VARCHAR(200),
+ valuenum DOUBLE PRECISION,
+ valueuom VARCHAR(20),
+ ref_range_lower DOUBLE PRECISION,
+ ref_range_upper DOUBLE PRECISION,
+ flag VARCHAR(10),
+ priority VARCHAR(7),
+ comments TEXT
+);
+
+DROP TABLE IF EXISTS mimic_hosp.microbiologyevents;
+CREATE TABLE mimic_hosp.microbiologyevents
+(
+ microevent_id INTEGER NOT NULL,
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER,
+ micro_specimen_id INTEGER NOT NULL,
+ order_provider_id VARCHAR(10),
+ chartdate TIMESTAMP(0) NOT NULL,
+ charttime TIMESTAMP(0),
+ spec_itemid INTEGER NOT NULL,
+ spec_type_desc VARCHAR(100) NOT NULL,
+ test_seq INTEGER NOT NULL,
+ storedate TIMESTAMP(0),
+ storetime TIMESTAMP(0),
+ test_itemid INTEGER,
+ test_name VARCHAR(100),
+ org_itemid INTEGER,
+ org_name VARCHAR(100),
+ isolate_num SMALLINT,
+ quantity VARCHAR(50),
+ ab_itemid INTEGER,
+ ab_name VARCHAR(30),
+ dilution_text VARCHAR(10),
+ dilution_comparison VARCHAR(20),
+ dilution_value DOUBLE PRECISION,
+ interpretation VARCHAR(5),
+ comments TEXT
+);
+
+DROP TABLE IF EXISTS mimic_hosp.omr;
+CREATE TABLE mimic_hosp.omr
+(
+ subject_id INTEGER NOT NULL,
+ chartdate DATE NOT NULL,
+ seq_num INTEGER NOT NULL,
+ result_name VARCHAR(100) NOT NULL,
+ result_value TEXT NOT NULL
+);
+
+DROP TABLE IF EXISTS mimic_hosp.patients;
+CREATE TABLE mimic_hosp.patients
+(
+ subject_id INTEGER NOT NULL,
+ gender CHAR(1) NOT NULL,
+ anchor_age SMALLINT,
+ anchor_year SMALLINT NOT NULL,
+ anchor_year_group VARCHAR(20) NOT NULL,
+ dod DATE
+);
+
+DROP TABLE IF EXISTS mimic_hosp.pharmacy;
+CREATE TABLE mimic_hosp.pharmacy
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ pharmacy_id INTEGER NOT NULL,
+ poe_id VARCHAR(25),
+ starttime TIMESTAMP(3),
+ stoptime TIMESTAMP(3),
+ medication TEXT,
+ proc_type VARCHAR(50) NOT NULL,
+ status VARCHAR(50),
+ entertime TIMESTAMP(3) NOT NULL,
+ verifiedtime TIMESTAMP(3),
+ route VARCHAR(50),
+ frequency VARCHAR(50),
+ disp_sched VARCHAR(255),
+ infusion_type VARCHAR(15),
+ sliding_scale VARCHAR(1),
+ lockout_interval VARCHAR(50),
+ basal_rate REAL,
+ one_hr_max VARCHAR(10),
+ doses_per_24_hrs REAL,
+ duration REAL,
+ duration_interval VARCHAR(50),
+ expiration_value INTEGER,
+ expiration_unit VARCHAR(50),
+ expirationdate TIMESTAMP(3),
+ dispensation VARCHAR(50),
+ fill_quantity VARCHAR(50)
+);
+
+DROP TABLE IF EXISTS mimic_hosp.poe_detail;
+CREATE TABLE mimic_hosp.poe_detail
+(
+ poe_id VARCHAR(25) NOT NULL,
+ poe_seq INTEGER NOT NULL,
+ subject_id INTEGER NOT NULL,
+ field_name VARCHAR(255) NOT NULL,
+ field_value TEXT
+);
+
+DROP TABLE IF EXISTS mimic_hosp.poe;
+CREATE TABLE mimic_hosp.poe
+(
+ poe_id VARCHAR(25) NOT NULL,
+ poe_seq INTEGER NOT NULL,
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER,
+ ordertime TIMESTAMP(0) NOT NULL,
+ order_type VARCHAR(25) NOT NULL,
+ order_subtype VARCHAR(50),
+ transaction_type VARCHAR(15),
+ discontinue_of_poe_id VARCHAR(25),
+ discontinued_by_poe_id VARCHAR(25),
+ order_provider_id VARCHAR(10),
+ order_status VARCHAR(15)
+);
+
+DROP TABLE IF EXISTS mimic_hosp.prescriptions;
+CREATE TABLE mimic_hosp.prescriptions
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ pharmacy_id INTEGER NOT NULL,
+ poe_id VARCHAR(25),
+ poe_seq INTEGER,
+ order_provider_id VARCHAR(10),
+ starttime TIMESTAMP(3),
+ stoptime TIMESTAMP(3),
+ drug_type VARCHAR(20) NOT NULL,
+ drug VARCHAR(255) NOT NULL,
+ formulary_drug_cd VARCHAR(50),
+ gsn VARCHAR(255),
+ ndc VARCHAR(25),
+ prod_strength VARCHAR(255),
+ form_rx VARCHAR(25),
+ dose_val_rx VARCHAR(100),
+ dose_unit_rx VARCHAR(50),
+ form_val_disp VARCHAR(50),
+ form_unit_disp VARCHAR(50),
+ doses_per_24_hrs REAL,
+ route VARCHAR(50)
+);
+
+DROP TABLE IF EXISTS mimic_hosp.procedures_icd;
+CREATE TABLE mimic_hosp.procedures_icd
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ seq_num INTEGER NOT NULL,
+ chartdate DATE NOT NULL,
+ icd_code VARCHAR(7),
+ icd_version SMALLINT
+);
+
+DROP TABLE IF EXISTS mimic_hosp.provider;
+CREATE TABLE mimic_hosp.provider
+(
+ provider_id VARCHAR(10) NOT NULL
+);
+
+DROP TABLE IF EXISTS mimic_hosp.services;
+CREATE TABLE mimic_hosp.services
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ transfertime TIMESTAMP NOT NULL,
+ prev_service VARCHAR(10),
+ curr_service VARCHAR(10)
+);
+
+DROP TABLE IF EXISTS mimic_hosp.transfers;
+CREATE TABLE mimic_hosp.transfers
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER,
+ transfer_id INTEGER NOT NULL,
+ eventtype VARCHAR(10),
+ careunit VARCHAR(255),
+ intime TIMESTAMP,
+ outtime TIMESTAMP
+);
+
+-- icu schema
+
+DROP TABLE IF EXISTS mimic_icu.caregiver;
+CREATE TABLE mimic_icu.caregiver
+(
+ caregiver_id INTEGER NOT NULL
+);
+
+DROP TABLE IF EXISTS mimic_icu.chartevents;
+CREATE TABLE mimic_icu.chartevents
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ stay_id INTEGER NOT NULL,
+ caregiver_id INTEGER,
+ charttime TIMESTAMP NOT NULL,
+ storetime TIMESTAMP,
+ itemid INTEGER NOT NULL,
+ value VARCHAR(200),
+ valuenum FLOAT,
+ valueuom VARCHAR(20),
+ warning SMALLINT
+);
+
+DROP TABLE IF EXISTS mimic_icu.datetimeevents;
+CREATE TABLE mimic_icu.datetimeevents
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ stay_id INTEGER NOT NULL,
+ caregiver_id INTEGER,
+ charttime TIMESTAMP NOT NULL,
+ storetime TIMESTAMP,
+ itemid INTEGER NOT NULL,
+ value TIMESTAMP NOT NULL,
+ valueuom VARCHAR(20),
+ warning SMALLINT
+);
+
+DROP TABLE IF EXISTS mimic_icu.d_items;
+CREATE TABLE mimic_icu.d_items
+(
+ itemid INTEGER NOT NULL,
+ label VARCHAR(100) NOT NULL,
+ abbreviation VARCHAR(50) NOT NULL,
+ linksto VARCHAR(30) NOT NULL,
+ category VARCHAR(50) NOT NULL,
+ unitname VARCHAR(50),
+ param_type VARCHAR(20) NOT NULL,
+ lownormalvalue FLOAT,
+ highnormalvalue FLOAT
+);
+
+DROP TABLE IF EXISTS mimic_icu.icustays;
+CREATE TABLE mimic_icu.icustays
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ stay_id INTEGER NOT NULL,
+ first_careunit VARCHAR(255),
+ last_careunit VARCHAR(255),
+ intime TIMESTAMP,
+ outtime TIMESTAMP,
+ los FLOAT
+);
+
+DROP TABLE IF EXISTS mimic_icu.ingredientevents;
+CREATE TABLE mimic_icu.ingredientevents
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ stay_id INTEGER,
+ caregiver_id INTEGER,
+ starttime TIMESTAMP NOT NULL,
+ endtime TIMESTAMP NOT NULL,
+ storetime TIMESTAMP,
+ itemid INTEGER NOT NULL,
+ amount FLOAT,
+ amountuom VARCHAR(20),
+ rate FLOAT,
+ rateuom VARCHAR(20),
+ orderid INTEGER NOT NULL,
+ linkorderid INTEGER,
+ statusdescription VARCHAR(20),
+ originalamount FLOAT,
+ originalrate FLOAT
+);
+
+DROP TABLE IF EXISTS mimic_icu.inputevents;
+CREATE TABLE mimic_icu.inputevents
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ stay_id INTEGER,
+ caregiver_id INTEGER,
+ starttime TIMESTAMP NOT NULL,
+ endtime TIMESTAMP NOT NULL,
+ storetime TIMESTAMP,
+ itemid INTEGER NOT NULL,
+ amount FLOAT,
+ amountuom VARCHAR(20),
+ rate FLOAT,
+ rateuom VARCHAR(20),
+ orderid INTEGER NOT NULL,
+ linkorderid INTEGER,
+ ordercategoryname VARCHAR(50),
+ secondaryordercategoryname VARCHAR(50),
+ ordercomponenttypedescription VARCHAR(100),
+ ordercategorydescription VARCHAR(30),
+ patientweight FLOAT,
+ totalamount FLOAT,
+ totalamountuom VARCHAR(50),
+ isopenbag SMALLINT,
+ continueinnextdept SMALLINT,
+ statusdescription VARCHAR(20),
+ originalamount FLOAT,
+ originalrate FLOAT
+);
+
+DROP TABLE IF EXISTS mimic_icu.outputevents;
+CREATE TABLE mimic_icu.outputevents
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ stay_id INTEGER NOT NULL,
+ caregiver_id INTEGER,
+ charttime TIMESTAMP(3) NOT NULL,
+ storetime TIMESTAMP(3) NOT NULL,
+ itemid INTEGER NOT NULL,
+ value FLOAT NOT NULL,
+ valueuom VARCHAR(20)
+);
+
+DROP TABLE IF EXISTS mimic_icu.procedureevents;
+CREATE TABLE mimic_icu.procedureevents
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER NOT NULL,
+ stay_id INTEGER NOT NULL,
+ caregiver_id INTEGER,
+ starttime TIMESTAMP NOT NULL,
+ endtime TIMESTAMP NOT NULL,
+ storetime TIMESTAMP NOT NULL,
+ itemid INTEGER NOT NULL,
+ value FLOAT,
+ valueuom VARCHAR(20),
+ location VARCHAR(100),
+ locationcategory VARCHAR(50),
+ orderid INTEGER,
+ linkorderid INTEGER,
+ ordercategoryname VARCHAR(50),
+ ordercategorydescription VARCHAR(30),
+ patientweight FLOAT,
+ isopenbag SMALLINT,
+ continueinnextdept SMALLINT,
+ statusdescription VARCHAR(20),
+ originalamount FLOAT,
+ originalrate FLOAT
+);
+/****
+ED TABLES
+****/
+
+--------------------------------------------------------
+-- DDL for Table diagnosis
+--------------------------------------------------------
+
+DROP TABLE IF EXISTS mimiciv_ed.diagnosis CASCADE;
+CREATE TABLE mimiciv_ed.diagnosis
+(
+ subject_id INTEGER NOT NULL,
+ stay_id INTEGER NOT NULL,
+ seq_num INTEGER NOT NULL,
+ icd_code VARCHAR(8) NOT NULL,
+ icd_version SMALLINT NOT NULL,
+ icd_title TEXT NOT NULL
+) ;
+
+--------------------------------------------------------
+-- DDL for Table edstays
+--------------------------------------------------------
+
+DROP TABLE IF EXISTS mimiciv_ed.edstays CASCADE;
+CREATE TABLE mimiciv_ed.edstays
+(
+ subject_id INTEGER NOT NULL,
+ hadm_id INTEGER,
+ stay_id INTEGER NOT NULL,
+ intime TIMESTAMP(0) NOT NULL,
+ outtime TIMESTAMP(0) NOT NULL,
+ gender VARCHAR(1) NOT NULL,
+ race VARCHAR(60),
+ arrival_transport VARCHAR(50) NOT NULL,
+ disposition VARCHAR(255)
+) ;
+
+--------------------------------------------------------
+-- DDL for Table medrecon
+--------------------------------------------------------
+
+DROP TABLE IF EXISTS mimiciv_ed.medrecon CASCADE;
+CREATE TABLE mimiciv_ed.medrecon
+(
+ subject_id INTEGER NOT NULL,
+ stay_id INTEGER NOT NULL,
+ charttime TIMESTAMP(0),
+ name VARCHAR(255),
+ gsn VARCHAR(10),
+ ndc VARCHAR(12),
+ etc_rn SMALLINT,
+ etccode VARCHAR(8),
+ etcdescription VARCHAR(255)
+) ;
+
+--------------------------------------------------------
+-- DDL for Table pyxis
+--------------------------------------------------------
+
+DROP TABLE IF EXISTS mimiciv_ed.pyxis CASCADE;
+CREATE TABLE mimiciv_ed.pyxis
+(
+ subject_id INTEGER NOT NULL,
+ stay_id INTEGER NOT NULL,
+ charttime TIMESTAMP(0),
+ med_rn SMALLINT NOT NULL,
+ name VARCHAR(255),
+ gsn_rn SMALLINT NOT NULL,
+ gsn VARCHAR(10)
+) ;
+
+--------------------------------------------------------
+-- PARTITION for Table triage
+--------------------------------------------------------
+
+DROP TABLE IF EXISTS mimiciv_ed.triage CASCADE;
+CREATE TABLE mimiciv_ed.triage
+(
+ subject_id INTEGER NOT NULL,
+ stay_id INTEGER NOT NULL,
+ temperature NUMERIC,
+ heartrate NUMERIC,
+ resprate NUMERIC,
+ o2sat NUMERIC,
+ sbp NUMERIC,
+ dbp NUMERIC,
+ pain TEXT,
+ acuity NUMERIC,
+ chiefcomplaint VARCHAR(255)
+) ;
+
+--------------------------------------------------------
+-- DDL for Table vitalsign
+--------------------------------------------------------
+
+DROP TABLE IF EXISTS mimiciv_ed.vitalsign CASCADE;
+CREATE TABLE mimiciv_ed.vitalsign
+(
+ subject_id INTEGER NOT NULL,
+ stay_id INTEGER NOT NULL,
+ charttime TIMESTAMP(0),
+ temperature NUMERIC,
+ heartrate NUMERIC,
+ resprate NUMERIC(10, 4),
+ o2sat NUMERIC,
+ sbp INTEGER,
+ dbp INTEGER,
+ rhythm TEXT,
+ pain TEXT
+);
\ No newline at end of file
diff --git a/pgmimic/_db/SQL/2.2/derived/demographics/age.sql b/pgmimic/_db/SQL/2.2/derived/demographics/age.sql
new file mode 100644
index 0000000..26fb466
--- /dev/null
+++ b/pgmimic/_db/SQL/2.2/derived/demographics/age.sql
@@ -0,0 +1,12 @@
+DROP TABLE IF EXISTS mimic_derived.age; CREATE TABLE mimic_derived.age AS
+SELECT
+ ad.subject_id
+ , ad.hadm_id
+ , ad.admittime
+ , pa.anchor_age
+ , pa.anchor_year
+ , pa.anchor_age + DATETIME_DIFF(ad.admittime, DATETIME(pa.anchor_year, 1, 1, 0, 0, 0), 'YEAR') AS age
+FROM mimic_hosp.admissions ad
+INNER JOIN mimic_hosp.patients pa
+ ON ad.subject_id = pa.subject_id
+;
\ No newline at end of file
diff --git a/pgmimic/_db/SQL/2.2/derived/measurement/height.sql b/pgmimic/_db/SQL/2.2/derived/measurement/height.sql
new file mode 100644
index 0000000..3420ea5
--- /dev/null
+++ b/pgmimic/_db/SQL/2.2/derived/measurement/height.sql
@@ -0,0 +1,42 @@
+DROP TABLE IF EXISTS height; CREATE TABLE height AS
+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
+)
+
+, 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
+FROM ht_stg0
+WHERE height IS NOT NULL
+ -- filter out bad heights
+ AND height > 120 AND height < 230;
\ No newline at end of file
diff --git a/pgmimic/_db/SQL/2.2/index.sql b/pgmimic/_db/SQL/2.2/index.sql
new file mode 100644
index 0000000..45433dd
--- /dev/null
+++ b/pgmimic/_db/SQL/2.2/index.sql
@@ -0,0 +1,185 @@
+SET search_path TO mimic_hosp;
+DROP INDEX IF EXISTS admissions_idx01;
+CREATE INDEX admissions_idx01
+ ON admissions (admittime, dischtime, deathtime);
+DROP INDEX IF EXISTS D_ICD_DIAG_idx02;
+CREATE INDEX D_ICD_DIAG_idx02
+ ON D_ICD_DIAGNOSES (LONG_TITLE);
+DROP INDEX IF EXISTS D_ICD_PROC_idx02;
+CREATE INDEX D_ICD_PROC_idx02
+ ON D_ICD_PROCEDURES (LONG_TITLE);
+DROP INDEX IF EXISTS drgcodes_idx01;
+CREATE INDEX drgcodes_idx01
+ ON drgcodes (drg_code, drg_type);
+DROP INDEX IF EXISTS drgcodes_idx02;
+CREATE INDEX drgcodes_idx02
+ ON drgcodes (description, drg_severity);
+DROP INDEX IF EXISTS d_labitems_idx01;
+CREATE INDEX d_labitems_idx01
+ ON d_labitems (label, fluid, category);
+DROP INDEX IF EXISTS emar_detail_idx01;
+CREATE INDEX emar_detail_idx01
+ ON emar_detail (pharmacy_id);
+DROP INDEX IF EXISTS emar_detail_idx02;
+CREATE INDEX emar_detail_idx02
+ ON emar_detail (product_code);
+DROP INDEX IF EXISTS emar_detail_idx03;
+CREATE INDEX emar_detail_idx03
+ ON emar_detail (route, site, side);
+DROP INDEX IF EXISTS EMAR_DET_idx04;
+CREATE INDEX EMAR_DET_idx04
+ ON EMAR_DETAIL (PRODUCT_DESCRIPTION);
+DROP INDEX IF EXISTS emar_idx01;
+CREATE INDEX emar_idx01
+ ON emar (poe_id);
+DROP INDEX IF EXISTS emar_idx02;
+CREATE INDEX emar_idx02
+ ON emar (pharmacy_id);
+DROP INDEX IF EXISTS emar_idx03;
+CREATE INDEX emar_idx03
+ ON emar (charttime, scheduletime, storetime);
+DROP INDEX IF EXISTS emar_idx04;
+CREATE INDEX emar_idx04
+ ON emar (medication);
+DROP INDEX IF EXISTS HCPCSEVENTS_idx04;
+CREATE INDEX HCPCSEVENTS_idx04
+ ON HCPCSEVENTS (SHORT_DESCRIPTION);
+DROP INDEX IF EXISTS labevents_idx01;
+CREATE INDEX labevents_idx01
+ ON labevents (charttime, storetime);
+DROP INDEX IF EXISTS labevents_idx02;
+CREATE INDEX labevents_idx02
+ ON labevents (specimen_id);
+DROP INDEX IF EXISTS microbiologyevents_idx01;
+CREATE INDEX microbiologyevents_idx01
+ ON microbiologyevents (chartdate, charttime, storedate, storetime);
+DROP INDEX IF EXISTS microbiologyevents_idx02;
+CREATE INDEX microbiologyevents_idx02
+ ON microbiologyevents (spec_itemid, test_itemid, org_itemid, ab_itemid);
+DROP INDEX IF EXISTS microbiologyevents_idx03;
+CREATE INDEX microbiologyevents_idx03
+ ON microbiologyevents (micro_specimen_id);
+DROP INDEX IF EXISTS patients_idx01;
+CREATE INDEX patients_idx01
+ ON patients (anchor_age);
+DROP INDEX IF EXISTS patients_idx02;
+CREATE INDEX patients_idx02
+ ON patients (anchor_year);
+DROP INDEX IF EXISTS pharmacy_idx01;
+CREATE INDEX pharmacy_idx01
+ ON pharmacy (poe_id);
+DROP INDEX IF EXISTS pharmacy_idx02;
+CREATE INDEX pharmacy_idx02
+ ON pharmacy (starttime, stoptime);
+DROP INDEX IF EXISTS pharmacy_idx03;
+CREATE INDEX pharmacy_idx03
+ ON pharmacy (medication);
+DROP INDEX IF EXISTS pharmacy_idx04;
+CREATE INDEX pharmacy_idx04
+ ON pharmacy (route);
+DROP INDEX IF EXISTS poe_idx01;
+CREATE INDEX poe_idx01
+ ON poe (order_type);
+DROP INDEX IF EXISTS prescriptions_idx01;
+CREATE INDEX prescriptions_idx01
+ ON prescriptions (starttime, stoptime);
+DROP INDEX IF EXISTS transfers_idx01;
+CREATE INDEX transfers_idx01
+ ON transfers (hadm_id);
+DROP INDEX IF EXISTS transfers_idx02;
+CREATE INDEX transfers_idx02
+ ON transfers (intime);
+DROP INDEX IF EXISTS transfers_idx03;
+CREATE INDEX transfers_idx03
+ ON transfers (careunit);
+SET search_path TO mimic_icu;
+DROP INDEX IF EXISTS chartevents_idx01;
+CREATE INDEX chartevents_idx01
+ ON chartevents (charttime, storetime);
+DROP INDEX IF EXISTS datetimeevents_idx01;
+CREATE INDEX datetimeevents_idx01
+ ON datetimeevents (charttime, storetime);
+DROP INDEX IF EXISTS datetimeevents_idx02;
+CREATE INDEX datetimeevents_idx02
+ ON datetimeevents (value);
+DROP INDEX IF EXISTS d_items_idx01;
+CREATE INDEX d_items_idx01
+ ON d_items (label, abbreviation);
+DROP INDEX IF EXISTS d_items_idx02;
+CREATE INDEX d_items_idx02
+ ON d_items (category);
+DROP INDEX IF EXISTS icustays_idx01;
+CREATE INDEX icustays_idx01
+ ON icustays (first_careunit, last_careunit);
+DROP INDEX IF EXISTS icustays_idx02;
+CREATE INDEX icustays_idx02
+ ON icustays (intime, outtime);
+DROP INDEX IF EXISTS inputevents_idx01;
+CREATE INDEX inputevents_idx01
+ ON inputevents (starttime, endtime);
+DROP INDEX IF EXISTS inputevents_idx02;
+CREATE INDEX inputevents_idx02
+ ON inputevents (ordercategorydescription);
+DROP INDEX IF EXISTS outputevents_idx01;
+CREATE INDEX outputevents_idx01
+ ON outputevents (charttime, storetime);
+DROP INDEX IF EXISTS procedureevents_idx01;
+CREATE INDEX procedureevents_idx01
+ ON procedureevents (starttime, endtime);
+DROP INDEX IF EXISTS procedureevents_idx02;
+CREATE INDEX procedureevents_idx02
+ ON procedureevents (ordercategoryname);
+
+/*
+ ED INDEX
+ */
+
+SET search_path TO mimiciv_ed;
+
+-- diagnosis
+
+DROP INDEX IF EXISTS diagnosis_idx01;
+CREATE INDEX diagnosis_idx01
+ ON diagnosis (subject_id, stay_id);
+
+DROP INDEX IF EXISTS diagnosis_idx02;
+CREATE INDEX diagnosis_idx02
+ ON diagnosis (icd_code, icd_version);
+
+-- edstays
+
+DROP INDEX IF EXISTS edstays_idx01;
+CREATE INDEX edstays_idx01
+ ON edstays (subject_id, hadm_id, stay_id);
+
+DROP INDEX IF EXISTS edstays_idx02;
+CREATE INDEX edstays_idx02
+ ON edstays (intime, outtime);
+
+-- medrecon
+
+DROP INDEX IF EXISTS medrecon_idx01;
+CREATE INDEX medrecon_idx01
+ ON medrecon (subject_id, stay_id, charttime);
+
+-- pyxis
+
+DROP INDEX IF EXISTS pyxis_idx01;
+CREATE INDEX pyxis_idx01
+ ON pyxis (subject_id, stay_id, charttime);
+
+DROP INDEX IF EXISTS pyxis_idx02;
+CREATE INDEX pyxis_idx02
+ ON pyxis (gsn);
+
+-- triage
+
+DROP INDEX IF EXISTS triage_idx01;
+CREATE INDEX triage_idx01
+ ON triage (subject_id, stay_id);
+
+-- vitalsign
+
+DROP INDEX IF EXISTS vitalsign_idx01;
+CREATE INDEX vitalsign_idx01
+ ON vitalsign (subject_id, stay_id, charttime);
\ No newline at end of file
diff --git a/pgmimic/_db/SQL/2.2/postgres-functions.sql b/pgmimic/_db/SQL/2.2/postgres-functions.sql
new file mode 100644
index 0000000..306aff3
--- /dev/null
+++ b/pgmimic/_db/SQL/2.2/postgres-functions.sql
@@ -0,0 +1,121 @@
+SET search_path TO mimic_derived, mimic_hosp, mimic_icu, mimic_ed;
+CREATE OR REPLACE FUNCTION REGEXP_EXTRACT(str TEXT, pattern TEXT) RETURNS TEXT AS $$
+BEGIN
+RETURN substring(str from pattern);
+END; $$
+LANGUAGE PLPGSQL;
+CREATE OR REPLACE FUNCTION REGEXP_CONTAINS(str TEXT, pattern TEXT) RETURNS BOOL AS $$
+BEGIN
+RETURN str ~ pattern;
+END; $$
+LANGUAGE PLPGSQL;
+CREATE OR REPLACE FUNCTION GENERATE_ARRAY(i INTEGER, j INTEGER)
+RETURNS setof INTEGER language sql as $$
+ SELECT GENERATE_SERIES(i, j)
+$$;
+CREATE OR REPLACE FUNCTION DATETIME(dt DATE) RETURNS TIMESTAMP(3) AS $$
+BEGIN
+RETURN CAST(dt AS TIMESTAMP(3));
+END; $$
+LANGUAGE PLPGSQL;
+CREATE OR REPLACE FUNCTION DATETIME(year INTEGER, month INTEGER, day INTEGER, hour INTEGER, minute INTEGER, second INTEGER) RETURNS TIMESTAMP(3) AS $$
+BEGIN
+RETURN TO_TIMESTAMP(
+ TO_CHAR(year, '0000') || TO_CHAR(month, '00') || TO_CHAR(day, '00') || TO_CHAR(hour, '00') || TO_CHAR(minute, '00') || TO_CHAR(second, '00'),
+ 'yyyymmddHH24MISS'
+);
+END; $$
+LANGUAGE PLPGSQL;
+CREATE OR REPLACE FUNCTION DATETIME_ADD(datetime_val TIMESTAMP(3), intvl INTERVAL) RETURNS TIMESTAMP(3) AS $$
+BEGIN
+RETURN datetime_val + intvl;
+END; $$
+LANGUAGE PLPGSQL;
+CREATE OR REPLACE FUNCTION DATE_ADD(dt DATE, intvl INTERVAL) RETURNS TIMESTAMP(3) AS $$
+BEGIN
+RETURN CAST(dt AS TIMESTAMP(3)) + intvl;
+END; $$
+LANGUAGE PLPGSQL;
+CREATE OR REPLACE FUNCTION DATETIME_SUB(datetime_val TIMESTAMP(3), intvl INTERVAL) RETURNS TIMESTAMP(3) AS $$
+BEGIN
+RETURN datetime_val - intvl;
+END; $$
+LANGUAGE PLPGSQL;
+CREATE OR REPLACE FUNCTION DATE_SUB(dt DATE, intvl INTERVAL) RETURNS TIMESTAMP(3) AS $$
+BEGIN
+RETURN CAST(dt AS TIMESTAMP(3)) - intvl;
+END; $$
+LANGUAGE PLPGSQL;
+CREATE OR REPLACE FUNCTION DATETIME_DIFF(endtime TIMESTAMP(3), starttime TIMESTAMP(3), datepart TEXT) RETURNS NUMERIC AS $$
+BEGIN
+RETURN
+ EXTRACT(EPOCH FROM endtime - starttime) /
+ CASE
+ WHEN datepart = 'SECOND' THEN 1.0
+ WHEN datepart = 'MINUTE' THEN 60.0
+ WHEN datepart = 'HOUR' THEN 3600.0
+ WHEN datepart = 'DAY' THEN 24*3600.0
+ WHEN datepart = 'YEAR' THEN 365.242*24*3600.0
+ ELSE NULL END;
+END; $$
+LANGUAGE PLPGSQL;
+CREATE OR REPLACE FUNCTION BIGQUERY_FORMAT_TO_PSQL(format_str VARCHAR(255)) RETURNS TEXT AS $$
+BEGIN
+RETURN
+ REPLACE(
+ REPLACE(
+ REPLACE(
+ REPLACE(
+ REPLACE(
+ REPLACE(
+ format_str
+ , '%S', 'SS'
+ )
+ , '%M', 'MI'
+ )
+ , '%H', 'HH24'
+ )
+ , '%d', 'dd'
+ )
+ , '%m', 'mm'
+ )
+ , '%Y', 'yyyy'
+ )
+;
+END; $$
+LANGUAGE PLPGSQL;
+CREATE OR REPLACE FUNCTION FORMAT_DATE(format_str VARCHAR(255), datetime_val TIMESTAMP(3)) RETURNS TEXT AS $$
+BEGIN
+RETURN TO_CHAR(
+ datetime_val,
+ BIGQUERY_FORMAT_TO_PSQL(format_str)
+);
+END; $$
+LANGUAGE PLPGSQL;
+
+
+CREATE OR REPLACE FUNCTION PARSE_DATE(format_str VARCHAR(255), string_val VARCHAR(255)) RETURNS DATE AS $$
+BEGIN
+RETURN TO_DATE(
+ string_val,
+ BIGQUERY_FORMAT_TO_PSQL(format_str)
+);
+END; $$
+LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION FORMAT_DATETIME(format_str VARCHAR(255), datetime_val TIMESTAMP(3)) RETURNS TEXT AS $$
+BEGIN
+RETURN TO_CHAR(
+ datetime_val,
+ BIGQUERY_FORMAT_TO_PSQL(format_str)
+);
+END; $$
+LANGUAGE PLPGSQL;
+CREATE OR REPLACE FUNCTION PARSE_DATETIME(format_str VARCHAR(255), string_val VARCHAR(255)) RETURNS TIMESTAMP(3) AS $$
+BEGIN
+RETURN TO_TIMESTAMP(
+ string_val,
+ BIGQUERY_FORMAT_TO_PSQL(format_str)
+);
+END; $$
+LANGUAGE PLPGSQL;
\ No newline at end of file
diff --git a/pgmimic/_db/__init__.py b/pgmimic/_db/__init__.py
new file mode 100644
index 0000000..e69de29
diff --git a/pgmimic/_db/_db_handler.py b/pgmimic/_db/_db_handler.py
new file mode 100644
index 0000000..2cf0ce8
--- /dev/null
+++ b/pgmimic/_db/_db_handler.py
@@ -0,0 +1,169 @@
+import psycopg2
+import subprocess
+
+
+class DataHandler:
+ def __init__(self, config):
+ self.config = config
+ self._connect()
+ return None
+
+ def _connect(self) -> None:
+ try:
+ self.conn = psycopg2.connect(
+ user=self.config["database"]["username"],
+ password=self.config["database"]["password"],
+ host=self.config["database"]["host"],
+ port=self.config["database"]["port"],
+ database=self.config["database"]["database"],
+ )
+ return self.conn
+ except ConnectionError as ce:
+ print(f"FATAL: Connection error. {repr(ce)}")
+
+ def _close(self) -> None:
+ self.conn.close()
+
+ def _check_data(self) -> bool:
+ # TODO - needs to change to check data in table,
+ # not just that fact that the table exists.
+ table_e_list = []
+ exists = False
+ db = self.config["database"]["database"]
+ curr = self.conn.cursor()
+ for schema in self.config["data"]["schemas"]:
+ for table in self.config["data"]["tables"][schema]:
+ sql = f"""
+ SELECT EXISTS(SELECT 1 FROM information_schema.tables
+ WHERE table_catalog='{db}' AND
+ table_schema='{schema}' AND
+ table_name='{table}');
+ """
+ curr.execute(sql)
+ result = curr.fetchone()
+ result = result[0]
+ if result is True:
+ table_e_list.append(True)
+ else:
+ table_e_list.append(False)
+ curr.close()
+ if all(table_e_list) is True:
+ exists = True
+ else:
+ exists = False
+
+ return exists
+
+ def _create_constraint(self):
+ curr = self.conn.cursor()
+ with open(f"_db/SQL/{self.config['data']['version']}/constraint.sql") as sql_file:
+ sql = sql_file.read()
+ for statement in sql.split(";"):
+ curr = self.conn.cursor()
+ if len(statement) < 1:
+ pass
+ else:
+ try:
+ curr.execute(statement)
+ self.conn.commit()
+ except Exception as e:
+ print(f"FATAL: Error creating tables. {repr(e)}")
+ try:
+ self.conn.commit()
+ except Exception as e:
+ self.conn.rollback()
+ print(f"FATAL: Error creating tables. {repr(e)}")
+ curr.close()
+ return None
+
+ def _create_index(self):
+ curr = self.conn.cursor()
+ with open(f"_db/SQL/{self.config['data']['version']}/index.sql") as sql_file:
+ sql = sql_file.read()
+ for statement in sql.split(";"):
+ curr = self.conn.cursor()
+ if len(statement) < 1:
+ pass
+ else:
+ try:
+ curr.execute(statement)
+ self.conn.commit()
+ except Exception as e:
+ print(f"FATAL: Error creating tables. {repr(e)}")
+ try:
+ self.conn.commit()
+ except Exception as e:
+ self.conn.rollback()
+ print(f"FATAL: Error creating tables. {repr(e)}")
+ curr.close()
+ return None
+
+ def _create_tables(self):
+ curr = self.conn.cursor()
+ with open(f"_db/SQL/{self.config['data']['version']}/create.sql") as sql_file:
+ sql = sql_file.read()
+ for statement in sql.split(";"):
+ curr = self.conn.cursor()
+ if len(statement) < 1:
+ pass
+ else:
+ try:
+ curr.execute(statement)
+ self.conn.commit()
+ except Exception as e:
+ print(f"FATAL: Error creating tables. {repr(e)}")
+ try:
+ self.conn.commit()
+ except Exception as e:
+ self.conn.rollback()
+ print(f"FATAL: Error creating tables. {repr(e)}")
+ curr.close()
+ return None
+
+ def _create_postgres_functions(self):
+ file_path = f"{self.config['data']['version']}/postgres-functions.sql"
+ psql_template = 'psql "postgresql://{}:{}@{}:{}/{}" --command "{}"'
+ command = f"\i _db/SQL/{file_path}"
+ bash_command = psql_template.format(
+ self.config["database"]["username"],
+ self.config["database"]["password"],
+ self.config["database"]["host"],
+ self.config["database"]["port"],
+ self.config["database"]["database"],
+ command.strip()
+ )
+ print(bash_command)
+ process = subprocess.Popen(
+ bash_command, stdout=subprocess.PIPE, shell=True
+ )
+ output, error = process.communicate()
+ print(output)
+ return None
+
+ def _write_mimic_data(self, files: list = None) -> None:
+ # TODO - need to progress here
+ psql_template = 'psql "postgresql://{}:{}@{}:{}/{}" --command "{}"'
+ for schema in self.config["data"]["schemas"]:
+ if schema == "mimic_derived":
+ pass
+ else:
+ for table in self.config["data"]["tables"][schema]:
+ file_path = [s for s in files if table in s][0]
+ command = f"\copy {schema}.{table} FROM PROGRAM 'gzip -dc \
+ {file_path} ' DELIMITER ',' CSV HEADER NULL ''"
+ bash_command = psql_template.format(
+ self.config["database"]["username"],
+ self.config["database"]["password"],
+ self.config["database"]["host"],
+ self.config["database"]["port"],
+ self.config["database"]["database"],
+ command.strip(),
+ )
+ print(bash_command)
+ process = subprocess.Popen(
+ bash_command, stdout=subprocess.PIPE, shell=True
+ )
+ output, error = process.communicate()
+ print(output)
+
+ return None
diff --git a/pgmimic/_files/__init__.py b/pgmimic/_files/__init__.py
new file mode 100644
index 0000000..e69de29
diff --git a/pgmimic/_files/_file_handler.py b/pgmimic/_files/_file_handler.py
new file mode 100644
index 0000000..e1072d8
--- /dev/null
+++ b/pgmimic/_files/_file_handler.py
@@ -0,0 +1,31 @@
+import glob
+
+
+class FileHandler:
+ def __init__(self) -> None:
+ return None
+
+ def path(self, path: str = None) -> None:
+ """
+ Set the file path for data
+ Args:
+ path (str): System path for file location
+ """
+ self.path = path
+ if self._exists(self.path) is False:
+ raise FileNotFoundError
+ return None
+
+ def _exists(self, path) -> bool:
+ """
+ Check if the data is stored in the provided path
+ """
+ files = glob.glob(path + "/**/*.csv.gz", recursive=True)
+ if len(files) > 0:
+ return True
+ else:
+ return False
+
+ def files(self) -> list:
+ files = glob.glob(self.path + "/**/*.csv.gz", recursive=True)
+ return files
diff --git a/pgmimic/_omop/__init__.py b/pgmimic/_omop/__init__.py
new file mode 100644
index 0000000..e69de29
diff --git a/pgmimic/importer/__init__.py b/pgmimic/importer/__init__.py
new file mode 100644
index 0000000..e69de29
diff --git a/pgmimic/importer/mimic_importer.py b/pgmimic/importer/mimic_importer.py
new file mode 100644
index 0000000..ce9039d
--- /dev/null
+++ b/pgmimic/importer/mimic_importer.py
@@ -0,0 +1,65 @@
+from _config._config_handler import ConfigHandler
+from _files._file_handler import FileHandler
+from _db._db_handler import DataHandler
+
+
+class MimicImporter:
+ def __init__(self, config) -> None:
+ # set config
+ try:
+ self._config_handler = ConfigHandler(config)
+ self.config = self._config_handler.get_config()
+ except Exception as e:
+ print(repr(e))
+ return None
+
+ def connect(self) -> None:
+ # Expects that config is loaded
+ """
+ Connect to PostgreSQL server per config
+ """
+ self._db_handler = DataHandler(self.config)
+ return None
+
+ def import_mimic(self) -> None:
+ # Expects that config is loaded, connection established
+ # check if data already loaded
+ if self._db_handler._check_data():
+ print("Data already imported...")
+ pass
+ else:
+ # create tables
+ print("Creating tables...\n")
+ self._db_handler._create_tables()
+ print("Tables created...\n")
+ # check data is available in path
+ self._file_handler = FileHandler()
+ try:
+ self.file_path = self._file_handler.path(
+ f"{self.config['data']['location']}/{self.config['data']['version']}"
+ )
+ except Exception as e:
+ print(
+ f"FATAL: Error finding files in path. Error Message: {repr(e)}"
+ )
+ files = self._file_handler.files()
+ # import data
+ self._db_handler._write_mimic_data(files)
+ # create constraints
+ print("Creating constraints...")
+ self._db_handler._create_constraint()
+ # create index
+ print("Creating indexes...")
+ self._db_handler._create_index()
+ print("Creating Postgres functions...")
+ self._db_handler._create_postgres_functions()
+ print("MIMIC import completed")
+ return None
+
+ def close(self) -> None:
+ """
+ Close MIMIC Importer created connections
+ """
+ # close database connection
+ self._db_handler._close()
+ return None
diff --git a/pgmimic/main.py b/pgmimic/main.py
new file mode 100644
index 0000000..49485ee
--- /dev/null
+++ b/pgmimic/main.py
@@ -0,0 +1,14 @@
+from importer.mimic_importer import MimicImporter
+
+
+def main():
+ mimic_importer = MimicImporter("config.json")
+ # Config will have db and file location config
+ mimic_importer.connect()
+ mimic_importer.import_mimic()
+ mimic_importer.close()
+ return None
+
+
+if __name__ == "__main__":
+ main()
diff --git a/pgmimic/notes.md b/pgmimic/notes.md
new file mode 100644
index 0000000..7ad56c9
--- /dev/null
+++ b/pgmimic/notes.md
@@ -0,0 +1,10 @@
+Pseudo
+----
+1. Check if data exists, if they do stop else
+ * COUNT(ID) FROM TABLE, for all tables
+2. Check zip files/data available
+3. Create tables (will drop if it exists)
+4. Import data
+5. Create indexes
+
+
diff --git a/requirements.txt b/requirements.txt
new file mode 100644
index 0000000..b966fa1
--- /dev/null
+++ b/requirements.txt
@@ -0,0 +1,11 @@
+black==22.6.0
+click==8.1.3
+flake8==4.0.1
+mccabe==0.6.1
+mypy-extensions==0.4.3
+pathspec==0.9.0
+platformdirs==2.5.2
+psycopg2==2.9.3
+pycodestyle==2.8.0
+pyflakes==2.4.0
+tomli==2.0.1