Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Addition of Freq distribution #211

Merged
merged 3 commits into from
Sep 7, 2017
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
40 changes: 40 additions & 0 deletions R/exportToJson.R
Expand Up @@ -1039,6 +1039,14 @@ generateDrugReports <- function(conn, dbms, cdmDatabaseSchema, resultsDatabaseSc
vocab_database_schema = vocabDatabaseSchema
)

queryDrugFrequencyDistribution <- loadRenderTranslateSql(sqlFilename = addCdmVersionPath("/drug/sqlFrequencyDistribution.sql",cdmVersion),
packageName = "Achilles",
dbms = dbms,
cdm_database_schema = cdmDatabaseSchema,
results_database_schema = resultsDatabaseSchema,
vocab_database_schema = vocabDatabaseSchema
)

queryQuantityDistribution <- loadRenderTranslateSql(sqlFilename = addCdmVersionPath("/drug/sqlQuantityDistribution.sql",cdmVersion),
packageName = "Achilles",
dbms = dbms,
Expand All @@ -1062,6 +1070,7 @@ generateDrugReports <- function(conn, dbms, cdmDatabaseSchema, resultsDatabaseSc
dataPrevalenceByMonth <- DatabaseConnector::querySql(conn,queryPrevalenceByMonth)
dataQuantityDistribution <- DatabaseConnector::querySql(conn,queryQuantityDistribution)
dataRefillsDistribution <- DatabaseConnector::querySql(conn,queryRefillsDistribution)
dataDrugFrequencyDistribution <- DatabaseConnector::querySql(conn,queryDrugFrequencyDistribution)

buildDrugReport <- function(concept_id) {
report <- {}
Expand All @@ -1070,6 +1079,7 @@ generateDrugReports <- function(conn, dbms, cdmDatabaseSchema, resultsDatabaseSc
report$DRUGS_BY_TYPE <- dataDrugsByType[dataDrugsByType$DRUG_CONCEPT_ID == concept_id, c(3,4)]
report$PREVALENCE_BY_GENDER_AGE_YEAR <- dataPrevalenceByGenderAgeYear[dataPrevalenceByGenderAgeYear$CONCEPT_ID == concept_id,c(3,4,5,6)]
report$PREVALENCE_BY_MONTH <- dataPrevalenceByMonth[dataPrevalenceByMonth$CONCEPT_ID == concept_id,c(3,4)]
report$DRUG_FREQUENCY_DISTRIBUTION <- dataDrugFrequencyDistribution[dataDrugFrequencyDistribution$CONCEPT_ID == concept_id,c(3,4)]
report$QUANTITY_DISTRIBUTION <- dataQuantityDistribution[dataQuantityDistribution$DRUG_CONCEPT_ID == concept_id, c(2,3,4,5,6,7,8,9)]
report$REFILLS_DISTRIBUTION <- dataRefillsDistribution[dataRefillsDistribution$DRUG_CONCEPT_ID == concept_id, c(2,3,4,5,6,7,8,9)]

Expand Down Expand Up @@ -1152,6 +1162,14 @@ generateProcedureReports <- function(conn, dbms, cdmDatabaseSchema, resultsDatab
vocab_database_schema = vocabDatabaseSchema
)

queryProcedureFrequencyDistribution <- loadRenderTranslateSql(sqlFilename = addCdmVersionPath("/procedure/sqlFrequencyDistribution.sql",cdmVersion),
packageName = "Achilles",
dbms = dbms,
cdm_database_schema = cdmDatabaseSchema,
results_database_schema = resultsDatabaseSchema,
vocab_database_schema = vocabDatabaseSchema
)

queryProceduresByType <- loadRenderTranslateSql(sqlFilename = addCdmVersionPath("/procedure/sqlProceduresByType.sql",cdmVersion),
packageName = "Achilles",
dbms = dbms,
Expand All @@ -1172,11 +1190,13 @@ generateProcedureReports <- function(conn, dbms, cdmDatabaseSchema, resultsDatab
dataPrevalenceByMonth <- DatabaseConnector::querySql(conn,queryPrevalenceByMonth)
dataProceduresByType <- DatabaseConnector::querySql(conn,queryProceduresByType)
dataAgeAtFirstOccurrence <- DatabaseConnector::querySql(conn,queryAgeAtFirstOccurrence)
dataProcedureFrequencyDistribution <- DatabaseConnector::querySql(conn,queryProcedureFrequencyDistribution)

buildProcedureReport <- function(concept_id) {
report <- {}
report$PREVALENCE_BY_GENDER_AGE_YEAR <- dataPrevalenceByGenderAgeYear[dataPrevalenceByGenderAgeYear$CONCEPT_ID == concept_id,c(3,4,5,6)]
report$PREVALENCE_BY_MONTH <- dataPrevalenceByMonth[dataPrevalenceByMonth$CONCEPT_ID == concept_id,c(3,4)]
report$PROCEDURE_FREQUENCY_DISTRIBUTION <- dataProcedureFrequencyDistribution[dataProcedureFrequencyDistribution$CONCEPT_ID == concept_id,c(3,4)]
report$PROCEDURES_BY_TYPE <- dataProceduresByType[dataProceduresByType$PROCEDURE_CONCEPT_ID == concept_id,c(4,5)]
report$AGE_AT_FIRST_OCCURRENCE <- dataAgeAtFirstOccurrence[dataAgeAtFirstOccurrence$CONCEPT_ID == concept_id,c(2,3,4,5,6,7,8,9)]
filename <- paste(outputPath, "/procedures/procedure_" , concept_id , ".json", sep='')
Expand Down Expand Up @@ -1710,6 +1730,14 @@ generateMeasurementReports <- function(conn, dbms, cdmDatabaseSchema, resultsDat
vocab_database_schema = vocabDatabaseSchema
)

queryFrequencyDistribution <- loadRenderTranslateSql(sqlFilename = addCdmVersionPath("/measurement/sqlFrequencyDistribution.sql",cdmVersion),
packageName = "Achilles",
dbms = dbms,
cdm_database_schema = cdmDatabaseSchema,
results_database_schema = resultsDatabaseSchema,
vocab_database_schema = vocabDatabaseSchema
)

queryMeasurementsByType <- loadRenderTranslateSql(sqlFilename = addCdmVersionPath("/measurement/sqlMeasurementsByType.sql",cdmVersion),
packageName = "Achilles",
dbms = dbms,
Expand Down Expand Up @@ -1775,11 +1803,13 @@ generateMeasurementReports <- function(conn, dbms, cdmDatabaseSchema, resultsDat
dataLowerLimitDistribution <- DatabaseConnector::querySql(conn,queryLowerLimitDistribution)
dataUpperLimitDistribution <- DatabaseConnector::querySql(conn,queryUpperLimitDistribution)
dataValuesRelativeToNorm <- DatabaseConnector::querySql(conn,queryValuesRelativeToNorm)
dataFrequencyDistribution <- DatabaseConnector::querySql(conn,queryFrequencyDistribution)

buildMeasurementReport <- function(concept_id) {
report <- {}
report$PREVALENCE_BY_GENDER_AGE_YEAR <- dataPrevalenceByGenderAgeYear[dataPrevalenceByGenderAgeYear$CONCEPT_ID == concept_id,c(3,4,5,6)]
report$PREVALENCE_BY_MONTH <- dataPrevalenceByMonth[dataPrevalenceByMonth$CONCEPT_ID == concept_id,c(3,4)]
report$FREQUENCY_DISTRIBUTION <- dataFrequencyDistribution[dataFrequencyDistribution$CONCEPT_ID == concept_id,c(3,4)]
report$MEASUREMENTS_BY_TYPE <- dataMeasurementsByType[dataMeasurementsByType$MEASUREMENT_CONCEPT_ID == concept_id,c(4,5)]
report$AGE_AT_FIRST_OCCURRENCE <- dataAgeAtFirstOccurrence[dataAgeAtFirstOccurrence$CONCEPT_ID == concept_id,c(2,3,4,5,6,7,8,9)]

Expand Down Expand Up @@ -1871,6 +1901,14 @@ generateObservationReports <- function(conn, dbms, cdmDatabaseSchema, resultsDat
vocab_database_schema = vocabDatabaseSchema
)

queryObsFrequencyDistribution <- loadRenderTranslateSql(sqlFilename = addCdmVersionPath("/observation/sqlFrequencyDistribution.sql",cdmVersion),
packageName = "Achilles",
dbms = dbms,
cdm_database_schema = cdmDatabaseSchema,
results_database_schema = resultsDatabaseSchema,
vocab_database_schema = vocabDatabaseSchema
)

queryObservationsByType <- loadRenderTranslateSql(sqlFilename = addCdmVersionPath("/observation/sqlObservationsByType.sql",cdmVersion),
packageName = "Achilles",
dbms = dbms,
Expand Down Expand Up @@ -1934,6 +1972,7 @@ generateObservationReports <- function(conn, dbms, cdmDatabaseSchema, resultsDat
dataPrevalenceByMonth <- DatabaseConnector::querySql(conn,queryPrevalenceByMonth)
dataObservationsByType <- DatabaseConnector::querySql(conn,queryObservationsByType)
dataAgeAtFirstOccurrence <- DatabaseConnector::querySql(conn,queryAgeAtFirstOccurrence)
dataObsFrequencyDistribution <- DatabaseConnector::querySql(conn,queryObsFrequencyDistribution)
if (cdmVersion == "4")
{
dataRecordsByUnit <- DatabaseConnector::querySql(conn,queryRecordsByUnit)
Expand All @@ -1947,6 +1986,7 @@ generateObservationReports <- function(conn, dbms, cdmDatabaseSchema, resultsDat
report <- {}
report$PREVALENCE_BY_GENDER_AGE_YEAR <- dataPrevalenceByGenderAgeYear[dataPrevalenceByGenderAgeYear$CONCEPT_ID == concept_id,c(3,4,5,6)]
report$PREVALENCE_BY_MONTH <- dataPrevalenceByMonth[dataPrevalenceByMonth$CONCEPT_ID == concept_id,c(3,4)]
report$OBS_FREQUENCY_DISTRIBUTION <- dataObsFrequencyDistribution[dataObsFrequencyDistribution$CONCEPT_ID == concept_id,c(3,4)]
report$OBSERVATIONS_BY_TYPE <- dataObservationsByType[dataObservationsByType$OBSERVATION_CONCEPT_ID == concept_id,c(4,5)]
report$AGE_AT_FIRST_OCCURRENCE <- dataAgeAtFirstOccurrence[dataAgeAtFirstOccurrence$CONCEPT_ID == concept_id,c(2,3,4,5,6,7,8,9)]

Expand Down
4 changes: 4 additions & 0 deletions inst/csv/analysisDetails.csv
Expand Up @@ -85,6 +85,7 @@
612,"Number of procedure occurrence records with invalid provider_id",,,,,
613,"Number of procedure occurrence records with invalid visit_id",,,,,
620,"Number of procedure occurrence records by procedure occurrence start month","calendar month",,,,
691,"Percentage of total persons that have at least x procedures","procedure_concept_id","procedure_person",,,
700,"Number of persons with at least one drug exposure, by drug_concept_id","drug_concept_id",,,,
701,"Number of drug exposure records, by drug_concept_id","drug_concept_id",,,,
702,"Number of persons by drug exposure start month, by drug_concept_id","drug_concept_id","calendar month",,,
Expand All @@ -101,6 +102,7 @@
716,"Distribution of refills by drug_concept_id","drug_concept_id",,,,
717,"Distribution of quantity by drug_concept_id","drug_concept_id",,,,
720,"Number of drug exposure records by drug exposure start month","calendar month",,,,
791,"Percentage of total persons that have at least x drug exposures","drug_concept_id","drug_person",,,
800,"Number of persons with at least one observation occurrence, by observation_concept_id","observation_concept_id",,,,
801,"Number of observation occurrence records, by observation_concept_id","observation_concept_id",,,,
802,"Number of persons by observation occurrence start month, by observation_concept_id","observation_concept_id","calendar month",,,
Expand All @@ -116,6 +118,7 @@
814,"Number of observation records with no value (numeric, string, or concept)",,,,,
815,"Distribution of numeric values, by observation_concept_id and unit_concept_id",,,,,
820,"Number of observation records by observation start month","calendar month",,,,
891,"Percentage of total persons that have at least x observations","observation_concept_id","observation_person",,,
900,"Number of persons with at least one drug era, by drug_concept_id","drug_concept_id",,,,
901,"Number of drug era records, by drug_concept_id","drug_concept_id",,,,
902,"Number of persons by drug era start month, by drug_concept_id","drug_concept_id","calendar month",,,
Expand Down Expand Up @@ -198,6 +201,7 @@
1818,"Number of measurement records below/within/above normal range, by measurement_concept_id and unit_concept_id",,,,,
1820,"Number of measurement records by measurement start month","calendar month",,,,
1821,"Number of measurement records with no numeric value",,,,,
1891,"Percentage of total persons that have at least x measurements","measurement_concept_id","measurement_person",,,
1900,"Source values mapped to concept_id 0 by table, by source_value","table_name","source_value",,,
2000,"Number of patients with at least 1 Dx and 1 Rx",,,,,
2001,"Number of patients with at least 1 Dx and 1 Proc",,,,,
Expand Down
4 changes: 2 additions & 2 deletions inst/sql/sql_server/AchillesHeel_v5.sql
Expand Up @@ -929,8 +929,8 @@ INNER JOIN @results_database_schema.ACHILLES_results ar2
1002
)
WHERE (
CAST(ar1.stratum_2 AS INT) + 1 = CAST(ar2.stratum_2 AS INT)
OR CAST(ar1.stratum_2 AS INT) + 89 = CAST(ar2.stratum_2 AS INT)
ROUND(CAST(ar1.stratum_2 AS DECIMAL(18,4)),0) + 1 = ROUND(CAST(ar2.stratum_2 AS DECIMAL(18,4)),0)
OR ROUND(CAST(ar1.stratum_2 AS DECIMAL(18,4)),0) + 89 = ROUND(CAST(ar2.stratum_2 AS DECIMAL(18,4)),0)
)
AND 1.0 * abs(ar2.count_value - ar1.count_value) / ar1.count_value > 1
AND ar1.count_value > 10
Expand Down
92 changes: 90 additions & 2 deletions inst/sql/sql_server/Achilles_v5.sql
Expand Up @@ -818,6 +818,8 @@ insert into @results_database_schema.ACHILLES_analysis (analysis_id, analysis_na
insert into @results_database_schema.ACHILLES_analysis (analysis_id, analysis_name, stratum_1_name)
values (620, 'Number of procedure occurrence records by procedure occurrence start month', 'calendar month');

insert into @results_database_schema.ACHILLES_analysis (analysis_id, analysis_name, stratum_1_name, stratum_2_name)
values (691, 'Number of persons that have at least x procedures', 'procedure_id', 'procedure_count');

--700- DRUG_EXPOSURE

Expand Down Expand Up @@ -875,6 +877,8 @@ insert into @results_database_schema.ACHILLES_analysis (analysis_id, analysis_na
insert into @results_database_schema.ACHILLES_analysis (analysis_id, analysis_name, stratum_1_name)
values (720, 'Number of drug exposure records by drug exposure start month', 'calendar month');

insert into @results_database_schema.ACHILLES_analysis (analysis_id, analysis_name, stratum_1_name, stratum_2_name)
values (791, 'Number of persons that have at least x drug exposures', 'drug_concept_id', 'drug_count');

--800- OBSERVATION

Expand Down Expand Up @@ -924,6 +928,8 @@ insert into @results_database_schema.ACHILLES_analysis (analysis_id, analysis_na
insert into @results_database_schema.ACHILLES_analysis (analysis_id, analysis_name, stratum_1_name)
values (820, 'Number of observation records by observation start month', 'calendar month');

insert into @results_database_schema.ACHILLES_analysis (analysis_id, analysis_name, stratum_1_name, stratum_2_name)
values (891, 'Number of persons that have at least x observations', 'observation_concept_id', 'observation_count');

--900- DRUG_ERA

Expand Down Expand Up @@ -1215,6 +1221,9 @@ insert into @results_database_schema.ACHILLES_analysis (analysis_id, analysis_na
insert into @results_database_schema.ACHILLES_analysis (analysis_id, analysis_name)
values (1821, 'Number of measurement records with no numeric value');

insert into @results_database_schema.ACHILLES_analysis (analysis_id, analysis_name, stratum_1_name, stratum_2_name)
values (1891, 'Number of persons that have at least x measurements', 'measurement_concept_id', 'measurement_count');

--1900 REPORTS

insert into @results_database_schema.ACHILLES_analysis (analysis_id, analysis_name, stratum_1_name, stratum_2_name)
Expand Down Expand Up @@ -3557,6 +3566,25 @@ group by YEAR(procedure_date)*100 + month(procedure_date)
--}


--{691 IN (@list_of_analysis_ids)}?{
-- 691 Number of total persons that have at least x procedures
insert into @results_database_schema.ACHILLES_results (analysis_id, stratum_1, stratum_2, count_value)
select
691 as analysis_id,
procedure_concept_id as stratum_1,
prc_cnt as stratum_2,
sum(count(person_id)) over (partition by procedure_concept_id order by prc_cnt desc) as count_value
from (
select
p.procedure_concept_id,
count(p.procedure_occurrence_id) as prc_cnt,
p.person_id
from @cdm_database_schema.procedure_occurrence p
group by p.person_id, p.procedure_concept_id
) as cnt_q
group by procedure_concept_id, prc_cnt;
--}

/********************************************

ACHILLES Analyses on DRUG_EXPOSURE table
Expand Down Expand Up @@ -4058,6 +4086,25 @@ group by YEAR(drug_exposure_start_date)*100 + month(drug_exposure_start_date)
;
--}

--{791 IN (@list_of_analysis_ids)}?{
-- 791 Number of total persons that have at least x drug exposures
insert into @results_database_schema.ACHILLES_results (analysis_id, stratum_1, stratum_2, count_value)
select
791 as analysis_id,
drug_concept_id as stratum_1,
drg_cnt as stratum_2,
sum(count(person_id)) over (partition by drug_concept_id order by drg_cnt desc) as count_value
from (
select
d.drug_concept_id,
count(d.drug_exposure_id) as drg_cnt,
d.person_id
from @cdm_database_schema.drug_exposure d
group by d.person_id, d.drug_concept_id
) as cnt_q
group by drug_concept_id, drg_cnt;
--}

/********************************************

ACHILLES Analyses on OBSERVATION table
Expand Down Expand Up @@ -4488,6 +4535,26 @@ group by YEAR(observation_date)*100 + month(observation_date)



--{891 IN (@list_of_analysis_ids)}?{
-- 891 Number of total persons that have at least x observations
insert into @results_database_schema.ACHILLES_results (analysis_id, stratum_1, stratum_2, count_value)
select
891 as analysis_id,
observation_concept_id as stratum_1,
obs_cnt as stratum_2,
sum(count(person_id)) over (partition by observation_concept_id order by obs_cnt desc) as count_value
from (
select
o.observation_concept_id,
count(o.observation_id) as obs_cnt,
o.person_id
from @cdm_database_schema.observation o
group by o.person_id, o.observation_concept_id
) as cnt_q
group by observation_concept_id, obs_cnt;
--}



/********************************************

Expand Down Expand Up @@ -7443,6 +7510,25 @@ where m.value_as_number is null
;
--}


--{1891 IN (@list_of_analysis_ids)}?{
-- 1891 Number of total persons that have at least x measurements
insert into @results_database_schema.ACHILLES_results (analysis_id, stratum_1, stratum_2, count_value)
select
1891 as analysis_id,
measurement_concept_id as stratum_1,
meas_cnt as stratum_2,
sum(count(person_id)) over (partition by measurement_concept_id order by meas_cnt desc) as count_value
from (
select
m.measurement_concept_id,
count(m.measurement_id) as meas_cnt,
m.person_id
from @cdm_database_schema.measurement m
group by m.person_id, m.measurement_concept_id
) as cnt_q
group by measurement_concept_id, meas_cnt;
--}
--end of measurment analyses

/********************************************
Expand Down Expand Up @@ -7672,6 +7758,8 @@ group by m.note_type_CONCEPT_ID


--final processing of results
delete from @results_database_schema.ACHILLES_results where count_value <= @smallcellcount;
delete from @results_database_schema.ACHILLES_results_dist where count_value <= @smallcellcount;
delete from @results_database_schema.ACHILLES_results
where count_value <= @smallcellcount;
delete from @results_database_schema.ACHILLES_results_dist
where count_value <= @smallcellcount;

12 changes: 12 additions & 0 deletions inst/sql/sql_server/export_v5/drug/sqlFrequencyDistribution.sql
@@ -0,0 +1,12 @@
select c1.concept_id as CONCEPT_ID,
c1.concept_name as CONCEPT_NAME,
cast(round((100.0*num.count_value / denom.count_value), 0) as int) as Y_NUM_PERSONS,
num.stratum_2 as X_COUNT
from
(select count_value from @results_database_schema.ACHILLES_results where analysis_id = 1) denom,
(select CAST(stratum_1 as int) stratum_1, CAST(stratum_2 as int) stratum_2, count_value
from @results_database_schema.ACHILLES_results
where analysis_id = 791) num
inner join @vocab_database_schema.concept c1 on num.stratum_1 = c1.concept_id
order by num.stratum_2