From 3697505b1ffcd2bfedaa67572065387737cdbc51 Mon Sep 17 00:00:00 2001 From: Pascal Brandt Date: Thu, 2 Jan 2020 13:03:12 -0800 Subject: [PATCH 1/7] =?UTF-8?q?=F0=9F=91=BC=20Automate=20schema=20creation?= =?UTF-8?q?.?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- pom.xml | 288 ++++--- .../V1.0.1__Create_f_person_table.pg.sql | 16 + .../V1.0.2__Create_f_person_index.pg.sql | 2 + .../V1.0.3__Create_Observation_view.pg.sql | 53 ++ .../flyway/FlywayPostgresMigrationsTest.java | 126 +++ .../ddl/postgresql/omop.cdm.v5.3.1.pg.sql | 740 ++++++++++++++++++ 6 files changed, 1122 insertions(+), 103 deletions(-) create mode 100644 src/main/resources/flyway/migrations/postgresql/V1.0.1__Create_f_person_table.pg.sql create mode 100644 src/main/resources/flyway/migrations/postgresql/V1.0.2__Create_f_person_index.pg.sql create mode 100644 src/main/resources/flyway/migrations/postgresql/V1.0.3__Create_Observation_view.pg.sql create mode 100644 src/test/java/edu/gatech/chai/flyway/FlywayPostgresMigrationsTest.java create mode 100644 src/test/resources/ddl/postgresql/omop.cdm.v5.3.1.pg.sql diff --git a/pom.xml b/pom.xml index 0e2509d..70247af 100644 --- a/pom.xml +++ b/pom.xml @@ -6,111 +6,193 @@ OR CONDITIONS OF ANY KIND, either express or implied. See the License for the specific language governing permissions and limitations under the License. --> - 4.0.0 + xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance" + xsi:schemaLocation="http://maven.apache.org/POM/4.0.0 http://maven.apache.org/maven-v4_0_0.xsd"> + 4.0.0 - edu.gatech.chai - omoponfhir-omopv5-jpabase - jar - 1.1.2 - omoponfhir-omopv5-jpabase - OMOP on FHIR JPABASE for OMOP version 5 - http://maven.apache.org + edu.gatech.chai + omoponfhir-omopv5-jpabase + jar + 1.1.2 + omoponfhir-omopv5-jpabase + OMOP on FHIR JPABASE for OMOP version 5 + http://maven.apache.org - - - Apache License, Version 2.0 - http://www.apache.org/licenses/LICENSE-2.0.txt - repo - - + + + Apache License, Version 2.0 + http://www.apache.org/licenses/LICENSE-2.0.txt + repo + + - - UTF-8 - 5.3.1.Final - 5.0.8.RELEASE - 5.3.1.Final - + + UTF-8 + 5.3.1.Final + 5.0.8.RELEASE + 5.3.1.Final + + 6.1.3 + 42.2.6 + + + + + true + 5.4.2 + 1.12.3 + - - - junit - junit - 3.8.1 - test - - - org.eclipse.persistence - javax.persistence - 2.2.0 - - - org.hibernate - hibernate-core - ${hibernate_version} - - - org.javassist - javassist - 3.20.0-GA - - - org.postgresql - postgresql - 9.4.1211.jre7 - - - org.springframework - spring-context - ${spring_version} - - - org.springframework - spring-orm - ${spring_version} - - - net.jcip - jcip-annotations - 1.0 - - - - org.json - json - 20180130 - - - org.slf4j - slf4j-api - 1.7.25 - - - org.apache.commons - commons-lang3 - 3.6 - - - - - - org.apache.maven.plugins - maven-surefire-plugin - 2.12.4 - - true - - - - org.apache.maven.plugins - maven-compiler-plugin - 3.8.0 - - 1.8 - 1.8 - - - - + + + org.eclipse.persistence + javax.persistence + 2.2.0 + + + org.hibernate + hibernate-core + ${hibernate_version} + + + org.javassist + javassist + 3.20.0-GA + + + org.postgresql + postgresql + 9.4.1211.jre7 + + + org.springframework + spring-context + ${spring_version} + + + org.springframework + spring-orm + ${spring_version} + + + net.jcip + jcip-annotations + 1.0 + + + + org.json + json + 20180130 + + + org.slf4j + slf4j-api + 1.7.25 + + + org.apache.commons + commons-lang3 + 3.6 + + + + org.flywaydb + flyway-core + ${flyway.version} + test + + + org.junit.jupiter + junit-jupiter-api + ${junit.jupiter.version} + test + + + org.junit.jupiter + junit-jupiter-params + ${junit.jupiter.version} + test + + + org.junit.jupiter + junit-jupiter-engine + ${junit.jupiter.version} + test + + + org.testcontainers + testcontainers + ${testcontainers.version} + test + + + org.testcontainers + junit-jupiter + 1.12.3 + ${testcontainers.version} + + + org.testcontainers + postgresql + ${testcontainers.version} + test + + + com.zaxxer + HikariCP + 3.4.1 + test + + + + + + org.apache.maven.plugins + maven-surefire-plugin + 2.19.1 + + ${skip.tests} + + + + org.junit.platform + junit-platform-surefire-provider + 1.0.1 + + + + + org.apache.maven.plugins + maven-compiler-plugin + 3.8.0 + + 1.8 + 1.8 + + + + org.flywaydb + flyway-maven-plugin + ${flyway.version} + + __ + + filesystem:src/main/resources/flyway/migrations/postgresql + + ${database.url} + ${database.user} + ${database.password} + true + + + + org.postgresql + postgresql + ${postgres.driver.version} + + + + + diff --git a/src/main/resources/flyway/migrations/postgresql/V1.0.1__Create_f_person_table.pg.sql b/src/main/resources/flyway/migrations/postgresql/V1.0.1__Create_f_person_table.pg.sql new file mode 100644 index 0000000..ebf0572 --- /dev/null +++ b/src/main/resources/flyway/migrations/postgresql/V1.0.1__Create_f_person_table.pg.sql @@ -0,0 +1,16 @@ +CREATE TABLE f_person +( + person_id INTEGER NOT NULL, + family_name VARCHAR(255), + given1_name VARCHAR(255), + given2_name VARCHAR(255), + prefix_name VARCHAR(255), + suffix_name VARCHAR(255), + preferred_language VARCHAR(255), + ssn VARCHAR(12), + active SMALLINT DEFAULT 1, + contact_point1 VARCHAR(255), + contact_point2 VARCHAR(255), + contact_point3 VARCHAR(255), + maritalstatus VARCHAR(255) +); \ No newline at end of file diff --git a/src/main/resources/flyway/migrations/postgresql/V1.0.2__Create_f_person_index.pg.sql b/src/main/resources/flyway/migrations/postgresql/V1.0.2__Create_f_person_index.pg.sql new file mode 100644 index 0000000..d2a2025 --- /dev/null +++ b/src/main/resources/flyway/migrations/postgresql/V1.0.2__Create_f_person_index.pg.sql @@ -0,0 +1,2 @@ +CREATE INDEX f_person_person_id_idx + ON f_person (person_id); \ No newline at end of file diff --git a/src/main/resources/flyway/migrations/postgresql/V1.0.3__Create_Observation_view.pg.sql b/src/main/resources/flyway/migrations/postgresql/V1.0.3__Create_Observation_view.pg.sql new file mode 100644 index 0000000..64e2204 --- /dev/null +++ b/src/main/resources/flyway/migrations/postgresql/V1.0.3__Create_Observation_view.pg.sql @@ -0,0 +1,53 @@ +create view f_observation_view as +SELECT measurement.measurement_id AS observation_id, + measurement.person_id, + measurement.measurement_concept_id AS observation_concept_id, + measurement.measurement_date AS observation_date, + measurement.measurement_datetime AS observation_time, + measurement.measurement_type_concept_id AS observation_type_concept_id, + measurement.operator_concept_id AS observation_operator_concept_id, + measurement.value_as_number, + NULL :: character varying AS value_as_string, + measurement.value_as_concept_id, + NULL :: integer AS qualifier_concept_id, + measurement.unit_concept_id, + measurement.range_low, + measurement.range_high, + measurement.provider_id, + measurement.visit_occurrence_id, + measurement.measurement_source_value AS source_value, + measurement.measurement_source_concept_id AS source_concept_id, + measurement.unit_source_value, + measurement.value_source_value, + NULL :: character varying AS qualifier_source_value +FROM measurement +UNION ALL +SELECT (-observation.observation_id) AS observation_id, + observation.person_id, + observation.observation_concept_id, + observation.observation_date, + observation.observation_datetime, + observation.observation_type_concept_id, + NULL :: integer AS observation_operator_concept_id, + observation.value_as_number, + observation.value_as_string, + observation.value_as_concept_id, + observation.qualifier_concept_id, + observation.unit_concept_id, + NULL :: double precision AS range_low, + NULL :: double precision AS range_high, + observation.provider_id, + observation.visit_occurrence_id, + observation.observation_source_value AS source_value, + observation.observation_source_concept_id AS source_concept_id, + observation.unit_source_value, + NULL :: character varying AS value_source_value, + observation.qualifier_source_value +FROM observation +WHERE (NOT (observation.observation_concept_id IN (SELECT c.concept_id + FROM concept c + WHERE (((upper((c.concept_name) :: text) ~~ '%ALLERG%' :: text) OR + (upper((c.concept_name) :: text) ~~ '%REACTION%' :: text)) AND + (((c.domain_id) :: text = 'Observation' :: text) OR + ((c.domain_id) :: text = 'Condition' :: text)) AND + ((c.invalid_reason) :: text <> 'D' :: text))))); \ No newline at end of file diff --git a/src/test/java/edu/gatech/chai/flyway/FlywayPostgresMigrationsTest.java b/src/test/java/edu/gatech/chai/flyway/FlywayPostgresMigrationsTest.java new file mode 100644 index 0000000..b32b05e --- /dev/null +++ b/src/test/java/edu/gatech/chai/flyway/FlywayPostgresMigrationsTest.java @@ -0,0 +1,126 @@ +package edu.gatech.chai.flyway; + +import com.zaxxer.hikari.HikariConfig; +import com.zaxxer.hikari.HikariDataSource; +import org.flywaydb.core.Flyway; +import org.junit.jupiter.api.AfterAll; +import org.junit.jupiter.api.BeforeAll; +import org.junit.jupiter.api.BeforeEach; +import org.junit.jupiter.api.Test; +import org.testcontainers.containers.JdbcDatabaseContainer; +import org.testcontainers.containers.PostgreSQLContainer; + +import java.sql.ResultSet; +import java.sql.SQLException; +import java.sql.Statement; + +import static org.junit.Assert.assertEquals; +import static org.junit.Assert.assertNull; + +public class FlywayPostgresMigrationsTest { + public static JdbcDatabaseContainer postgres; + + public static HikariDataSource datasource; + + @BeforeAll + public static void setup() { + postgres = new PostgreSQLContainer<>().withInitScript("ddl/postgresql/omop.cdm.v5.3.1.pg.sql"); + postgres.start(); + } + + // From here: https://github.com/testcontainers/testcontainers-java/blob/aa1c65b6efcc6d052fe71043d9985d69df70771f/modules/jdbc-test/src/test/java/org/testcontainers/junit/AbstractContainerDatabaseTest.java + HikariDataSource getDataSource(JdbcDatabaseContainer container) { + HikariConfig hikariConfig = new HikariConfig(); + hikariConfig.setJdbcUrl(container.getJdbcUrl()); + hikariConfig.setUsername(container.getUsername()); + hikariConfig.setPassword(container.getPassword()); + hikariConfig.setDriverClassName(container.getDriverClassName()); + + return new HikariDataSource(hikariConfig); + } + + ResultSet performQuery(JdbcDatabaseContainer container, String sql) throws SQLException { + datasource = getDataSource(container); + Statement statement = datasource.getConnection().createStatement(); + statement.execute(sql); + ResultSet resultSet = statement.getResultSet(); + + resultSet.next(); + return resultSet; + } + + ResultSet getTableIndices(JdbcDatabaseContainer container, String tableName) throws SQLException { + datasource = getDataSource(container); + return datasource.getConnection().getMetaData().getIndexInfo(null, null, tableName, false, false); + } + + ResultSet getTableMetadata(JdbcDatabaseContainer container, String tableName) throws SQLException { + datasource = getDataSource(container); + return datasource.getConnection().getMetaData().getTables(null, null, tableName, null); + } + + @BeforeEach + public void runMigrations() throws Exception { + Flyway flyway = Flyway + .configure() + .dataSource(postgres.getJdbcUrl(), postgres.getUsername(), postgres.getPassword()) + .locations("classpath:flyway/migrations/postgresql/") + .baselineOnMigrate(true) + .load(); + + flyway.migrate(); + } + + @Test + public void testFPerson() throws Exception { + // Check the table exists + ResultSet resultSet = performQuery(postgres, "SELECT * from f_person"); + + // Count the number of columns + assertEquals("Ensure we have the correct number of columns", 13, resultSet.getMetaData().getColumnCount()); + + // Check the index was created + resultSet = getTableIndices(postgres, "f_person"); + + boolean indexExists = false; + while (resultSet.next()) { + if (resultSet.getString("INDEX_NAME").equals("f_person_person_id_idx")) { + indexExists = true; + } + } + + assertEquals("Ensure index exists", true, indexExists); + } + + @Test + public void testObservationView() throws Exception { + // Check the view exists + ResultSet resultSet = null; + + try { + resultSet = performQuery(postgres, "SELECT * from f_observation_view"); + } catch (Exception e) { + assertNull("Ensure table exists", e); + } + + // Count the columns + assertEquals("Ensure we have the correct number of columns", 21, resultSet.getMetaData().getColumnCount()); + + // Check that it's a view + resultSet = getTableMetadata(postgres, "f_observation_view"); + + resultSet.next(); + assertEquals("Ensure we have a view", true, resultSet.getString("TABLE_TYPE").equals("VIEW")); + } + + @AfterAll + public static void cleanup() { + if (datasource != null) { + datasource.close(); + } + + if (postgres != null) { + postgres.stop(); + } + } +} diff --git a/src/test/resources/ddl/postgresql/omop.cdm.v5.3.1.pg.sql b/src/test/resources/ddl/postgresql/omop.cdm.v5.3.1.pg.sql new file mode 100644 index 0000000..db65224 --- /dev/null +++ b/src/test/resources/ddl/postgresql/omop.cdm.v5.3.1.pg.sql @@ -0,0 +1,740 @@ +/********************************************************************************* +# Copyright 2017-11 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. +********************************************************************************/ + +/************************ + + ####### # # ####### ###### ##### ###### # # ####### ##### + # # ## ## # # # # # # # # ## ## # # # # # + # # # # # # # # # # # # # # # # # # # # # + # # # # # # # ###### # # # # # # # # ###### ##### + # # # # # # # # # # # # # # # ### # + # # # # # # # # # # # # # # # # # ### # # + ####### # # ####### # ##### ###### # # ## ##### ### ##### + + +postgresql script to create OMOP common data model version 5.3 + +last revised: 14-June-2018 + +Authors: Patrick Ryan, Christian Reich, Clair Blacketer + + +*************************/ + + +/************************ + +Standardized vocabulary + +************************/ + + +CREATE TABLE concept +( + concept_id INTEGER NOT NULL, + concept_name VARCHAR(255) NOT NULL, + domain_id VARCHAR(20) NOT NULL, + vocabulary_id VARCHAR(20) NOT NULL, + concept_class_id VARCHAR(20) NOT NULL, + standard_concept VARCHAR(1) NULL, + concept_code VARCHAR(50) NOT NULL, + valid_start_date DATE NOT NULL, + valid_end_date DATE NOT NULL, + invalid_reason VARCHAR(1) NULL +) +; + + +CREATE TABLE vocabulary +( + vocabulary_id VARCHAR(20) NOT NULL, + vocabulary_name VARCHAR(255) NOT NULL, + vocabulary_reference VARCHAR(255) NOT NULL, + vocabulary_version VARCHAR(255) NOT NULL, + vocabulary_concept_id INTEGER NOT NULL +) +; + + +CREATE TABLE domain +( + domain_id VARCHAR(20) NOT NULL, + domain_name VARCHAR(255) NOT NULL, + domain_concept_id INTEGER NOT NULL +) +; + + +CREATE TABLE concept_class +( + concept_class_id VARCHAR(20) NOT NULL, + concept_class_name VARCHAR(255) NOT NULL, + concept_class_concept_id INTEGER NOT NULL +) +; + + +CREATE TABLE concept_relationship +( + concept_id_1 INTEGER NOT NULL, + concept_id_2 INTEGER NOT NULL, + relationship_id VARCHAR(20) NOT NULL, + valid_start_date DATE NOT NULL, + valid_end_date DATE NOT NULL, + invalid_reason VARCHAR(1) NULL +) +; + + +CREATE TABLE relationship +( + relationship_id VARCHAR(20) NOT NULL, + relationship_name VARCHAR(255) NOT NULL, + is_hierarchical VARCHAR(1) NOT NULL, + defines_ancestry VARCHAR(1) NOT NULL, + reverse_relationship_id VARCHAR(20) NOT NULL, + relationship_concept_id INTEGER NOT NULL +) +; + + +CREATE TABLE concept_synonym +( + concept_id INTEGER NOT NULL, + concept_synonym_name VARCHAR(1000) NOT NULL, + language_concept_id INTEGER NOT NULL +) +; + + +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 source_to_concept_map +( + source_code VARCHAR(50) NOT NULL, + source_concept_id INTEGER NOT NULL, + source_vocabulary_id VARCHAR(20) NOT NULL, + source_code_description VARCHAR(255) NULL, + target_concept_id INTEGER NOT NULL, + target_vocabulary_id VARCHAR(20) NOT NULL, + valid_start_date DATE NOT NULL, + valid_end_date DATE NOT NULL, + invalid_reason VARCHAR(1) NULL +) +; + + + +CREATE TABLE drug_strength +( + drug_concept_id INTEGER NOT NULL, + ingredient_concept_id INTEGER NOT NULL, + amount_value NUMERIC NULL, + amount_unit_concept_id INTEGER NULL, + numerator_value NUMERIC NULL, + numerator_unit_concept_id INTEGER NULL, + denominator_value NUMERIC NULL, + denominator_unit_concept_id INTEGER NULL, + box_size INTEGER NULL, + valid_start_date DATE NOT NULL, + valid_end_date DATE NOT NULL, + invalid_reason VARCHAR(1) NULL +) +; + + + +CREATE TABLE cohort_definition +( + cohort_definition_id INTEGER NOT NULL, + cohort_definition_name VARCHAR(255) NOT NULL, + cohort_definition_description TEXT NULL, + definition_type_concept_id INTEGER NOT NULL, + cohort_definition_syntax TEXT NULL, + subject_concept_id INTEGER NOT NULL, + cohort_initiation_date DATE NULL +) +; + + +CREATE TABLE attribute_definition +( + attribute_definition_id INTEGER NOT NULL, + attribute_name VARCHAR(255) NOT NULL, + attribute_description TEXT NULL, + attribute_type_concept_id INTEGER NOT NULL, + attribute_syntax TEXT NULL +) +; + + +/************************** + +Standardized meta-data + +***************************/ + + +CREATE TABLE cdm_source +( + cdm_source_name VARCHAR(255) NOT NULL, + cdm_source_abbreviation VARCHAR(25) NULL, + cdm_holder VARCHAR(255) NULL, + source_description TEXT NULL, + source_documentation_reference VARCHAR(255) NULL, + cdm_etl_reference VARCHAR(255) NULL, + source_release_date DATE NULL, + cdm_release_date DATE NULL, + cdm_version VARCHAR(10) NULL, + vocabulary_version VARCHAR(20) NULL +) +; + + +CREATE TABLE metadata +( + metadata_concept_id INTEGER NOT NULL, + metadata_type_concept_id INTEGER NOT NULL, + name VARCHAR(250) NOT NULL, + value_as_string TEXT NULL, + value_as_concept_id INTEGER NULL, + metadata_date DATE NULL, + metadata_datetime TIMESTAMP NULL +) +; + + +/************************ + +Standardized clinical data + +************************/ + +--HINT DISTRIBUTE_ON_KEY(person_id) +CREATE TABLE person +( + person_id INTEGER NOT NULL, + gender_concept_id INTEGER NOT NULL, + year_of_birth INTEGER NOT NULL, + month_of_birth INTEGER NULL, + day_of_birth INTEGER NULL, + birth_datetime TIMESTAMP NULL, + race_concept_id INTEGER NOT NULL, + ethnicity_concept_id INTEGER NOT NULL, + location_id INTEGER NULL, + provider_id INTEGER NULL, + care_site_id INTEGER NULL, + person_source_value VARCHAR(50) NULL, + gender_source_value VARCHAR(50) NULL, + gender_source_concept_id INTEGER NULL, + race_source_value VARCHAR(50) NULL, + race_source_concept_id INTEGER NULL, + ethnicity_source_value VARCHAR(50) NULL, + ethnicity_source_concept_id INTEGER NULL +) +; + + +--HINT DISTRIBUTE_ON_KEY(person_id) +CREATE TABLE observation_period +( + observation_period_id INTEGER NOT NULL, + person_id INTEGER NOT NULL, + observation_period_start_date DATE NOT NULL, + observation_period_end_date DATE NOT NULL, + period_type_concept_id INTEGER NOT NULL +) +; + + +--HINT DISTRIBUTE_ON_KEY(person_id) +CREATE TABLE specimen +( + specimen_id INTEGER NOT NULL, + person_id INTEGER NOT NULL, + specimen_concept_id INTEGER NOT NULL, + specimen_type_concept_id INTEGER NOT NULL, + specimen_date DATE NOT NULL, + specimen_datetime TIMESTAMP NULL, + quantity NUMERIC NULL, + unit_concept_id INTEGER NULL, + anatomic_site_concept_id INTEGER NULL, + disease_status_concept_id INTEGER NULL, + specimen_source_id VARCHAR(50) NULL, + specimen_source_value VARCHAR(50) NULL, + unit_source_value VARCHAR(50) NULL, + anatomic_site_source_value VARCHAR(50) NULL, + disease_status_source_value VARCHAR(50) NULL +) +; + + +--HINT DISTRIBUTE_ON_KEY(person_id) +CREATE TABLE death +( + person_id INTEGER NOT NULL, + death_date DATE NOT NULL, + death_datetime TIMESTAMP NULL, + death_type_concept_id INTEGER NOT NULL, + cause_concept_id INTEGER NULL, + cause_source_value VARCHAR(50) NULL, + cause_source_concept_id INTEGER NULL +) +; + + +--HINT DISTRIBUTE_ON_KEY(person_id) +CREATE TABLE visit_occurrence +( + visit_occurrence_id INTEGER NOT NULL, + person_id INTEGER NOT NULL, + visit_concept_id INTEGER NOT NULL, + visit_start_date DATE NOT NULL, + visit_start_datetime TIMESTAMP NULL, + visit_end_date DATE NOT NULL, + visit_end_datetime TIMESTAMP NULL, + visit_type_concept_id INTEGER NOT NULL, + provider_id INTEGER NULL, + care_site_id INTEGER NULL, + visit_source_value VARCHAR(50) NULL, + visit_source_concept_id INTEGER NULL, + admitting_source_concept_id INTEGER NULL, + admitting_source_value VARCHAR(50) NULL, + discharge_to_concept_id INTEGER NULL, + discharge_to_source_value VARCHAR(50) NULL, + preceding_visit_occurrence_id INTEGER NULL +) +; + + +--HINT DISTRIBUTE_ON_KEY(person_id) +CREATE TABLE visit_detail +( + visit_detail_id INTEGER NOT NULL, + person_id INTEGER NOT NULL, + visit_detail_concept_id INTEGER NOT NULL, + visit_detail_start_date DATE NOT NULL, + visit_detail_start_datetime TIMESTAMP NULL, + visit_detail_end_date DATE NOT NULL, + visit_detail_end_datetime TIMESTAMP NULL, + visit_detail_type_concept_id INTEGER NOT NULL, + provider_id INTEGER NULL, + care_site_id INTEGER NULL, + admitting_source_concept_id INTEGER NULL, + discharge_to_concept_id INTEGER NULL, + preceding_visit_detail_id INTEGER NULL, + visit_detail_source_value VARCHAR(50) NULL, + visit_detail_source_concept_id INTEGER NULL, + admitting_source_value VARCHAR(50) NULL, + discharge_to_source_value VARCHAR(50) NULL, + visit_detail_parent_id INTEGER NULL, + visit_occurrence_id INTEGER NOT NULL +) +; + + +--HINT DISTRIBUTE_ON_KEY(person_id) +CREATE TABLE procedure_occurrence +( + procedure_occurrence_id INTEGER NOT NULL, + person_id INTEGER NOT NULL, + procedure_concept_id INTEGER NOT NULL, + procedure_date DATE NOT NULL, + procedure_datetime TIMESTAMP NULL, + procedure_type_concept_id INTEGER NOT NULL, + modifier_concept_id INTEGER NULL, + quantity INTEGER NULL, + provider_id INTEGER NULL, + visit_occurrence_id INTEGER NULL, + visit_detail_id INTEGER NULL, + procedure_source_value VARCHAR(50) NULL, + procedure_source_concept_id INTEGER NULL, + modifier_source_value VARCHAR(50) NULL +) +; + + +--HINT DISTRIBUTE_ON_KEY(person_id) +CREATE TABLE drug_exposure +( + drug_exposure_id INTEGER NOT NULL, + person_id INTEGER NOT NULL, + drug_concept_id INTEGER NOT NULL, + drug_exposure_start_date DATE NOT NULL, + drug_exposure_start_datetime TIMESTAMP NULL, + drug_exposure_end_date DATE NOT NULL, + drug_exposure_end_datetime TIMESTAMP NULL, + verbatim_end_date DATE NULL, + drug_type_concept_id INTEGER NOT NULL, + stop_reason VARCHAR(20) NULL, + refills INTEGER NULL, + quantity NUMERIC NULL, + days_supply INTEGER NULL, + sig TEXT NULL, + route_concept_id INTEGER NULL, + lot_number VARCHAR(50) NULL, + provider_id INTEGER NULL, + visit_occurrence_id INTEGER NULL, + visit_detail_id INTEGER NULL, + drug_source_value VARCHAR(50) NULL, + drug_source_concept_id INTEGER NULL, + route_source_value VARCHAR(50) NULL, + dose_unit_source_value VARCHAR(50) NULL +) +; + + +--HINT DISTRIBUTE_ON_KEY(person_id) +CREATE TABLE device_exposure +( + device_exposure_id INTEGER NOT NULL, + person_id INTEGER NOT NULL, + device_concept_id INTEGER NOT NULL, + device_exposure_start_date DATE NOT NULL, + device_exposure_start_datetime TIMESTAMP NULL, + device_exposure_end_date DATE NULL, + device_exposure_end_datetime TIMESTAMP NULL, + device_type_concept_id INTEGER NOT NULL, + unique_device_id VARCHAR(50) NULL, + quantity INTEGER NULL, + provider_id INTEGER NULL, + visit_occurrence_id INTEGER NULL, + visit_detail_id INTEGER NULL, + device_source_value VARCHAR(100) NULL, + device_source_concept_id INTEGER NULL +) +; + + +--HINT DISTRIBUTE_ON_KEY(person_id) +CREATE TABLE condition_occurrence +( + condition_occurrence_id INTEGER NOT NULL, + person_id INTEGER NOT NULL, + condition_concept_id INTEGER NOT NULL, + condition_start_date DATE NOT NULL, + condition_start_datetime TIMESTAMP NULL, + condition_end_date DATE NULL, + condition_end_datetime TIMESTAMP NULL, + condition_type_concept_id INTEGER NOT NULL, + stop_reason VARCHAR(20) NULL, + provider_id INTEGER NULL, + visit_occurrence_id INTEGER NULL, + visit_detail_id INTEGER NULL, + condition_source_value VARCHAR(50) NULL, + condition_source_concept_id INTEGER NULL, + condition_status_source_value VARCHAR(50) NULL, + condition_status_concept_id INTEGER NULL +) +; + + +--HINT DISTRIBUTE_ON_KEY(person_id) +CREATE TABLE measurement +( + measurement_id INTEGER NOT NULL, + person_id INTEGER NOT NULL, + measurement_concept_id INTEGER NOT NULL, + measurement_date DATE NOT NULL, + measurement_datetime TIMESTAMP NULL, + measurement_time VARCHAR(10) NULL, + measurement_type_concept_id INTEGER NOT NULL, + operator_concept_id INTEGER NULL, + value_as_number NUMERIC NULL, + value_as_concept_id INTEGER NULL, + unit_concept_id INTEGER NULL, + range_low NUMERIC NULL, + range_high NUMERIC NULL, + provider_id INTEGER NULL, + visit_occurrence_id INTEGER NULL, + visit_detail_id INTEGER NULL, + measurement_source_value VARCHAR(50) NULL, + measurement_source_concept_id INTEGER NULL, + unit_source_value VARCHAR(50) NULL, + value_source_value VARCHAR(50) NULL +) +; + + +--HINT DISTRIBUTE_ON_KEY(person_id) +CREATE TABLE note +( + note_id INTEGER NOT NULL, + person_id INTEGER NOT NULL, + note_date DATE NOT NULL, + note_datetime TIMESTAMP NULL, + note_type_concept_id INTEGER NOT NULL, + note_class_concept_id INTEGER NOT NULL, + note_title VARCHAR(250) NULL, + note_text TEXT NULL, + encoding_concept_id INTEGER NOT NULL, + language_concept_id INTEGER NOT NULL, + provider_id INTEGER NULL, + visit_occurrence_id INTEGER NULL, + visit_detail_id INTEGER NULL, + note_source_value VARCHAR(50) NULL +) +; + + + +CREATE TABLE note_nlp +( + note_nlp_id INTEGER 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 +) +; + + +--HINT DISTRIBUTE_ON_KEY(person_id) +CREATE TABLE observation +( + observation_id INTEGER NOT NULL, + person_id INTEGER NOT NULL, + observation_concept_id INTEGER NOT NULL, + observation_date DATE NOT NULL, + observation_datetime TIMESTAMP NULL, + observation_type_concept_id INTEGER NOT NULL, + value_as_number NUMERIC NULL, + value_as_string VARCHAR(60) NULL, + value_as_concept_id INTEGER NULL, + qualifier_concept_id INTEGER NULL, + unit_concept_id INTEGER NULL, + provider_id INTEGER NULL, + visit_occurrence_id INTEGER NULL, + visit_detail_id INTEGER NULL, + observation_source_value VARCHAR(50) NULL, + observation_source_concept_id INTEGER NULL, + unit_source_value VARCHAR(50) NULL, + qualifier_source_value VARCHAR(50) NULL +) +; + + +CREATE TABLE fact_relationship +( + domain_concept_id_1 INTEGER NOT NULL, + fact_id_1 INTEGER NOT NULL, + domain_concept_id_2 INTEGER NOT NULL, + fact_id_2 INTEGER NOT NULL, + relationship_concept_id INTEGER NOT NULL +) +; + + +/************************ + +Standardized health system data + +************************/ + + +CREATE TABLE location +( + location_id INTEGER NOT NULL, + address_1 VARCHAR(50) NULL, + address_2 VARCHAR(50) NULL, + city VARCHAR(50) NULL, + state VARCHAR(2) NULL, + zip VARCHAR(9) NULL, + county VARCHAR(20) NULL, + location_source_value VARCHAR(50) NULL +) +; + + +CREATE TABLE care_site +( + care_site_id INTEGER NOT NULL, + care_site_name VARCHAR(255) NULL, + place_of_service_concept_id INTEGER NULL, + location_id INTEGER NULL, + care_site_source_value VARCHAR(50) NULL, + place_of_service_source_value VARCHAR(50) NULL +) +; + + +CREATE TABLE provider +( + provider_id INTEGER NOT NULL, + provider_name VARCHAR(255) NULL, + NPI VARCHAR(20) NULL, + DEA VARCHAR(20) NULL, + specialty_concept_id INTEGER NULL, + care_site_id INTEGER NULL, + year_of_birth INTEGER NULL, + gender_concept_id INTEGER NULL, + provider_source_value VARCHAR(50) NULL, + specialty_source_value VARCHAR(50) NULL, + specialty_source_concept_id INTEGER NULL, + gender_source_value VARCHAR(50) NULL, + gender_source_concept_id INTEGER NULL +) +; + + +/************************ + +Standardized health economics + +************************/ + + +--HINT DISTRIBUTE_ON_KEY(person_id) +CREATE TABLE payer_plan_period +( + payer_plan_period_id INTEGER NOT NULL, + person_id INTEGER NOT NULL, + payer_plan_period_start_date DATE NOT NULL, + payer_plan_period_end_date DATE NOT NULL, + payer_concept_id INTEGER NULL, + payer_source_value VARCHAR(50) NULL, + payer_source_concept_id INTEGER NULL, + plan_concept_id INTEGER NULL, + plan_source_value VARCHAR(50) NULL, + plan_source_concept_id INTEGER NULL, + sponsor_concept_id INTEGER NULL, + sponsor_source_value VARCHAR(50) NULL, + sponsor_source_concept_id INTEGER NULL, + family_source_value VARCHAR(50) NULL, + stop_reason_concept_id INTEGER NULL, + stop_reason_source_value VARCHAR(50) NULL, + stop_reason_source_concept_id INTEGER NULL +) +; + + +CREATE TABLE cost +( + cost_id INTEGER NOT NULL, + cost_event_id INTEGER NOT NULL, + cost_domain_id VARCHAR(20) NOT NULL, + cost_type_concept_id INTEGER NOT NULL, + currency_concept_id INTEGER NULL, + total_charge NUMERIC NULL, + total_cost NUMERIC NULL, + total_paid NUMERIC NULL, + paid_by_payer NUMERIC NULL, + paid_by_patient NUMERIC NULL, + paid_patient_copay NUMERIC NULL, + paid_patient_coinsurance NUMERIC NULL, + paid_patient_deductible NUMERIC NULL, + paid_by_primary NUMERIC NULL, + paid_ingredient_cost NUMERIC NULL, + paid_dispensing_fee NUMERIC NULL, + payer_plan_period_id INTEGER NULL, + amount_allowed NUMERIC NULL, + revenue_code_concept_id INTEGER NULL, + reveue_code_source_value VARCHAR(50) NULL, + drg_concept_id INTEGER NULL, + drg_source_value VARCHAR(3) NULL +) +; + + +/************************ + +Standardized derived elements + +************************/ + + +--HINT DISTRIBUTE_ON_KEY(subject_id) +CREATE TABLE cohort +( + cohort_definition_id INTEGER NOT NULL, + subject_id INTEGER NOT NULL, + cohort_start_date DATE NOT NULL, + cohort_end_date DATE NOT NULL +) +; + + +--HINT DISTRIBUTE_ON_KEY(subject_id) +CREATE TABLE cohort_attribute +( + cohort_definition_id INTEGER NOT NULL, + subject_id INTEGER NOT NULL, + cohort_start_date DATE NOT NULL, + cohort_end_date DATE NOT NULL, + attribute_definition_id INTEGER NOT NULL, + value_as_number NUMERIC NULL, + value_as_concept_id INTEGER NULL +) +; + + +--HINT DISTRIBUTE_ON_KEY(person_id) +CREATE TABLE drug_era +( + drug_era_id INTEGER NOT NULL, + person_id INTEGER NOT NULL, + drug_concept_id INTEGER NOT NULL, + drug_era_start_date DATE NOT NULL, + drug_era_end_date DATE NOT NULL, + drug_exposure_count INTEGER NULL, + gap_days INTEGER NULL +) +; + + +--HINT DISTRIBUTE_ON_KEY(person_id) +CREATE TABLE dose_era +( + dose_era_id INTEGER NOT NULL, + person_id INTEGER NOT NULL, + drug_concept_id INTEGER NOT NULL, + unit_concept_id INTEGER NOT NULL, + dose_value NUMERIC NOT NULL, + dose_era_start_date DATE NOT NULL, + dose_era_end_date DATE NOT NULL +) +; + + +--HINT DISTRIBUTE_ON_KEY(person_id) +CREATE TABLE condition_era +( + condition_era_id INTEGER NOT NULL, + person_id INTEGER NOT NULL, + condition_concept_id INTEGER NOT NULL, + condition_era_start_date DATE NOT NULL, + condition_era_end_date DATE NOT NULL, + condition_occurrence_count INTEGER NULL +) +; From 9a454950b6e5f746816124a49dbc03c6ba311977 Mon Sep 17 00:00:00 2001 From: Pascal Brandt Date: Thu, 2 Jan 2020 13:19:21 -0800 Subject: [PATCH 2/7] =?UTF-8?q?=F0=9F=91=B7=F0=9F=8F=BC=E2=80=8D=E2=99=82?= =?UTF-8?q?=EF=B8=8F=20Add=20CI=20testing.?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- .travis.yml | 20 ++++++++++++++++++++ 1 file changed, 20 insertions(+) create mode 100644 .travis.yml diff --git a/.travis.yml b/.travis.yml new file mode 100644 index 0000000..1eb72ae --- /dev/null +++ b/.travis.yml @@ -0,0 +1,20 @@ +language: java +jdk: + - openjdk10 + +sudo: required +services: + - docker + +# Fix for https://travis-ci.community/t/problematic-docker-compose-version-1-23-1/5362/3 +before_install: + - sudo rm /usr/local/bin/docker-compose + - curl -L https://github.com/docker/compose/releases/download/1.24.1/docker-compose-Linux-x86_64 > docker-compose + - chmod +x docker-compose + - sudo mv docker-compose /usr/local/bin + +install: + - mvn -Ptravis install -DskipTests=true -Dmaven.javadoc.skip=true -B -V + +script: + - mvn test -Dskip.tests=false \ No newline at end of file From 937939b91f15b2a5e97456e2fe2455294b7f1fb3 Mon Sep 17 00:00:00 2001 From: Pascal Brandt Date: Thu, 2 Jan 2020 14:21:37 -0800 Subject: [PATCH 3/7] =?UTF-8?q?=F0=9F=93=93=20Add=20documentation.?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- README.md | 35 +++++++++++++++++++++++++++++++++++ 1 file changed, 35 insertions(+) diff --git a/README.md b/README.md index 8d97cbe..b152523 100644 --- a/README.md +++ b/README.md @@ -1 +1,36 @@ # omoponfhir-omopv5-jpabase + + +[![Build Status](https://travis-ci.org/PheMA/omoponfhir-omopv5-jpabase.svg?branch=flyway)](https://travis-ci.org/PheMA/omoponfhir-omopv5-jpabase) + +Java library containing Hibernate JPA entities used by OMOP on FHIR. + + +## Schema Preparation + +At least one table and one view need to be created to support mapping the OMOP CDM to FHIR. First, the `f_person` table +must be created to contain additional demographic information used by FHIR, but not typically stored in the OMOP CDM. +Second, since both the CDM `measurement` and `observation` tables map to the FHIR Observation resource, we +create a view called `f_observation_view`, which is a union of these two tables. + +The PostgreSQL scripts for creating these two tables, as well as an index on `f_person` can be found in +[`src/main/resources/flyway/migrations/postgresql`](src/main/resources/flyway/migrations/postgresql). + +### Automatic Schema Creation + +To automatically create the necessary tables, or apply any updates implemented since you last ran the scripts, do the +following. + +First, clone this repository: + +``` +git clone https://github.com/omoponfhir/omoponfhir-omopv5-jpabase.git +``` + +Then, use Maven and Flyway to apply the scripts for you: + +```sh +mvn flyway:migrate -Ddatabase.url='jdbc:postgresql://localhost:5432/postgres?currentSchema=cdm' -Ddatabase.user=postgres -Ddatabase.password=postgres +``` + +Adjust the parameters as required. Importantly, ensure the correct schema is selected (`cdm` in the above example). \ No newline at end of file From cebea7dde70e037be63c34f69d5855bf171201bc Mon Sep 17 00:00:00 2001 From: Pascal Brandt Date: Thu, 2 Jan 2020 15:12:27 -0800 Subject: [PATCH 4/7] =?UTF-8?q?=F0=9F=8E=AB=20Add=20id=5Fmapping=20migrati?= =?UTF-8?q?on=20and=20test.?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- .../V1.0.4__Create_id_mapping_table.pg.sql | 8 +++++++ .../flyway/FlywayPostgresMigrationsTest.java | 21 +++++++++++++++++++ 2 files changed, 29 insertions(+) create mode 100644 src/main/resources/flyway/migrations/postgresql/V1.0.4__Create_id_mapping_table.pg.sql diff --git a/src/main/resources/flyway/migrations/postgresql/V1.0.4__Create_id_mapping_table.pg.sql b/src/main/resources/flyway/migrations/postgresql/V1.0.4__Create_id_mapping_table.pg.sql new file mode 100644 index 0000000..f0c40c3 --- /dev/null +++ b/src/main/resources/flyway/migrations/postgresql/V1.0.4__Create_id_mapping_table.pg.sql @@ -0,0 +1,8 @@ +CREATE TABLE id_mapping +( + id INTEGER NOT NULL, + fhir_id INTEGER NULL, + omop_id INTEGER NULL, + related_resource varchar(255) NULL, + CONSTRAINT id_mapping_pkey PRIMARY KEY (id) +); \ No newline at end of file diff --git a/src/test/java/edu/gatech/chai/flyway/FlywayPostgresMigrationsTest.java b/src/test/java/edu/gatech/chai/flyway/FlywayPostgresMigrationsTest.java index b32b05e..cf6b95f 100644 --- a/src/test/java/edu/gatech/chai/flyway/FlywayPostgresMigrationsTest.java +++ b/src/test/java/edu/gatech/chai/flyway/FlywayPostgresMigrationsTest.java @@ -113,6 +113,27 @@ public void testObservationView() throws Exception { assertEquals("Ensure we have a view", true, resultSet.getString("TABLE_TYPE").equals("VIEW")); } + @Test + public void testIdMapping() throws Exception { + // Check the table exists + ResultSet resultSet = performQuery(postgres, "SELECT * from id_mapping"); + + // Count the number of columns + assertEquals("Ensure we have the correct number of columns", 4, resultSet.getMetaData().getColumnCount()); + + // Check the index was created + resultSet = getTableIndices(postgres, "id_mapping"); + + boolean indexExists = false; + while (resultSet.next()) { + if (resultSet.getString("INDEX_NAME").equals("id_mapping_pkey")) { + indexExists = true; + } + } + + assertEquals("Ensure index exists", true, indexExists); + } + @AfterAll public static void cleanup() { if (datasource != null) { From cd4c2366b6a1928098069e385c024608c26c4349 Mon Sep 17 00:00:00 2001 From: Pascal Brandt Date: Thu, 2 Jan 2020 16:46:43 -0800 Subject: [PATCH 5/7] =?UTF-8?q?=F0=9F=92=A9=20Unfortunate=20observation=5F?= =?UTF-8?q?time=20workaround.?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- .../V1.0.3__Create_Observation_view.pg.sql | 130 +++++++++++------- 1 file changed, 77 insertions(+), 53 deletions(-) diff --git a/src/main/resources/flyway/migrations/postgresql/V1.0.3__Create_Observation_view.pg.sql b/src/main/resources/flyway/migrations/postgresql/V1.0.3__Create_Observation_view.pg.sql index 64e2204..8d538bf 100644 --- a/src/main/resources/flyway/migrations/postgresql/V1.0.3__Create_Observation_view.pg.sql +++ b/src/main/resources/flyway/migrations/postgresql/V1.0.3__Create_Observation_view.pg.sql @@ -1,53 +1,77 @@ -create view f_observation_view as -SELECT measurement.measurement_id AS observation_id, - measurement.person_id, - measurement.measurement_concept_id AS observation_concept_id, - measurement.measurement_date AS observation_date, - measurement.measurement_datetime AS observation_time, - measurement.measurement_type_concept_id AS observation_type_concept_id, - measurement.operator_concept_id AS observation_operator_concept_id, - measurement.value_as_number, - NULL :: character varying AS value_as_string, - measurement.value_as_concept_id, - NULL :: integer AS qualifier_concept_id, - measurement.unit_concept_id, - measurement.range_low, - measurement.range_high, - measurement.provider_id, - measurement.visit_occurrence_id, - measurement.measurement_source_value AS source_value, - measurement.measurement_source_concept_id AS source_concept_id, - measurement.unit_source_value, - measurement.value_source_value, - NULL :: character varying AS qualifier_source_value -FROM measurement -UNION ALL -SELECT (-observation.observation_id) AS observation_id, - observation.person_id, - observation.observation_concept_id, - observation.observation_date, - observation.observation_datetime, - observation.observation_type_concept_id, - NULL :: integer AS observation_operator_concept_id, - observation.value_as_number, - observation.value_as_string, - observation.value_as_concept_id, - observation.qualifier_concept_id, - observation.unit_concept_id, - NULL :: double precision AS range_low, - NULL :: double precision AS range_high, - observation.provider_id, - observation.visit_occurrence_id, - observation.observation_source_value AS source_value, - observation.observation_source_concept_id AS source_concept_id, - observation.unit_source_value, - NULL :: character varying AS value_source_value, - observation.qualifier_source_value -FROM observation -WHERE (NOT (observation.observation_concept_id IN (SELECT c.concept_id - FROM concept c - WHERE (((upper((c.concept_name) :: text) ~~ '%ALLERG%' :: text) OR - (upper((c.concept_name) :: text) ~~ '%REACTION%' :: text)) AND - (((c.domain_id) :: text = 'Observation' :: text) OR - ((c.domain_id) :: text = 'Condition' :: text)) AND - ((c.invalid_reason) :: text <> 'D' :: text))))); \ No newline at end of file +DO +$$ + <> + DECLARE + obs_time_exists boolean := false; + obs_time_col_string varchar := ''; + BEGIN + SELECT EXISTS(SELECT table_name + FROM information_schema.columns + WHERE table_name = 'observation' + AND column_name = 'observation_time') + into obs_time_exists; + + CASE WHEN obs_time_exists = TRUE + THEN + obs_time_col_string = 'observation_time'; + ELSE + obs_time_col_string = 'observation.observation_datetime::timestamp::time::varchar(10)'; + END CASE; + + EXECUTE $sql$ + CREATE view f_observation_view AS + SELECT measurement.measurement_id AS observation_id, + measurement.person_id, + measurement.measurement_concept_id AS observation_concept_id, + measurement.measurement_date AS observation_date, + measurement.measurement_time AS observation_time, + measurement.measurement_type_concept_id AS observation_type_concept_id, + measurement.operator_concept_id AS observation_operator_concept_id, + measurement.value_as_number, + NULL :: character varying AS value_as_string, + measurement.value_as_concept_id, + NULL :: integer AS qualifier_concept_id, + measurement.unit_concept_id, + measurement.range_low, + measurement.range_high, + measurement.provider_id, + measurement.visit_occurrence_id, + measurement.measurement_source_value AS source_value, + measurement.measurement_source_concept_id AS source_concept_id, + measurement.unit_source_value, + measurement.value_source_value, + NULL :: character varying AS qualifier_source_value + FROM measurement + UNION ALL + SELECT (-observation.observation_id) AS observation_id, + observation.person_id, + observation.observation_concept_id, + observation.observation_date, + $sql$ || obs_time_col_string || $sql$, + observation.observation_type_concept_id, + NULL :: integer AS observation_operator_concept_id, + observation.value_as_number, + observation.value_as_string, + observation.value_as_concept_id, + observation.qualifier_concept_id, + observation.unit_concept_id, + NULL :: double precision AS range_low, + NULL :: double precision AS range_high, + observation.provider_id, + observation.visit_occurrence_id, + observation.observation_source_value AS source_value, + observation.observation_source_concept_id AS source_concept_id, + observation.unit_source_value, + NULL :: character varying AS value_source_value, + observation.qualifier_source_value + FROM observation + WHERE (NOT (observation.observation_concept_id IN (SELECT c.concept_id + FROM concept c + WHERE (((upper((c.concept_name) :: text) ~~ '%ALLERG%' :: text) OR + (upper((c.concept_name) :: text) ~~ '%REACTION%' :: text)) AND + (((c.domain_id) :: text = 'Observation' :: text) OR + ((c.domain_id) :: text = 'Condition' :: text)) AND + ((c.invalid_reason) :: text <> 'D' :: text))))) + $sql$; + END create_observation_view +$$; \ No newline at end of file From 1f483e599c1267c07045fd719dc0a93c44589313 Mon Sep 17 00:00:00 2001 From: Pascal Brandt Date: Thu, 2 Jan 2020 17:27:36 -0800 Subject: [PATCH 6/7] =?UTF-8?q?=F0=9F=99=88=20Correct=20POM=20copy/paste?= =?UTF-8?q?=20error.?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- pom.xml | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/pom.xml b/pom.xml index 70247af..6d7ea5b 100644 --- a/pom.xml +++ b/pom.xml @@ -129,8 +129,8 @@ org.testcontainers junit-jupiter - 1.12.3 - ${testcontainers.version} + ${testcontainers.version} + test org.testcontainers From c821fc879686ff0c8e3edb93ede3c28090cc32d0 Mon Sep 17 00:00:00 2001 From: Pascal Brandt Date: Thu, 2 Jan 2020 19:31:46 -0800 Subject: [PATCH 7/7] =?UTF-8?q?=F0=9F=98=B8=20Relax=20measure=5Ftime=20req?= =?UTF-8?q?uirement=20and=20only=20check=20in=20current=20schema.?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- .../V1.0.3__Create_Observation_view.pg.sql | 23 ++++++++++++++++--- 1 file changed, 20 insertions(+), 3 deletions(-) diff --git a/src/main/resources/flyway/migrations/postgresql/V1.0.3__Create_Observation_view.pg.sql b/src/main/resources/flyway/migrations/postgresql/V1.0.3__Create_Observation_view.pg.sql index 8d538bf..1aa39df 100644 --- a/src/main/resources/flyway/migrations/postgresql/V1.0.3__Create_Observation_view.pg.sql +++ b/src/main/resources/flyway/migrations/postgresql/V1.0.3__Create_Observation_view.pg.sql @@ -4,11 +4,14 @@ $$ DECLARE obs_time_exists boolean := false; obs_time_col_string varchar := ''; + measurement_time_exists boolean := false; + measurement_col_string varchar := ''; BEGIN SELECT EXISTS(SELECT table_name FROM information_schema.columns WHERE table_name = 'observation' - AND column_name = 'observation_time') + AND column_name = 'observation_time' + AND table_schema = current_schema()) into obs_time_exists; CASE WHEN obs_time_exists = TRUE @@ -18,13 +21,27 @@ $$ obs_time_col_string = 'observation.observation_datetime::timestamp::time::varchar(10)'; END CASE; + SELECT EXISTS(SELECT table_name + FROM information_schema.columns + WHERE table_name = 'measurement' + AND column_name = 'measurement_time' + AND table_schema = current_schema()) + into measurement_time_exists; + + CASE WHEN measurement_time_exists = TRUE + THEN + measurement_col_string = 'measurement_time'; + ELSE + measurement_col_string = 'measurement.measurement_datetime::timestamp::time::varchar(10)'; + END CASE; + EXECUTE $sql$ CREATE view f_observation_view AS SELECT measurement.measurement_id AS observation_id, measurement.person_id, measurement.measurement_concept_id AS observation_concept_id, measurement.measurement_date AS observation_date, - measurement.measurement_time AS observation_time, + $sql$ || measurement_col_string || $sql$ AS observation_time, measurement.measurement_type_concept_id AS observation_type_concept_id, measurement.operator_concept_id AS observation_operator_concept_id, measurement.value_as_number, @@ -74,4 +91,4 @@ $$ ((c.invalid_reason) :: text <> 'D' :: text))))) $sql$; END create_observation_view -$$; \ No newline at end of file +$$;