From 0efff04be90f59e6e9a17b1874aa884a7c33e899 Mon Sep 17 00:00:00 2001 From: ohsudev Date: Thu, 22 Jan 2026 13:25:47 -0800 Subject: [PATCH] Modified Compliance reports to remove subquery results errors. --- .../onprc_ehr_compliancedb-25.000-25.001.sql | 579 ++++++++++++++++++ .../ONPRC_EHR_ComplianceDBModule.java | 2 +- 2 files changed, 580 insertions(+), 1 deletion(-) create mode 100644 ONPRC_EHR_ComplianceDB/resources/schemas/dbscripts/sqlserver/onprc_ehr_compliancedb-25.000-25.001.sql diff --git a/ONPRC_EHR_ComplianceDB/resources/schemas/dbscripts/sqlserver/onprc_ehr_compliancedb-25.000-25.001.sql b/ONPRC_EHR_ComplianceDB/resources/schemas/dbscripts/sqlserver/onprc_ehr_compliancedb-25.000-25.001.sql new file mode 100644 index 000000000..c64d1ffad --- /dev/null +++ b/ONPRC_EHR_ComplianceDB/resources/schemas/dbscripts/sqlserver/onprc_ehr_compliancedb-25.000-25.001.sql @@ -0,0 +1,579 @@ +ALTER TABLE onprc_ehr_compliancedb.ComplianceProcedureReport ALTER COLUMN expired_period varchar(50) NULL; +GO + +ALTER TABLE onprc_ehr_compliancedb.ComplianceProcedureReport ALTER COLUMN new_expired_period varchar(50) NULL; +GO + +ALTER TABLE onprc_ehr_compliancedb.ComplianceRecentReport ALTER COLUMN expired_period varchar(50) NULL; +GO + +ALTER TABLE onprc_ehr_compliancedb.ComplianceRecentReport ALTER COLUMN new_expired_period varchar(50) NULL; +GO + + + +EXEC core.fn_dropifexists 'p_ComplianceProcedureOverDueSoon_Process', 'onprc_ehr_compliancedb', 'PROCEDURE'; +GO + +-- Author: R. Blasa +-- Created: 9-20-2024 + +/* +** +** Created by +** Blasa 9-20-2024 Created a storedprocedure to create a static set of data from +** the ComplianceProcedureRecentTest.sql query +** +** 1-22-2026 Fix the issues with more than one subquery results +** +** +** +*/ + +CREATE Procedure onprc_ehr_compliancedb.p_ComplianceProcedureOverDueSoon_Process + + +AS + + + ----- Reset Reporting table + Delete onprc_ehr_compliancedb.ComplianceProcedureReport + + If @@Error <> 0 + GoTo Err_Proc + + + +BEGIN + + Insert into onprc_ehr_compliancedb.ComplianceProcedureReport + ( + requirementname, + employeeid, + unit, + category, + trackingflag, + email, + lastname, + firstname, + host, + supervisor, + trainee_type, + requirement_name_type, + times_completed, + expired_period, + new_expired_Period, + mostrecentcompleted_date, + comment, + snooze_date, + months_until_renewal + + ) + + + + + + select b.requirementname, + a.employeeid, + string_agg(a.unit,char(10)) as unit, + string_agg(a.category,char(10)) as category, + string_agg(b.trackingflag,char(10)) as trackingflag, + (select h.email from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as email, + (select h.lastname from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as lastname, + (select h.firstname from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as firstname, + (select h.majorudds from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as host, + (select h.supervisor from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as supervisor, + (select h.type from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as trainee_type, ----- type trainee, or trainer + (select string_agg(h.type,char(10)) from ehr_compliancedb.Requirements h where h.requirementname = b.requirementname) as requirement_type, + + (select count(zz.date) from ehr_compliancedb.completiondates zz where zz.requirementname= b.requirementname and zz.employeeid= a.employeeid ) as times_Completed, + + (select string_agg(k.expireperiod,char(10)) from ehr_compliancedb.Requirements k where k.requirementname = b.requirementname) as ExpiredPeriod, + + ( select (datediff(month,max(pq.date), tt.reviewdate) ) from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = b.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = a.employeeid group by tt.expireperiod, tt.reviewdate + having (COALESCE(tt.expireperiod,0)) > (datediff(month,max(pq.date), tt.reviewdate)) and (tt.reviewdate is not null) ) as NewExpirePeriod, + + (select max(zz.date) from ehr_compliancedb.completiondates zz where zz.requirementname= b.requirementname and zz.employeeid= a.employeeid ) as mostrecentcompleted_date, + + (Select distinct string_agg(yy.comment, char(10)) from ehr_compliancedb.completiondates yy where yy.date in (select max(zz.date) from ehr_compliancedb.completiondates zz where zz.requirementname= b.requirementname and zz.employeeid= a.employeeid ) + And yy.requirementname= b.requirementname and yy.employeeid= a.employeeid ) as comment, + + (Select distinct string_agg(yy.snooze_date, char(10)) from ehr_compliancedb.completiondates yy where yy.date in (select max(zz.date) from ehr_compliancedb.completiondates zz where zz.requirementname= b.requirementname and zz.employeeid= a.employeeid ) + And yy.requirementname= b.requirementname and yy.employeeid= a.employeeid ) as snooze_date, + + CAST( + CASE + + WHEN (select max(st.date) from ehr_compliancedb.completiondates st where st.requirementname = b.requirementname and st.employeeid = a.employeeid ) IS NULL then 0 + WHEN ( select (COALESCE(tt.expireperiod,0)) from ehr_compliancedb.requirements tt where tt.requirementname = b.requirementname group by tt.expireperiod ) = 0 then Null + + + WHEN ( select count(*) from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = b.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = a.employeeid group by tt.expireperiod, tt.reviewdate + having (tt.reviewdate) > (max(pq.date)) ) > 0 THEN + + ( select (datediff(month,max(pq.date), tt.reviewdate) - ( datediff(month,max(pq.date), getdate()) ) )from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = b.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = a.employeeid group by tt.expireperiod, tt.reviewdate + having (tt.reviewdate) > (max(pq.date)) ) + + + ELSE ( select (COALESCE(tt.expireperiod,0)) - ( datediff(month,max(pq.date), getdate()) ) from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = b.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = a.employeeid group by tt.expireperiod ) + + END AS Float) AS MonthsUntilRenewal + + + + from ehr_Compliancedb.employeeperunit a ,ehr_compliancedb.requirementspercategory b + where ( a.unit = b.unit or a.category = b.category ) + And b.requirementname not in (select distinct t.requirementname from ehr_compliancedb.employeerequirementexemptions t Where a.employeeid = t.employeeid + And b.requirementname = t.requirementname) + And a.employeeid in (select p.employeeid from ehr_compliancedb.employees p where a.employeeid = p.employeeid And p.enddate is null) + And b.requirementname in (select q.requirementname from ehr_compliancedb.Requirements q where q.requirementname = b.requirementname And q.dateDisabled is null ) + + + group by b.requirementname,a.employeeid + + union + + select a.requirementname, + a.employeeid, + null as unit, + null as category, + 'None' as trackingflag, + (select h.email from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as email, + (select h.lastname from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as lastname, + (select h.firstname from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as firstname, + (select h.majorudds from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as host, + (select h.supervisor from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as supervisor, + (select h.type from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as trainee_type, ----- type trainee, or trainer + (select string_agg(h.type,char(10))from ehr_compliancedb.Requirements h where h.requirementname = a.requirementname) as requirement_type, ----- type trainee, or trainer + + + (select count(zz.date) from ehr_compliancedb.completiondates zz where zz.requirementname= a.requirementname and zz.employeeid= a.employeeid ) as timesCompleted, + + (select string_agg(k.expireperiod,char(10)) from ehr_compliancedb.Requirements k where k.requirementname = a.requirementname) as ExpiredPeriod, + + ( select (datediff(month,max(pq.date), tt.reviewdate) )from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = a.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = a.employeeid group by tt.expireperiod, tt.reviewdate + having (COALESCE(tt.expireperiod,0)) > (datediff(month,max(pq.date), tt.reviewdate)) and (tt.reviewdate is not null) ) as NewExpirePeriod, + + (select max(zz.date) from ehr_compliancedb.completiondates zz where zz.requirementname= a.requirementname and zz.employeeid= a.employeeid ) as MostRecentDate, + + (Select distinct string_agg(yy.comment, char(10)) from ehr_compliancedb.completiondates yy where yy.date in (select max(zz.date) from ehr_compliancedb.completiondates zz where zz.requirementname= a.requirementname and zz.employeeid= a.employeeid ) + And yy.requirementname= a.requirementname and yy.employeeid= a.employeeid ) as comment, + + (Select distinct string_agg(yy.snooze_date, char(10)) from ehr_compliancedb.completiondates yy where yy.date in (select max(zz.date) from ehr_compliancedb.completiondates zz where zz.requirementname= a.requirementname and zz.employeeid= a.employeeid ) + And yy.requirementname= a.requirementname and yy.employeeid= a.employeeid ) as snooze_date, + + CAST( + CASE + WHEN (select max(st.date) from ehr_compliancedb.completiondates st where st.requirementname = a.requirementname and st.employeeid = a.employeeid ) IS NULL then 0 + WHEN ( select (COALESCE(tt.expireperiod,0)) from ehr_compliancedb.requirements tt where tt.requirementname = a.requirementname group by tt.expireperiod ) = 0 then Null + + + WHEN ( select count(*) from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = a.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = a.employeeid group by tt.expireperiod, tt.reviewdate + having (tt.reviewdate) > (max(pq.date)) ) > 0 THEN + + ( select (datediff(month,max(pq.date), tt.reviewdate) - ( datediff(month,max(pq.date), getdate())) ) from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = a.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = a.employeeid group by tt.expireperiod, tt.reviewdate + having (tt.reviewdate) > (max(pq.date)) ) + + + ELSE ( select (COALESCE(tt.expireperiod,0)) - ( datediff(month,max(pq.date), getdate())) from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = a.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = a.employeeid group by tt.expireperiod ) + + END AS FLOAT) AS MonthsUntilRenewal + + + from ehr_compliancedb.completiondates a + where a.requirementname not in (select distinct h.requirementname from ehr_compliancedb.employeeperunit k, ehr_compliancedb.requirementspercategory h Where (k.unit = h.unit + or k.category = h.category) And a.employeeid = k.employeeid ) + And a.requirementname not in (select distinct t.requirementname from ehr_compliancedb.employeerequirementexemptions t Where a.employeeid = t.employeeid + And a.requirementname = t.requirementname) + And a.employeeid in (select p.employeeid from ehr_compliancedb.employees p where a.employeeid = p.employeeid And p.enddate is null) + And a.requirementname in (select q.requirementname from ehr_compliancedb.Requirements q where q.requirementname = a.requirementname And q.dateDisabled is null ) + + group by a.requirementname,a.employeeid + + union + + -- Additional requirements for employees that have not completed training, but is required + select j.requirementname, + j.employeeid, + null as unit, + null as category, + string_agg(j.trackingflag,char(10)) as trackingflag, + (select h.email from ehr_compliancedb.employees h where h.employeeid = j.employeeid) as email, + (select h.lastname from ehr_compliancedb.employees h where h.employeeid = j.employeeid) as lastname, + (select h.firstname from ehr_compliancedb.employees h where h.employeeid = j.employeeid) as firstname, + (select h.majorudds from ehr_compliancedb.employees h where h.employeeid = j.employeeid) as host, + (select h.supervisor from ehr_compliancedb.employees h where h.employeeid = j.employeeid) as supervisor, + (select h.type from ehr_compliancedb.employees h where h.employeeid = j.employeeid) as trainee_type, ----- type trainee, or trainer + (select string_agg(h.type,char(10)) from ehr_compliancedb.Requirements h where h.requirementname = j.requirementname) as requirement_type, ----- type trainee, or trainer + 0 as timesCompleted, + (select string_agg(k.expireperiod,char(10)) from ehr_compliancedb.Requirements k where k.requirementname = j.requirementname) as ExpiredPeriod, + ( select (datediff(month,max(pq.date), tt.reviewdate) )from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = j.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = j.employeeid group by tt.expireperiod, tt.reviewdate + having (COALESCE(tt.expireperiod,0)) > (datediff(month,max(pq.date), tt.reviewdate)) and (tt.reviewdate is not null) ) as NewExpirePeriod, + null as MostRecentDate, + '' as comment, + null as snooze_date, + CAST( + CASE + + WHEN (select max(st.date) from ehr_compliancedb.completiondates st where st.requirementname = j.requirementname and st.employeeid = j.employeeid ) IS NULL then 0 + WHEN ( select (COALESCE(tt.expireperiod,0)) from ehr_compliancedb.requirements tt where tt.requirementname = j.requirementname group by tt.expireperiod ) = 0 then Null + + + WHEN ( select count(*) from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = j.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = j.employeeid group by tt.expireperiod, tt.reviewdate + having (tt.reviewdate) > (max(pq.date)) ) > 0 THEN + + ( select (datediff(month,max(pq.date), tt.reviewdate) - ( datediff(month,max(pq.date), getdate())) ) from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = j.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = j.employeeid group by tt.expireperiod, tt.reviewdate + having (tt.reviewdate) > (max(pq.date)) ) + + + ELSE ( select (COALESCE(tt.expireperiod,0)) - ( datediff(month,max(pq.date), getdate())) from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = j.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = j.employeeid group by tt.expireperiod ) + + END AS FLOAT) AS MonthsUntilRenewal + + + + from onprc_ehr_compliancedb.RequirementsPerEmployee j + Where j.employeeid in (select p.employeeid from ehr_compliancedb.employees p where j.employeeid = p.employeeid And p.enddate is null) + And j.requirementname in (select q.requirementname from ehr_compliancedb.Requirements q where q.requirementname = j.requirementname And q.dateDisabled is null ) + And j.requirementname not in (select distinct h.requirementname from ehr_compliancedb.employeeperunit k, ehr_compliancedb.requirementspercategory h Where (k.unit = h.unit + or k.category = h.category) And j.employeeid = k.employeeid ) + And j.requirementname not in (select distinct t.requirementname from ehr_compliancedb.employeerequirementexemptions t Where j.employeeid = t.employeeid And j.requirementname = t.requirementname) + And j.requirementname not in (select distinct k.requirementname from ehr_compliancedb.completiondates k Where k.employeeid = j.employeeid) + + group by j.requirementname,j.employeeid + + order by employeeid,requirementname, mostrecentcompleted_date desc + + + If @@Error <> 0 + GoTo Err_Proc + + + + + RETURN 0 + + +Err_Proc: + + RETURN 1 + + +END + +GO + + + + +EXEC core.fn_dropifexists 'p_ComplianceRecentOverDueSoon_Process', 'onprc_ehr_compliancedb', 'PROCEDURE'; +GO + +-- Author: R. Blasa +-- Created: 9-20-2024 + +/* +** +** Created by +** Blasa 9-20-2024 Created a storedprocedure to create a static set of data from +** the ComplianceRecentTest.sql query +** +** 1-22-2026 Fix the issues with more than one subquery results +** +** +*/ + +CREATE Procedure onprc_ehr_compliancedb.p_ComplianceRecentOverDueSoon_Process + + + AS + + + +----- Reset Reporting table +Delete onprc_ehr_compliancedb.ComplianceRecentReport + + If @@Error <> 0 + GoTo Err_Proc + + + +BEGIN + +Insert into onprc_ehr_compliancedb.ComplianceRecentReport +( + requirementname, + employeeid, + unit, + category, + trackingflag, + email, + lastname, + firstname, + host, + supervisor, + trainee_type, + requirement_name_type, + times_completed, + expired_period, + new_expired_Period, + mostrecentcompleted_date, + comment, + snooze_date, + months_until_renewal + +) + + + + +select b.requirementname, + a.employeeid, + string_agg(a.unit,char(10)) as unit, + string_agg(a.category,char(10)) as category, + string_agg(b.trackingflag,char(10)) as trackingflag, + (select h.email from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as email, + (select h.lastname from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as lastname, + (select h.firstname from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as firstname, + (select h.majorudds from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as host, + (select h.supervisor from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as supervisor, + (select h.type from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as trainee_type, ----- type trainee, or trainer + (select string_agg(h.type,char(10)) from ehr_compliancedb.Requirements h where h.requirementname = b.requirementname) as requirement_type, ----- type trainee, or trainer + + + (select count(zz.date) from ehr_compliancedb.completiondates zz where zz.requirementname= b.requirementname and zz.employeeid= a.employeeid ) as times_Completed, + + (select string_agg(k.expireperiod,char(10)) from ehr_compliancedb.Requirements k where k.requirementname = b.requirementname) as ExpiredPeriod, + + ( select (datediff(month,max(pq.date), tt.reviewdate) ) from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = b.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = a.employeeid group by tt.expireperiod, tt.reviewdate + having (COALESCE(tt.expireperiod,0)) > (datediff(month,max(pq.date), tt.reviewdate)) and (tt.reviewdate is not null) ) as NewExpirePeriod, + + (select max(zz.date) from ehr_compliancedb.completiondates zz where zz.requirementname= b.requirementname and zz.employeeid= a.employeeid ) as mostrecentcompleted_date, + + (Select distinct string_agg(yy.comment, char(10)) from ehr_compliancedb.completiondates yy where yy.date in (select max(zz.date) from ehr_compliancedb.completiondates zz where zz.requirementname= b.requirementname and zz.employeeid= a.employeeid ) + And yy.requirementname= b.requirementname and yy.employeeid= a.employeeid ) as comment, + + (Select distinct string_agg(yy.snooze_date, char(10)) from ehr_compliancedb.completiondates yy where yy.date in (select max(zz.date) from ehr_compliancedb.completiondates zz where zz.requirementname= b.requirementname and zz.employeeid= a.employeeid ) + And yy.requirementname= b.requirementname and yy.employeeid= a.employeeid ) as snooze_date, + + CAST( + CASE + + WHEN (select max(st.date) from ehr_compliancedb.completiondates st where st.requirementname = b.requirementname and st.employeeid = a.employeeid ) IS NULL then 0 + WHEN ( select (COALESCE(tt.expireperiod,0)) from ehr_compliancedb.requirements tt where tt.requirementname = b.requirementname group by tt.expireperiod ) = 0 then Null + + + WHEN ( select count(*) from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = b.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = a.employeeid group by tt.expireperiod, tt.reviewdate + having (tt.reviewdate) > (max(pq.date)) ) > 0 THEN + + ( select (datediff(month,max(pq.date), tt.reviewdate) - ( datediff(month,max(pq.date), getdate())) ) from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = b.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = a.employeeid group by tt.expireperiod, tt.reviewdate + having (tt.reviewdate) > (max(pq.date)) ) + + + + + ELSE ( select (COALESCE(tt.expireperiod,0)) - ( datediff(month,max(pq.date), getdate())) from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = b.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = a.employeeid group by tt.expireperiod ) + + END AS FLOAT) AS MonthsUntilRenewal + + + +from ehr_Compliancedb.employeeperunit a ,ehr_compliancedb.requirementspercategory b +where ( a.unit = b.unit or a.category = b.category ) + And b.requirementname not in (select distinct t.requirementname from ehr_compliancedb.employeerequirementexemptions t Where a.employeeid = t.employeeid + And b.requirementname = t.requirementname) + And a.employeeid in (select p.employeeid from ehr_compliancedb.employees p where a.employeeid = p.employeeid And p.enddate is null) + And b.requirementname in (select q.requirementname from ehr_compliancedb.Requirements q where q.requirementname = b.requirementname And q.dateDisabled is null ) + + +group by b.requirementname,a.employeeid + + +union + +select a.requirementname, + a.employeeid, + null as unit, + null as category, + 'None' as trackingflag, + (select h.email from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as email, + (select h.lastname from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as lastname, + (select h.firstname from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as firstname, + (select h.majorudds from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as host, + (select h.supervisor from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as supervisor, + (select h.type from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as trainee_type, ----- type trainee, or trainer + (select string_agg(h.type,char(10)) from ehr_compliancedb.Requirements h where h.requirementname = a.requirementname) as requirement_type, ----- type trainee, or trainer + + + (select count(zz.date) from ehr_compliancedb.completiondates zz where zz.requirementname= a.requirementname and zz.employeeid= a.employeeid ) as timesCompleted, + + (select string_agg(k.expireperiod,char(10)) from ehr_compliancedb.Requirements k where k.requirementname = a.requirementname) as ExpiredPeriod, + + ( select (datediff(month,max(pq.date), tt.reviewdate) )from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = a.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = a.employeeid group by tt.expireperiod, tt.reviewdate + having (COALESCE(tt.expireperiod,0)) > (datediff(month,max(pq.date), tt.reviewdate)) and (tt.reviewdate is not null) ) as NewExpirePeriod, + + (select max(zz.date) from ehr_compliancedb.completiondates zz where zz.requirementname= a.requirementname and zz.employeeid= a.employeeid ) as MostRecentDate, + + (Select distinct string_agg(yy.comment, char(10)) from ehr_compliancedb.completiondates yy where yy.date in (select max(zz.date) from ehr_compliancedb.completiondates zz where zz.requirementname= a.requirementname and zz.employeeid= a.employeeid ) + And yy.requirementname= a.requirementname and yy.employeeid= a.employeeid ) as comment, + + (Select distinct string_agg(yy.snooze_date, char(10)) from ehr_compliancedb.completiondates yy where yy.date in (select max(zz.date) from ehr_compliancedb.completiondates zz where zz.requirementname= a.requirementname and zz.employeeid= a.employeeid ) + And yy.requirementname= a.requirementname and yy.employeeid= a.employeeid ) as snooze_date, + + CAST( + CASE + WHEN (select max(st.date) from ehr_compliancedb.completiondates st where st.requirementname = a.requirementname and st.employeeid = a.employeeid ) IS NULL then 0 + WHEN ( select (COALESCE(tt.expireperiod,0)) from ehr_compliancedb.requirements tt where tt.requirementname = a.requirementname group by tt.expireperiod ) = 0 then Null + + + WHEN ( select count(*) from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = a.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = a.employeeid group by tt.expireperiod, tt.reviewdate + having (tt.reviewdate) > (max(pq.date)) ) > 0 THEN + + ( select (datediff(month,max(pq.date), tt.reviewdate) - ( datediff(month,max(pq.date), getdate())) ) from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = a.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = a.employeeid group by tt.expireperiod, tt.reviewdate + having (tt.reviewdate) > (max(pq.date)) ) + + + ELSE ( select (COALESCE(tt.expireperiod,0)) - ( datediff(month,max(pq.date), getdate())) from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = a.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = a.employeeid group by tt.expireperiod ) + + END AS FLOAT) AS MonthsUntilRenewal + + +from ehr_compliancedb.completiondates a +where a.requirementname not in (select distinct h.requirementname from ehr_compliancedb.employeeperunit k, ehr_compliancedb.requirementspercategory h Where (k.unit = h.unit + or k.category = h.category) And a.employeeid = k.employeeid ) + And a.requirementname not in (select distinct t.requirementname from ehr_compliancedb.employeerequirementexemptions t Where a.employeeid = t.employeeid + And a.requirementname = t.requirementname) + And a.employeeid in (select p.employeeid from ehr_compliancedb.employees p where a.employeeid = p.employeeid And p.enddate is null) + And a.requirementname in (select q.requirementname from ehr_compliancedb.Requirements q where q.requirementname = a.requirementname And q.dateDisabled is null ) + +group by a.requirementname,a.employeeid + +UNION + +--- Training that was completed by as an employee training exemptions, and at least completed one, or more times + +select a.requirementname, + a.employeeid, + null as unit, + null as category, + 'No' as trackingflag, + (select h.email from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as email, + (select h.lastname from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as lastname, + (select h.firstname from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as firstname, + (select h.majorudds from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as host, + (select h.supervisor from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as supervisor, + (select h.type from ehr_compliancedb.employees h where h.employeeid = a.employeeid) as trainee_type, ----- type trainee, or trainer + (select string_agg(h.type,char(10)) from ehr_compliancedb.Requirements h where h.requirementname = a.requirementname) as requirement_type, ----- type trainee, or trainer + + + (select count(zz.date) from ehr_compliancedb.completiondates zz where zz.requirementname= a.requirementname and zz.employeeid= a.employeeid ) as timesCompleted, + + (select string_agg(k.expireperiod,char(10)) from ehr_compliancedb.Requirements k where k.requirementname = a.requirementname) as ExpiredPeriod, + + ( select (datediff(month,max(pq.date), tt.reviewdate) )from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = a.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = a.employeeid group by tt.expireperiod, tt.reviewdate + having (COALESCE(tt.expireperiod,0)) > (datediff(month,max(pq.date), tt.reviewdate)) and (tt.reviewdate is not null) ) as NewExpirePeriod, + + (select max(zz.date) from ehr_compliancedb.completiondates zz where zz.requirementname= a.requirementname and zz.employeeid= a.employeeid ) as MostRecentDate, + + (Select distinct string_agg(yy.comment, char(10)) from ehr_compliancedb.completiondates yy where yy.date in (select max(zz.date) from ehr_compliancedb.completiondates zz where zz.requirementname= a.requirementname and zz.employeeid= a.employeeid ) + And yy.requirementname= a.requirementname and yy.employeeid= a.employeeid ) as comment, + + (Select distinct string_agg(yy.snooze_date, char(10)) from ehr_compliancedb.completiondates yy where yy.date in (select max(zz.date) from ehr_compliancedb.completiondates zz where zz.requirementname= a.requirementname and zz.employeeid= a.employeeid ) + And yy.requirementname= a.requirementname and yy.employeeid= a.employeeid ) as snooze_date, + + CAST( + CASE + WHEN (select max(st.date) from ehr_compliancedb.completiondates st where st.requirementname = a.requirementname and st.employeeid = a.employeeid ) IS NULL then 0 + WHEN ( select (COALESCE(tt.expireperiod,0)) from ehr_compliancedb.requirements tt where tt.requirementname = a.requirementname group by tt.expireperiod ) = 0 then Null + + + WHEN ( select count(*) from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = a.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = a.employeeid group by tt.expireperiod, tt.reviewdate + having (tt.reviewdate) > (max(pq.date)) ) > 0 THEN + + ( select ( datediff(month,max(pq.date), tt.reviewdate) - (datediff(month,max(pq.date), getdate())) )from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = a.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = a.employeeid group by tt.expireperiod, tt.reviewdate + having (tt.reviewdate) > (max(pq.date)) ) + + + ELSE ( select (COALESCE(tt.expireperiod,0)) - ( datediff(month,max(pq.date), getdate())) from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = a.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = a.employeeid group by tt.expireperiod ) + + END AS DECIMAL) AS MonthsUntilRenewal + + +from ehr_compliancedb.employeerequirementexemptions a +Where a.employeeid in (select p.employeeid from ehr_compliancedb.employees p where a.employeeid = p.employeeid And p.enddate is null) + And a.requirementname in (select q.requirementname from ehr_compliancedb.Requirements q where q.requirementname = a.requirementname And q.dateDisabled is null ) + +group by a.requirementname,a.employeeid + +UNION + +--- Additional requirements for employees that have not completed training, but is required + +select j.requirementname, + j.employeeid, + null as unit, + null as category, + string_agg(j.trackingflag,char(10)) as trackingflag, + (select h.email from ehr_compliancedb.employees h where h.employeeid = j.employeeid) as email, + (select h.lastname from ehr_compliancedb.employees h where h.employeeid = j.employeeid) as lastname, + (select h.firstname from ehr_compliancedb.employees h where h.employeeid = j.employeeid) as firstname, + (select h.majorudds from ehr_compliancedb.employees h where h.employeeid = j.employeeid) as host, + (select h.supervisor from ehr_compliancedb.employees h where h.employeeid = j.employeeid) as supervisor, + (select h.type from ehr_compliancedb.employees h where h.employeeid = j.employeeid) as trainee_type, ----- type trainee, or trainer + (select string_agg(h.type,char(10)) from ehr_compliancedb.Requirements h where h.requirementname = j.requirementname) as requirement_type, ----- type trainee, or trainer + 0 as timesCompleted, + (select string_agg(k.expireperiod,char(10)) from ehr_compliancedb.Requirements k where k.requirementname = j.requirementname) as ExpiredPeriod, + ( select (datediff(month,max(pq.date), tt.reviewdate) )from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = j.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = j.employeeid group by tt.expireperiod, tt.reviewdate + having (COALESCE(tt.expireperiod,0)) > (datediff(month,max(pq.date), tt.reviewdate)) and (tt.reviewdate is not null) ) as NewExpirePeriod, + null as MostRecentDate, + '' as comment, + null as snooze_date, + CAST( + CASE + + WHEN (select max(st.date) from ehr_compliancedb.completiondates st where st.requirementname = j.requirementname and st.employeeid = j.employeeid ) IS NULL then 0 + WHEN ( select (COALESCE(tt.expireperiod,0)) from ehr_compliancedb.requirements tt where tt.requirementname = j.requirementname group by tt.expireperiod ) = 0 then Null + + WHEN ( select count(*) from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = j.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = j.employeeid group by tt.expireperiod, tt.reviewdate + having (tt.reviewdate) > (max(pq.date)) ) > 0 THEN + + ( select (datediff(month,max(pq.date), tt.reviewdate) - ( datediff(month,max(pq.date), getdate())) ) from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = j.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = j.employeeid group by tt.expireperiod, tt.reviewdate + having (tt.reviewdate) > (max(pq.date)) ) + + + ELSE ( select (COALESCE(tt.expireperiod,0)) - ( datediff(month,max(pq.date), getdate())) from ehr_compliancedb.requirements tt, ehr_compliancedb.completiondates pq where tt.requirementname = j.requirementname and pq.requirementname = tt.requirementname and pq.employeeid = j.employeeid group by tt.expireperiod ) + + END AS FLOAT) AS MonthsUntilRenewal + + +from onprc_ehr_compliancedb.RequirementsPerEmployee j +Where j.employeeid in (select p.employeeid from ehr_compliancedb.employees p where j.employeeid = p.employeeid And p.enddate is null) + And j.requirementname in (select q.requirementname from ehr_compliancedb.Requirements q where q.requirementname = j.requirementname And q.dateDisabled is null ) + And j.requirementname not in (select distinct h.requirementname from ehr_compliancedb.employeeperunit k, ehr_compliancedb.requirementspercategory h Where (k.unit = h.unit + or k.category = h.category) And j.employeeid = k.employeeid ) + And j.requirementname not in (select distinct t.requirementname from ehr_compliancedb.employeerequirementexemptions t Where j.employeeid = t.employeeid And j.requirementname = t.requirementname) + And j.requirementname not in (select distinct k.requirementname from ehr_compliancedb.completiondates k Where k.employeeid = j.employeeid) + +group by j.requirementname,j.employeeid + +order by employeeid,requirementname, mostrecentcompleted_date desc + + + If @@Error <> 0 + GoTo Err_Proc + + + + + RETURN 0 + + +Err_Proc: + + RETURN 1 + + +END + +GO \ No newline at end of file diff --git a/ONPRC_EHR_ComplianceDB/src/org/labkey/ONPRCEHR_ComplianceDB/ONPRC_EHR_ComplianceDBModule.java b/ONPRC_EHR_ComplianceDB/src/org/labkey/ONPRCEHR_ComplianceDB/ONPRC_EHR_ComplianceDBModule.java index 4ee6b9e89..e03bd4352 100644 --- a/ONPRC_EHR_ComplianceDB/src/org/labkey/ONPRCEHR_ComplianceDB/ONPRC_EHR_ComplianceDBModule.java +++ b/ONPRC_EHR_ComplianceDB/src/org/labkey/ONPRCEHR_ComplianceDB/ONPRC_EHR_ComplianceDBModule.java @@ -55,7 +55,7 @@ public String getName() @Override public Double getSchemaVersion() { - return 24.012; + return 25.001; } //Modified: 9-8-025 @Override