Skip to content

Commit

Permalink
Merge pull request #127 from OHDSI/devH5
Browse files Browse the repository at this point in the history
new rules 32,33 and 34 and updates and one new analysis
  • Loading branch information
chrisknoll authored Jun 15, 2016
2 parents 23465e5 + 67cee40 commit 648f270
Show file tree
Hide file tree
Showing 3 changed files with 147 additions and 15 deletions.
4 changes: 2 additions & 2 deletions DESCRIPTION
Original file line number Diff line number Diff line change
@@ -1,8 +1,8 @@
Package: Achilles
Type: Package
Title: Creates descriptive statistics summary for an entire OMOP CDM instance.
Version: 1.0
Date: 2014-04-03
Version: 1.3
Date: 2016-06-10
Author: Patrick Ryan, Martijn Schuemie
Maintainer: Patrick Ryan <[email protected]>
LazyData: true
Expand Down
98 changes: 85 additions & 13 deletions inst/sql/sql_server/AchillesHeel_v5.sql
Original file line number Diff line number Diff line change
Expand Up @@ -136,23 +136,62 @@ select

where analysis_id in (2000,2001,2002,2003);

--iris derived measure from visit data
--insert into @results_database_schema.ACHILLES_results_derived (statistic_value,measure_id)
-- select sum(count_value) as statistic_value,
-- 'Visit:PersonCnt' as measure_id
-- from @results_database_schema.achilles_results where analysis_id = 200;
-- WRONG (has more patients than total)


insert into @results_database_schema.ACHILLES_results_derived (statistic_value,measure_id)
select sum(count_value) as statistic_value,
'Visit:InstanceCnt' as measure_id
from @results_database_schema.achilles_results where analysis_id = 201;

--in dist analysis/measure 203 - a number similar to that is computed above but it is on person level


--age at first observation by decile
insert into @results_database_schema.ACHILLES_results_derived (stratum_1,statistic_value,measure_id)
select cast(floor(cast(stratum_1 as int)/10) as varchar) as stratum_1,
sum(count_value) as statistic_value,
'AgeAtFirstObsByDecile:PersonCnt' as measure_id
from @results_database_schema.achilles_results where analysis_id = 101
group by floor(cast(stratum_1 as int)/10);

--count whether all deciles from 0 to 8 are there (has later a rule: if less the threshold, issue notification)
insert into @results_database_schema.ACHILLES_results_derived (statistic_value,measure_id)
select count(*) as statistic_value,
'AgeAtFirstObsByDecile:DecileCnt' as measure_id
from @results_database_schema.ACHILLES_results_derived
where measure_id = 'AgeAtFirstObsByDecile:PersonCnt'
and cast(stratum_1 as int) <=8;

--this is also in dist measure 203
--insert into @results_database_schema.ACHILLES_results_derived (statistic_value,measure_id)
-- select sum(count_value) as statistic_value,
-- 'Visit:InstanceCnt' as measure_id
-- from @results_database_schema.achilles_results where analysis_id = 201;

--data density measures
--for drug (exposure and eras)
insert into @results_database_schema.ACHILLES_results_derived (statistic_value,measure_id)
select count(*) as statistic_value, 'DrugExposure:ConceptCnt' as measure_id
from @results_database_schema.ACHILLES_results where analysis_id = 701;

insert into @results_database_schema.ACHILLES_results_derived (statistic_value,measure_id)
select count(*) as statistic_value, 'DrugEra:ConceptCnt' as measure_id
from @results_database_schema.ACHILLES_results where analysis_id = 901;


--unmapped data (concept_0) derived measures (focusing on source values)

insert into @results_database_schema.ACHILLES_results_derived (stratum_1,statistic_value,measure_id)
select stratum_1,
count(*) as statistic_value,
'UnmappedDataByDomain:SourceValueCnt' as measure_id
from @results_database_schema.achilles_results where analysis_id = 1900 group by stratum_1;


--count of specialties in the provider table
--(subsequent rule can check if this count is > trehshold) (general population dataset only))
insert into @results_database_schema.ACHILLES_results_derived (statistic_value,measure_id)
select
count(*) as statistic_value,
'Provider:SpeciatlyCnt' as measure_id
from @results_database_schema.achilles_results where analysis_id = 301;

--end of derived general measures
--end of derived general measures ********************************************************************



Expand Down Expand Up @@ -1004,7 +1043,7 @@ and d.statistic_value > 10000 --thresholds will be decided in the ongoing DQ-St
;

--rule32 DQ rule
--usis iris: patietnts with at least one visit visit
--uses iris: patients with at least one visit visit
--does 100-THE IRIS MEASURE to check for percentage of patients with no visits

INSERT INTO @results_database_schema.ACHILLES_HEEL_results (ACHILLES_HEEL_warning,rule_id)
Expand All @@ -1016,3 +1055,36 @@ where d.measure_id = 'ach_2003:Percentage'
and 100-d.statistic_value > 5 --thresholds will be decided in the ongoing DQ-Study2
;

--rule33 DQ rule (for general population only)
--NOTIFICATION: database does not have all age 0-80 represented


INSERT INTO @results_database_schema.ACHILLES_HEEL_results (ACHILLES_HEEL_warning,rule_id)
SELECT
'NOTIFICATION: [GeneralPopulationOnly] Not all deciles represented at first observation' as ACHILLES_HEEL_warning,
33 as rule_id
FROM @results_database_schema.ACHILLES_results_derived d
where d.measure_id = 'AgeAtFirstObsByDecile:DecileCnt'
and d.statistic_value <9 --we expect deciles 0,1,2,3,4,5,6,7,8
;


--rule34 DQ rule
--NOTIFICATION: number of unmapped source values exceeds threshold
--related to rule 27 that looks at percentage of unmapped rows (rows as focus)
--this rule is looking at source values (as focus)


INSERT INTO @results_database_schema.ACHILLES_HEEL_results (ACHILLES_HEEL_warning,rule_id,record_count)
SELECT
'NOTIFICATION: Count of unmapped source values exceeds threshold in: ' +cast(stratum_1 as varchar) as ACHILLES_HEEL_warning,
34 as rule_id,
cast(statistic_value as int) as record_count
FROM @results_database_schema.ACHILLES_results_derived d
where measure_id = 'UnmappedDataByDomain:SourceValueCnt'
and statistic_value > 1000; --threshold will be decided in DQ study 2





60 changes: 60 additions & 0 deletions inst/sql/sql_server/Achilles_v5.sql
Original file line number Diff line number Diff line change
Expand Up @@ -615,6 +615,10 @@ insert into @results_database_schema.ACHILLES_analysis (analysis_id, analysis_na
insert into @results_database_schema.ACHILLES_analysis (analysis_id, analysis_name)
values (118, 'Number of observation periods with invalid person_id');

insert into @results_database_schema.ACHILLES_analysis (analysis_id, analysis_name, stratum_1_name)
values (119, 'Number of observation period records by period_type_concept_id','period_type_concept_id');




--200- VISIT_OCCURRENCE
Expand Down Expand Up @@ -1943,6 +1947,18 @@ where p1.person_id is null
;
--}

--{119 IN (@list_of_analysis_ids)}?{
-- 119 Number of observation period records by period_type_concept_id
insert into @results_database_schema.ACHILLES_results (analysis_id, stratum_1,count_value)
select 119 as analysis_id,
op1.period_type_concept_id as stratum_1,
COUNT_BIG(*) as count_value
from
@cdm_database_schema.observation_period op1
group by op1.period_type_concept_id
;
--}


/********************************************
Expand Down Expand Up @@ -2278,6 +2294,23 @@ group by YEAR(visit_start_date)*100 + month(visit_start_date)
;
--}


--{221 IN (@list_of_analysis_ids)}?{
-- 221 Number of persons by visit start year
insert into @results_database_schema.ACHILLES_results (analysis_id, stratum_1, count_value)
select 221 as analysis_id,
YEAR(visit_start_date) as stratum_1,
COUNT_BIG(distinct PERSON_ID) as count_value
from
@cdm_database_schema.visit_occurrence vo1
group by YEAR(visit_start_date)
;
--}





/********************************************
ACHILLES Analyses on PROVIDER table
Expand Down Expand Up @@ -7281,6 +7314,31 @@ where m.value_as_number is null

--end of measurment analyses

/********************************************
Reports
*********************************************/


--{1900 IN (@list_of_analysis_ids)}?{
-- 1900 concept_0 report

INSERT INTO @results_database_schema.ACHILLES_results (analysis_id, stratum_1, stratum_2, count_value)
select 1900 as analysis_id, table_name as stratum_1, source_value as stratum_2, cnt as count_value
from (
select 'measurement' as table_name,measurement_source_value as source_value, COUNT_BIG(*) as cnt from @cdm_database_schema.measurement where measurement_concept_id = 0 group by measurement_source_value
union
select 'procedure_occurrence' as table_name,procedure_source_value as source_value, COUNT_BIG(*) as cnt from @cdm_database_schema.procedure_occurrence where procedure_concept_id = 0 group by procedure_source_value
union
select 'drug_exposure' as table_name,drug_source_value as source_value, COUNT_BIG(*) as cnt from @cdm_database_schema.drug_exposure where drug_concept_id = 0 group by drug_source_value
union
select 'condition_occurrence' as table_name,condition_source_value as source_value, COUNT_BIG(*) as cnt from @cdm_database_schema.condition_occurrence where condition_concept_id = 0 group by condition_source_value
) a
where cnt >= 1 --use other threshold if needed (e.g., 10)
order by a.table_name desc, cnt desc
;
--}


/********************************************
Expand Down Expand Up @@ -7347,6 +7405,8 @@ select 2002 as analysis_id,

--{2003 IN (@list_of_analysis_ids)}?{
-- 2003 Patients with at least one visit
-- this analysis is in fact redundant, since it is possible to get it via
-- dist analysis 203 and query select count_value from achilles_results_dist where analysis_id = 203;
insert into @results_database_schema.ACHILLES_results (analysis_id, count_value)
select 2003 as analysis_id, COUNT_BIG(distinct person_id) as count_value
from @cdm_database_schema.visit_occurrence;
Expand Down

0 comments on commit 648f270

Please sign in to comment.