Skip to content

Commit

Permalink
Addresses cdm proposal #85
Browse files Browse the repository at this point in the history
  • Loading branch information
clairblacketer committed Jul 14, 2017
1 parent 9a93623 commit f9ab885
Show file tree
Hide file tree
Showing 13 changed files with 194 additions and 4 deletions.
24 changes: 23 additions & 1 deletion Impala/OMOP_CDM_ddl_Impala.sql
Original file line number Diff line number Diff line change
Expand Up @@ -462,15 +462,37 @@ CREATE TABLE note (
note_date VARCHAR(8), -- DATE
note_time VARCHAR(10),
note_type_concept_id INTEGER,
note_class_concept_id INTEGER,
note_title VARCHAR(250),
note_text STRING, -- TEXT
encoding_concept_id INTEGER,
language_concept_id INTEGER,
provider_id INTEGER,
visit_occurrence_id INTEGER,
note_source_value VARCHAR(50)
)
;



CREATE TABLE note_nlp (
note_nlp_id BIGINT,
note_id INTEGER,
section_concept_id INTEGER,
snippet VARCHAR(250),
offset VARCHAR(250),
lexical_variant VARCHAR(250),
note_nlp_concept_id INTEGER,
note_nlp_source_concept_id INTEGER,
nlp_system VARCHAR(250),
nlp_date VARCHAR(8),
nlp_time VARCHAR(10),
term_exists VARCHAR(1),
term_temporal VARCHAR(50),
term_modifiers VARCHAR(2000)
)
;


CREATE TABLE observation (
observation_id INTEGER,
person_id INTEGER,
Expand Down
28 changes: 28 additions & 0 deletions Impala/OMOP_Parquet_v5.2.sql
Original file line number Diff line number Diff line change
Expand Up @@ -342,12 +342,40 @@ SELECT
TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(note_date AS STRING), 1, 4), SUBSTR(CAST(note_date AS STRING), 5, 2), SUBSTR(CAST(note_date AS STRING), 7, 2)), 'UTC') AS note_date,
TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(note_date AS STRING), 1, 4), SUBSTR(CAST(note_date AS STRING), 5, 2), SUBSTR(CAST(note_date AS STRING), 7, 2)), 'UTC') AS note_datetime,
note_type_concept_id,
note_class_concept_id,
note_title,
note_text, -- TEXT
encoding_concept_id,
language_concept_id,
provider_id,
visit_occurrence_id,
note_source_value
FROM omop_cdm.note;

CREATE TABLE omop_cdm_parquet.note_nlp
STORED AS PARQUET
AS
SELECT
note_nlp_id,
note_id,
section_concept_id,
snippet,
offset,
lexical_variant,
note_nlp_concept_id,
note_nlp_source_concept_id,
nlp_system,
TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(nlp_date AS STRING), 1, 4), SUBSTR(CAST(nlp_date AS STRING), 5, 2), SUBSTR(CAST(nlp_date AS STRING), 7, 2)), 'UTC') AS nlp_date,
TO_UTC_TIMESTAMP(CONCAT_WS('-', SUBSTR(CAST(nlp_date AS STRING), 1, 4), SUBSTR(CAST(nlp_date AS STRING), 5, 2), SUBSTR(CAST(nlp_date AS STRING), 7, 2)), 'UTC') AS nlp_datetime,
term_exists,
term_temporal,
term_modifiers
FROM omop_cdm.note_nlp;





CREATE TABLE omop_cdm_parquet.observation
STORED AS PARQUET
AS
Expand Down
15 changes: 15 additions & 0 deletions Oracle/OMOP CDM constraints - Oracle.sql
Original file line number Diff line number Diff line change
Expand Up @@ -126,6 +126,8 @@ ALTER TABLE measurement ADD CONSTRAINT xpk_measurement PRIMARY KEY ( measurement

ALTER TABLE note ADD CONSTRAINT xpk_note PRIMARY KEY ( note_id ) ;

ALTER TABLE note_nlp ADD CONSTRAINT xpk_note_nlp PRIMARY KEY ( note_nlp_id ) ;

ALTER TABLE observation ADD CONSTRAINT xpk_observation PRIMARY KEY ( observation_id ) ;


Expand Down Expand Up @@ -411,11 +413,24 @@ ALTER TABLE note ADD CONSTRAINT fpk_note_person FOREIGN KEY (person_id) REFEREN

ALTER TABLE note ADD CONSTRAINT fpk_note_type_concept FOREIGN KEY (note_type_concept_id) REFERENCES concept (concept_id);

ALTER TABLE note ADD CONSTRAINT fpk_note_class_concept FOREIGN KEY (note_class_concept_id) REFERENCES concept (concept_id);

ALTER TABLE note ADD CONSTRAINT fpk_note_encoding_concept FOREIGN KEY (encoding_concept_id) REFERENCES concept (concept_id);

ALTER TABLE note ADD CONSTRAINT fpk_language_concept FOREIGN KEY (language_concept_id) REFERENCES concept (concept_id);

ALTER TABLE note ADD CONSTRAINT fpk_note_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id);

ALTER TABLE note ADD CONSTRAINT fpk_note_visit FOREIGN KEY (visit_occurrence_id) REFERENCES visit_occurrence (visit_occurrence_id);


ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_note FOREIGN KEY (note_id) REFERENCES note (note_id);

ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_section_concept FOREIGN KEY (section_concept_id) REFERENCES concept (concept_id);

ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_concept FOREIGN KEY (note_nlp_concept_id) REFERENCES concept (concept_id);


ALTER TABLE observation ADD CONSTRAINT fpk_observation_person FOREIGN KEY (person_id) REFERENCES person (person_id);

ALTER TABLE observation ADD CONSTRAINT fpk_observation_concept FOREIGN KEY (observation_concept_id) REFERENCES concept (concept_id);
Expand Down
23 changes: 23 additions & 0 deletions Oracle/OMOP CDM ddl - Oracle.sql
Original file line number Diff line number Diff line change
Expand Up @@ -445,14 +445,37 @@ CREATE TABLE note
note_date DATE NOT NULL ,
note_datetime TIMESTAMP WITH TIME ZONE NULL ,
note_type_concept_id INTEGER NOT NULL ,
note_class_concept_id INTEGER NOT NULL ,
note_title VARCHAR(250) NULL ,
note_text CLOB NOT NULL ,
encoding_concept_id INTEGER NOT NULL ,
language_concept_id INTEGER NOT NULL ,
provider_id INTEGER NULL ,
visit_occurrence_id INTEGER NULL ,
note_source_value VARCHAR(50) NULL
)
;


/*This table is new in CDM v5.2*/
CREATE TABLE note_nlp
(
note_nlp_id NUMBER(19) NOT NULL ,
note_id INTEGER NOT NULL ,
section_concept_id INTEGER NULL ,
snippet VARCHAR(250) NULL ,
offset VARCHAR(250) NULL ,
lexical_variant VARCHAR(250) NOT NULL ,
note_nlp_concept_id INTEGER NULL ,
note_nlp_source_concept_id INTEGER NULL ,
nlp_system VARCHAR(250) NULL ,
nlp_date DATE NOT NULL ,
nlp_datetime TIMESTAMP WITH TIME ZONE NULL ,
term_exists VARCHAR(1) NULL ,
term_temporal VARCHAR(50) NULL ,
term_modifiers VARCHAR(2000) NULL
)
;

CREATE TABLE observation
(
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -113,6 +113,10 @@ CREATE INDEX idx_note_person_id ON note (person_id ASC);
CREATE INDEX idx_note_concept_id ON note (note_type_concept_id ASC);
CREATE INDEX idx_note_visit_id ON note (visit_occurrence_id ASC);

CREATE INDEX idx_note_nlp_person_id ON note_nlp (person_id ASC);
CREATE INDEX idx_note_nlp_note_id ON note_nlp (note_id ASC);
CREATE INDEX idx_note_nlp_concept_id ON note_nlp (note_nlp_concept_id ASC);

CREATE INDEX idx_observation_person_id ON observation (person_id ASC);
CREATE INDEX idx_observation_concept_id ON observation (observation_concept_id ASC);
CREATE INDEX idx_observation_visit_id ON observation (visit_occurrence_id ASC);
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -132,6 +132,10 @@ CREATE INDEX idx_note_person_id ON note (person_id ASC);
CREATE INDEX idx_note_concept_id ON note (note_type_concept_id ASC);
CREATE INDEX idx_note_visit_id ON note (visit_occurrence_id ASC);

CREATE INDEX idx_note_nlp_person_id ON note_nlp (person_id ASC);
CREATE INDEX idx_note_nlp_note_id ON note_nlp (note_id ASC);
CREATE INDEX idx_note_nlp_concept_id ON note_nlp (note_nlp_concept_id ASC);

CREATE INDEX idx_observation_person_id ON observation (person_id ASC);
CREATE INDEX idx_observation_concept_id ON observation (observation_concept_id ASC);
CREATE INDEX idx_observation_visit_id ON observation (visit_occurrence_id ASC);
Expand Down
15 changes: 15 additions & 0 deletions PostgreSQL/OMOP CDM constraints - PostgreSQL.sql
Original file line number Diff line number Diff line change
Expand Up @@ -126,6 +126,8 @@ ALTER TABLE measurement ADD CONSTRAINT xpk_measurement PRIMARY KEY ( measurement

ALTER TABLE note ADD CONSTRAINT xpk_note PRIMARY KEY ( note_id ) ;

ALTER TABLE note_nlp ADD CONSTRAINT xpk_note_nlp PRIMARY KEY NONCLUSTERED ( note_nlp_id ) ;

ALTER TABLE observation ADD CONSTRAINT xpk_observation PRIMARY KEY ( observation_id ) ;


Expand Down Expand Up @@ -410,11 +412,24 @@ ALTER TABLE note ADD CONSTRAINT fpk_note_person FOREIGN KEY (person_id) REFEREN

ALTER TABLE note ADD CONSTRAINT fpk_note_type_concept FOREIGN KEY (note_type_concept_id) REFERENCES concept (concept_id);

ALTER TABLE note ADD CONSTRAINT fpk_note_class_concept FOREIGN KEY (note_class_concept_id) REFERENCES concept (concept_id);

ALTER TABLE note ADD CONSTRAINT fpk_note_encoding_concept FOREIGN KEY (encoding_concept_id) REFERENCES concept (concept_id);

ALTER TABLE note ADD CONSTRAINT fpk_language_concept FOREIGN KEY (language_concept_id) REFERENCES concept (concept_id);

ALTER TABLE note ADD CONSTRAINT fpk_note_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id);

ALTER TABLE note ADD CONSTRAINT fpk_note_visit FOREIGN KEY (visit_occurrence_id) REFERENCES visit_occurrence (visit_occurrence_id);


ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_note FOREIGN KEY (note_id) REFERENCES note (note_id);

ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_section_concept FOREIGN KEY (section_concept_id) REFERENCES concept (concept_id);

ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_concept FOREIGN KEY (note_nlp_concept_id) REFERENCES concept (concept_id);


ALTER TABLE observation ADD CONSTRAINT fpk_observation_person FOREIGN KEY (person_id) REFERENCES person (person_id);

ALTER TABLE observation ADD CONSTRAINT fpk_observation_concept FOREIGN KEY (observation_concept_id) REFERENCES concept (concept_id);
Expand Down
27 changes: 26 additions & 1 deletion PostgreSQL/OMOP CDM ddl - PostgreSQL.sql
Original file line number Diff line number Diff line change
Expand Up @@ -445,7 +445,11 @@ CREATE TABLE note
note_date DATE NOT NULL ,
note_datetime TIMESTAMP NULL ,
note_type_concept_id INTEGER NOT NULL ,
note_text TEXT NOT NULL ,
note_class_concept_id INTEGER NOT NULL ,
note_title VARCHAR(250) NULL ,
note_text TEXT NOT NULL ,
encoding_concept_id INTEGER NOT NULL ,
language_concept_id INTEGER NOT NULL ,
provider_id INTEGER NULL ,
visit_occurrence_id INTEGER NULL ,
note_source_value VARCHAR(50) NULL
Expand All @@ -454,6 +458,27 @@ CREATE TABLE note



/*This table is new in CDM v5.2*/
CREATE TABLE note_nlp
(
note_nlp_id BIGINT NOT NULL ,
note_id INTEGER NOT NULL ,
section_concept_id INTEGER NULL ,
snippet VARCHAR(250) NULL ,
offset VARCHAR(250) NULL ,
lexical_variant VARCHAR(250) NOT NULL ,
note_nlp_concept_id INTEGER NULL ,
note_nlp_source_concept_id INTEGER NULL ,
nlp_system VARCHAR(250) NULL ,
nlp_date DATE NOT NULL ,
nlp_datetime TIMESTAMP NULL ,
term_exists VARCHAR(1) NULL ,
term_temporal VARCHAR(50) NULL ,
term_modifiers VARCHAR(2000) NULL
)
;


CREATE TABLE observation
(
observation_id INTEGER NOT NULL ,
Expand Down
5 changes: 5 additions & 0 deletions PostgreSQL/OMOP CDM indexes required - PostgreSQL.sql
Original file line number Diff line number Diff line change
Expand Up @@ -153,6 +153,11 @@ CLUSTER note USING idx_note_person_id ;
CREATE INDEX idx_note_concept_id ON note (note_type_concept_id ASC);
CREATE INDEX idx_note_visit_id ON note (visit_occurrence_id ASC);

CREATE INDEX idx_note_nlp_person_id ON note_nlp (person_id ASC);
CLUSTER note_nlp USING idx_note_nlp_person_id ;
CREATE INDEX idx_note_nlp_note_id ON note_nlp (note_id ASC);
CREATE INDEX idx_note_nlp_concept_id ON note_nlp (note_nlp_concept_id ASC);

CREATE INDEX idx_observation_person_id ON observation (person_id ASC);
CLUSTER observation USING idx_observation_person_id ;
CREATE INDEX idx_observation_concept_id ON observation (observation_concept_id ASC);
Expand Down
7 changes: 6 additions & 1 deletion README.md
Original file line number Diff line number Diff line change
Expand Up @@ -22,8 +22,13 @@ This version is based on the CDM working group proposals:
* [#69](https://github.com/OHDSI/CommonDataModel/issues/69) Adds the following fields to COST:
* DRG_CONCEPT_ID
* DRG_SOURCE_VALUE
* [#85](https://github.com/OHDSI/CommonDataModel/issues/85) Adds the NOTE_NLP table and the following fields to NOTE:
* NOTE_CLASS_CONCEPT_ID
* NOTE_TITLE
* ENCODING_CONCEPT_ID
* LANGUAGE_CONCEPT_ID

and is **backwards compatibile with v5.0.1**. The proposed and accepted changes include adding a datetime field to every table that had a date column and adding field DENOMINATOR_VALUE to the DRUG_STRENGTH table. These were the new columns added:
This version is **backwards compatibile with v5.0.1**.


---------
Expand Down
16 changes: 16 additions & 0 deletions Sql Server/OMOP CDM constraints - SQL Server.sql
Original file line number Diff line number Diff line change
Expand Up @@ -126,6 +126,8 @@ ALTER TABLE measurement ADD CONSTRAINT xpk_measurement PRIMARY KEY NONCLUSTERED

ALTER TABLE note ADD CONSTRAINT xpk_note PRIMARY KEY NONCLUSTERED ( note_id ) ;

ALTER TABLE note_nlp ADD CONSTRAINT xpk_note_nlp PRIMARY KEY NONCLUSTERED ( note_nlp_id ) ;

ALTER TABLE observation ADD CONSTRAINT xpk_observation PRIMARY KEY NONCLUSTERED ( observation_id ) ;


Expand Down Expand Up @@ -410,11 +412,25 @@ ALTER TABLE note ADD CONSTRAINT fpk_note_person FOREIGN KEY (person_id) REFEREN

ALTER TABLE note ADD CONSTRAINT fpk_note_type_concept FOREIGN KEY (note_type_concept_id) REFERENCES concept (concept_id);

ALTER TABLE note ADD CONSTRAINT fpk_note_class_concept FOREIGN KEY (note_class_concept_id) REFERENCES concept (concept_id);

ALTER TABLE note ADD CONSTRAINT fpk_note_encoding_concept FOREIGN KEY (encoding_concept_id) REFERENCES concept (concept_id);

ALTER TABLE note ADD CONSTRAINT fpk_language_concept FOREIGN KEY (language_concept_id) REFERENCES concept (concept_id);

ALTER TABLE note ADD CONSTRAINT fpk_note_provider FOREIGN KEY (provider_id) REFERENCES provider (provider_id);

ALTER TABLE note ADD CONSTRAINT fpk_note_visit FOREIGN KEY (visit_occurrence_id) REFERENCES visit_occurrence (visit_occurrence_id);


ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_note FOREIGN KEY (note_id) REFERENCES note (note_id);

ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_section_concept FOREIGN KEY (section_concept_id) REFERENCES concept (concept_id);

ALTER TABLE note_nlp ADD CONSTRAINT fpk_note_nlp_concept FOREIGN KEY (note_nlp_concept_id) REFERENCES concept (concept_id);



ALTER TABLE observation ADD CONSTRAINT fpk_observation_person FOREIGN KEY (person_id) REFERENCES person (person_id);

ALTER TABLE observation ADD CONSTRAINT fpk_observation_concept FOREIGN KEY (observation_concept_id) REFERENCES concept (concept_id);
Expand Down
26 changes: 25 additions & 1 deletion Sql Server/OMOP CDM ddl - SQL Server.sql
Original file line number Diff line number Diff line change
Expand Up @@ -445,14 +445,38 @@ CREATE TABLE note
note_date DATE NOT NULL ,
note_datetime DATETIME2 NULL ,
note_type_concept_id INTEGER NOT NULL ,
note_text VARCHAR(MAX) NOT NULL ,
note_class_concept_id INTEGER NOT NULL ,
note_title VARCHAR(250) NULL ,
note_text VARCHAR(MAX) NULL ,
encoding_concept_id INTEGER NOT NULL ,
language_concept_id INTEGER NOT NULL ,
provider_id INTEGER NULL ,
visit_occurrence_id INTEGER NULL ,
note_source_value VARCHAR(50) NULL
)
;


/*This table is new in CDM v5.2*/
CREATE TABLE note_nlp
(
note_nlp_id BIGINT NOT NULL ,
note_id INTEGER NOT NULL ,
section_concept_id INTEGER NULL ,
snippet VARCHAR(250) NULL ,
offset VARCHAR(250) NULL ,
lexical_variant VARCHAR(250) NOT NULL ,
note_nlp_concept_id INTEGER NULL ,
note_nlp_source_concept_id INTEGER NULL ,
nlp_system VARCHAR(250) NULL ,
nlp_date DATE NOT NULL ,
nlp_datetime DATETIME2 NULL ,
term_exists VARCHAR(1) NULL ,
term_temporal VARCHAR(50) NULL ,
term_modifiers VARCHAR(2000) NULL
)
;


CREATE TABLE observation
(
Expand Down
4 changes: 4 additions & 0 deletions Sql Server/OMOP CDM indexes required - SQL Server.sql
Original file line number Diff line number Diff line change
Expand Up @@ -131,6 +131,10 @@ CREATE CLUSTERED INDEX idx_note_person_id ON note (person_id ASC);
CREATE INDEX idx_note_concept_id ON note (note_type_concept_id ASC);
CREATE INDEX idx_note_visit_id ON note (visit_occurrence_id ASC);

CREATE CLUSTERED INDEX idx_note_nlp_person_id ON note_nlp (person_id ASC);
CREATE INDEX idx_note_nlp_note_id ON note_nlp (note_id ASC);
CREATE INDEX idx_note_nlp_concept_id ON note_nlp (note_nlp_concept_id ASC);

CREATE CLUSTERED INDEX idx_observation_person_id ON observation (person_id ASC);
CREATE INDEX idx_observation_concept_id ON observation (observation_concept_id ASC);
CREATE INDEX idx_observation_visit_id ON observation (visit_occurrence_id ASC);
Expand Down

0 comments on commit f9ab885

Please sign in to comment.