SQL: Unbilled After Hours Codes

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 all encounter notes reflecting dates of Saturday or Sunday where neither 99050 or 99051 was billed for a date of service range that you specify.

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

Caveats

Inpatient services (POS 21 and 22) are excluded.

SQL Code: Firebird

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

select distinct * from
(
select a.patno, a.date1,  cptcode, a.ins_carrier_code from 
(
SELECT at1.PATNO,
      at1.DATE1, at1.ins_carrier_code, lname,
      EXTRACT(WEEKDAY FROM at1.DATE1) as weekday
FROM ARCHIVE_TRANSACTIONS at1
inner join register on register.patno = at1.patno

WHERE
      ( at1.DATE1 BETWEEN :start_date and :end_date)
      AND ( at1.CPTCODE NOT IN ('1', '2', '26', 'PLA')
      and at1.archive_flag = 1 )
      AND ( at1.POS NOT IN ('21','22') ) 
and EXTRACT(WEEKDAY FROM at1.DATE1) in (6,7)
ORDER BY at1.DATE1,
             at1.PATNO
) a
left outer join
(select patno, date1, cptcode from archive_transactions where date1 between :start_date and :end_date and cptcode in ('99051','99050') and archive_flag = 1) ah on (ah.patno = a.patno) and (ah.date1 = a.date1)
) where cptcode is null


SQL Code: MySQL

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

select distinct * from
(
select a.patno, a.date1,  cptcode, a.ins_carrier_code from 
(
SELECT at1.PATNO,
      at1.DATE1, at1.ins_carrier_code, lname,
      WEEKDAY(at1.DATE1) as wkday
FROM ARCHIVE_TRANSACTIONS at1
inner join register on register.patno = at1.patno

WHERE
      ( at1.DATE1 BETWEEN :start_date and :end_date)
      AND ( at1.CPTCODE NOT IN ('1', '2', '26', 'PLA')
      and at1.archive_flag = 1 )
      AND ( at1.POS NOT IN ('21','22') ) 
and weekday(at1.DATE1) in (6,7)
ORDER BY at1.DATE1,
             at1.PATNO
) a
left outer join
(select patno, date1, cptcode from archive_transactions where date1 between :start_date and :end_date and cptcode in ('99051','99050') and archive_flag = 1) ah on (ah.patno = a.patno) and (ah.date1 = a.date1)
) t1 where cptcode is null