From 7fa4deb62c2aa79aa4b52fc496eb711acfbef30b Mon Sep 17 00:00:00 2001 From: Ajit Londhe Date: Tue, 2 Oct 2018 12:49:16 -0700 Subject: [PATCH] Brought back missing analyses, bugfixes for PG/Oracle, Redshift (#321) * Fix for #317 (more Oracle cast issues), #313 (allow vocabDatabaseSchema parameter in achillesHeel), #312 (convert cdmVersion to character). Also, some strange encoding in the exportToJson.R script. Removed redundant concept_hierarchy.sql file (this was supposed to be removed for 1.6). * Added analyses 822, 823, 1822, 1823 back. Fixed missing null cast in Heel RD 25. Adjusted analysis_details CSV to match new analyses. Added drop index statements. * Fixes to analysis_details CSV, analysis 1822 had the wrong field name, added drop if not null statements in dropAllScratchTables * Removed usage of DatabaseConnector::getTableNames() due to inconsistent effectiveness in Redshift * Updated version number to 1.6.1 --- DESCRIPTION | 6 +- R/Achilles.R | 30 +- R/AchillesHeel.R | 8 + R/exportToJson.R | 2 +- .../achilles/achilles_analysis_details.csv | 6 +- inst/sql/sql_server/analyses/1822.sql | 15 + inst/sql/sql_server/analyses/1823.sql | 15 + inst/sql/sql_server/analyses/822.sql | 15 + inst/sql/sql_server/analyses/823.sql | 15 + .../heels/parallel/heel_results/rule_10.sql | 2 +- .../heels/parallel/heel_results/rule_11.sql | 2 +- .../heels/parallel/heel_results/rule_12.sql | 2 +- .../heels/parallel/heel_results/rule_13.sql | 2 +- .../heels/parallel/heel_results/rule_14.sql | 2 +- .../heels/parallel/heel_results/rule_17.sql | 2 +- .../heels/parallel/heel_results/rule_4.sql | 2 +- .../heels/parallel/heel_results/rule_5.sql | 2 +- .../heels/parallel/heel_results/rule_7.sql | 2 +- .../heels/parallel/heel_results/rule_8.sql | 2 +- .../heels/parallel/heel_results/rule_9.sql | 2 +- .../heels/parallel/results_derived/25.sql | 2 +- .../post_processing/achilles_indices.sql | 5 + .../concept_hierarchies/condition.sql | 2 +- .../concept_hierarchies/drug.sql | 2 +- .../concept_hierarchies/drug_era.sql | 4 +- .../concept_hierarchies/measurement.sql | 4 +- .../concept_hierarchies/observation.sql | 4 +- .../concept_hierarchies/procedure.sql | 4 +- .../post_processing/concept_hierarchy.sql | 573 ------------------ man/achilles.Rd | 9 +- man/achillesHeel.Rd | 11 +- man/dropAllScratchTables.Rd | 7 +- man/exportDeathToJson.Rd | 5 +- man/exportDrugEraToJson.Rd | 5 +- man/exportDrugToJson.Rd | 5 +- man/exportHeelToJson.Rd | 5 +- man/exportMetaToJson.Rd | 5 +- man/exportPersonToJson.Rd | 5 +- man/exportToJson.Rd | 7 +- man/exportVisitToJson.Rd | 5 +- 40 files changed, 160 insertions(+), 643 deletions(-) create mode 100644 inst/sql/sql_server/analyses/1822.sql create mode 100644 inst/sql/sql_server/analyses/1823.sql create mode 100644 inst/sql/sql_server/analyses/822.sql create mode 100644 inst/sql/sql_server/analyses/823.sql delete mode 100755 inst/sql/sql_server/post_processing/concept_hierarchy.sql diff --git a/DESCRIPTION b/DESCRIPTION index 1372f95b..aec82c4f 100755 --- a/DESCRIPTION +++ b/DESCRIPTION @@ -1,8 +1,8 @@ Package: Achilles Type: Package Title: Creates descriptive statistics summary for an entire OMOP CDM instance -Version: 1.6 -Date: 2018-04-09 +Version: 1.6.1 +Date: 2018-10-02 Author: Patrick Ryan, Martijn Schuemie, Vojtech Huser, Chris Knoll, Ajit Londhe Maintainer: Patrick Ryan LazyData: true @@ -20,4 +20,4 @@ Suggests: R.utils License: Apache License Roxygen: list(wrap = FALSE) -RoxygenNote: 6.0.1 +RoxygenNote: 6.1.0 diff --git a/R/Achilles.R b/R/Achilles.R index f7046cbb..6ae3f18d 100755 --- a/R/Achilles.R +++ b/R/Achilles.R @@ -105,6 +105,8 @@ achilles <- function (connectionDetails, cdmVersion <- .getCdmVersion(connectionDetails, cdmDatabaseSchema) } + cdmVersion <- as.character(cdmVersion) + # Check CDM version is valid --------------------------------------------------------------------------------------------------- if (compareVersion(a = as.character(cdmVersion), b = "5") < 0) { @@ -839,9 +841,6 @@ dropAllScratchTables <- function(connectionDetails, connection <- DatabaseConnector::connect(connectionDetails = connectionDetails) - scratchTables <- lapply(DatabaseConnector::getTableNames(connection = connection, - databaseSchema = scratchDatabaseSchema), function(t) tolower(t)) - if ("achilles" %in% tableTypes) { # Drop Achilles Scratch Tables ------------------------------------------------------ @@ -856,13 +855,11 @@ dropAllScratchTables <- function(connectionDetails, sprintf("%s_dist_%d", tempAchillesPrefix, id) }) - dropTables <- c(Reduce(intersect, list(scratchTables, resultsTables)), - Reduce(intersect, list(scratchTables, resultsDistTables))) - - dropSqls <- lapply(dropTables, function(scratchTable) { - SqlRender::renderSql("drop table @scratchDatabaseSchema.@scratchTable;", - scratchDatabaseSchema = scratchDatabaseSchema, - scratchTable = scratchTable)$sql + dropSqls <- lapply(c(resultsTables, resultsDistTables), function(scratchTable) { + sql <- SqlRender::renderSql("IF OBJECT_ID('@scratchDatabaseSchema.@scratchTable', 'U') IS NOT NULL DROP TABLE @scratchDatabaseSchema.@scratchTable;", + scratchDatabaseSchema = scratchDatabaseSchema, + scratchTable = scratchTable)$sql + sql <- SqlRender::translateSql(sql = sql, targetDialect = connectionDetails$dbms)$sql }) cluster <- OhdsiRTools::makeCluster(numberOfThreads = numThreads, singleThreadToMain = TRUE) @@ -890,13 +887,12 @@ dropAllScratchTables <- function(connectionDetails, parallelHeelTables <- lapply(parallelFiles, function(t) tolower(paste(tempHeelPrefix, trimws(tools::file_path_sans_ext(basename(t))), sep = "_"))) - - dropTables <- Reduce(intersect, list(scratchTables, parallelHeelTables)) - dropSqls <- lapply(dropTables, function(scratchTable) { - SqlRender::renderSql("drop table @scratchDatabaseSchema.@scratchTable;", + dropSqls <- lapply(parallelHeelTables, function(scratchTable) { + sql <- SqlRender::renderSql("IF OBJECT_ID('@scratchDatabaseSchema.@scratchTable', 'U') IS NOT NULL DROP TABLE @scratchDatabaseSchema.@scratchTable;", scratchDatabaseSchema = scratchDatabaseSchema, scratchTable = scratchTable)$sql + sql <- SqlRender::translateSql(sql = sql, targetDialect = connectionDetails$dbms)$sql }) cluster <- OhdsiRTools::makeCluster(numberOfThreads = numThreads, singleThreadToMain = TRUE) @@ -924,12 +920,12 @@ dropAllScratchTables <- function(connectionDetails, conceptHierarchyTables <- lapply(hierarchySqlFiles, function(t) tolower(paste(tempAchillesPrefix, "ch", trimws(tools::file_path_sans_ext(basename(t))), sep = "_"))) - dropTables <- Reduce(intersect, list(scratchTables, conceptHierarchyTables)) - dropSqls <- lapply(dropTables, function(scratchTable) { - SqlRender::renderSql("drop table @scratchDatabaseSchema.@scratchTable;", + dropSqls <- lapply(conceptHierarchyTables, function(scratchTable) { + sql <- SqlRender::renderSql("IF OBJECT_ID('@scratchDatabaseSchema.@scratchTable', 'U') IS NOT NULL DROP TABLE @scratchDatabaseSchema.@scratchTable;", scratchDatabaseSchema = scratchDatabaseSchema, scratchTable = scratchTable)$sql + sql <- SqlRender::translateSql(sql = sql, targetDialect = connectionDetails$dbms)$sql }) cluster <- OhdsiRTools::makeCluster(numberOfThreads = numThreads, singleThreadToMain = TRUE) diff --git a/R/AchillesHeel.R b/R/AchillesHeel.R index e1b113b5..dd2fa1be 100755 --- a/R/AchillesHeel.R +++ b/R/AchillesHeel.R @@ -38,6 +38,7 @@ #' @param resultsDatabaseSchema string name of database schema that we can write final results to. Default is cdmDatabaseSchema. On SQL Server, this should specifiy both the database and the schema, #' so for example 'results.dbo'. #' @param scratchDatabaseSchema (OPTIONAL, multi-threaded mode) Name of a fully qualified schema that is accessible to/from the resultsDatabaseSchema, that can store all of the scratch tables. Default is resultsDatabaseSchema. +#' @param vocabDatabaseSchema String name of database schema that contains OMOP Vocabulary. Default is cdmDatabaseSchema. On SQL Server, this should specifiy both the database and the schema, so for example 'results.dbo'. #' @param cdmVersion Define the OMOP CDM version used: currently supports v5 and above. Default = "5". #' @param numThreads (OPTIONAL, multi-threaded mode) The number of threads to use to run Achilles in parallel. Default is 1 thread. #' @param tempHeelPrefix (OPTIONAL, multi-threaded mode) The prefix to use for the "temporary" (but actually permanent) Heel tables. Default is "tmpheel" @@ -55,6 +56,7 @@ #' cdmDatabaseSchema = "cdm", #' resultsDatabaseSchema = "results", #' scratchDatabaseSchema = "scratch", +#' vocabDatabaseSchema = "vocab", #' cdmVersion = "5.3.0", #' numThreads = 10) #' } @@ -63,6 +65,7 @@ achillesHeel <- function(connectionDetails, cdmDatabaseSchema, resultsDatabaseSchema = cdmDatabaseSchema, scratchDatabaseSchema = resultsDatabaseSchema, + vocabDatabaseSchema = cdmDatabaseSchema, cdmVersion = "5", numThreads = 1, tempHeelPrefix = "tmpheel", @@ -79,6 +82,8 @@ achillesHeel <- function(connectionDetails, cdmVersion <- .getCdmVersion(connectionDetails, cdmDatabaseSchema) } + cdmVersion <- as.character(cdmVersion) + # Check CDM version is valid --------------------------------------------------------------------------------------------------- if (compareVersion(a = cdmVersion, b = "5") < 0) { @@ -145,6 +150,7 @@ achillesHeel <- function(connectionDetails, cdmDatabaseSchema = cdmDatabaseSchema, resultsDatabaseSchema = resultsDatabaseSchema, scratchDatabaseSchema = scratchDatabaseSchema, + vocabDatabaseSchema = vocabDatabaseSchema, schemaDelim = schemaDelim, tempHeelPrefix = tempHeelPrefix, numThreads = numThreads, @@ -360,6 +366,7 @@ achillesHeel <- function(connectionDetails, cdmDatabaseSchema, resultsDatabaseSchema, scratchDatabaseSchema, + vocabDatabaseSchema, schemaDelim, tempHeelPrefix, numThreads, @@ -375,6 +382,7 @@ achillesHeel <- function(connectionDetails, cdmDatabaseSchema = cdmDatabaseSchema, resultsDatabaseSchema = resultsDatabaseSchema, scratchDatabaseSchema = scratchDatabaseSchema, + vocabDatabaseSchema = vocabDatabaseSchema, schemaDelim = schemaDelim, tempHeelPrefix = tempHeelPrefix, heelName = gsub(pattern = ".sql", replacement = "", x = basename(heelFile))) diff --git a/R/exportToJson.R b/R/exportToJson.R index 3d7148eb..de1522ae 100755 --- a/R/exportToJson.R +++ b/R/exportToJson.R @@ -1482,7 +1482,7 @@ generateObservationPeriodReport <- function(conn, dbms, cdmDatabaseSchema, resul # a. Visualization: scatterplot # b. X-axis: length of observation period # c. Y-axis: % of population observed - # d. Note: will look like a Kaplan-Meier ‘survival’ plot, but information is the same as shown in ‘length of observation’ barchart, just plotted as cumulative + # d. Note: will look like a Kaplan-Meier survival plot, but information is the same as shown in a length of observation barchart, just plotted as cumulative renderedSql <- SqlRender::loadRenderTranslateSql(sqlFilename = "export/observationperiod/cumulativeduration.sql", packageName = "Achilles", diff --git a/inst/csv/achilles/achilles_analysis_details.csv b/inst/csv/achilles/achilles_analysis_details.csv index 007fd64e..f6077043 100644 --- a/inst/csv/achilles/achilles_analysis_details.csv +++ b/inst/csv/achilles/achilles_analysis_details.csv @@ -118,6 +118,8 @@ ANALYSIS_ID,DISTRIBUTION,COST,DISTRIBUTED_FIELD,ANALYSIS_NAME,STRATUM_1_NAME,STR 814,0,0,,"Number of observation records with no value (numeric, string, or concept)",,,,, 815,1,0,,"Distribution of numeric values, by observation_concept_id and unit_concept_id",,,,, 820,0,0,,Number of observation records by observation start month,calendar month,,,, +822,0,0,,"Number of observation records, by observation_concept_id and value_as_concept_id",observation_concept_id,value_as_concept_id,,, +823,0,0,,"Number of observation records, by observation_concept_id and qualifier_concept_id",observation_concept_id,qualifier_concept_id,,, 891,0,0,,Percentage of total persons that have at least x observations,observation_concept_id,observation_person,,, 900,0,0,,"Number of persons with at least one drug era, by drug_concept_id",drug_concept_id,,,, 901,0,0,,"Number of drug era records, by drug_concept_id",drug_concept_id,,,, @@ -197,10 +199,12 @@ ANALYSIS_ID,DISTRIBUTION,COST,DISTRIBUTED_FIELD,ANALYSIS_NAME,STRATUM_1_NAME,STR 1814,0,0,,"Number of measurement records with no value (numeric, string, or concept)",,,,, 1815,1,0,,"Distribution of numeric values, by measurement_concept_id and unit_concept_id",,,,, 1816,1,0,,"Distribution of low range, by measurement_concept_id and unit_concept_id",,,,, -1817,1,0,,"Distribution of high range, by observation_concept_id and unit_concept_id",,,,, +1817,1,0,,"Distribution of high range, by measurement_concept_id and unit_concept_id",,,,, 1818,0,0,,"Number of measurement records below/within/above normal range, by measurement_concept_id and unit_concept_id",,,,, 1820,0,0,,Number of measurement records by measurement start month,calendar month,,,, 1821,0,0,,Number of measurement records with no numeric value,,,,, +1822,0,0,,"Number of measurement records, by measurement_concept_id and value_as_concept_id",measurement_concept_id,value_as_concept_id,,, +1823,0,0,,"Number of measurement records, by measurement_concept_id and operator_concept_id",measurement_concept_id,operator_concept_id,,, 1891,0,0,,Percentage of total persons that have at least x measurements,measurement_concept_id,measurement_person,,, 1900,0,0,,"Source values mapped to concept_id 0 by table, by source_value",table_name,source_value,,, 2000,0,0,,Number of patients with at least 1 Dx and 1 Rx,,,,, diff --git a/inst/sql/sql_server/analyses/1822.sql b/inst/sql/sql_server/analyses/1822.sql new file mode 100644 index 00000000..31264ed3 --- /dev/null +++ b/inst/sql/sql_server/analyses/1822.sql @@ -0,0 +1,15 @@ + +-- 1822 Number of measurement records, by measurement_concept_id and value_as_concept_id + +--HINT DISTRIBUTE_ON_KEY(stratum_1) +select + 1822 AS analysis_id, + cast(measurement_concept_id AS varchar(255)) AS stratum_1, + cast(value_as_concept_id AS varchar(255)) AS stratum_2, + cast(null as varchar(255)) as stratum_3, + cast(null as varchar(255)) as stratum_4, + cast(null as varchar(255)) as stratum_5, + count_big(*) AS count_value +into @scratchDatabaseSchema@schemaDelim@tempAchillesPrefix_1822 +from @cdmDatabaseSchema.measurement +group by measurement_concept_id, value_as_concept_id; \ No newline at end of file diff --git a/inst/sql/sql_server/analyses/1823.sql b/inst/sql/sql_server/analyses/1823.sql new file mode 100644 index 00000000..e2a75a2e --- /dev/null +++ b/inst/sql/sql_server/analyses/1823.sql @@ -0,0 +1,15 @@ + +-- 1823 Number of measurement records, by measurement_concept_id and operator_concept_id + +--HINT DISTRIBUTE_ON_KEY(stratum_1) +select + 1823 AS analysis_id, + cast(measurement_concept_id AS varchar(255)) AS stratum_1, + cast(operator_concept_id AS varchar(255)) AS stratum_2, + cast(null as varchar(255)) as stratum_3, + cast(null as varchar(255)) as stratum_4, + cast(null as varchar(255)) as stratum_5, + count_big(*) AS count_value +into @scratchDatabaseSchema@schemaDelim@tempAchillesPrefix_1823 +from @cdmDatabaseSchema.measurement +group by measurement_concept_id, operator_concept_id \ No newline at end of file diff --git a/inst/sql/sql_server/analyses/822.sql b/inst/sql/sql_server/analyses/822.sql new file mode 100644 index 00000000..46a7435f --- /dev/null +++ b/inst/sql/sql_server/analyses/822.sql @@ -0,0 +1,15 @@ + +-- 822 Number of observation records, by observation_concept_id and value_as_concept_id, observation_concept_id + +--HINT DISTRIBUTE_ON_KEY(stratum_1) +select + 822 AS analysis_id, + cast(observation_concept_id AS varchar(255)) AS stratum_1, + cast(value_as_concept_id AS varchar(255)) AS stratum_2, + cast(null as varchar(255)) as stratum_3, + cast(null as varchar(255)) as stratum_4, + cast(null as varchar(255)) as stratum_5, + count_big(*) AS count_value +into @scratchDatabaseSchema@schemaDelim@tempAchillesPrefix_822 +from @cdmDatabaseSchema.observation +group by observation_concept_id, value_as_concept_id; \ No newline at end of file diff --git a/inst/sql/sql_server/analyses/823.sql b/inst/sql/sql_server/analyses/823.sql new file mode 100644 index 00000000..782ca974 --- /dev/null +++ b/inst/sql/sql_server/analyses/823.sql @@ -0,0 +1,15 @@ + +-- 823 Number of observation records, by observation_concept_id and qualifier_concept_id + +--HINT DISTRIBUTE_ON_KEY(stratum_1) +select + 823 AS analysis_id, + cast(observation_concept_id AS varchar(255)) AS stratum_1, + cast(qualifier_concept_id AS varchar(255)) AS stratum_2, + cast(null as varchar(255)) as stratum_3, + cast(null as varchar(255)) as stratum_4, + cast(null as varchar(255)) as stratum_5, + count_big(*) AS count_value +into @scratchDatabaseSchema@schemaDelim@tempAchillesPrefix_823 +from @cdmDatabaseSchema.observation +group by observation_concept_id, qualifier_concept_id; \ No newline at end of file diff --git a/inst/sql/sql_server/heels/parallel/heel_results/rule_10.sql b/inst/sql/sql_server/heels/parallel/heel_results/rule_10.sql index 75541ced..2797559f 100755 --- a/inst/sql/sql_server/heels/parallel/heel_results/rule_10.sql +++ b/inst/sql/sql_server/heels/parallel/heel_results/rule_10.sql @@ -16,7 +16,7 @@ from FROM @resultsDatabaseSchema.ACHILLES_results or1 INNER JOIN @resultsDatabaseSchema.ACHILLES_analysis oa1 ON or1.analysis_id = oa1.analysis_id - INNER JOIN @cdmDatabaseSchema.concept c1 + INNER JOIN @vocabDatabaseSchema.concept c1 ON or1.stratum_1 = CAST(c1.concept_id AS VARCHAR(19)) WHERE or1.analysis_id IN (202) AND or1.stratum_1 IS NOT NULL diff --git a/inst/sql/sql_server/heels/parallel/heel_results/rule_11.sql b/inst/sql/sql_server/heels/parallel/heel_results/rule_11.sql index f9df6a59..394d3aa3 100755 --- a/inst/sql/sql_server/heels/parallel/heel_results/rule_11.sql +++ b/inst/sql/sql_server/heels/parallel/heel_results/rule_11.sql @@ -16,7 +16,7 @@ from FROM @resultsDatabaseSchema.ACHILLES_results or1 INNER JOIN @resultsDatabaseSchema.ACHILLES_analysis oa1 ON or1.analysis_id = oa1.analysis_id - INNER JOIN @cdmDatabaseSchema.concept c1 + INNER JOIN @vocabDatabaseSchema.concept c1 ON or1.stratum_1 = CAST(c1.concept_id AS VARCHAR(19)) WHERE or1.analysis_id IN (301) AND or1.stratum_1 IS NOT NULL diff --git a/inst/sql/sql_server/heels/parallel/heel_results/rule_12.sql b/inst/sql/sql_server/heels/parallel/heel_results/rule_12.sql index 9737ed42..f2ed9ba8 100755 --- a/inst/sql/sql_server/heels/parallel/heel_results/rule_12.sql +++ b/inst/sql/sql_server/heels/parallel/heel_results/rule_12.sql @@ -16,7 +16,7 @@ from FROM @resultsDatabaseSchema.ACHILLES_results or1 INNER JOIN @resultsDatabaseSchema.ACHILLES_analysis oa1 ON or1.analysis_id = oa1.analysis_id - INNER JOIN @cdmDatabaseSchema.concept c1 + INNER JOIN @vocabDatabaseSchema.concept c1 ON or1.stratum_1 = CAST(c1.concept_id AS VARCHAR(19)) WHERE or1.analysis_id IN ( 400, diff --git a/inst/sql/sql_server/heels/parallel/heel_results/rule_13.sql b/inst/sql/sql_server/heels/parallel/heel_results/rule_13.sql index 2387efe7..bd9482b0 100755 --- a/inst/sql/sql_server/heels/parallel/heel_results/rule_13.sql +++ b/inst/sql/sql_server/heels/parallel/heel_results/rule_13.sql @@ -16,7 +16,7 @@ from FROM @resultsDatabaseSchema.ACHILLES_results or1 INNER JOIN @resultsDatabaseSchema.ACHILLES_analysis oa1 ON or1.analysis_id = oa1.analysis_id - INNER JOIN @cdmDatabaseSchema.concept c1 + INNER JOIN @vocabDatabaseSchema.concept c1 ON or1.stratum_1 = CAST(c1.concept_id AS VARCHAR(19)) WHERE or1.analysis_id IN ( 700, diff --git a/inst/sql/sql_server/heels/parallel/heel_results/rule_14.sql b/inst/sql/sql_server/heels/parallel/heel_results/rule_14.sql index 0de7eb38..cf97f9d9 100755 --- a/inst/sql/sql_server/heels/parallel/heel_results/rule_14.sql +++ b/inst/sql/sql_server/heels/parallel/heel_results/rule_14.sql @@ -16,7 +16,7 @@ from FROM @resultsDatabaseSchema.ACHILLES_results or1 INNER JOIN @resultsDatabaseSchema.ACHILLES_analysis oa1 ON or1.analysis_id = oa1.analysis_id - INNER JOIN @cdmDatabaseSchema.concept c1 + INNER JOIN @vocabDatabaseSchema.concept c1 ON or1.stratum_1 = CAST(c1.concept_id AS VARCHAR(19)) WHERE or1.analysis_id IN (600) AND or1.stratum_1 IS NOT NULL diff --git a/inst/sql/sql_server/heels/parallel/heel_results/rule_17.sql b/inst/sql/sql_server/heels/parallel/heel_results/rule_17.sql index 02a4df15..7b3e99cc 100755 --- a/inst/sql/sql_server/heels/parallel/heel_results/rule_17.sql +++ b/inst/sql/sql_server/heels/parallel/heel_results/rule_17.sql @@ -16,7 +16,7 @@ from FROM @resultsDatabaseSchema.ACHILLES_results or1 INNER JOIN @resultsDatabaseSchema.ACHILLES_analysis oa1 ON or1.analysis_id = oa1.analysis_id - INNER JOIN @cdmDatabaseSchema.concept c1 + INNER JOIN @vocabDatabaseSchema.concept c1 ON or1.stratum_1 = CAST(c1.concept_id AS VARCHAR(19)) WHERE or1.analysis_id IN (1610) AND or1.stratum_1 IS NOT NULL diff --git a/inst/sql/sql_server/heels/parallel/heel_results/rule_4.sql b/inst/sql/sql_server/heels/parallel/heel_results/rule_4.sql index b1ce7c82..42b3358a 100755 --- a/inst/sql/sql_server/heels/parallel/heel_results/rule_4.sql +++ b/inst/sql/sql_server/heels/parallel/heel_results/rule_4.sql @@ -16,7 +16,7 @@ from FROM @resultsDatabaseSchema.ACHILLES_results or1 INNER JOIN @resultsDatabaseSchema.ACHILLES_analysis oa1 ON or1.analysis_id = oa1.analysis_id - LEFT JOIN @cdmDatabaseSchema.concept c1 + LEFT JOIN @vocabDatabaseSchema.concept c1 ON or1.stratum_1 = CAST(c1.concept_id AS VARCHAR(19)) WHERE or1.analysis_id IN ( 2, diff --git a/inst/sql/sql_server/heels/parallel/heel_results/rule_5.sql b/inst/sql/sql_server/heels/parallel/heel_results/rule_5.sql index 98caba70..d50f846c 100755 --- a/inst/sql/sql_server/heels/parallel/heel_results/rule_5.sql +++ b/inst/sql/sql_server/heels/parallel/heel_results/rule_5.sql @@ -19,7 +19,7 @@ from FROM @resultsDatabaseSchema.ACHILLES_results or1 INNER JOIN @resultsDatabaseSchema.ACHILLES_analysis oa1 ON or1.analysis_id = oa1.analysis_id - LEFT JOIN @cdmDatabaseSchema.concept c1 + LEFT JOIN @vocabDatabaseSchema.concept c1 ON or1.stratum_2 = CAST(c1.concept_id AS VARCHAR(19)) WHERE or1.analysis_id IN ( 405, diff --git a/inst/sql/sql_server/heels/parallel/heel_results/rule_7.sql b/inst/sql/sql_server/heels/parallel/heel_results/rule_7.sql index 32a65194..5f44db0c 100755 --- a/inst/sql/sql_server/heels/parallel/heel_results/rule_7.sql +++ b/inst/sql/sql_server/heels/parallel/heel_results/rule_7.sql @@ -17,7 +17,7 @@ from FROM @resultsDatabaseSchema.ACHILLES_results or1 INNER JOIN @resultsDatabaseSchema.ACHILLES_analysis oa1 ON or1.analysis_id = oa1.analysis_id - INNER JOIN @cdmDatabaseSchema.concept c1 + INNER JOIN @vocabDatabaseSchema.concept c1 ON or1.stratum_1 = CAST(c1.concept_id AS VARCHAR(19)) WHERE or1.analysis_id IN (2) AND or1.stratum_1 IS NOT NULL diff --git a/inst/sql/sql_server/heels/parallel/heel_results/rule_8.sql b/inst/sql/sql_server/heels/parallel/heel_results/rule_8.sql index 824b5d09..06ca3cda 100755 --- a/inst/sql/sql_server/heels/parallel/heel_results/rule_8.sql +++ b/inst/sql/sql_server/heels/parallel/heel_results/rule_8.sql @@ -16,7 +16,7 @@ from FROM @resultsDatabaseSchema.ACHILLES_results or1 INNER JOIN @resultsDatabaseSchema.ACHILLES_analysis oa1 ON or1.analysis_id = oa1.analysis_id - INNER JOIN @cdmDatabaseSchema.concept c1 + INNER JOIN @vocabDatabaseSchema.concept c1 ON or1.stratum_1 = CAST(c1.concept_id AS VARCHAR(19)) WHERE or1.analysis_id IN (4) AND or1.stratum_1 IS NOT NULL diff --git a/inst/sql/sql_server/heels/parallel/heel_results/rule_9.sql b/inst/sql/sql_server/heels/parallel/heel_results/rule_9.sql index 4271cc61..ff718093 100755 --- a/inst/sql/sql_server/heels/parallel/heel_results/rule_9.sql +++ b/inst/sql/sql_server/heels/parallel/heel_results/rule_9.sql @@ -16,7 +16,7 @@ from FROM @resultsDatabaseSchema.ACHILLES_results or1 INNER JOIN @resultsDatabaseSchema.ACHILLES_analysis oa1 ON or1.analysis_id = oa1.analysis_id - INNER JOIN @cdmDatabaseSchema.concept c1 + INNER JOIN @vocabDatabaseSchema.concept c1 ON or1.stratum_1 = CAST(c1.concept_id AS VARCHAR(19)) WHERE or1.analysis_id IN (5) AND or1.stratum_1 IS NOT NULL diff --git a/inst/sql/sql_server/heels/parallel/results_derived/25.sql b/inst/sql/sql_server/heels/parallel/results_derived/25.sql index 6a51a0ad..89c9dcba 100755 --- a/inst/sql/sql_server/heels/parallel/results_derived/25.sql +++ b/inst/sql/sql_server/heels/parallel/results_derived/25.sql @@ -17,7 +17,7 @@ from ( --100000+analysis_id, select - NULL as analysis_id, + cast(null as int) as analysis_id, stratum_2 as stratum_1, cast(null as varchar(255)) as stratum_2, count_value, diff --git a/inst/sql/sql_server/post_processing/achilles_indices.sql b/inst/sql/sql_server/post_processing/achilles_indices.sql index e25264b0..e5c13205 100755 --- a/inst/sql/sql_server/post_processing/achilles_indices.sql +++ b/inst/sql/sql_server/post_processing/achilles_indices.sql @@ -39,10 +39,15 @@ CREATE CLUSTERED COLUMNSTORE INDEX ClusteredIndex_Achilles_results ON @resultsDatabaseSchema.ACHILLES_results; } + +DROP INDEX IF EXISTS idx_ar_aid on @resultsDatabaseSchema.ACHILLES_results (analysis_id); CREATE INDEX idx_ar_aid ON @resultsDatabaseSchema.ACHILLES_results (analysis_id); + +DROP INDEX IF EXISTS idx_ar_s1 on @resultsDatabaseSchema.ACHILLES_results (stratum_1); CREATE INDEX idx_ar_s1 ON @resultsDatabaseSchema.ACHILLES_results (stratum_1); + CREATE INDEX idx_ar_s2 ON @resultsDatabaseSchema.ACHILLES_results (stratum_2); CREATE INDEX idx_ar_aid_s1 diff --git a/inst/sql/sql_server/post_processing/concept_hierarchies/condition.sql b/inst/sql/sql_server/post_processing/concept_hierarchies/condition.sql index 46dfce8f..f3793989 100755 --- a/inst/sql/sql_server/post_processing/concept_hierarchies/condition.sql +++ b/inst/sql/sql_server/post_processing/concept_hierarchies/condition.sql @@ -5,7 +5,7 @@ snomed.concept_id, snomed.concept_name AS concept_name, 'Condition' AS treemap, - null as concept_hierarchy_type, + cast(null as varchar(20)) as concept_hierarchy_type, pt_to_hlt.pt_concept_name as level1_concept_name, hlt_to_hlgt.hlt_concept_name as level2_concept_name, hlgt_to_soc.hlgt_concept_name as level3_concept_name, diff --git a/inst/sql/sql_server/post_processing/concept_hierarchies/drug.sql b/inst/sql/sql_server/post_processing/concept_hierarchies/drug.sql index 141314ed..6ba7aef9 100755 --- a/inst/sql/sql_server/post_processing/concept_hierarchies/drug.sql +++ b/inst/sql/sql_server/post_processing/concept_hierarchies/drug.sql @@ -5,7 +5,7 @@ rxnorm.concept_id, rxnorm.concept_name AS concept_name, 'Drug' AS treemap, - null as concept_hierarchy_type, + cast(null as varchar(20)) as concept_hierarchy_type, rxnorm.rxnorm_ingredient_concept_name as level1_concept_name, atc5_to_atc3.atc5_concept_name as level2_concept_name, atc3_to_atc1.atc3_concept_name as level3_concept_name, diff --git a/inst/sql/sql_server/post_processing/concept_hierarchies/drug_era.sql b/inst/sql/sql_server/post_processing/concept_hierarchies/drug_era.sql index ee6c5b28..0602ad62 100755 --- a/inst/sql/sql_server/post_processing/concept_hierarchies/drug_era.sql +++ b/inst/sql/sql_server/post_processing/concept_hierarchies/drug_era.sql @@ -5,11 +5,11 @@ rxnorm.rxnorm_ingredient_concept_id as concept_id, rxnorm.rxnorm_ingredient_concept_name as concept_name, 'Drug Era' AS treemap, - null as concept_hierarchy_type, + cast(null as varchar(20)) as concept_hierarchy_type, atc5_to_atc3.atc5_concept_name as level1_concept_name, atc3_to_atc1.atc3_concept_name as level2_concept_name, atc1.concept_name as level3_concept_name, - null as level4_concept_name + cast(null as varchar(255)) as level4_concept_name into @scratchDatabaseSchema@schemaDelim@tempAchillesPrefix_ch_drug_era FROM ( diff --git a/inst/sql/sql_server/post_processing/concept_hierarchies/measurement.sql b/inst/sql/sql_server/post_processing/concept_hierarchies/measurement.sql index 5e97fc8c..b7279233 100755 --- a/inst/sql/sql_server/post_processing/concept_hierarchies/measurement.sql +++ b/inst/sql/sql_server/post_processing/concept_hierarchies/measurement.sql @@ -5,11 +5,11 @@ m.concept_id, m.concept_name, 'Measurement' AS treemap, - null as concept_hierarchy_type, + cast(null as varchar(20)) as concept_hierarchy_type, max(c1.concept_name) AS level1_concept_name, max(c2.concept_name) AS level2_concept_name, max(c3.concept_name) AS level3_concept_name, - null as level4_concept_name + cast(null as varchar(255)) as level4_concept_name into @scratchDatabaseSchema@schemaDelim@tempAchillesPrefix_ch_measurement FROM ( diff --git a/inst/sql/sql_server/post_processing/concept_hierarchies/observation.sql b/inst/sql/sql_server/post_processing/concept_hierarchies/observation.sql index 78646439..f7fbd91f 100755 --- a/inst/sql/sql_server/post_processing/concept_hierarchies/observation.sql +++ b/inst/sql/sql_server/post_processing/concept_hierarchies/observation.sql @@ -5,11 +5,11 @@ obs.concept_id, obs.concept_name, 'Observation' AS treemap, - null as concept_hierarchy_type, + cast(null as varchar(20)) as concept_hierarchy_type, max(c1.concept_name) AS level1_concept_name, max(c2.concept_name) AS level2_concept_name, max(c3.concept_name) AS level3_concept_name, - null as level4_concept_name + cast(null as varchar(255)) as level4_concept_name into @scratchDatabaseSchema@schemaDelim@tempAchillesPrefix_ch_observation FROM ( diff --git a/inst/sql/sql_server/post_processing/concept_hierarchies/procedure.sql b/inst/sql/sql_server/post_processing/concept_hierarchies/procedure.sql index db2a17e5..e3c3ded5 100755 --- a/inst/sql/sql_server/post_processing/concept_hierarchies/procedure.sql +++ b/inst/sql/sql_server/post_processing/concept_hierarchies/procedure.sql @@ -5,11 +5,11 @@ procs.concept_id, procs.proc_concept_name as concept_name, 'Procedure' AS treemap, - null as concept_hierarchy_type, + cast(null as varchar(20)) as concept_hierarchy_type, max(proc_hierarchy.os3_concept_name) AS level1_concept_name, max(proc_hierarchy.os2_concept_name) AS level2_concept_name, max(proc_hierarchy.os1_concept_name) AS level3_concept_name, - null as level4_concept_name + cast(null as varchar(255)) as level4_concept_name into @scratchDatabaseSchema@schemaDelim@tempAchillesPrefix_ch_procedure FROM ( diff --git a/inst/sql/sql_server/post_processing/concept_hierarchy.sql b/inst/sql/sql_server/post_processing/concept_hierarchy.sql deleted file mode 100755 index 63abc525..00000000 --- a/inst/sql/sql_server/post_processing/concept_hierarchy.sql +++ /dev/null @@ -1,573 +0,0 @@ -{DEFAULT @resultsDatabaseSchema = 'webapi.dbo'} -{DEFAULT @vocabDatabaseSchema = 'omopcdm.dbo'} - -/*********************************************************************/ -/***** Create hierarchy lookup table for the treemap hierarchies *****/ -/*********************************************************************/ -IF OBJECT_ID('@resultsDatabaseSchema.concept_hierarchy', 'U') IS NOT NULL - DROP TABLE @resultsDatabaseSchema.concept_hierarchy; - - -/***********************************************************/ -/***** Populate the hierarchy lookup table per treemap *****/ -/***********************************************************/ -/********** CONDITION/CONDITION_ERA **********/ - - - SELECT - snomed.concept_id, - snomed.concept_name AS concept_name, - 'Condition' AS treemap, - null as concept_hierarchy_type, - pt_to_hlt.pt_concept_name as level1_concept_name, - hlt_to_hlgt.hlt_concept_name as level2_concept_name, - hlgt_to_soc.hlgt_concept_name as level3_concept_name, - soc.concept_name AS level4_concept_name -into #ch_condition - - FROM - ( - SELECT - concept_id, - concept_name - FROM @vocabDatabaseSchema.concept - WHERE domain_id = 'Condition' - ) snomed - LEFT JOIN - (SELECT - c1.concept_id AS snomed_concept_id, - max(c2.concept_id) AS pt_concept_id - FROM - @vocabDatabaseSchema.concept c1 - INNER JOIN - @vocabDatabaseSchema.concept_ancestor ca1 - ON c1.concept_id = ca1.descendant_concept_id - AND c1.domain_id = 'Condition' - AND ca1.min_levels_of_separation = 1 - INNER JOIN - @vocabDatabaseSchema.concept c2 - ON ca1.ancestor_concept_id = c2.concept_id - AND c2.vocabulary_id = 'MedDRA' - GROUP BY c1.concept_id - ) snomed_to_pt - ON snomed.concept_id = snomed_to_pt.snomed_concept_id - - LEFT JOIN - (SELECT - c1.concept_id AS pt_concept_id, - c1.concept_name AS pt_concept_name, - max(c2.concept_id) AS hlt_concept_id - FROM - @vocabDatabaseSchema.concept c1 - INNER JOIN - @vocabDatabaseSchema.concept_ancestor ca1 - ON c1.concept_id = ca1.descendant_concept_id - AND c1.vocabulary_id = 'MedDRA' - AND ca1.min_levels_of_separation = 1 - INNER JOIN - @vocabDatabaseSchema.concept c2 - ON ca1.ancestor_concept_id = c2.concept_id - AND c2.vocabulary_id = 'MedDRA' - GROUP BY c1.concept_id, c1.concept_name - ) pt_to_hlt - ON snomed_to_pt.pt_concept_id = pt_to_hlt.pt_concept_id - - LEFT JOIN - (SELECT - c1.concept_id AS hlt_concept_id, - c1.concept_name AS hlt_concept_name, - max(c2.concept_id) AS hlgt_concept_id - FROM - @vocabDatabaseSchema.concept c1 - INNER JOIN - @vocabDatabaseSchema.concept_ancestor ca1 - ON c1.concept_id = ca1.descendant_concept_id - AND c1.vocabulary_id = 'MedDRA' - AND ca1.min_levels_of_separation = 1 - INNER JOIN - @vocabDatabaseSchema.concept c2 - ON ca1.ancestor_concept_id = c2.concept_id - AND c2.vocabulary_id = 'MedDRA' - GROUP BY c1.concept_id, c1.concept_name - ) hlt_to_hlgt - ON pt_to_hlt.hlt_concept_id = hlt_to_hlgt.hlt_concept_id - - LEFT JOIN - (SELECT - c1.concept_id AS hlgt_concept_id, - c1.concept_name AS hlgt_concept_name, - max(c2.concept_id) AS soc_concept_id - FROM - @vocabDatabaseSchema.concept c1 - INNER JOIN - @vocabDatabaseSchema.concept_ancestor ca1 - ON c1.concept_id = ca1.descendant_concept_id - AND c1.vocabulary_id = 'MedDRA' - AND ca1.min_levels_of_separation = 1 - INNER JOIN - @vocabDatabaseSchema.concept c2 - ON ca1.ancestor_concept_id = c2.concept_id - AND c2.vocabulary_id = 'MedDRA' - GROUP BY c1.concept_id, c1.concept_name - ) hlgt_to_soc - ON hlt_to_hlgt.hlgt_concept_id = hlgt_to_soc.hlgt_concept_id - - LEFT JOIN @vocabDatabaseSchema.concept soc - ON hlgt_to_soc.soc_concept_id = soc.concept_id; - -/********** DRUG **********/ - - SELECT - rxnorm.concept_id, - rxnorm.concept_name AS concept_name, - 'Drug' AS treemap, - null as concept_hierarchy_type, - rxnorm.rxnorm_ingredient_concept_name as level1_concept_name, - atc5_to_atc3.atc5_concept_name as level2_concept_name, - atc3_to_atc1.atc3_concept_name as level3_concept_name, - atc1.concept_name AS level4_concept_name -into #ch_drug - FROM - ( - SELECT - c1.concept_id, - c1.concept_name, - c2.concept_id AS rxnorm_ingredient_concept_id, - c2.concept_name AS RxNorm_ingredient_concept_name - FROM @vocabDatabaseSchema.concept c1 - INNER JOIN @vocabDatabaseSchema.concept_ancestor ca1 - ON c1.concept_id = ca1.descendant_concept_id - AND c1.domain_id = 'Drug' - INNER JOIN @vocabDatabaseSchema.concept c2 - ON ca1.ancestor_concept_id = c2.concept_id - AND c2.domain_id = 'Drug' - AND c2.concept_class_id = 'Ingredient' - ) rxnorm - LEFT JOIN - (SELECT - c1.concept_id AS rxnorm_ingredient_concept_id, - max(c2.concept_id) AS atc5_concept_id - FROM - @vocabDatabaseSchema.concept c1 - INNER JOIN - @vocabDatabaseSchema.concept_ancestor ca1 - ON c1.concept_id = ca1.descendant_concept_id - AND c1.domain_id = 'Drug' - AND c1.concept_class_id = 'Ingredient' - INNER JOIN - @vocabDatabaseSchema.concept c2 - ON ca1.ancestor_concept_id = c2.concept_id - AND c2.vocabulary_id = 'ATC' - AND c2.concept_class_id = 'ATC 4th' - GROUP BY c1.concept_id - ) rxnorm_to_atc5 - ON rxnorm.rxnorm_ingredient_concept_id = rxnorm_to_atc5.rxnorm_ingredient_concept_id - - LEFT JOIN - (SELECT - c1.concept_id AS atc5_concept_id, - c1.concept_name AS atc5_concept_name, - max(c2.concept_id) AS atc3_concept_id - FROM - @vocabDatabaseSchema.concept c1 - INNER JOIN - @vocabDatabaseSchema.concept_ancestor ca1 - ON c1.concept_id = ca1.descendant_concept_id - AND c1.vocabulary_id = 'ATC' - AND c1.concept_class_id = 'ATC 4th' - INNER JOIN - @vocabDatabaseSchema.concept c2 - ON ca1.ancestor_concept_id = c2.concept_id - AND c2.vocabulary_id = 'ATC' - AND c2.concept_class_id = 'ATC 2nd' - GROUP BY c1.concept_id, c1.concept_name - ) atc5_to_atc3 - ON rxnorm_to_atc5.atc5_concept_id = atc5_to_atc3.atc5_concept_id - - LEFT JOIN - (SELECT - c1.concept_id AS atc3_concept_id, - c1.concept_name AS atc3_concept_name, - max(c2.concept_id) AS atc1_concept_id - FROM - @vocabDatabaseSchema.concept c1 - INNER JOIN - @vocabDatabaseSchema.concept_ancestor ca1 - ON c1.concept_id = ca1.descendant_concept_id - AND c1.vocabulary_id = 'ATC' - AND c1.concept_class_id = 'ATC 2nd' - INNER JOIN - @vocabDatabaseSchema.concept c2 - ON ca1.ancestor_concept_id = c2.concept_id - AND c2.vocabulary_id = 'ATC' - AND c2.concept_class_id = 'ATC 1st' - GROUP BY c1.concept_id, c1.concept_name - ) atc3_to_atc1 - ON atc5_to_atc3.atc3_concept_id = atc3_to_atc1.atc3_concept_id - - LEFT JOIN @vocabDatabaseSchema.concept atc1 - ON atc3_to_atc1.atc1_concept_id = atc1.concept_id; - -/********** DRUG_ERA **********/ - - SELECT - rxnorm.rxnorm_ingredient_concept_id as concept_id, - rxnorm.rxnorm_ingredient_concept_name as concept_name, - 'Drug Era' AS treemap, - null as concept_hierarchy_type, - atc5_to_atc3.atc5_concept_name as level1_concept_name, - atc3_to_atc1.atc3_concept_name as level2_concept_name, - atc1.concept_name as level3_concept_name, - null as level4_concept_name -into #ch_drug_era - FROM - ( - SELECT - c2.concept_id AS rxnorm_ingredient_concept_id, - c2.concept_name AS RxNorm_ingredient_concept_name - FROM - @vocabDatabaseSchema.concept c2 - WHERE - c2.domain_id = 'Drug' - AND c2.concept_class_id = 'Ingredient' - ) rxnorm - LEFT JOIN - (SELECT - c1.concept_id AS rxnorm_ingredient_concept_id, - max(c2.concept_id) AS atc5_concept_id - FROM - @vocabDatabaseSchema.concept c1 - INNER JOIN - @vocabDatabaseSchema.concept_ancestor ca1 - ON c1.concept_id = ca1.descendant_concept_id - AND c1.domain_id = 'Drug' - AND c1.concept_class_id = 'Ingredient' - INNER JOIN - @vocabDatabaseSchema.concept c2 - ON ca1.ancestor_concept_id = c2.concept_id - AND c2.vocabulary_id = 'ATC' - AND c2.concept_class_id = 'ATC 4th' - GROUP BY c1.concept_id - ) rxnorm_to_atc5 - ON rxnorm.rxnorm_ingredient_concept_id = rxnorm_to_atc5.rxnorm_ingredient_concept_id - - LEFT JOIN - (SELECT - c1.concept_id AS atc5_concept_id, - c1.concept_name AS atc5_concept_name, - max(c2.concept_id) AS atc3_concept_id - FROM - @vocabDatabaseSchema.concept c1 - INNER JOIN - @vocabDatabaseSchema.concept_ancestor ca1 - ON c1.concept_id = ca1.descendant_concept_id - AND c1.vocabulary_id = 'ATC' - AND c1.concept_class_id = 'ATC 4th' - INNER JOIN - @vocabDatabaseSchema.concept c2 - ON ca1.ancestor_concept_id = c2.concept_id - AND c2.vocabulary_id = 'ATC' - AND c2.concept_class_id = 'ATC 2nd' - GROUP BY c1.concept_id, c1.concept_name - ) atc5_to_atc3 - ON rxnorm_to_atc5.atc5_concept_id = atc5_to_atc3.atc5_concept_id - - LEFT JOIN - (SELECT - c1.concept_id AS atc3_concept_id, - c1.concept_name AS atc3_concept_name, - max(c2.concept_id) AS atc1_concept_id - FROM - @vocabDatabaseSchema.concept c1 - INNER JOIN - @vocabDatabaseSchema.concept_ancestor ca1 - ON c1.concept_id = ca1.descendant_concept_id - AND c1.vocabulary_id = 'ATC' - AND c1.concept_class_id = 'ATC 2nd' - INNER JOIN - @vocabDatabaseSchema.concept c2 - ON ca1.ancestor_concept_id = c2.concept_id - AND c2.vocabulary_id = 'ATC' - AND c2.concept_class_id = 'ATC 1st' - GROUP BY c1.concept_id, c1.concept_name - ) atc3_to_atc1 - ON atc5_to_atc3.atc3_concept_id = atc3_to_atc1.atc3_concept_id - - LEFT JOIN @vocabDatabaseSchema.concept atc1 - ON atc3_to_atc1.atc1_concept_id = atc1.concept_id; - -/********** MEASUREMENT **********/ - - SELECT - m.concept_id, - m.concept_name, - 'Measurement' AS treemap, - null as concept_hierarchy_type, - max(c1.concept_name) AS level1_concept_name, - max(c2.concept_name) AS level2_concept_name, - max(c3.concept_name) AS level3_concept_name, - null as level4_concept_name -into #ch_measurement - FROM - ( - SELECT DISTINCT - concept_id, - concept_name - FROM @vocabDatabaseSchema.concept c - WHERE domain_id = 'Measurement' - ) m - LEFT JOIN @vocabDatabaseSchema.concept_ancestor ca1 - ON M.concept_id = ca1.DESCENDANT_CONCEPT_ID AND ca1.min_levels_of_separation = 1 - LEFT JOIN @vocabDatabaseSchema.concept c1 ON ca1.ANCESTOR_CONCEPT_ID = c1.concept_id - LEFT JOIN @vocabDatabaseSchema.concept_ancestor ca2 - ON c1.concept_id = ca2.DESCENDANT_CONCEPT_ID AND ca2.min_levels_of_separation = 1 - LEFT JOIN @vocabDatabaseSchema.concept c2 ON ca2.ANCESTOR_CONCEPT_ID = c2.concept_id - LEFT JOIN @vocabDatabaseSchema.concept_ancestor ca3 - ON c2.concept_id = ca3.DESCENDANT_CONCEPT_ID AND ca3.min_levels_of_separation = 1 - LEFT JOIN @vocabDatabaseSchema.concept c3 ON ca3.ANCESTOR_CONCEPT_ID = c3.concept_id - GROUP BY M.concept_id, M.concept_name; - -/********** OBSERVATION **********/ - - SELECT - obs.concept_id, - obs.concept_name, - 'Observation' AS treemap, - null as concept_hierarchy_type, - max(c1.concept_name) AS level1_concept_name, - max(c2.concept_name) AS level2_concept_name, - max(c3.concept_name) AS level3_concept_name, - null as level4_concept_name -into #ch_observation - FROM - ( - SELECT - concept_id, - concept_name - FROM @vocabDatabaseSchema.concept - WHERE domain_id = 'Observation' - ) obs - LEFT JOIN @vocabDatabaseSchema.concept_ancestor ca1 - ON obs.concept_id = ca1.DESCENDANT_CONCEPT_ID AND ca1.min_levels_of_separation = 1 - LEFT JOIN @vocabDatabaseSchema.concept c1 ON ca1.ANCESTOR_CONCEPT_ID = c1.concept_id - LEFT JOIN @vocabDatabaseSchema.concept_ancestor ca2 - ON c1.concept_id = ca2.DESCENDANT_CONCEPT_ID AND ca2.min_levels_of_separation = 1 - LEFT JOIN @vocabDatabaseSchema.concept c2 ON ca2.ANCESTOR_CONCEPT_ID = c2.concept_id - LEFT JOIN @vocabDatabaseSchema.concept_ancestor ca3 - ON c2.concept_id = ca3.DESCENDANT_CONCEPT_ID AND ca3.min_levels_of_separation = 1 - LEFT JOIN @vocabDatabaseSchema.concept c3 ON ca3.ANCESTOR_CONCEPT_ID = c3.concept_id - GROUP BY obs.concept_id, obs.concept_name; - -/********** PROCEDURE **********/ - - SELECT - procs.concept_id, - procs.proc_concept_name as concept_name, - 'Procedure' AS treemap, - null as concept_hierarchy_type, - max(proc_hierarchy.os3_concept_name) AS level1_concept_name, - max(proc_hierarchy.os2_concept_name) AS level2_concept_name, - max(proc_hierarchy.os1_concept_name) AS level3_concept_name, - null as level4_concept_name -into #ch_procedure - FROM - ( - SELECT - c1.concept_id, - v1.vocabulary_name + ' ' + c1.concept_code + ': ' + c1.concept_name AS proc_concept_name - FROM @vocabDatabaseSchema.concept c1 - INNER JOIN @vocabDatabaseSchema.vocabulary v1 - ON c1.vocabulary_id = v1.vocabulary_id - WHERE c1.domain_id = 'Procedure' - ) procs - LEFT JOIN - (SELECT - ca0.DESCENDANT_CONCEPT_ID, - max(ca0.ancestor_concept_id) AS ancestor_concept_id - FROM @vocabDatabaseSchema.concept_ancestor ca0 - INNER JOIN - (SELECT DISTINCT c2.concept_id AS os3_concept_id - FROM @vocabDatabaseSchema.concept_ancestor ca1 - INNER JOIN - @vocabDatabaseSchema.concept c1 - ON ca1.DESCENDANT_CONCEPT_ID = c1.concept_id - INNER JOIN - @vocabDatabaseSchema.concept_ancestor ca2 - ON c1.concept_id = ca2.ANCESTOR_CONCEPT_ID - INNER JOIN - @vocabDatabaseSchema.concept c2 - ON ca2.DESCENDANT_CONCEPT_ID = c2.concept_id - WHERE ca1.ancestor_concept_id = 4040390 - AND ca1.Min_LEVELS_OF_SEPARATION = 2 - AND ca2.MIN_LEVELS_OF_SEPARATION = 1 - ) t1 - ON ca0.ANCESTOR_CONCEPT_ID = t1.os3_concept_id - GROUP BY ca0.descendant_concept_id - ) ca1 - ON procs.concept_id = ca1.DESCENDANT_CONCEPT_ID - LEFT JOIN - ( - SELECT - proc_by_os1.os1_concept_name, - proc_by_os2.os2_concept_name, - proc_by_os3.os3_concept_name, - proc_by_os3.os3_concept_id - FROM - (SELECT - DESCENDANT_CONCEPT_ID AS os1_concept_id, - concept_name AS os1_concept_name - FROM @vocabDatabaseSchema.concept_ancestor ca1 - INNER JOIN - @vocabDatabaseSchema.concept c1 - ON ca1.DESCENDANT_CONCEPT_ID = c1.concept_id - WHERE ancestor_concept_id = 4040390 - AND Min_LEVELS_OF_SEPARATION = 1 - ) proc_by_os1 - - INNER JOIN - (SELECT - max(c1.CONCEPT_ID) AS os1_concept_id, - c2.concept_id AS os2_concept_id, - c2.concept_name AS os2_concept_name - FROM @vocabDatabaseSchema.concept_ancestor ca1 - INNER JOIN - @vocabDatabaseSchema.concept c1 - ON ca1.DESCENDANT_CONCEPT_ID = c1.concept_id - INNER JOIN - @vocabDatabaseSchema.concept_ancestor ca2 - ON c1.concept_id = ca2.ANCESTOR_CONCEPT_ID - INNER JOIN - @vocabDatabaseSchema.concept c2 - ON ca2.DESCENDANT_CONCEPT_ID = c2.concept_id - WHERE ca1.ancestor_concept_id = 4040390 - AND ca1.Min_LEVELS_OF_SEPARATION = 1 - AND ca2.MIN_LEVELS_OF_SEPARATION = 1 - GROUP BY c2.concept_id, c2.concept_name - ) proc_by_os2 - ON proc_by_os1.os1_concept_id = proc_by_os2.os1_concept_id - - INNER JOIN - (SELECT - max(c1.CONCEPT_ID) AS os2_concept_id, - c2.concept_id AS os3_concept_id, - c2.concept_name AS os3_concept_name - FROM @vocabDatabaseSchema.concept_ancestor ca1 - INNER JOIN - @vocabDatabaseSchema.concept c1 - ON ca1.DESCENDANT_CONCEPT_ID = c1.concept_id - INNER JOIN - @vocabDatabaseSchema.concept_ancestor ca2 - ON c1.concept_id = ca2.ANCESTOR_CONCEPT_ID - INNER JOIN - @vocabDatabaseSchema.concept c2 - ON ca2.DESCENDANT_CONCEPT_ID = c2.concept_id - WHERE ca1.ancestor_concept_id = 4040390 - AND ca1.Min_LEVELS_OF_SEPARATION = 2 - AND ca2.MIN_LEVELS_OF_SEPARATION = 1 - GROUP BY c2.concept_id, c2.concept_name - ) proc_by_os3 - ON proc_by_os2.os2_concept_id = proc_by_os3.os2_concept_id - ) proc_hierarchy - ON ca1.ancestor_concept_id = proc_hierarchy.os3_concept_id - GROUP BY procs.concept_id, - procs.proc_concept_name; - -select * into -@resultsDatabaseSchema.concept_hierarchy -from -( - select - concept_id, - cast(concept_name as VARCHAR(400)) as concept_name, - cast(treemap as VARCHAR(20)) as treemap, - cast(concept_hierarchy_type as VARCHAR(20)) as concept_hierarchy_type, - cast(level1_concept_name as VARCHAR(255)) as level1_concept_name, - cast(level2_concept_name as VARCHAR(255)) as level2_concept_name, - cast(level3_concept_name as VARCHAR(255)) as level3_concept_name, - cast(level4_concept_name as VARCHAR(255)) as level4_concept_name - from #ch_condition - - union all - - select - concept_id, - cast(concept_name as VARCHAR(400)) as concept_name, - cast(treemap as VARCHAR(20)) as treemap, - cast(concept_hierarchy_type as VARCHAR(20)) as concept_hierarchy_type, - cast(level1_concept_name as VARCHAR(255)) as level1_concept_name, - cast(level2_concept_name as VARCHAR(255)) as level2_concept_name, - cast(level3_concept_name as VARCHAR(255)) as level3_concept_name, - cast(level4_concept_name as VARCHAR(255)) as level4_concept_name - from #ch_drug - - union all - - select - concept_id, - cast(concept_name as VARCHAR(400)) as concept_name, - cast(treemap as VARCHAR(20)) as treemap, - cast(concept_hierarchy_type as VARCHAR(20)) as concept_hierarchy_type, - cast(level1_concept_name as VARCHAR(255)) as level1_concept_name, - cast(level2_concept_name as VARCHAR(255)) as level2_concept_name, - cast(level3_concept_name as VARCHAR(255)) as level3_concept_name, - cast(level4_concept_name as VARCHAR(255)) as level4_concept_name - from #ch_drug_era - - union all - - select - concept_id, - cast(concept_name as VARCHAR(400)) as concept_name, - cast(treemap as VARCHAR(20)) as treemap, - cast(concept_hierarchy_type as VARCHAR(20)) as concept_hierarchy_type, - cast(level1_concept_name as VARCHAR(255)) as level1_concept_name, - cast(level2_concept_name as VARCHAR(255)) as level2_concept_name, - cast(level3_concept_name as VARCHAR(255)) as level3_concept_name, - cast(level4_concept_name as VARCHAR(255)) as level4_concept_name - from #ch_measurement - - union all - - select - concept_id, - cast(concept_name as VARCHAR(400)) as concept_name, - cast(treemap as VARCHAR(20)) as treemap, - cast(concept_hierarchy_type as VARCHAR(20)) as concept_hierarchy_type, - cast(level1_concept_name as VARCHAR(255)) as level1_concept_name, - cast(level2_concept_name as VARCHAR(255)) as level2_concept_name, - cast(level3_concept_name as VARCHAR(255)) as level3_concept_name, - cast(level4_concept_name as VARCHAR(255)) as level4_concept_name - from #ch_observation - - union all - - select - concept_id, - cast(concept_name as VARCHAR(400)) as concept_name, - cast(treemap as VARCHAR(20)) as treemap, - cast(concept_hierarchy_type as VARCHAR(20)) as concept_hierarchy_type, - cast(level1_concept_name as VARCHAR(255)) as level1_concept_name, - cast(level2_concept_name as VARCHAR(255)) as level2_concept_name, - cast(level3_concept_name as VARCHAR(255)) as level3_concept_name, - cast(level4_concept_name as VARCHAR(255)) as level4_concept_name - from #ch_procedure -) Q -; - -truncate table #ch_condition; -drop table #ch_condition; - -truncate table #ch_drug; -drop table #ch_drug; - -truncate table #ch_drug_era; -drop table #ch_drug_era; - -truncate table #ch_measurement; -drop table #ch_measurement; - -truncate table #ch_observation; -drop table #ch_observation; - -truncate table #ch_procedure; -drop table #ch_procedure; diff --git a/man/achilles.Rd b/man/achilles.Rd index a6ba0be9..1cf0d569 100755 --- a/man/achilles.Rd +++ b/man/achilles.Rd @@ -8,10 +8,11 @@ achilles(connectionDetails, cdmDatabaseSchema, oracleTempSchema = cdmDatabaseSchema, resultsDatabaseSchema = cdmDatabaseSchema, scratchDatabaseSchema = resultsDatabaseSchema, - vocabDatabaseSchema = cdmDatabaseSchema, sourceName = "", analysisIds, - createTable = TRUE, smallCellCount = 5, cdmVersion = "5", - runHeel = TRUE, validateSchema = FALSE, runCostAnalysis = FALSE, - conceptHierarchy = TRUE, createIndices = TRUE, numThreads = 1, + vocabDatabaseSchema = cdmDatabaseSchema, sourceName = "", + analysisIds, createTable = TRUE, smallCellCount = 5, + cdmVersion = "5", runHeel = TRUE, validateSchema = FALSE, + runCostAnalysis = FALSE, conceptHierarchy = TRUE, + createIndices = TRUE, numThreads = 1, tempAchillesPrefix = "tmpach", dropScratchTables = TRUE, sqlOnly = FALSE, outputFolder = "output", logMultiThreadPerformance = FALSE) diff --git a/man/achillesHeel.Rd b/man/achillesHeel.Rd index f4dba926..997bd5f9 100755 --- a/man/achillesHeel.Rd +++ b/man/achillesHeel.Rd @@ -6,9 +6,11 @@ \usage{ achillesHeel(connectionDetails, cdmDatabaseSchema, resultsDatabaseSchema = cdmDatabaseSchema, - scratchDatabaseSchema = resultsDatabaseSchema, cdmVersion = "5", - numThreads = 1, tempHeelPrefix = "tmpheel", dropScratchTables = FALSE, - ThresholdAgeWarning = 125, ThresholdOutpatientVisitPerc = 0.43, + scratchDatabaseSchema = resultsDatabaseSchema, + vocabDatabaseSchema = cdmDatabaseSchema, cdmVersion = "5", + numThreads = 1, tempHeelPrefix = "tmpheel", + dropScratchTables = FALSE, ThresholdAgeWarning = 125, + ThresholdOutpatientVisitPerc = 0.43, ThresholdMinimalPtMeasDxRx = 20.5, outputFolder = "output", sqlOnly = FALSE) } @@ -22,6 +24,8 @@ so for example 'results.dbo'.} \item{scratchDatabaseSchema}{(OPTIONAL, multi-threaded mode) Name of a fully qualified schema that is accessible to/from the resultsDatabaseSchema, that can store all of the scratch tables. Default is resultsDatabaseSchema.} +\item{vocabDatabaseSchema}{String name of database schema that contains OMOP Vocabulary. Default is cdmDatabaseSchema. On SQL Server, this should specifiy both the database and the schema, so for example 'results.dbo'.} + \item{cdmVersion}{Define the OMOP CDM version used: currently supports v5 and above. Default = "5".} \item{numThreads}{(OPTIONAL, multi-threaded mode) The number of threads to use to run Achilles in parallel. Default is 1 thread.} @@ -56,6 +60,7 @@ nothing is returned cdmDatabaseSchema = "cdm", resultsDatabaseSchema = "results", scratchDatabaseSchema = "scratch", + vocabDatabaseSchema = "vocab", cdmVersion = "5.3.0", numThreads = 10) } diff --git a/man/dropAllScratchTables.Rd b/man/dropAllScratchTables.Rd index cc453888..cec31606 100755 --- a/man/dropAllScratchTables.Rd +++ b/man/dropAllScratchTables.Rd @@ -6,7 +6,8 @@ \usage{ dropAllScratchTables(connectionDetails, scratchDatabaseSchema, tempAchillesPrefix = "tmpach", tempHeelPrefix = "tmpheel", - numThreads = 1, tableTypes = c("achilles", "heel")) + numThreads = 1, tableTypes = c("achilles", "heel", + "concept_hierarchy")) } \arguments{ \item{connectionDetails}{An R object of type \code{connectionDetails} created using the function \code{createConnectionDetails} in the \code{DatabaseConnector} package.} @@ -19,11 +20,11 @@ dropAllScratchTables(connectionDetails, scratchDatabaseSchema, \item{numThreads}{The number of threads to use to run this function. Default is 1 thread.} -\item{tableTypes}{The types of Achilles scratch tables to drop: achilles or heel or both} +\item{tableTypes}{The types of Achilles scratch tables to drop: achilles or heel or concept_hierarchy or all 3} } \description{ Drop all possible scratch tables } \details{ -Drop all possible Achilles and Heel scratch tables +Drop all possible Achilles, Heel, and Concept Hierarchy scratch tables } diff --git a/man/exportDeathToJson.Rd b/man/exportDeathToJson.Rd index 3a9b5712..ed621333 100755 --- a/man/exportDeathToJson.Rd +++ b/man/exportDeathToJson.Rd @@ -4,8 +4,9 @@ \alias{exportDeathToJson} \title{exportDeathToJson} \usage{ -exportDeathToJson(connectionDetails, cdmDatabaseSchema, resultsDatabaseSchema, - outputPath = getwd(), vocabDatabaseSchema = cdmDatabaseSchema) +exportDeathToJson(connectionDetails, cdmDatabaseSchema, + resultsDatabaseSchema, outputPath = getwd(), + vocabDatabaseSchema = cdmDatabaseSchema) } \arguments{ \item{connectionDetails}{An R object of type ConnectionDetail (details for the function that contains server info, database type, optionally username/password, port)} diff --git a/man/exportDrugEraToJson.Rd b/man/exportDrugEraToJson.Rd index 2da66ded..7cc560c5 100755 --- a/man/exportDrugEraToJson.Rd +++ b/man/exportDrugEraToJson.Rd @@ -4,8 +4,9 @@ \alias{exportDrugEraToJson} \title{exportDrugEraToJson} \usage{ -exportDrugEraToJson(connectionDetails, cdmDatabaseSchema, resultsDatabaseSchema, - outputPath = getwd(), vocabDatabaseSchema = cdmDatabaseSchema) +exportDrugEraToJson(connectionDetails, cdmDatabaseSchema, + resultsDatabaseSchema, outputPath = getwd(), + vocabDatabaseSchema = cdmDatabaseSchema) } \arguments{ \item{connectionDetails}{An R object of type ConnectionDetail (details for the function that contains server info, database type, optionally username/password, port)} diff --git a/man/exportDrugToJson.Rd b/man/exportDrugToJson.Rd index dede5f57..bb03623d 100755 --- a/man/exportDrugToJson.Rd +++ b/man/exportDrugToJson.Rd @@ -4,8 +4,9 @@ \alias{exportDrugToJson} \title{exportDrugToJson} \usage{ -exportDrugToJson(connectionDetails, cdmDatabaseSchema, resultsDatabaseSchema, - outputPath = getwd(), vocabDatabaseSchema = cdmDatabaseSchema) +exportDrugToJson(connectionDetails, cdmDatabaseSchema, + resultsDatabaseSchema, outputPath = getwd(), + vocabDatabaseSchema = cdmDatabaseSchema) } \arguments{ \item{connectionDetails}{An R object of type ConnectionDetail (details for the function that contains server info, database type, optionally username/password, port)} diff --git a/man/exportHeelToJson.Rd b/man/exportHeelToJson.Rd index 6cec4240..1a0186df 100755 --- a/man/exportHeelToJson.Rd +++ b/man/exportHeelToJson.Rd @@ -4,8 +4,9 @@ \alias{exportHeelToJson} \title{exportHeelToJson} \usage{ -exportHeelToJson(connectionDetails, cdmDatabaseSchema, resultsDatabaseSchema, - outputPath = getwd(), vocabDatabaseSchema = cdmDatabaseSchema) +exportHeelToJson(connectionDetails, cdmDatabaseSchema, + resultsDatabaseSchema, outputPath = getwd(), + vocabDatabaseSchema = cdmDatabaseSchema) } \arguments{ \item{connectionDetails}{An R object of type ConnectionDetail (details for the function that contains server info, database type, optionally username/password, port)} diff --git a/man/exportMetaToJson.Rd b/man/exportMetaToJson.Rd index 779a23cd..cac75c4f 100755 --- a/man/exportMetaToJson.Rd +++ b/man/exportMetaToJson.Rd @@ -4,8 +4,9 @@ \alias{exportMetaToJson} \title{exportMetaToJson} \usage{ -exportMetaToJson(connectionDetails, cdmDatabaseSchema, resultsDatabaseSchema, - outputPath = getwd(), vocabDatabaseSchema = cdmDatabaseSchema) +exportMetaToJson(connectionDetails, cdmDatabaseSchema, + resultsDatabaseSchema, outputPath = getwd(), + vocabDatabaseSchema = cdmDatabaseSchema) } \arguments{ \item{connectionDetails}{An R object of type ConnectionDetail (details for the function that contains server info, database type, optionally username/password, port)} diff --git a/man/exportPersonToJson.Rd b/man/exportPersonToJson.Rd index e9c93e68..df133f19 100755 --- a/man/exportPersonToJson.Rd +++ b/man/exportPersonToJson.Rd @@ -4,8 +4,9 @@ \alias{exportPersonToJson} \title{exportPersonToJson} \usage{ -exportPersonToJson(connectionDetails, cdmDatabaseSchema, resultsDatabaseSchema, - outputPath = getwd(), vocabDatabaseSchema = cdmDatabaseSchema) +exportPersonToJson(connectionDetails, cdmDatabaseSchema, + resultsDatabaseSchema, outputPath = getwd(), + vocabDatabaseSchema = cdmDatabaseSchema) } \arguments{ \item{connectionDetails}{An R object of type ConnectionDetail (details for the function that contains server info, database type, optionally username/password, port)} diff --git a/man/exportToJson.Rd b/man/exportToJson.Rd index e52f42f8..95ab6ddc 100755 --- a/man/exportToJson.Rd +++ b/man/exportToJson.Rd @@ -5,7 +5,7 @@ \title{exportToJson} \usage{ exportToJson(connectionDetails, cdmDatabaseSchema, resultsDatabaseSchema, - outputPath = getwd(), reports = allReports, + outputPath = getwd(), reports = getAllReports(), vocabDatabaseSchema = cdmDatabaseSchema, compressIntoOneFile = FALSE) } \arguments{ @@ -21,7 +21,10 @@ exportToJson(connectionDetails, cdmDatabaseSchema, resultsDatabaseSchema, \item{vocabDatabaseSchema}{string name of database schema that contains OMOP Vocabulary. Default is cdmDatabaseSchema. On SQL Server, this should specifiy both the database and the schema, so for example 'results.dbo'.} -\item{compressIntoOneFile}{Boolean indicating if the JSON files should be compressed into one zip file +\item{compressIntoOneFile}{Boolean indicating if the JSON files should be compressed into one zip file. + Please note that in Windows, the zip application must be stored in the system environment, + e.g. Sys.setenv("R_ZIPCMD", "some_path_to_zip"). + Due to recursion, the actual Achilles files and folders will be embedded in any parent directories that the source folder has. See \code{data(allReports)} for a list of all report types} } diff --git a/man/exportVisitToJson.Rd b/man/exportVisitToJson.Rd index 010923e9..5413213f 100755 --- a/man/exportVisitToJson.Rd +++ b/man/exportVisitToJson.Rd @@ -4,8 +4,9 @@ \alias{exportVisitToJson} \title{exportVisitToJson} \usage{ -exportVisitToJson(connectionDetails, cdmDatabaseSchema, resultsDatabaseSchema, - outputPath = getwd(), vocabDatabaseSchema = cdmDatabaseSchema) +exportVisitToJson(connectionDetails, cdmDatabaseSchema, + resultsDatabaseSchema, outputPath = getwd(), + vocabDatabaseSchema = cdmDatabaseSchema) } \arguments{ \item{connectionDetails}{An R object of type ConnectionDetail (details for the function that contains server info, database type, optionally username/password, port)}