Important Content Update Message
We are currently updating the OP Help Center content for the release of OP 20. OP 20 (official version 20.0.x) is the certified, 2015 Edition, version of the Office Practicum software. This is displayed in your software (Help tab > About) and in the Help Center tab labeled Version 20.0. We appreciate your patience as we continue to update all of our content.

SQL: Total Number of Sick (New and Est) by Location and Provider

About

Shows number of each type of sick visit, sum of new and established sick visits, and grand total of sick visits for a period you specify, grouped by location and rendering provider.

A sample image of this SQL report run in the Database Viewer is shown below:

Caveats

Takes a while to run. Do not run for periods exceeding a year at a time.

Code

To highlight and copy the code below to your clipboard, simply click the Copy button.

With raw_sums as (
select location.id as locnum, p.rend_addr_id, s99201, s99202, s99203, s99204, s99205, s99211, s99212, s99213, s99214, s99215 from location
left outer join
 (select distinct loc_id, rend_addr_id from archive_transactions where date1 between :Start_date and :end_Date and cptcode between '99201' and '99215') p on p.loc_id = location.id
left outer join
 (select loc_id, rend_addr_id,count(cptcode) as s99201 from archive_transactions where cptcode = '99201' and archive_Flag = 1 and date1 between :Start_date and :end_Date group by loc_id, rend_addr_id ) a on a.loc_id = location.id and a.rend_addr_id = p.rend_addr_id
left outer join
 (select loc_id, rend_addr_id,  count(cptcode) as s99202 from archive_transactions where cptcode = '99202' and archive_Flag = 1 and date1 between :Start_date and :end_Date  group by loc_id, rend_addr_id) b on b.loc_id = location.id and   b.rend_addr_id = p.rend_addr_id
left outer join
 (select loc_id, rend_addr_id,  count(cptcode) as s99203 from archive_transactions where cptcode = '99203' and archive_Flag = 1 and date1 between :Start_date and :end_Date  group by loc_id, rend_addr_id) c on c.loc_id = location.id and   c.rend_addr_id = p.rend_addr_id
left outer join
 (select loc_id, rend_addr_id,  count(cptcode) as s99204 from archive_transactions where cptcode = '99204' and archive_Flag = 1 and date1 between :Start_date and :end_Date  group by loc_id, rend_addr_id) d on d.loc_id = location.id and   d.rend_addr_id = p.rend_addr_id
left outer join
 (select loc_id, rend_addr_id,  count(cptcode) as s99205 from archive_transactions where cptcode = '99205' and archive_Flag = 1 and date1 between :Start_date and :end_Date  group by loc_id, rend_addr_id) e on e.loc_id = location.id and   e.rend_addr_id = p.rend_addr_id
left outer join
 (select loc_id, rend_addr_id,  count(cptcode) as s99211 from archive_transactions where cptcode = '99211' and archive_Flag = 1 and date1 between :Start_date and :end_Date  group by loc_id, rend_addr_id) f on f.loc_id = location.id and   f.rend_addr_id = p.rend_addr_id
left outer join
 (select loc_id, rend_addr_id,  count(cptcode) as s99212 from archive_transactions where cptcode = '99212' and archive_Flag = 1 and date1 between :Start_date and :end_Date  group by loc_id, rend_addr_id) g on g.loc_id = location.id and   g.rend_addr_id = p.rend_addr_id
left outer join
 (select loc_id, rend_addr_id,  count(cptcode) as s99213 from archive_transactions where cptcode = '99213' and archive_Flag = 1 and date1 between :Start_date and :end_Date  group by loc_id, rend_addr_id) h on h.loc_id = location.id and   h.rend_addr_id = p.rend_addr_id
left outer join
 (select loc_id, rend_addr_id,  count(cptcode) as s99214 from archive_transactions where cptcode = '99214' and archive_Flag = 1 and date1 between :Start_date and :end_Date  group by loc_id, rend_addr_id) i on i.loc_id = location.id and   i.rend_addr_id = p.rend_addr_id
left outer join
 (select loc_id, rend_addr_id,  count(cptcode) as s99215 from archive_transactions where cptcode = '99215' and archive_Flag = 1 and date1 between :Start_date and :end_Date  group by loc_id, rend_addr_id) j on j.loc_id = location.id and   j.rend_addr_id = p.rend_addr_id

where location.archive_flag <> 1

), all_locs as
(select id, loc_name from location where archive_flag <> 1),

provider_new_sums as
(
Select loc_id, rend_addr_id, count(cptcode) as total_new from
(
Select loc_id, rend_addr_id, cptcode from archive_Transactions at1
where date1 between :Start_date and :end_Date and  (cptcode between '99201' and '99205') and at1.archive_Flag = 1
) group by loc_id,  rend_addr_id
),
provider_est_sums as 
(

Select loc_id, rend_addr_id, count(cptcode) as total_est from
(
Select loc_id, rend_addr_id, cptcode from archive_Transactions at1
where date1 between :Start_date and :end_Date and  (cptcode between '99211' and '99215') and at1.archive_Flag = 1
) group by loc_id,  rend_addr_id


)


select loc_name, staffname, s99201, s99202, s99203, s99204,s99205,total_new, s99211,s99212,s99213,s99214,s99215, total_est, coalesce(total_new,0) + coalesce(total_est,0) as grand_total from
(
Select all_locs.loc_name, staffname, raw_sums.s99201, raw_sums.s99202, raw_sums.s99203, raw_sums.s99204, raw_sums.s99205, pns.total_new, 
raw_sums.s99211, raw_sums.s99212, raw_sums.s99213, raw_sums.s99214, raw_sums.s99215,
pes.total_est from all_locs
Left outer join raw_sums on raw_sums.locnum = all_locs.id
left outer join provider_new_sums pns on pns.loc_id = raw_sums.locnum and  pns.rend_addr_id = raw_sums.rend_addr_id
left outer join provider_est_sums pes on pes.loc_id = raw_sums.locnum and  pes.rend_addr_id = raw_sums.rend_addr_id
left outer join staff1 on staff1.staffid = raw_sums.rend_addr_id
union


select loc_name, '_Total' as staffname, sum(s99201) as t_99201, sum(s99202) as t_99202, sum(s99203) as t_99203, sum(s99204) as t_99204, sum(s99205) as t_99205, 
sum(total_new) as t_new, sum(s99211) as t_99211, sum(s99212) as t_99212, sum(s99213) as t_99213, sum(s99214) as t_99214, sum(s99215) as t_99215, sum(total_est) as t_est from
(
Select all_locs.loc_name, raw_sums.*, pns.total_new, pes.total_est from all_locs
Left outer join raw_sums on raw_sums.locnum = all_locs.id
left outer join provider_new_sums pns on pns.loc_id = raw_sums.locnum and  pns.rend_addr_id = raw_sums.rend_addr_id
left outer join provider_est_sums pes on pes.loc_id = raw_sums.locnum and  pes.rend_addr_id = raw_sums.rend_addr_id
) group by loc_name, locnum

) order by loc_name, staffname