SQL: Multiple Future Appointments

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 patient name, DOB, patient phone number and schedule information (scheduled provider, date/time, and location) for patients who have more than one future appointment scheduled.

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

Caveats

  • Only future non-cancelled appointments are included.
  • “Future appointments” start tomorrow (ie. the day AFTER the run date) and do not include dates later in the day of the report run date.

SQL Code: Firebird

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

select patno, ( fname || ' ' || lname) as patient_name,  birthdat, code1 as appt_type, hphone,  loc_name, staffname as scheduled_provider, dateadd(minute,start_time,appt_date) as my_appt_time from schedule
inner join register on register.patno = schedule.patno
inner join staff1 on staff1.staffid = schedule.addr_id
inner join location on location.id = schedule.loc_id
 where  appt_date > cast('today' as timestamp) and visit_status is null
and patno in
(

select patno from
(
select patno, count(patno) as n from
(
select patno, ( fname || ' ' || lname) as patient_name,  birthdat, code1 as appt_type, hphone,  loc_name, staffname as scheduled_provider, dateadd(minute,start_time,appt_date) as my_appt_time from schedule
inner join register on register.patno = schedule.patno
inner join staff1 on staff1.staffid = schedule.addr_id
inner join location on location.id = schedule.loc_id
 where  appt_date > cast('today' as timestamp) and visit_status is null
order by patno
) group by patno
) where n>1
) order by patno, my_appt_time


SQL Code: MySQL

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

select schedule.patno, ( fname || ' ' || lname) as patient_name,  birthdat, code1 as appt_type, hphone,  loc_name, staffname as scheduled_provider, date_add(cast(appt_date as datetime),interval start_time minute) as my_appt_time
 from schedule
inner join register on register.patno = schedule.patno
inner join staff1 on staff1.staffid = schedule.addr_id
inner join location on location.id = schedule.loc_id
 where  appt_date > curdate() and visit_status is null
and register.patno in
(
select patno from
(
select patno, count(patno) as n from
(
select register.patno, ( fname || ' ' || lname) as patient_name,  birthdat, code1 as appt_type, hphone,  loc_name, staffname as scheduled_provider, date_add(cast(appt_date as datetime),interval start_time minute) as my_appt_time from schedule
inner join register on register.patno = schedule.patno
inner join staff1 on staff1.staffid = schedule.addr_id
inner join location on location.id = schedule.loc_id
 where  appt_date >curdate() and visit_status is null
order by patno
) t1 group by patno
) t2 where n>1
)  order by patno, my_appt_time