Accounts and Payors in Collections

I need a list showing all patients that are in collections.

Actually, patients are not in collections in SOS, payors are. The following query produces a list of payors that have a balance in collections, along with their associated patient accounts. The first query sorts in payor order, with payor name in the first column. The second query is the same results, but the patient column is first, and the list is sorted in that order.

SELECT
  a.payorname +', '+a.firstname AS "Payor",
  a.collectdate AS "To Collections",
  b.balance,
  c.lastname+', '+c.firstname+' / '+id AS "Account"
FROM
  sos.payors a
  JOIN sos.ptpayors b ON a.payornum = b.payornum
  JOIN sos.patients c ON b.ptnum = c.ptnum
WHERE
  b.balance > 0
  AND a.collectdate IS NOT NULL
ORDER BY "Payor"

 

Same as the above, but in Patient Account order:

 

SELECT
  c.lastname+', '+c.firstname+' / '+id AS "Account",
  a.collectdate AS "To Collections",
  b.balance,
  a.payorname +', '+a.firstname AS "Payor"
FROM
  sos.payors a
  JOIN sos.ptpayors b ON a.payornum = b.payornum
  JOIN sos.patients c ON b.ptnum = c.ptnum
WHERE
  b.balance > 0
  AND a.collectdate IS NOT NULL
ORDER BY "Account"

 

Another example, this one with primary provider, payor address and phone numbers, and last date of service:

 

SELECT
  c.lastname+', '+c.firstname AS "AccountName",
  c.id AS "AccountNumber",
  c.socsec AS "PatientSSNum",
  d.provlname +' '+ d.provfname AS "PriProvider",
  a.payorname +' '+a.firstname AS "Payor",
  a.Addr1,
  a.Addr2,
  a.City,
  a.State,
  a.zip,
  a.Phone1Desc,
  a.Phone1Area +'-'+ a.Phone1 AS "Phone_1",
  a.Phone1Ext,
  a.Phone2Desc,
  a.Phone2Area +'-'+ a.Phone2 AS "Phone_2",
  a.Phone2Ext,
  a.Phone3Desc,
  a.Phone3Area +'-'+ a.Phone3 AS "Phone_3",
  a.Phone3Ext,
  lastchargedate(c.ptnum) AS "Last DOS",
  b.balance
FROM
  sos.payors a
  JOIN sos.ptpayors b ON a.payornum = b.payornum
  JOIN sos.patients c ON b.ptnum = c.ptnum
  LEFT OUTER JOIN sos.providers d ON c.providernum = d.providernum
WHERE
  b.balance > 0
  AND a.collectdate IS NOT NULL
ORDER BY 
  "AccountName"

Leave a Reply

Your email address will not be published. Required fields are marked *

You may use these HTML tags and attributes:

<a href="" title=""> <abbr title=""> <acronym title=""> <b> <blockquote cite=""> <cite> <code> <del datetime=""> <em> <i> <q cite=""> <s> <strike> <strong>

This site uses Akismet to reduce spam. Learn how your comment data is processed.