SQL: Accounts Receivable for Dates of Service

There are two versions of this SQL: Firebird and MySQL. The MySQL version only applies to clients who are have migrated to MySQL.. All other Practices should continue to use the Firebird version of this code. Click to expand and copy the code you need. If you are unsure which code to use, please check with your Practice Administrator.

About

This report shows the CURRENT aging for a set of PAST date of service transactions that you specify.

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

Caveats

  • Insurance amounts age between the date of service and today.  
  • Patient amounts age between the date of patient responsibility and today.
  • The date range that you set does not create or recreate your historical aging. For example, if you run this report for 1/1/2018-12/31/2018 on 3/1/2019, it will show you how receivables from 2018 look on 3/1/19. There will be nothing in the insurance side in your 0-30 and 30-60 buckets because no date between 1/1/2018 and 12/31/2018 is under 60 days from 3/1/2019.
  • To see “where are all my receivables currently?” choose the complete date range that you have been running OP (i.e. from date = started using OP date; to date = today). 
  • An “Unvoided PLA” row means you have not voided and reassigned practice level adjustments.   See Billing Transaction Analysis: Practice Level Adjustment for more information.

SQL Code: Firebird

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

with ar as
(
select trnsxno, rend_staff, patno, dos, ins_carrier_code, cptcode, charge, ins_balance, pt_balance, p1 as ins_paid, a1 as ins_adj, c1 as pt_paid, w1 as pt_adj, all_aging, case when all_aging <=30 then '0-30' when all_aging >30 and all_aging <=60 then '31-60' when all_aging >60 and all_aging <=90 then '61-90' when all_aging >90 and all_aging <=120 then '91-120' else '121+'  end as aging from
(
select b.*, case when ins_balance >= 0.01 then cast('today' as date)-dos  when pt_balance >=0.01 then cast('today' as date)- coalesce(pt_resp_date,dos) end as all_aging from
(
select a.* from
(
select trnsxno,staffname as rend_staff, patno,  date1 as DOS, ins_carrier_code, cptcode,  charge, tx_balance as ins_balance, copaybalance as pt_balance, coalesce(p,0) as  p1, coalesce(a,0) as a1, coalesce( c,0) as c1,coalesce(w,0) as w1 from
(select 
 trnsxno, patno, rend_addr_id, cptcode, date1, ins_carrier_code, charge, tx_balance, copaybalance from archive_transactions where date1 between :startdate and :enddate and cptcode not in ('1','2','3','4') and archive_flag = 1) at1
left outer join
(select txnopaid,  sum(payment) as p,  sum(adjustment) as a, sum(copayrecd) as c, sum(copayadjustment) as w from archive_transactions where archive_flag = 1 group by txnopaid) at2 on at2.txnopaid = at1.trnsxno
left outer join
staff1 on staff1.staffid = at1.rend_addr_id
) a
where abs(charge - p1-a1-c1-w1 )>=0.01 and (ins_balance >= 0.01 or pt_balance >=0.01)
) b 
left outer join 
(select txnopaid, max(date1) as pt_resp_date from archive_transactions where cptcode ='4' and archive_flag = 1 group by txnopaid) at3 on b.trnsxno = at3.txnopaid
) c
where patno >99
), patadj as
(
select trnsxno, rend_staff, patno, dos, ins_carrier_code, cptcode, charge, ins_balance, pt_balance, p1 as ins_paid, a1 as ins_adj, c1 as pt_paid, w1 as pt_adj, all_aging, case when all_aging <=30 then '0-30' when all_aging >30 and all_aging <=60 then '31-60' when all_aging >60 and all_aging <=90 then '61-90' when all_aging >90 and all_aging <=120 then '91-120' else '121+'  end as aging from
(
select b.*, case when ins_balance >= 0.01 then cast('today' as date)-dos  when pt_balance >=0.01 then cast('today' as date)- coalesce(pt_resp_date,dos) end as all_aging from
(
select a.* from
(
select trnsxno,staffname as rend_staff, patno,  date1 as DOS, ins_carrier_code, cptcode,  charge, tx_balance as ins_balance, copaybalance as pt_balance, coalesce(p,0) as  p1, coalesce(a,0) as a1, coalesce( c,0) as c1,coalesce(w,0) as w1 from
(select 
 trnsxno, patno, rend_addr_id, cptcode, date1, ins_carrier_code, charge, tx_balance, copaybalance from archive_transactions where date1 between :startdate and :enddate and cptcode not in ('1','2','3','4') and archive_flag = 1) at1
left outer join
(select txnopaid,  sum(payment) as p,  sum(adjustment) as a, sum(copayrecd) as c, sum(copayadjustment) as w from archive_transactions where archive_flag = 1 group by txnopaid) at2 on at2.txnopaid = at1.trnsxno
left outer join
staff1 on staff1.staffid = at1.rend_addr_id
) a
where abs(charge - p1-a1-c1-w1 )>=0.01 and (ins_balance >= 0.01 or pt_balance >=0.01)
) b 
left outer join 
(select txnopaid, max(date1) as pt_resp_date from archive_transactions where cptcode ='4' and archive_flag = 1 group by txnopaid) at3 on b.trnsxno = at3.txnopaid
) c
where patno = -5)

select 'True Receivables' as rowtype, aging, sum(ins_balance) as insag, sum(pt_balance) as ptag from ar group by aging 
union
select 'Unvoided PLA' as rowtype, aging, sum(ins_balance) as insag, sum(pt_balance) as ptag from patadj group by aging


SQL Code: MySQL

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

select 'True Receivables' as rowtype, aging, sum(ins_balance) as insag, sum(pt_balance) as ptag from
(
select trnsxno, rend_staff, patno, dos, ins_carrier_code, cptcode, charge, ins_balance, pt_balance, p1 as ins_paid, a1 as ins_adj, c1 as pt_paid, w1 as pt_adj, all_aging, case when all_aging <=30 then '0-30' when all_aging >30 and all_aging <=60 then '31-60' when all_aging >60 and all_aging <=90 then '61-90' when all_aging >90 and all_aging <=120 then '91-120' else '121+'  end as aging from
(
select b.*, case when ins_balance >= 0.01 then  timestampdiff(day,dos,curdate())  when pt_balance >=0.01 then timestampdiff(day,coalesce(pt_resp_date,dos),curdate())  end as all_aging from
(
select a.* from
(
select trnsxno,staffname as rend_staff, patno,  date1 as DOS, ins_carrier_code, cptcode,  charge, tx_balance as ins_balance, copaybalance as pt_balance, coalesce(p,0) as  p1, coalesce(a,0) as a1, coalesce( c,0) as c1,coalesce(w,0) as w1 from
(select 
 trnsxno, patno, rend_addr_id, cptcode, date1, ins_carrier_code, charge, tx_balance, copaybalance from archive_transactions where date1 between :start_date and :end_date and cptcode not in ('1','2','3','4') and archive_flag = 1) at1
left outer join
(select txnopaid,  sum(payment) as p,  sum(adjustment) as a, sum(copayrecd) as c, sum(copayadjustment) as w from archive_transactions where archive_flag = 1 group by txnopaid) at2 on at2.txnopaid = at1.trnsxno
left outer join
staff1 on staff1.staffid = at1.rend_addr_id
) a
where abs(charge - p1-a1-c1-w1 )>=0.01 and (ins_balance >= 0.01 or pt_balance >=0.01)
) b 
left outer join 
(select txnopaid, max(date1) as pt_resp_date from archive_transactions where cptcode ='4' and archive_flag = 1 group by txnopaid) at3 on b.trnsxno = at3.txnopaid
) c
where patno >99 ) ar group by aging 
union
select 'Unvoided PLA' as rowtype, aging, sum(ins_balance) as insag, sum(pt_balance) as ptag from
( select trnsxno, rend_staff, patno, dos, ins_carrier_code, cptcode, charge, ins_balance, pt_balance, p1 as ins_paid, a1 as ins_adj, c1 as pt_paid, w1 as pt_adj, all_aging, case when all_aging <=30 then '0-30' 
when all_aging >30 and all_aging <=60 then '31-60' when all_aging >60 and all_aging <=90 then '61-90' when all_aging >90 and all_aging <=120 then '91-120' else '121+'  end as aging from
( select b.*, case when ins_balance >= 0.01 then timestampdiff(day,dos,curdate())  when pt_balance >=0.01 then timestampdiff(day, coalesce(pt_resp_date,dos),curdate()) end as all_aging from
( select a.* from
( select trnsxno,staffname as rend_staff, patno,  date1 as DOS, ins_carrier_code, cptcode,  charge, tx_balance as ins_balance, copaybalance as pt_balance, coalesce(p,0) as  p1, coalesce(a,0) as a1, coalesce( c,0) as c1,coalesce(w,0) as w1 from
(select trnsxno, patno, rend_addr_id, cptcode, date1, ins_carrier_code, charge, tx_balance, copaybalance from archive_transactions where date1 between :startdate and :enddate and cptcode not in ('1','2','3','4') and archive_flag = 1) at1
left outer join (select txnopaid,  sum(payment) as p,  sum(adjustment) as a, sum(copayrecd) as c, sum(copayadjustment) as w from archive_transactions where archive_flag = 1 group by txnopaid) at2 on at2.txnopaid = at1.trnsxno
left outer join
staff1 on staff1.staffid = at1.rend_addr_id
) a where abs(charge - p1-a1-c1-w1 )>=0.01 and (ins_balance >= 0.01 or pt_balance >=0.01)) b  left outer join 
 (select txnopaid, max(date1) as pt_resp_date from archive_transactions where cptcode ='4' and archive_flag = 1 group by txnopaid) at3 on b.trnsxno = at3.txnopaid
) c where patno = -5)  patadj group by aging