Skip to content

Commit

Permalink
Add REST endpoint, which generates DDL for Result schema (#285)
Browse files Browse the repository at this point in the history
  • Loading branch information
marpozh authored and anthonysena committed Feb 7, 2018
1 parent efaca11 commit c92863d
Show file tree
Hide file tree
Showing 9 changed files with 523 additions and 15 deletions.
2 changes: 1 addition & 1 deletion pom.xml
Expand Up @@ -254,7 +254,7 @@
<dependency>
<groupId>com.amazon.redshift</groupId>
<artifactId>redshift-jdbc4-no-awssdk</artifactId>
<version>1.2.8.1005</version>
<version>1.2.10.1009</version>
</dependency>
</dependencies>
</dependencyManagement>
Expand Down
Expand Up @@ -23,6 +23,9 @@
import org.springframework.jdbc.datasource.DriverManagerDataSource;
import org.springframework.transaction.support.TransactionTemplate;

import java.sql.Connection;
import java.util.Properties;

/**
*
*/
Expand Down Expand Up @@ -112,6 +115,7 @@ public JdbcTemplate getJdbcTemplate() {
}

public JdbcTemplate getSourceJdbcTemplate(Source source) {

DriverManagerDataSource dataSource = new DriverManagerDataSource(source.getSourceConnection());
JdbcTemplate template = new JdbcTemplate(dataSource);
return template;
Expand Down
80 changes: 80 additions & 0 deletions src/main/java/org/ohdsi/webapi/service/DDLService.java
@@ -0,0 +1,80 @@
/*
*
* Copyright 2017 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.
*
* Authors: Maria Pozhidaeva
*
*/
package org.ohdsi.webapi.service;

import static org.ohdsi.webapi.service.SqlRenderService.translateSQL;

import java.util.Arrays;
import java.util.Collection;
import java.util.HashMap;
import javax.ws.rs.DefaultValue;
import javax.ws.rs.GET;
import javax.ws.rs.Path;
import javax.ws.rs.Produces;
import javax.ws.rs.QueryParam;
import org.ohdsi.circe.helper.ResourceHelper;
import org.ohdsi.webapi.sqlrender.SourceStatement;
import org.ohdsi.webapi.sqlrender.TranslatedStatement;
import org.springframework.stereotype.Component;

@Path("/ddl/")
@Component
public class DDLService {

private static final Collection<String> COMMON_COHORT_RESULT_FILE_PATHS = Arrays.asList(
"/db/cohort_results/cohort_feasiblity.sql",
"/db/cohort_results/cohort_features_results.sql",
"/db/cohort_results/ir_analysis.sql",
"/db/cohort_results/createHeraclesTables.sql");

private static final String INDEXES_COHORT_RESULT_FILE_PATHS = "/db/cohort_results/heracles_indexes.sql";
private static final Collection<String> DBMS_NO_INDEXES = Arrays.asList("redshift", "impala", "netezza");

@GET
@Path("results")
@Produces("text/plain")
public String generateResultSQL(@QueryParam("dialect") String dialect, @DefaultValue("results") @QueryParam("schema") String schema) {

StringBuilder sqlBuilder = new StringBuilder();
for (String fileName : COMMON_COHORT_RESULT_FILE_PATHS){
sqlBuilder.append("\n").append(ResourceHelper.GetResourceAsString(fileName));
}
if (dialect == null || DBMS_NO_INDEXES.stream().noneMatch(dbms -> dbms.equals(dialect.toLowerCase()))) {
sqlBuilder.append("\n").append(ResourceHelper.GetResourceAsString(INDEXES_COHORT_RESULT_FILE_PATHS));
}
String result = sqlBuilder.toString();
if(dialect != null){
result = translateSqlFile(result, dialect, schema);
}
return result.replaceAll(";", ";\n");
}

private String translateSqlFile(String sql, String dialect, String schema) {

SourceStatement statement = new SourceStatement();
statement.targetDialect = dialect.toLowerCase();
statement.sql = sql;
HashMap<String, String> parameters = new HashMap<>();
parameters.put("results_schema", schema);
statement.parameters = parameters;
TranslatedStatement translatedStatement = translateSQL(statement);
return translatedStatement.targetSQL;
}

}
36 changes: 22 additions & 14 deletions src/main/java/org/ohdsi/webapi/service/SqlRenderService.java
@@ -1,45 +1,53 @@
package org.ohdsi.webapi.service;

import java.util.HashMap;
import java.util.ArrayList;
import java.util.HashMap;
import javax.servlet.ServletContext;
import javax.ws.rs.Consumes;
import javax.ws.rs.POST;
import javax.ws.rs.Path;
import javax.ws.rs.Produces;
import javax.ws.rs.core.Context;
import javax.ws.rs.core.MediaType;

import org.ohdsi.sql.SqlRender;
import org.ohdsi.sql.SqlTranslate;
import org.ohdsi.webapi.sqlrender.SourceStatement;
import org.ohdsi.webapi.sqlrender.TranslatedStatement;
import org.springframework.beans.factory.annotation.Autowired;
import org.springframework.context.ApplicationContext;

/**
*
* @author Lee Evans
*/
@Path("/sqlrender/")
public class SqlRenderService {

@Context
ServletContext context;
@Autowired
ApplicationContext applicationContext;

@Path("translate")
@POST
@Produces(MediaType.APPLICATION_JSON)
@Consumes(MediaType.APPLICATION_JSON)
public TranslatedStatement translateSQL(SourceStatement sourceStatement) {
public TranslatedStatement translateSQLFromSourceStatement(SourceStatement sourceStatement) {

return translateSQL(sourceStatement);
}

static TranslatedStatement translateSQL(SourceStatement sourceStatement) {

TranslatedStatement translated = new TranslatedStatement();

try {

String parameterKeys[] = getMapKeys(sourceStatement.parameters);
String parameterValues[] = getMapValues(sourceStatement.parameters, parameterKeys);

String renderedSQL = SqlRender.renderSql(sourceStatement.sql, parameterKeys, parameterValues );
String renderedSQL = SqlRender.renderSql(sourceStatement.sql, parameterKeys, parameterValues);

if ((sourceStatement.targetDialect == null) || ("sql server".equals(sourceStatement.targetDialect))) {
translated.targetSQL = renderedSQL;
} else {
Expand All @@ -49,28 +57,28 @@ public TranslatedStatement translateSQL(SourceStatement sourceStatement) {
} catch (Exception exception) {
throw new RuntimeException(exception);
}

return translated;
}
private String[] getMapKeys(HashMap<String,String> parameters) {

private static String[] getMapKeys(HashMap<String, String> parameters) {
if (parameters == null) {
return null;
} else {
return parameters.keySet().toArray(new String[parameters.keySet().size()]);
}
}

private String[] getMapValues(HashMap<String,String> parameters, String[] parameterKeys) {
private static String[] getMapValues(HashMap<String, String> parameters, String[] parameterKeys) {
ArrayList<String> parameterValues = new ArrayList<>();
if (parameters == null) {
return null;
} else {
for (String parameterKey : parameterKeys) {
parameterValues.add((String) parameters.get(parameterKey));
parameterValues.add(parameters.get(parameterKey));
}
return parameterValues.toArray(new String[parameterValues.size()]);
}
}

}
54 changes: 54 additions & 0 deletions src/main/resources/db/cohort_results/cohort_feasiblity.sql
@@ -0,0 +1,54 @@
IF OBJECT_ID('@results_schema.cohort_inclusion', 'U') IS NULL
CREATE TABLE @results_schema.cohort_inclusion(
cohort_definition_id int NOT NULL,
rule_sequence int NOT NULL,
name varchar(255) NULL,
description varchar(1000) NULL
);

IF OBJECT_ID('@results_schema.cohort_inclusion_result', 'U') IS NULL
CREATE TABLE @results_schema.cohort_inclusion_result(
cohort_definition_id int NOT NULL,
inclusion_rule_mask bigint NOT NULL,
person_count bigint NOT NULL
);

IF OBJECT_ID('@results_schema.cohort_inclusion_stats', 'U') IS NULL
CREATE TABLE @results_schema.cohort_inclusion_stats(
cohort_definition_id int NOT NULL,
rule_sequence int NOT NULL,
person_count bigint NOT NULL,
gain_count bigint NOT NULL,
person_total bigint NOT NULL
);

IF OBJECT_ID('@results_schema.cohort_summary_stats', 'U') IS NULL
CREATE TABLE @results_schema.cohort_summary_stats(
cohort_definition_id int NOT NULL,
base_count bigint NOT NULL,
final_count bigint NOT NULL
);

IF OBJECT_ID('@results_schema.feas_study_result', 'U') IS NULL
CREATE TABLE $results_schema.feas_study_result(
study_id int NOT NULL,
inclusion_rule_mask bigint NOT NULL,
person_count bigint NOT NULL
);

IF OBJECT_ID('@results_schema.feas_study_inclusion_stats', 'U') IS NULL
CREATE TABLE $results_schema.feas_study_inclusion_stats(
study_id int NOT NULL,
rule_sequence int NOT NULL,
name varchar(255) NOT NULL,
person_count bigint NOT NULL,
gain_count bigint NOT NULL,
person_total bigint NOT NULL
);

IF OBJECT_ID('@results_schema.feas_study_index_stats', 'U') IS NULL
CREATE TABLE $results_schema.feas_study_index_stats(
study_id int NOT NULL,
person_count bigint NOT NULL,
match_count bigint NOT NULL
);
48 changes: 48 additions & 0 deletions src/main/resources/db/cohort_results/cohort_features_results.sql
@@ -0,0 +1,48 @@
IF OBJECT_ID('@results_schema.cohort_features_dist', 'U') IS NULL
CREATE TABLE @results_schema.cohort_features_dist
(
cohort_definition_id bigint,
covariate_id bigint,
count_value float,
min_value float,
max_value float,
average_value float,
standard_deviation float,
median_value float,
p10_value float,
p25_value float,
p75_value float,
p90_value float
);

IF OBJECT_ID('@results_schema.cohort_features', 'U') IS NULL
CREATE TABLE @results_schema.cohort_features
(
cohort_definition_id bigint,
covariate_id bigint,
sum_value bigint,
average_value float
);

IF OBJECT_ID('@results_schema.cohort_features_ref', 'U') IS NULL
CREATE TABLE @results_schema.cohort_features_ref
(
cohort_definition_id bigint,
covariate_id bigint,
covariate_name varchar(1000),
analysis_id int,
concept_id int
);

IF OBJECT_ID('@results_schema.cohort_features_analysis_ref', 'U') IS NULL
CREATE TABLE @results_schema.cohort_features_analysis_ref
(
cohort_definition_id bigint,
analysis_id int,
analysis_name varchar(1000),
domain_id varchar(100),
start_day int,
end_day int,
is_binary char,
missing_means_zero char
);

0 comments on commit c92863d

Please sign in to comment.