Merge pull request #10 from leeevans/other-dbms-ddl-control-files
V4 control files and DDL
This commit is contained in:
commit
d23321a00b
|
@ -0,0 +1,51 @@
|
||||||
|
/*********************************************************************************
|
||||||
|
# Copyright 2015 Observational Health Data Sciences and Informatics
|
||||||
|
#
|
||||||
|
#
|
||||||
|
# Licensed under the Apache License, Version 2.0 (the "License");
|
||||||
|
# you may not use this file except in compliance with the License.
|
||||||
|
# You may obtain a copy of the License at
|
||||||
|
#
|
||||||
|
# http://www.apache.org/licenses/LICENSE-2.0
|
||||||
|
#
|
||||||
|
# Unless required by applicable law or agreed to in writing, software
|
||||||
|
# distributed under the License is distributed on an "AS IS" BASIS,
|
||||||
|
# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
|
||||||
|
# See the License for the specific language governing permissions and
|
||||||
|
# limitations under the License.4
|
||||||
|
********************************************************************************/
|
||||||
|
|
||||||
|
/************************
|
||||||
|
|
||||||
|
####### # # ####### ###### ##### ###### # # ## #######
|
||||||
|
# # ## ## # # # # # # # # ## ## # # # # #
|
||||||
|
# # # # # # # # # # # # # # # # # # # # # #
|
||||||
|
# # # # # # # ###### # # # # # # # # ####### #######
|
||||||
|
# # # # # # # # # # # # # # # #
|
||||||
|
# # # # # # # # # # # # # # # # # #
|
||||||
|
####### # # ####### # ##### ###### # # ## # # #####
|
||||||
|
|
||||||
|
|
||||||
|
script to load the Vocabulary related tables in the OMOP common data model, version 4.5 for Oracle database
|
||||||
|
|
||||||
|
last revised: 19 Mar 2015
|
||||||
|
|
||||||
|
author: Lee Evans
|
||||||
|
|
||||||
|
Notes
|
||||||
|
|
||||||
|
1) This script assumes the CDM version 4.5 vocabulary zip file has been unzipped into the "C:\CDM" directory.
|
||||||
|
2) If you unzipped your CDM version 4.5 vocabulary files into a different directory then replace all file paths below, with your directory path.
|
||||||
|
3) If you have existing data in your CDM vocabulary tables then backup that data (if needed) and truncate those tables before loading
|
||||||
|
|
||||||
|
|
||||||
|
*************************/
|
||||||
|
|
||||||
|
sqlldr CDM/<password> CONTROL=CONCEPT.ctl LOG=C:\CDM\CONCEPT.log BAD=C:\CDM\CONCEPT.bad
|
||||||
|
sqlldr CDM/<password> CONTROL=CONCEPT_ANCESTOR.ctl LOG=C:\CDM\CONCEPT_ANCESTOR.log BAD=C:\CDM\CONCEPT_ANCESTOR.bad
|
||||||
|
sqlldr CDM/<password> CONTROL=CONCEPT_RELATIONSHIP.ctl LOG=C:\CDM\CONCEPT_RELATIONSHIP.log BAD=C:\CDM\CONCEPT_RELATIONSHIP.bad
|
||||||
|
sqlldr CDM/<password> CONTROL=CONCEPT_SYNONYM.ctl LOG=C:\CDM\CONCEPT_SYNONYM.log BAD=C:\CDM\CONCEPT_SYNONYM.bad
|
||||||
|
sqlldr CDM/<password> CONTROL=DRUG_STRENGTH.ctl LOG=C:\CDM\DRUG_STRENGTH.log BAD=C:\CDM\DRUG_STRENGTH.bad
|
||||||
|
sqlldr CDM/<password> CONTROL=RELATIONSHIP.ctl LOG=C:\CDM\RELATIONSHIP.log BAD=C:\CDM\RELATIONSHIP.bad
|
||||||
|
sqlldr CDM/<password> CONTROL=VOCABULARY.ctl LOG=C:\CDM\VOCABULARY.log BAD=C:\CDM\VOCABULARY.bad
|
||||||
|
sqlldr CDM/<password> CONTROL=SOURCE_TO_CONCEPT_MAP.ctl LOG=C:\CDM\SOURCE_TO_CONCEPT_MAP.log BAD=C:\CDM\SOURCE_TO_CONCEPT_MAP.bad
|
|
@ -0,0 +1,18 @@
|
||||||
|
options (skip=1)
|
||||||
|
load data
|
||||||
|
infile concept.csv
|
||||||
|
into table concept
|
||||||
|
replace
|
||||||
|
fields terminated by '\t'
|
||||||
|
trailing nullcols
|
||||||
|
(
|
||||||
|
concept_id,
|
||||||
|
concept_name CHAR(256),
|
||||||
|
concept_level,
|
||||||
|
concept_class,
|
||||||
|
vocabulary_id,
|
||||||
|
concept_code,
|
||||||
|
valid_start_date DATE 'YYYYMMDD',
|
||||||
|
valid_end_date DATE 'YYYYMMDD',
|
||||||
|
invalid_reason
|
||||||
|
)
|
|
@ -0,0 +1,13 @@
|
||||||
|
options (skip=1)
|
||||||
|
load data
|
||||||
|
infile concept_ancestor.csv
|
||||||
|
into table concept_ancestor
|
||||||
|
replace
|
||||||
|
fields terminated by '\t'
|
||||||
|
trailing nullcols
|
||||||
|
(
|
||||||
|
ancestor_concept_id,
|
||||||
|
descendant_concept_id,
|
||||||
|
min_levels_of_separation,
|
||||||
|
max_levels_of_separation
|
||||||
|
)
|
|
@ -0,0 +1,15 @@
|
||||||
|
options (skip=1)
|
||||||
|
load data
|
||||||
|
infile concept_relationship.csv
|
||||||
|
into table concept_relationship
|
||||||
|
replace
|
||||||
|
fields terminated by '\t'
|
||||||
|
trailing nullcols
|
||||||
|
(
|
||||||
|
concept_id_1,
|
||||||
|
concept_id_2,
|
||||||
|
relationship_id,
|
||||||
|
valid_start_date DATE 'YYYYMMDD',
|
||||||
|
valid_end_date DATE 'YYYYMMDD',
|
||||||
|
invalid_reason
|
||||||
|
)
|
|
@ -0,0 +1,12 @@
|
||||||
|
options (skip=1)
|
||||||
|
load data
|
||||||
|
infile concept_synonym.csv
|
||||||
|
into table concept_synonym
|
||||||
|
replace
|
||||||
|
fields terminated by '\t'
|
||||||
|
trailing nullcols
|
||||||
|
(
|
||||||
|
concept_synonym_id,
|
||||||
|
concept_id,
|
||||||
|
concept_synonym_name CHAR(1000)
|
||||||
|
)
|
|
@ -0,0 +1,19 @@
|
||||||
|
options (skip=1)
|
||||||
|
load data
|
||||||
|
infile drug_strength.csv
|
||||||
|
into table drug_strength
|
||||||
|
replace
|
||||||
|
fields terminated by '\t'
|
||||||
|
trailing nullcols
|
||||||
|
(
|
||||||
|
drug_concept_id,
|
||||||
|
ingredient_concept_id,
|
||||||
|
amount_value,
|
||||||
|
amount_unit,
|
||||||
|
concentration_value,
|
||||||
|
concentration_enum_unit,
|
||||||
|
concentration_denom_unit,
|
||||||
|
valid_start_date DATE 'YYYYMMDD',
|
||||||
|
valid_end_date DATE 'YYYYMMDD',
|
||||||
|
invalid_reason
|
||||||
|
)
|
|
@ -0,0 +1,14 @@
|
||||||
|
options (skip=1)
|
||||||
|
load data
|
||||||
|
infile relationship.csv
|
||||||
|
into table relationship
|
||||||
|
replace
|
||||||
|
fields terminated by '\t'
|
||||||
|
trailing nullcols
|
||||||
|
(
|
||||||
|
relationship_id,
|
||||||
|
relationship_name,
|
||||||
|
is_hierarchical,
|
||||||
|
defines_ancestry,
|
||||||
|
reverse_relationship
|
||||||
|
)
|
|
@ -0,0 +1,19 @@
|
||||||
|
options (skip=1)
|
||||||
|
load data
|
||||||
|
infile source_to_concept_map.csv
|
||||||
|
into table source_to_concept_map
|
||||||
|
replace
|
||||||
|
fields terminated by '\t'
|
||||||
|
trailing nullcols
|
||||||
|
(
|
||||||
|
source_code,
|
||||||
|
source_vocabulary_id,
|
||||||
|
source_code_description CHAR(256),
|
||||||
|
target_concept_id,
|
||||||
|
target_vocabulary_id,
|
||||||
|
mapping_type,
|
||||||
|
primary_map,
|
||||||
|
valid_start_date DATE 'YYYYMMDD',
|
||||||
|
valid_end_date DATE 'YYYYMMDD',
|
||||||
|
invalid_reason
|
||||||
|
)
|
|
@ -0,0 +1,11 @@
|
||||||
|
options (skip=1)
|
||||||
|
load data
|
||||||
|
infile vocabulary.csv
|
||||||
|
into table vocabulary
|
||||||
|
replace
|
||||||
|
fields terminated by '\t'
|
||||||
|
trailing nullcols
|
||||||
|
(
|
||||||
|
vocabulary_id,
|
||||||
|
vocabulary_name
|
||||||
|
)
|
|
@ -0,0 +1,131 @@
|
||||||
|
|
||||||
|
/*********************************************************************************
|
||||||
|
# Copyright 2015 Observational Health Data Sciences and Informatics
|
||||||
|
#
|
||||||
|
#
|
||||||
|
# Licensed under the Apache License, Version 2.0 (the "License");
|
||||||
|
# you may not use this file except in compliance with the License.
|
||||||
|
# You may obtain a copy of the License at
|
||||||
|
#
|
||||||
|
# http://www.apache.org/licenses/LICENSE-2.0
|
||||||
|
#
|
||||||
|
# Unless required by applicable law or agreed to in writing, software
|
||||||
|
# distributed under the License is distributed on an "AS IS" BASIS,
|
||||||
|
# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
|
||||||
|
# See the License for the specific language governing permissions and
|
||||||
|
# limitations under the License.4
|
||||||
|
********************************************************************************/
|
||||||
|
|
||||||
|
/************************
|
||||||
|
|
||||||
|
####### # # ####### ###### ##### ###### # # ## #######
|
||||||
|
# # ## ## # # # # # # # # ## ## # # # # #
|
||||||
|
# # # # # # # # # # # # # # # # # # # # # #
|
||||||
|
# # # # # # # ###### # # # # # # # # ####### #######
|
||||||
|
# # # # # # # # # # # # # # # #
|
||||||
|
# # # # # # # # # # # # # # # # # #
|
||||||
|
####### # # ####### # ##### ###### # # ## # # #####
|
||||||
|
|
||||||
|
|
||||||
|
script to create OMOP common data model, version 4.5 for PostgreSQL database
|
||||||
|
|
||||||
|
last revised: 20 Mar 2015
|
||||||
|
|
||||||
|
author: Lee Evans
|
||||||
|
|
||||||
|
|
||||||
|
*************************/
|
||||||
|
|
||||||
|
CREATE TABLE concept (
|
||||||
|
concept_id integer NOT NULL,
|
||||||
|
concept_name varchar(256) NOT NULL,
|
||||||
|
concept_level integer NOT NULL,
|
||||||
|
concept_class varchar(60) NOT NULL,
|
||||||
|
vocabulary_id integer NOT NULL,
|
||||||
|
concept_code varchar(40) NOT NULL,
|
||||||
|
valid_start_date date NOT NULL,
|
||||||
|
valid_end_date date NOT NULL DEFAULT '2099-12-31'::date,
|
||||||
|
invalid_reason varchar(1)
|
||||||
|
)
|
||||||
|
;
|
||||||
|
|
||||||
|
|
||||||
|
CREATE TABLE concept_ancestor (
|
||||||
|
ancestor_concept_id INTEGER NOT NULL,
|
||||||
|
descendant_concept_id INTEGER NOT NULL,
|
||||||
|
min_levels_of_separation INTEGER NOT NULL,
|
||||||
|
max_levels_of_separation INTEGER NOT NULL
|
||||||
|
)
|
||||||
|
;
|
||||||
|
|
||||||
|
|
||||||
|
CREATE TABLE concept_relationship (
|
||||||
|
concept_id_1 integer NOT NULL,
|
||||||
|
concept_id_2 integer NOT NULL,
|
||||||
|
relationship_id integer NOT NULL,
|
||||||
|
valid_start_date date NOT NULL,
|
||||||
|
valid_end_date date NOT NULL DEFAULT '2099-12-31'::date,
|
||||||
|
invalid_reason varchar(1)
|
||||||
|
)
|
||||||
|
;
|
||||||
|
|
||||||
|
|
||||||
|
CREATE TABLE concept_synonym (
|
||||||
|
concept_synonym_id integer NOT NULL,
|
||||||
|
concept_id integer NOT NULL,
|
||||||
|
concept_synonym_name varchar(1000) NOT NULL
|
||||||
|
)
|
||||||
|
;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
CREATE TABLE drug_strength (
|
||||||
|
drug_concept_id integer NOT NULL,
|
||||||
|
ingredient_concept_id integer NOT NULL,
|
||||||
|
amount_value double precision,
|
||||||
|
amount_unit varchar(60),
|
||||||
|
concentration_value double precision,
|
||||||
|
concentration_enum_unit character varying(60),
|
||||||
|
concentration_denom_unit character varying(60),
|
||||||
|
valid_start_date date NOT NULL,
|
||||||
|
valid_end_date date NOT NULL,
|
||||||
|
invalid_reason varchar(1)
|
||||||
|
)
|
||||||
|
;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
CREATE TABLE relationship (
|
||||||
|
relationship_id VARCHAR(20) NOT NULL,
|
||||||
|
relationship_name VARCHAR(256) NOT NULL,
|
||||||
|
is_hierarchical integer NOT NULL,
|
||||||
|
defines_ancestry integer DEFAULT 1,
|
||||||
|
reverse_relationship integer
|
||||||
|
)
|
||||||
|
;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
CREATE TABLE source_to_concept_map (
|
||||||
|
source_code VARCHAR(40) NOT NULL,
|
||||||
|
source_vocabulary_id INTEGER NOT NULL,
|
||||||
|
source_code_description VARCHAR(256),
|
||||||
|
target_concept_id INTEGER NOT NULL,
|
||||||
|
target_vocabulary_id INTEGER NOT NULL,
|
||||||
|
mapping_type VARCHAR(256),
|
||||||
|
primary_map VARCHAR(1),
|
||||||
|
valid_start_date DATE NOT NULL,
|
||||||
|
valid_end_date DATE NOT NULL,
|
||||||
|
invalid_reason VARCHAR(1) NULL
|
||||||
|
)
|
||||||
|
;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
CREATE TABLE vocabulary (
|
||||||
|
vocabulary_id integer NOT NULL,
|
||||||
|
vocabulary_name VARCHAR(256) NOT NULL
|
||||||
|
)
|
||||||
|
;
|
|
@ -0,0 +1,54 @@
|
||||||
|
/*********************************************************************************
|
||||||
|
# Copyright 2015 Observational Health Data Sciences and Informatics
|
||||||
|
#
|
||||||
|
#
|
||||||
|
# Licensed under the Apache License, Version 2.0 (the "License");
|
||||||
|
# you may not use this file except in compliance with the License.
|
||||||
|
# You may obtain a copy of the License at
|
||||||
|
#
|
||||||
|
# http://www.apache.org/licenses/LICENSE-2.0
|
||||||
|
#
|
||||||
|
# Unless required by applicable law or agreed to in writing, software
|
||||||
|
# distributed under the License is distributed on an "AS IS" BASIS,
|
||||||
|
# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
|
||||||
|
# See the License for the specific language governing permissions and
|
||||||
|
# limitations under the License.
|
||||||
|
********************************************************************************/
|
||||||
|
|
||||||
|
/************************
|
||||||
|
|
||||||
|
####### # # ####### ###### ##### ###### # # #######
|
||||||
|
# # ## ## # # # # # # # # ## ## # # #
|
||||||
|
# # # # # # # # # # # # # # # # # # # #
|
||||||
|
# # # # # # # ###### # # # # # # # # ######
|
||||||
|
# # # # # # # # # # # # # # #
|
||||||
|
# # # # # # # # # # # # # # # # #
|
||||||
|
####### # # ####### # ##### ###### # # ## #####
|
||||||
|
|
||||||
|
|
||||||
|
Script to load the common data model, version 4.5 vocabulary tables for PostgreSQL database
|
||||||
|
|
||||||
|
Notes
|
||||||
|
|
||||||
|
1) This script assumes the CDM version 4.5 vocabulary zip file has been unzipped into the "C:\CDM" directory.
|
||||||
|
2) If you unzipped your CDM version 4.5 vocabulary files into a different directory then replace all file paths below, with your directory path.
|
||||||
|
3) Run this SQL query script in the database where you created your CDM Version 4.5 tables
|
||||||
|
|
||||||
|
last revised: 20th March 2015
|
||||||
|
|
||||||
|
author: Lee Evans
|
||||||
|
|
||||||
|
|
||||||
|
*************************/
|
||||||
|
|
||||||
|
COPY CONCEPT FROM 'C:\CDM\CONCEPT.csv' WITH DELIMITER E'\t' CSV HEADER QUOTE E'\b' ;
|
||||||
|
COPY CONCEPT_ANCESTOR FROM 'C:\CDM\CONCEPT_ANCESTOR.csv' WITH DELIMITER E'\t' CSV HEADER QUOTE E'\b' ;
|
||||||
|
COPY CONCEPT_RELATIONSHIP FROM 'C:\CDM\CONCEPT_RELATIONSHIP.csv' WITH DELIMITER E'\t' CSV HEADER QUOTE E'\b' ;
|
||||||
|
COPY CONCEPT_SYNONYM FROM 'C:\CDM\CONCEPT_SYNONYM.csv' WITH DELIMITER E'\t' CSV HEADER QUOTE E'\b' ;
|
||||||
|
COPY DRUG_STRENGTH FROM 'C:\CDM\DRUG_STRENGTH.csv' WITH DELIMITER E'\t' CSV HEADER QUOTE E'\b' ;
|
||||||
|
COPY RELATIONSHIP FROM 'C:\CDM\RELATIONSHIP.csv' WITH DELIMITER E'\t' CSV HEADER QUOTE E'\b' ;
|
||||||
|
COPY SOURCE_TO_CONCEPT_MAP FROM 'C:\CDM\SOURCE_TO_CONCEPT_MAP.csv' WITH DELIMITER E'\t' CSV HEADER QUOTE E'\b' ;
|
||||||
|
COPY VOCABULARY FROM 'C:\CDM\VOCABULARY.csv' WITH DELIMITER E'\t' CSV HEADER QUOTE E'\b' ;
|
||||||
|
|
||||||
|
|
||||||
|
|
|
@ -0,0 +1,117 @@
|
||||||
|
/*********************************************************************************
|
||||||
|
# Copyright 2015 Observational Health Data Sciences and Informatics
|
||||||
|
#
|
||||||
|
#
|
||||||
|
# Licensed under the Apache License, Version 2.0 (the "License");
|
||||||
|
# you may not use this file except in compliance with the License.
|
||||||
|
# You may obtain a copy of the License at
|
||||||
|
#
|
||||||
|
# http://www.apache.org/licenses/LICENSE-2.0
|
||||||
|
#
|
||||||
|
# Unless required by applicable law or agreed to in writing, software
|
||||||
|
# distributed under the License is distributed on an "AS IS" BASIS,
|
||||||
|
# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
|
||||||
|
# See the License for the specific language governing permissions and
|
||||||
|
# limitations under the License.4
|
||||||
|
********************************************************************************/
|
||||||
|
|
||||||
|
/************************
|
||||||
|
|
||||||
|
####### # # ####### ###### ##### ###### # # ## #######
|
||||||
|
# # ## ## # # # # # # # # ## ## # # # # #
|
||||||
|
# # # # # # # # # # # # # # # # # # # # # #
|
||||||
|
# # # # # # # ###### # # # # # # # # ####### #######
|
||||||
|
# # # # # # # # # # # # # # # #
|
||||||
|
# # # # # # # # # # # # # # # # # #
|
||||||
|
####### # # ####### # ##### ###### # # ## # # #####
|
||||||
|
|
||||||
|
|
||||||
|
script to create OMOP common data model, version 4.5 for Sql Server database
|
||||||
|
|
||||||
|
last revised: 20 Mar 2015
|
||||||
|
|
||||||
|
author: Lee Evans
|
||||||
|
|
||||||
|
|
||||||
|
*************************/
|
||||||
|
|
||||||
|
|
||||||
|
CREATE TABLE CONCEPT(
|
||||||
|
CONCEPT_ID int NOT NULL,
|
||||||
|
CONCEPT_NAME varchar(256) NOT NULL,
|
||||||
|
CONCEPT_LEVEL int NOT NULL,
|
||||||
|
CONCEPT_CLASS varchar(60) NOT NULL,
|
||||||
|
VOCABULARY_ID int NOT NULL,
|
||||||
|
CONCEPT_CODE varchar(40) NOT NULL,
|
||||||
|
VALID_START_DATE date NOT NULL,
|
||||||
|
VALID_END_DATE date NOT NULL DEFAULT ('31-Dec-2099'),
|
||||||
|
INVALID_REASON char(1) NULL
|
||||||
|
);
|
||||||
|
|
||||||
|
|
||||||
|
CREATE TABLE CONCEPT_ANCESTOR(
|
||||||
|
ANCESTOR_CONCEPT_ID int NOT NULL,
|
||||||
|
DESCENDANT_CONCEPT_ID int NOT NULL,
|
||||||
|
MAX_LEVELS_OF_SEPARATION int NULL,
|
||||||
|
MIN_LEVELS_OF_SEPARATION int NULL
|
||||||
|
);
|
||||||
|
|
||||||
|
|
||||||
|
CREATE TABLE CONCEPT_RELATIONSHIP(
|
||||||
|
CONCEPT_ID_1 int NOT NULL,
|
||||||
|
CONCEPT_ID_2 int NOT NULL,
|
||||||
|
RELATIONSHIP_ID int NOT NULL,
|
||||||
|
VALID_START_DATE date NOT NULL,
|
||||||
|
VALID_END_DATE date NOT NULL DEFAULT ('31-Dec-2099'),
|
||||||
|
INVALID_REASON char(1) NULL
|
||||||
|
);
|
||||||
|
|
||||||
|
|
||||||
|
CREATE TABLE CONCEPT_SYNONYM(
|
||||||
|
CONCEPT_SYNONYM_ID int NOT NULL,
|
||||||
|
CONCEPT_ID int NOT NULL,
|
||||||
|
CONCEPT_SYNONYM_NAME varchar(1000) NOT NULL
|
||||||
|
);
|
||||||
|
|
||||||
|
|
||||||
|
CREATE TABLE DRUG_STRENGTH(
|
||||||
|
DRUG_CONCEPT_ID int NOT NULL,
|
||||||
|
INGREDIENT_CONCEPT_ID int NOT NULL,
|
||||||
|
AMOUNT_VALUE float NULL,
|
||||||
|
AMOUNT_UNIT varchar(60) NULL,
|
||||||
|
CONCENTRATION_VALUE float NULL,
|
||||||
|
CONCENTRATION_ENUM_UNIT varchar(60) NULL,
|
||||||
|
CONCENTRATION_DENOM_UNIT varchar(60) NULL,
|
||||||
|
VALID_START_DATE date NOT NULL,
|
||||||
|
VALID_END_DATE date NOT NULL,
|
||||||
|
INVALID_REASON varchar(1) NULL
|
||||||
|
);
|
||||||
|
|
||||||
|
|
||||||
|
CREATE TABLE RELATIONSHIP(
|
||||||
|
RELATIONSHIP_ID int NOT NULL,
|
||||||
|
RELATIONSHIP_NAME varchar(256) NOT NULL,
|
||||||
|
IS_HIERARCHICAL int NOT NULL,
|
||||||
|
DEFINES_ANCESTRY int NOT NULL DEFAULT ((1)),
|
||||||
|
REVERSE_RELATIONSHIP int NULL
|
||||||
|
);
|
||||||
|
|
||||||
|
|
||||||
|
CREATE TABLE SOURCE_TO_CONCEPT_MAP(
|
||||||
|
SOURCE_CODE varchar(40) NOT NULL,
|
||||||
|
SOURCE_VOCABULARY_ID int NOT NULL,
|
||||||
|
SOURCE_CODE_DESCRIPTION varchar(256) NULL,
|
||||||
|
TARGET_CONCEPT_ID int NOT NULL,
|
||||||
|
TARGET_VOCABULARY_ID int NOT NULL,
|
||||||
|
MAPPING_TYPE varchar(256) NULL,
|
||||||
|
PRIMARY_MAP char(1) NULL,
|
||||||
|
VALID_START_DATE date NOT NULL,
|
||||||
|
VALID_END_DATE date NOT NULL DEFAULT ('31-Dec-2099'),
|
||||||
|
INVALID_REASON char(1) NULL
|
||||||
|
);
|
||||||
|
|
||||||
|
|
||||||
|
CREATE TABLE VOCABULARY(
|
||||||
|
VOCABULARY_ID int NOT NULL,
|
||||||
|
VOCABULARY_NAME varchar(256) NOT NULL
|
||||||
|
);
|
|
@ -1,7 +1,7 @@
|
||||||
Common-Data-Model / Oracle
|
Common-Data-Model / SQL Server
|
||||||
=================
|
=================
|
||||||
|
|
||||||
This folder contains the SQL scripts for Oracle.
|
This folder contains the SQL scripts for SQL Server.
|
||||||
|
|
||||||
In order to create your instantiation of the Common Data Model, we recommend following these steps:
|
In order to create your instantiation of the Common Data Model, we recommend following these steps:
|
||||||
|
|
||||||
|
|
|
@ -0,0 +1,130 @@
|
||||||
|
/*********************************************************************************
|
||||||
|
# Copyright 2015 Observational Health Data Sciences and Informatics
|
||||||
|
#
|
||||||
|
#
|
||||||
|
# Licensed under the Apache License, Version 2.0 (the "License");
|
||||||
|
# you may not use this file except in compliance with the License.
|
||||||
|
# You may obtain a copy of the License at
|
||||||
|
#
|
||||||
|
# http://www.apache.org/licenses/LICENSE-2.0
|
||||||
|
#
|
||||||
|
# Unless required by applicable law or agreed to in writing, software
|
||||||
|
# distributed under the License is distributed on an "AS IS" BASIS,
|
||||||
|
# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
|
||||||
|
# See the License for the specific language governing permissions and
|
||||||
|
# limitations under the License.
|
||||||
|
********************************************************************************/
|
||||||
|
|
||||||
|
/************************
|
||||||
|
|
||||||
|
####### # # ####### ###### ##### ###### # # #######
|
||||||
|
# # ## ## # # # # # # # # ## ## # # #
|
||||||
|
# # # # # # # # # # # # # # # # # # # #
|
||||||
|
# # # # # # # ###### # # # # # # # # ######
|
||||||
|
# # # # # # # # # # # # # # #
|
||||||
|
# # # # # # # # # # # # # # # # #
|
||||||
|
####### # # ####### # ##### ###### # # ## #####
|
||||||
|
|
||||||
|
|
||||||
|
Script to load the common data model, version 4.5 vocabulary tables for SQL Server database
|
||||||
|
|
||||||
|
Notes
|
||||||
|
|
||||||
|
1) This script assumes the CDM version 4.5 vocabulary zip file has been unzipped into the "C:\CDM" directory.
|
||||||
|
2) If you unzipped your CDM version 4.5 vocabulary files into a different directory then replace all file paths below, with your directory path.
|
||||||
|
3) Run this SQL query script in the database where you created your CDM Version 4.5 tables
|
||||||
|
|
||||||
|
last revised: 20th March 2015
|
||||||
|
|
||||||
|
author: Lee Evans
|
||||||
|
|
||||||
|
|
||||||
|
*************************/
|
||||||
|
|
||||||
|
TRUNCATE TABLE CONCEPT;
|
||||||
|
BULK INSERT CONCEPT
|
||||||
|
FROM 'C:\CDM\CONCEPT.csv'
|
||||||
|
WITH (
|
||||||
|
FIRSTROW = 2,
|
||||||
|
FIELDTERMINATOR = '\t',
|
||||||
|
ROWTERMINATOR = '0x0a',
|
||||||
|
ERRORFILE = 'C:\CDM\CONCEPT.bad',
|
||||||
|
TABLOCK
|
||||||
|
);
|
||||||
|
|
||||||
|
TRUNCATE TABLE CONCEPT_ANCESTOR;
|
||||||
|
BULK INSERT CONCEPT_ANCESTOR
|
||||||
|
FROM 'C:\CDM\CONCEPT_ANCESTOR.csv'
|
||||||
|
WITH (
|
||||||
|
FIRSTROW = 2,
|
||||||
|
FIELDTERMINATOR = '\t',
|
||||||
|
ROWTERMINATOR = '0x0a',
|
||||||
|
ERRORFILE = 'C:\CDM\CONCEPT_ANCESTOR.bad',
|
||||||
|
TABLOCK
|
||||||
|
);
|
||||||
|
|
||||||
|
TRUNCATE TABLE CONCEPT_RELATIONSHIP;
|
||||||
|
BULK INSERT CONCEPT_RELATIONSHIP
|
||||||
|
FROM 'C:\CDM\CONCEPT_RELATIONSHIP.csv'
|
||||||
|
WITH (
|
||||||
|
FIRSTROW = 2,
|
||||||
|
FIELDTERMINATOR = '\t',
|
||||||
|
ROWTERMINATOR = '0x0a',
|
||||||
|
ERRORFILE = 'C:\CDM\CONCEPT_RELATIONSHIP.bad',
|
||||||
|
TABLOCK
|
||||||
|
);
|
||||||
|
|
||||||
|
TRUNCATE TABLE CONCEPT_SYNONYM;
|
||||||
|
BULK INSERT CONCEPT_SYNONYM
|
||||||
|
FROM 'C:\CDM\CONCEPT_SYNONYM.csv'
|
||||||
|
WITH (
|
||||||
|
FIRSTROW = 2,
|
||||||
|
FIELDTERMINATOR = '\t',
|
||||||
|
ROWTERMINATOR = '0x0a',
|
||||||
|
ERRORFILE = 'C:\CDM\CONCEPT_SYNONYM.bad',
|
||||||
|
TABLOCK
|
||||||
|
);
|
||||||
|
|
||||||
|
TRUNCATE TABLE DRUG_STRENGTH;
|
||||||
|
BULK INSERT DRUG_STRENGTH
|
||||||
|
FROM 'C:\CDM\DRUG_STRENGTH.csv'
|
||||||
|
WITH (
|
||||||
|
FIRSTROW = 2,
|
||||||
|
FIELDTERMINATOR = '\t',
|
||||||
|
ROWTERMINATOR = '0x0a',
|
||||||
|
ERRORFILE = 'C:\CDM\DRUG_STRENGTH.bad',
|
||||||
|
TABLOCK
|
||||||
|
);
|
||||||
|
|
||||||
|
TRUNCATE TABLE RELATIONSHIP;
|
||||||
|
BULK INSERT RELATIONSHIP
|
||||||
|
FROM 'C:\CDM\RELATIONSHIP.csv'
|
||||||
|
WITH (
|
||||||
|
FIRSTROW = 2,
|
||||||
|
FIELDTERMINATOR = '\t',
|
||||||
|
ROWTERMINATOR = '0x0a',
|
||||||
|
ERRORFILE = 'C:\CDM\RELATIONSHIP.bad',
|
||||||
|
TABLOCK
|
||||||
|
);
|
||||||
|
|
||||||
|
TRUNCATE TABLE SOURCE_TO_CONCEPT_MAP;
|
||||||
|
BULK INSERT SOURCE_TO_CONCEPT_MAP
|
||||||
|
FROM 'C:\CDM\SOURCE_TO_CONCEPT_MAP.csv'
|
||||||
|
WITH (
|
||||||
|
FIRSTROW = 2,
|
||||||
|
FIELDTERMINATOR = '\t',
|
||||||
|
ROWTERMINATOR = '0x0a',
|
||||||
|
ERRORFILE = 'C:\CDM\SOURCE_TO_CONCEPT_MAP.bad',
|
||||||
|
TABLOCK
|
||||||
|
);
|
||||||
|
|
||||||
|
TRUNCATE TABLE VOCABULARY;
|
||||||
|
BULK INSERT VOCABULARY
|
||||||
|
FROM 'C:\CDM\VOCABULARY.csv'
|
||||||
|
WITH (
|
||||||
|
FIRSTROW = 2,
|
||||||
|
FIELDTERMINATOR = '\t',
|
||||||
|
ROWTERMINATOR = '0x0a',
|
||||||
|
ERRORFILE = 'C:\CDM\VOCABULARY.bad',
|
||||||
|
TABLOCK
|
||||||
|
);
|
Loading…
Reference in New Issue