Skip to content

Instantly share code, notes, and snippets.

@rhettc
Forked from markwhat1/query_examples.sql
Created May 7, 2020 12:52
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save rhettc/c6094ce13dd51cc798f6b8f9e656caf6 to your computer and use it in GitHub Desktop.
Save rhettc/c6094ce13dd51cc798f6b8f9e656caf6 to your computer and use it in GitHub Desktop.
Open Dental Query Examples
This file has been truncated, but you can view the full file.
Home Welcome to the Open Dental Query Examples Page
These query examples were written for other practices, usually for a specific purpose. There may be additional changes needed to return the results you want.
Queries are sorted chronologically, with queries written for older versions listed first and queries written for newer versions listed last.
We recommend looking at higher numbered queries first, because older queries may not work in new versions.
If you find a query you like, copy/paste the query into Open Dental to run it. See User Queries
If needed, change
any required variables before running. Look at the query comments for variable descriptions.
If you need
help finding a query, modifying a query, or would like a custom query, fill out and submit a Query Request Form
Limit query results by category.Up to 3 categories can be selected.Results will only include queries that match ALL selected categories.
Return Queries About: AND AND
Result Count : 1251
QueryID Query, with Title and Notes
All claims that are currently open that were sent on a given day -
change
DateSent value as needed
/*1*/
SELECT *
FROM claim
WHERE DateSent = '2005-04-19'
AND ClaimStatus = 'S'
All treatment planned procedures
, ordered by patient - See also
#50 & #56
/*2*/
SELECT PatNum, ProcCode, ProcFee, Surf, ToothNum
FROM procedurelog,
procedurecode
WHERE ProcStatus = 1
AND procedurelog.CodeNum = procedurecode.CodeNum
ORDER BY PatNum
Birthday postcards for a one week range - In the example,
from 10/06 to 10/13
/*3*/ SELECT LName,
FName,
Address,
Address2,
City,
State,
Zip,
Birthdate
FROM patient
WHERE SUBSTRING(Birthdate, 6, 5) >= '10-06'
AND SUBSTRING(Birthdate, 6, 5) <= '10-13'
AND PatStatus = 0
ORDER BY LName, FName
Daily patient payments organized by chart number and date entry.- In the example, for 7/29/2005
/*4 Daily patient payments organized by chart number and date entry.*/
/*Query code written/modifed 10/21/2016*/
SELECT payment.PayDate,
payment.DateEntry,
patient.ChartNumber,
CONCAT(patient.LName, ', ', patient.FName, ' ', patient.MiddleI) AS plfname,
payment.PayType,
payment.CheckNum,
payment.PayAmt
FROM payment,
patient
WHERE payment.PatNum = patient.PatNum
AND payment.PayAmt > 0
AND payment.DateEntry = CURDATE() /* Replace =CURDATE() with ='2016-12-31' including apostrophes */
ORDER BY payment.DateEntry, patient.ChartNumber
Daily Insurance payments organized by chart number - In the example, for 7/29/2005
/*5*/ SELECT patient.ChartNumber,
CONCAT(patient.LName, ', ', patient.FName, ' ', patient.MiddleI) AS Name,
claimpayment.CheckDate,
carrier.CarrierName,
claimpayment.CheckNum,
claimproc.ClaimNum,
SUM(claimproc.InsPayAmt) as $Amt
FROM claimpayment,
claimproc,
insplan,
patient,
carrier
WHERE claimproc.ClaimPaymentNum = claimpayment.ClaimPaymentNum
AND claimproc.PlanNum = insplan.PlanNum
AND claimproc.PatNum = patient.PatNum
AND carrier.CarrierNum = insplan.CarrierNum
AND (claimproc.Status = '1' OR claimproc.Status = '4')
AND claimpayment.CheckDate = '2005-07-29'
GROUP BY claimproc.ClaimNum
Aging report which includes date of last payment - The last payment date is only for payments entered
on the guarantor of the family.
/*6*/ SELECT CONCAT(LName,', ',FName,' ',MiddleI)
,Bal_0_30,Bal_31_60,Bal_61_90,BalOver90
,BalTotal,InsEst,BalTotal-InsEst AS $pat,
DATE_FORMAT(MAX(paysplit.ProcDate),'%m/%d/%Y') AS lastPayment
FROM patient
LEFT JOIN paysplit
ON paysplit.PatNum=patient.PatNum
WHERE (patstatus != 2)
AND (Bal_0_30
> '.005' OR Bal_31_60
> '.005' OR Bal_61_90
> '.005' OR BalOver90
> '.005' OR BalTotal
< '-.005')
GROUP BY patient.PatNum
ORDER BY LName, FName
Aging report which includes chart numbers -
/*7*/ SELECT ChartNumber
, CONCAT(LName, ', ', FName, ' ', MiddleI) AS Patient
, Bal_0_30
, Bal_31_60
, Bal_61_90
, BalOver90
, BalTotal
, InsEst
, BalTotal - InsEst AS $pat
FROM patient
WHERE (patstatus != 2)
AND (Bal_0_30 > '.005' OR Bal_31_60 > '.005' OR Bal_61_90 > '.005' OR BalOver90 > '.005'
OR BalTotal < '-.005')
ORDER BY LName, FName
Daily procedures report which includes chart numbers -
/*8 Daily procedures report which includes chart numbers*/
SET @FromDate = '2008-01-01', @ToDate = '2008-01-31'; /*change dates here*/
SELECT pl.ProcDate,
pa.ChartNumber,
CONCAT(pa.LName, ', ', pa.FName, ' ', pa.MiddleI) AS PatName,
ProcCode,
pl.ToothNum,
pc.Descript,
pr.Abbr,
pl.ProcFee * (pl.UnitQty + pl.BaseUnits) -
(CASE WHEN ISNULL(claimproc.WriteOff) THEN 0 ELSE (SUM(claimproc.WriteOff)) END) AS $fee
FROM patient pa
INNER JOIN procedurelog pl ON pa.PatNum = pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum = pc.CodeNum
INNER JOIN provider pr ON pr.ProvNum = pl.ProvNum
LEFT JOIN claimproc ON pl.ProcNum = claimproc.ProcNum
AND claimproc.Status = '7'
WHERE pl.ProcStatus = '2'
AND pl.ProcDate >= @FromDate
AND pl.ProcDate <= @ToDate
GROUP BY pl.ProcNum
ORDER BY pl.ProcDate, PatName
The account balances for all patients
with an appointment
on a specific day -
/*9 Estimated balances for patients with an appointment on a specific day*/
/*Query code written/modified: 04/04/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @AptDateTime = '2018-04-04';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SET @AsOf = CURDATE();
SET @PayPlanVersion = IFNULL((SELECT ValueString
FROM preference
WHERE prefName LIKE 'PayPlansVersion'), 1);
SELECT appointment.AptDateTime,
patient.LName,
patient.FName,
FORMAT(IFNULL(aging.PatBal, 0), 2) AS PatEstBalance
FROM appointment
INNER JOIN patient ON appointment.PatNum = patient.PatNum
LEFT JOIN (
SELECT D.PatNum,
ROUND(D.PatBal, 2) AS PatBal
FROM (
/*Get the family level charges, credits, and ins estimates*/
SELECT p.PatNum,
p.LName,
p.FName,
SUM(B.PatBal) AS PatBal
FROM (
/*Get Patient level charges and credits*/
SELECT RawPatTrans.PatNum,
SUM(RawPatTrans.TranAmount) AS PatBal
FROM (
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,
pl.PatNum AS PatNum,
pl.ProcDate AS TranDate,
pl.ProcFee * (pl.UnitQty + pl.BaseUnits) AS TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus = 2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,
ps.PatNum AS PatNum,
ps.DatePay AS TranDate,
(CASE
WHEN @PayPlanVersion IN (1, 3)
THEN (CASE WHEN ps.PayPlanNum = 0 THEN -ps.SplitAmt ELSE 0 END)
ELSE -ps.SplitAmt END) AS TranAmount
FROM paysplit ps
WHERE ps.SplitAmt != 0
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,
a.PatNum AS PatNum,
a.AdjDate AS TranDate,
a.AdjAmt AS TranAmount
FROM adjustment a
WHERE a.AdjAmt != 0
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,
cp.PatNum AS PatNum,
cp.DateCp AS TranDate,
(CASE WHEN cp.payplannum = 0 THEN -cp.InsPayAmt ELSE 0 END) -
cp.Writeoff AS TranAmount
FROM claimproc cp
WHERE cp.Status IN (1, 4, 5, 7)/*received,supplemental,CapClaim, or CapComplete*/
UNION ALL
/*Version 1: Payment plan principal for the entire office history for those using the original payplans accounting*/
SELECT 'PayPlan1' AS TranType,
pp.PatNum AS PatNum,
pp.PayPlanDate AS TranDate,
-pp.CompletedAmt AS TranAmount
FROM payplan pp
WHERE @PayPlanVersion = 1
AND pp.CompletedAmt != 0
#GROUP BY pp.PayPlanNum
UNION ALL
/*Version 2: Payment plan charges for those using line-item account for payplans*/
SELECT 'PayPlan2' AS TranType,
ppc.PatNum AS PatNum,
ppc.ChargeDate TranDate,
(CASE
WHEN ppc.ChargeType != 0
THEN -ppc.Principal #if credit, subtract the principal
WHEN pplan.PlanNum = 0 THEN ppc.Principal + ppc.Interest
ELSE 0 END) #if debit and a patient plan, add principal and interest
AS TranAmount
FROM payplancharge ppc
LEFT JOIN payplan pplan ON pplan.PayPlanNum = ppc.PayPlanNum
WHERE @PayPlanVersion = 2
AND ChargeDate <= @AsOf
UNION ALL
/*Version 3: Age credits only*/
SELECT 'PayPlan3' TranType,
ppc.PatNum AS PatNum,
ppc.ChargeDate TranDate,
-ppc.Principal TranAmount
FROM payplancharge ppc
LEFT JOIN payplan pp ON pp.PayPlanNum = ppc.PayPlanNum
WHERE ppc.ChargeDate <= @AsOf
AND ppc.ChargeType = 1 /*Credit*/
AND @PayPlanVersion = 3
) RawPatTrans
WHERE TranDate <= @AsOf
GROUP BY RawPatTrans.PatNum
) B
LEFT JOIN (
/*Get patient level InsPayEst and Writeoffs from unreceived claims.*/
SELECT cp.PatNum, SUM(cp.InsPayEst) AS InsEst, SUM(cp.Writeoff) AS Writeoff
FROM claimproc cp
WHERE cp.PatNum != 0
AND ((cp.Status = 0 AND cp.ProcDate <= @AsOf) OR (cp.Status = 1 AND cp.DateCP > @AsOf))
AND cp.ProcDate <= @ASOf
GROUP BY cp.PatNum
) C ON C.PatNum = B.PatNum
INNER JOIN patient p ON p.PatNum = B.PatNum
GROUP BY p.PatNum
) D
) aging ON aging.PatNum = patient.PatNum
WHERE appointment.AptDateTime LIKE CONCAT(@AptDateTime, '%')
AND AptStatus != 6 /*Planned*/
AND AptStatus != 3 /*UnschedList*/
All lab cases
with a status of received, and appointment not complete -
/*10*/ SELECT PatNum, AptDateTime, AptStatus
FROM appointment a
WHERE AptStatus != '2'
AND (SELECT COUNT(*) FROM labcase c WHERE c.AptNum = a.AptNum) > 0
ORDER BY AptDateTime
OBSOLETE Production by fee schedule for date range - OBSOLETE This is a useful report
, but please note that the amounts are taken
from claims you've sent. So, it will never include private pay, and if you billed with UCR fees showing, it will use those fees, which are higher. Also, secondary claims are incl
/*11 OBSOLETE, if you need aquery like this one, you must request it from us or compose it */ SELECT definition.ItemName,SUM(claimproc.FeeBilled) AS Production
FROM definition,claimproc,insplan
WHERE definition.Category=7
AND definition.DefNum=insplan.FeeSched
AND insplan.PlanNum=claimproc.PlanNum
AND claimproc.ProcDate >= '2005-04-01 '
AND claimproc.ProcDate < ' 2005-05-01 '
GROUP BY definition.DefNum
ORDER BY definition.ItemOrder
Treatment planned procedures - It sorts by the cost of the procedure, which is usually what you want. You can increase the limit to get more rows in your results.
/*12*/ SELECT ProcFee,ProcCode,PatNum
FROM procedurelog pl
LEFT JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
WHERE ProcStatus=1
ORDER BY ProcFee DESC;
Public Health Raw Population Data. - SEE REPLICATION WARNING for versions before 14.3.1. This query will not work on versions 7.8.1 or higher of Open Dental as the school table was removed.
/*13 Public Health Raw Population Data. This query will not work on versions 7.8.1 or higher of Open Dental as the school table was removed.*/
/*WARNING On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS tempbroken;
CREATE TEMPORARY TABLE tempbroken(
PatNum mediumint unsigned NOT NULL,
NumberBroken smallint NOT NULL,
PRIMARY KEY (PatNum));
INSERT INTO tempbroken SELECT PatNum,COUNT(*)
FROM adjustment WHERE AdjType=14
AND AdjDate >= ' 2005-09-01 '
AND AdjDate <=' 2005-09-30 '
GROUP BY PatNum;
SELECT patient.PatNum,MIN(procedurelog.ProcDate) AS ProcDate,
CONCAT(provider.LName,'
, ',provider.FName) as ProvName,
County,county.CountyCode,GradeSchool,school.SchoolCode,
GradeLevel,Birthdate,Race,Gender,Urgency,BillingType,
patient.NextAptNum='-1 ' AS Done,
tempbroken.NumberBroken
FROM patient,provider
LEFT JOIN procedurelog ON procedurelog.PatNum=patient.PatNum
LEFT JOIN school ON patient.GradeSchool=school.SchoolName
LEFT JOIN county ON patient.County=county.CountyName
LEFT JOIN tempbroken ON tempbroken.PatNum=patient.PatNum
WHERE (procedurelog.ProcStatus=' 2 '
AND procedurelog.ProvNum=provider.ProvNum
AND procedurelog.ProcDate >=' 2005-09-01 '
AND procedurelog.ProcDate <=' 2005-09-30 ')
OR tempbroken.NumberBroken>0
GROUP BY patient.PatNum
ORDER By ProcDate;
DROP TABLE IF EXISTS tempbroken;
Daily Procedures: Grouped by Procedure Code -
/*14 Daily Procedures: Grouped by Procedure Code*/
SET @FromDate=' 2012-01-01 ' , @ToDate=' 2012-01-13 ';
SELECT definition.ItemName,procedurecode.ProcCode,
procedurecode.Descript,Count(*),
AVG(procedurelog.ProcFee) AS $AvgFee,
SUM(procedurelog.ProcFee) AS $TotFee
FROM procedurelog,procedurecode,definition
WHERE procedurelog.ProcStatus =2
AND procedurelog.CodeNum=procedurecode.CodeNum
AND definition.DefNum=procedurecode.ProcCat
AND procedurelog.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY procedurecode.ProcCode
ORDER BY definition.ItemOrder,procedurecode.ProcCode;
A list of all referrals you have received for a user specific date range - For Versions 17.1 and greater. Please update your version accordingly. Shows how many patients referred by each source in the date range.
/*15 A list of all referrals you have received for a user specific date range.
For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 02/22/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2018-01-01 ', @ToDate=' 2018-01-31 ';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT referral.LName,
referral.FName,
COUNT(*)
FROM referral
INNER JOIN refattach ON referral.ReferralNum=refattach.ReferralNum
AND refattach.RefType = 1 /*Is From referrals*/
AND refattach.RefDate BETWEEN @FromDate AND @ToDate
GROUP BY referral.ReferralNum
For public health clinics, the production by gradeschool. - For versions greater than 7.3, replace GradeSchool with SiteNum to get the query to work.
/*16*/ SELECT SUM(procedurelog.ProcFee),patient.GradeSchool
FROM procedurelog,patient
WHERE procedurelog.PatNum=patient.PatNum
AND procedurelog.ProcStatus=2
AND procedurelog.ProcDate >= ' 2005-10-01 '
AND procedurelog.ProcDate < ' 2005-11-01 '
GROUP BY patient.GradeSchool
ORDER BY patient.GradeSchool
For public health clinics, the number of patients seen at each grade school for a date range -
/*17*/ SELECT patient.GradeSchool,COUNT(DISTINCT patient.PatNum) AS patients
FROM patient,procedurelog
WHERE patient.PatNum=procedurelog.PatNum
AND procedurelog.ProcDate >= ' 2005-10-01 '
AND procedurelog.ProcDate < ' 2005-11-01 '
GROUP BY patient.GradeSchool
Count of patients, grouped by billing type - Includes inactive and archived patients
/*18*/ SELECT BillingType,COUNT(*)FROM patient
WHERE PatStatus != 4
GROUP BY BillingType
List of new patients for a given date range - Does not confirm patient was actually seen
/*19*/ SELECT * FROM patient
WHERE DateFirstVisit >= ' 2005-10-01 '
AND DateFirstVisit < ' 2005-11-01 '
AND patient.patstatus = ' 0 '
Referral sources with how many unique patients referred and gross production for the specified date range - For Versions 17.1 and greater. Please update your version accordingly.
/*20 List of referral sources, how many unique patients referred, and how much production from each source*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 02/22/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2018-01-01 ', @ToDate=' 2018-01-31 ';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT r.LName,
r.FName,
COUNT(DISTINCT ra.PatNum) AS HowMany,
FORMAT(SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)),2) AS $HowMuch
FROM referral r
INNER JOIN refattach ra ON r.ReferralNum=ra.ReferralNum
AND ra.RefType = 1 /*Is From referrals*/
INNER JOIN procedurelog pl ON pl.PatNum=ra.PatNum
AND pl.ProcStatus = 2 /*Completed*/
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY r.ReferralNum
ORDER BY HowMany DESC
Number of patients seen for a given date range (two years in the example). - Patients will only be counted once for the date range, not once for every visit. This is a good way to measure active patients.
/*22*/ SELECT COUNT(DISTINCT PatNum) FROM procedurelog
WHERE ProcStatus=2
AND ProcDate>=' 2004-01-01 '
AND ProcDate< ' 2006-01-01 '
For Payment Plans, this lists guarantors of plans for which the date of the first payment will soon be due. - In the example, it lists all plans where the date of the first charge is in the month of March, 2006.
/*23*/ SELECT patient.LName,patient.FName,MIN(payplancharge.ChargeDate) AS FirstCharge
FROM payplancharge,patient
WHERE payplancharge.Guarantor=patient.PatNum
GROUP BY PayPlanNum
HAVING FirstCharge >= ' 2006-03-01 '
AND FirstCharge < ' 2006-04-01 '
For Payment Plans, this lists guarantors of plans for which the date of the last payment is approaching. -
/*24*/ SELECT patient.LName,patient.FName,MAX(payplancharge.ChargeDate) AS LastCharge
FROM payplancharge,patient
WHERE payplancharge.Guarantor=patient.PatNum
GROUP BY PayPlanNum
HAVING LastCharge >= ' 2006-07-01 '
AND LastCharge < ' 2006-08-01 '
For Payment Plans, lists all charges due for a date range and includes billing type. - Example is for the month of March.
/*25*/ SELECT LName,FName,BillingType,ChargeDate
FROM payplancharge,patient
WHERE payplancharge.Guarantor=patient.PatNum
AND ChargeDate >= ' 2006-03-01 '
AND ChargeDate < ' 2006-04-01 '
ORDER BY BillingType,LName,FName
A list of all subscibers who have a particular carrier. In the example, it' s for Delta
, but you can substitute your own search string between the %'s. - Will show dropped plans. Returns subscribers, DOES NOT GIVE patients who have the plan, see #118
/*26*/ SELECT c.CarrierName,p.*
FROM patient p
INNER JOIN inssub iss ON iss.Subscriber=p.PatNum
INNER JOIN insplan ip ON ip.PlanNum=iss.PlanNum
INNER JOIN carrier c ON ip.CarrierNum=c.CarrierNum
WHERE c.CarrierName LIKE '%Delta%'
ORDER BY c.CarrierName
A list of referrals during a specific date range. - For Versions 17.1 and greater. Please update your version accordingly. Best for exporting to a text file for use in a letter merge.
/*27 A list of referrals during a specific date range.*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/03/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2016-04-19 ', @ToDate=' 2016-04-21 ';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT patient.PatNum,
patient.LName,
patient.FName,
patient.MiddleI,
patient.Preferred,
patient.Salutation,
patient.Address,
patient.Address2,
patient.City,
patient.State,
patient.Zip ,
referral.LName AS RefLName,
referral.FName AS RefFName,
referral.MName AS RefMName,
referral.Title AS RefTitle,
referral.Address AS RefAddress,
referral.Address2 AS RefAddress2,
referral.City AS RefCity,
referral.ST AS RefST,
referral.Zip AS RefZip,
referral.Specialty AS RefSpecialty
FROM patient
INNER JOIN refattach ON patient.PatNum=refattach.PatNum
AND refattach.RefType = 1 /*RefFrom*/
AND refattach.RefDate BETWEEN @FromDate AND @ToDate
INNER JOIN referral ON referral.ReferralNum=refattach.ReferralNum
AND referral.NotPerson = ' 0 ' /*False*/
ORDER BY referral.Specialty, referral.LName, referral.FName
An alternative way of finding procedures not billed to insurance. - Only works on small databases which were not converted from other programs. Might not be very useful.
/*28*/ SELECT procedurelog.PatNum, claimproc.ProcNum, procedurelog.ProcDate,
procedurelog.ProcStatus, patient.LName, patient.FName,
carrier.CarrierName, insplan.CarrierNum
FROM procedurelog
LEFT JOIN patient ON procedurelog.PatNum = patient.PatNum
LEFT JOIN claimproc ON procedurelog.ProcNum = claimproc.ProcNum
LEFT JOIN patplan ON patient.PatNum=patPlan.PatNum
LEFT JOIN inssub ON patplan.InsSubNum=inssub.InsSubNum
LEFT JOIN insplan ON inssub.PlanNum = insplan.PlanNum
LEFT JOIN carrier ON insplan.CarrierNum = carrier.CarrierNum
GROUP BY procedurelog.PatNum, claimproc.ProcNum, procedurelog.ProcDate,
procedurelog.ProcStatus, patient.LName, patient.FName,
carrier.CarrierName, insplan.CarrierNum
HAVING claimproc.ProcNum IS NULL AND procedurelog.ProcStatus=2
ORDER BY procedurelog.ProcDate
Patient payments for one day - For instance, cash, check, or credit card.
/*29*/ SELECT PayDate,PayType,PayAmt,CheckNum,BankBranch,PatNum
FROM payment
WHERE PayDate = ' 2006-02-23 '
ORDER BY PayAmt
Patient payments for one day grouped by type, so only the totals for each type show -
/*30*/ SELECT PayDate,PayType,SUM(PayAmt)
FROM payment
WHERE PayDate = ' 2006-02-23 '
GROUP BY PayType
ORDER BY PayAmt
A list of all outstanding preauthorizations -
/*31*/ SELECT *
FROM claim
WHERE ClaimType = ' PreAuth'
AND ClaimStatus != 'R'
ORDER BY DateService
List of writeoffs for a daterange and for one provider - Leave out the line containing ProvNum to get for all providers
/*32*/ SELECT PatNum,ProvNum,PlanNum,WriteOff AS $Amt,DateCP,DateEntry FROM claimproc
WHERE WriteOff >0
AND DateCP >= '2006-01-01 '
AND DateCP < ' 2006-04-01 '
AND ProvNum=1
ORDER BY DateCP
Quarterly Production by billing type. - Does not include adjustments.
/*33*/ SELECT YEAR(procedurelog.ProcDate)AS "Year", QUARTER(procedurelog.ProcDate) AS "Quarter", definition.ItemName AS "Billing Type", SUM(procedurelog.ProcFee) AS "$Production"
FROM procedurelog, patient, definition
WHERE ProcStatus = 2 /* complete procs*/
AND YEAR(procedurelog.ProcDate) = 2006 /* change year as needed */
AND procedurelog.PatNum = patient.PatNum
AND definition.DefNum = patient.BillingType
GROUP BY QUARTER(procedurelog.ProcDate), patient.BillingType
ORDER BY QUARTER(procedurelog.ProcDate), patient.BillingType
Calculates the total income from each carrier in a given period of time. - Might be useful for comparing 1099s received from insurance at the end of the year.
/*34*/ SELECT CarrierName, SUM(CheckAmt) AS $Income
FROM claimpayment
WHERE CheckDate >= ' 2006-01-01 '
AND CheckDate < ' 2007-01-01 '
GROUP BY CarrierName
List of families seen in the last three years - Useful for generating a list of patients for Christmas cards.
/*35 List of families seen in the last three years - Useful for generating a list of patients for Christmas cards.*/
/* After saving the resulting datafile, you would use the letter merge feature of Word to actually print the cards or labels. The first name is not very useful because it is the guarantors name, not the patient' s name.*/
/* This query gives names and addresses of guarantors for each family where at least one active patient has been seen (with procedures completed) within the past three years, and where the guarantor address has a valid zip code. Only visits after today's date three years ago are included. */
SET @FromDate = CURDATE() - INTERVAL 3 YEAR;
SET @ToDate = CURDATE();
SELECT g.LName, g.FName, g.Address, g.Address2, g.City, g.State, g.Zip
FROM patient p
INNER JOIN patient g ON p.Guarantor = g.PatNum
INNER JOIN procedurelog pl ON pl.PatNum = p.PatNum
WHERE p.PatStatus = 0
/*only patients with procedures completed within the last three years.*/
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus = 2
AND Length(g.Zip) > 4
GROUP BY g.PatNum
ORDER BY g.LName, g.FName
A list of patients seen between two dates (based
on procedures completed in date range
)
.
-
/*36 A list of patients seen between two dates (based on procedures completed in date range).*/
SET @FromDate = '2017-01-01',@ToDate = '2017-12-31';
SET @pos = 0;
SELECT @pos := @pos + 1 AS '#Pats', A.*
FROM (
SELECT p.LName, p.FName, p.Address, p.Address2, p.City, p.State, p.Zip
FROM patient p
INNER JOIN procedurelog pl ON pl.PatNum = p.PatNum
AND pl.ProcStatus = 2
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
WHERE p.PatStatus = 0
GROUP BY p.PatNum
ORDER BY p.LName, p.FName
) A;
A list of all guarantors of patients with an active status - This is another way of getting a Christmas card list without filtering out patients who have not been in for a while.
/*37*/ SELECT DISTINCTROW g.LName, g.FName, g.Address, g.Address2, g.City,
g.State, g.Zip
FROM patient p
INNER JOIN patient g ON p.Guarantor=g.PatNum
WHERE p.PatStatus=0
ORDER BY g.LName, g.FName;
List and count of patients that were seen by you in a date range and their referrals - For Versions 17.1 and greater. Please
update your version accordingly.
/*38 List and count of patients that were seen by you in a date range and their referrals*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/03/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate = '2018-01-01', @ToDate = '2018-01-05';
SET @pos = 0;
SELECT @pos := @pos + 1 AS 'Row#',
A.*
FROM (
SELECT patient.PatNum,
patient.lname,
patient.fname,
RefDate DateReferred,
(CASE
WHEN RefType = 0 THEN 'To'
WHEN RefType = 1 THEN 'From'
ELSE 'RefCustom'
END) AS ReferredType,
refattach.referralnum
FROM patient
INNER JOIN procedurelog ON procedurelog.PatNum = patient.PatNum
AND procedurelog.ProcDate BETWEEN @FromDate AND @ToDate
INNER JOIN refattach ON refattach.PatNum = patient.PatNum
INNER JOIN referral r ON refattach.ReferralNum = r.ReferralNum
AND patient.patstatus = '0' /*Active*/
GROUP BY patient.PatNum, r.ReferralNum, refattach.RefAttachNum
ORDER BY ReferredType, r.LName, r.FName, patient.LName, patient.FName
) A
List of patients and their addresses who have not been seen since a certain date - (the example uses Sept 1
, 2005).It will also give you the date of their last visit.Submitted by Jorge Bonilla
, DMD
/*39 List of patients and their addresses who have not been seen since a certain date */
SELECT patient.LName,
patient.FName,
patient.Address,
patient.Address2,
patient.City,
patient.State,
patient.Zip,
procedurelog.ProcDate
FROM patient,
procedurelog
WHERE procedurelog.PatNum = patient.PatNum
AND procedurelog.procstatus = '2'
GROUP BY procedurelog.PatNum
HAVING MAX(ProcDate) < '2011-09-01'
MISLEADING QUERY List of all patients
, their balances
, and their most recent payments.- NOTE: not just active patients
, note also that guarantors are the only ones that actually have aging balances
, so don 't count on this one to give useful information.
/*40*/ SELECT patient.PatNum, Concat(patient.LName,'
, ',patient.FName), patient.Bal_0_30, patient.Bal_31_60, patient.Bal_61_90, patient.BalOver90, patient.BalTotal, payment.PayAmt, payment.PayDate
FROM patient
LEFT JOIN payment ON payment.PatNum=patient.PatNum
AND payment.PayDate=(SELECT MAX(payment2.PayDate)
FROM payment AS payment2
WHERE payment.PatNum = payment2.PatNum)
ORDER BY patient.PatNum;
List of subscribers for a given carrier and groupnum. - Note that it is subscribers, not patients. See 118 also
/*41. List of subscribers for a given carrier and groupnum. Note subscribers, not patients. See 118 also*/
SELECT c.CarrierName,p.PatNum
FROM patient p
INNER JOIN inssub ON inssub.Subscriber=p.PatNum
INNER JOIN insplan ip ON ip.PlanNum=inssub.PlanNum
INNER JOIN carrier c ON ip.CarrierNum=c.CarrierNum
WHERE c.CarrierName LIKE ' Blue%'
AND ip.GroupNum LIKE '%%'
ORDER BY c.CarrierName, ip.GroupNum,p.LName;
Sums of Aging report without having to print the entire report. - If you do not update aging first, results will not be current
/*42*/ SELECT SUM(Bal_0_30) as ' Total 0-30 ', SUM(Bal_31_60) as ' Total 31-60 ',
SUM(Bal_61_90) as ' Total 61-90 ', SUM(BalOver90) as ' Total BalOver90 ',
SUM(BalTotal) as ' TOTAL of BALANCES ', SUM(InsEst) as ' Total Ins.
Est.', SUM(BalTotal-InsEst) AS ' Total Pat.Est.'
FROM patient
WHERE (patstatus != 2)
AND (Bal_0_30 > '.005 ' OR Bal_31_60 > '.005 ' OR Bal_61_90 > '.005 ' OR BalOver90 > '.005 ' OR BalTotal < '-.005 ')
Appointment history for one patient. - Change the 581 to the appropriate PatNum before running
/*43*/ SELECT a.AptStatus, DATE_FORMAT(a.AptDateTime, '%m-%d-%Y ') as ' Date ', DATE_FORMAT(a.AptDateTime, '%l:%i %p ') as ' Time ', CHAR_LENGTH(a.Pattern)*5 AS ' Min ', ProcDescript as ' Procedures ', Note as ' Notes ' From appointment a WHERE a.PatNum = ' 581 '
For a user set time period, this query will return the number of procedures, the total fees, and the percentages of each for each category of dental codes. - SEE REPLICATION WARNING for versions before 14.3.1.
/*45*/ SET @FromDate= ' 2007-08-21 ', @ToDate=' 2007-08-22 '; /*change dates here*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @TotNum=0, @TotFee=0;
DROP TABLE IF EXISTS tmp1; DROP TABLE IF EXISTS tmp2;
/*Create temp table containing summary info by procedure*/
CREATE TABLE tmp1 SELECT MID(procedurecode.ProcCode,2,4) AS ' cat ', Count(*) as ' num ',
SUM(procedurelog.ProcFee) as ' fee '
FROM procedurelog,procedurecode,definition
WHERE procedurelog.ProcStatus =2
AND procedurelog.CodeNum=procedurecode.CodeNum
AND definition.DefNum=procedurecode.ProcCat
AND procedurelog.ProcDate >= @FromDate
AND procedurelog.ProcDate <= @ToDate
GROUP BY cat
ORDER BY cat;
/*Create a temp table grouping the procedures and info by range*/
CREATE TABLE tmp2 (Category CHAR(40), Fees FLOAT NOT NULL, Number FLOAT NOT NULL, PercDollar FLOAT NOT NULL, PercQuant FLOAT NOT NULL);
/*Create Prepared insert Statements and execute*/
/*A do loop could be used here but would not neccesarily work on all DB types*/
PREPARE ins FROM '
INSERT INTO tmp2 (Category, Fees, Number)
SELECT ?, SUM(Fee), SUM(num)
FROM tmp1
WHERE cat > ?
AND cat < ?'; SET @cat=' Diagnostic ', @StCode=99, @EndCode=1000; EXECUTE ins USING @cat, @StCode, @EndCode; SET @cat=' Preventative ', @StCode=999, @EndCode=2000; EXECUTE ins USING @cat, @StCode, @EndCode; SET @cat=' Restorative ', @StCode=1999, @EndCode=3000; EXECUTE ins USING @cat, @StCode, @EndCode; SET @cat=' Endodontics ', @StCode=2999, @EndCode=4000; EXECUTE ins USING @cat, @StCode, @EndCode; SET @cat=' Periodontics ', @StCode=3999, @EndCode=5000; EXECUTE ins USING @cat, @StCode, @EndCode; SET @cat=' Prosthodontics (Removable) ', @StCode=4999, @EndCode=5900; EXECUTE ins USING @cat, @StCode, @EndCode; SET @cat=' Maxillofacial Prosthestics ', @StCode=5899, @EndCode=6000; EXECUTE ins USING @cat, @StCode, @EndCode; SET @cat=' Implant Services ', @StCode=5999, @EndCode=6200; EXECUTE ins USING @cat, @StCode, @EndCode; SET @cat=' Prosthodontics (Fixed) ', @StCode=6199, @EndCode=7000; EXECUTE ins USING @cat, @StCode, @EndCode; SET @cat=' Oral
and Maxillofacial Surgery ', @StCode=6999, @EndCode=8000; EXECUTE ins USING @cat, @StCode, @EndCode; SET @cat=' Orthodontics ', @StCode=7999, @EndCode=9000; EXECUTE ins USING @cat, @StCode, @EndCode; SET @cat=' Adjunctive General Services ', @StCode=8999, @EndCode=10000; EXECUTE ins USING @cat, @StCode, @EndCode; /*Insert totals, can' t use procedure when changing @variable
values */
INSERT INTO tmp2 (Category, Fees, Number)
SELECT 'Total', @TotFee := SUM(fee), @TotNum := SUM(num)
FROM tmp1
WHERE cat>99 AND cat<10000; /*Cacluate the percentages*/ UPDATE tmp2
SET PercDollar= CASE
WHEN @TotFee = 0 THEN 0
ELSE
FORMAT(100 * Fees / @TotFee, 2) END;
UPDATE tmp2
SET PercQuant= CASE
WHEN @TotNum = 0 THEN 0
ELSE
FORMAT(100 * Number / @TotNum, 2) END;
/*Display Results*/
SELECT Category, Number, Fees as 'Fees', PercDollar, PercQuant
FROM tmp2;
DROP TABLE IF EXISTS tmp1;
DROP TABLE IF EXISTS tmp2;
Mailing information for guarantors of active patients. -
/*46. Mailing information for guarantors of active patients*/
SELECT g.LName, g.FName, g.Address, g.Address2, g.City, g.State, g.Zip
FROM patient p
INNER JOIN patient g ON g.PatNum = p.Guarantor
WHERE p.PatStatus = 0
AND LENGTH(g.Zip) > 4
GROUP BY g.PatNum
ORDER BY g.LName, g.FName;
Daily payments summarized by type -
/*47*/
SET @date = '2007-09-25';
SELECT definition.ItemName AS PaymentType,
SUM(paysplit.SplitAmt) AS PaymentAmt
FROM payment,
definition,
paysplit
WHERE paysplit.DatePay = @date
AND payment.PayNum = paysplit.PayNum
AND definition.DefNum = payment.PayType
GROUP BY payment.PayType
UNION
SELECT 'Ins Checks',
SUM(claimproc.InsPayAmt) AS InsAmt
FROM claimproc
WHERE claimproc.DateCP = @date
AND (claimproc.Status = 1 OR claimproc.Status = 4)
New patients for time span who were actually seen - Excludes ones who made an appointment
, but then no -showed.
/*48 New patients for time span who were actually seen*/
/*Query code written/modified: 10/21/2015*/
SET @FromDate='2015-01-01'
, @ToDate='2015-01-30';
SET @pos = 0;
SELECT @pos := @pos + 1 AS PatCount, A.*
FROM (
SELECT patient.PatNum, patient.DateFirstVisit
FROM patient,
procedurelog
WHERE procedurelog.PatNum = patient.PatNum
AND patient.patstatus = '0'
AND procedurelog.ProcDate BETWEEN @FromDate
AND @ToDate
AND procedurelog.ProcStatus = 2
AND patient.DateFirstVisit >= @FromDate
AND procedurelog.ProcFee > 0
GROUP BY patient.PatNum
ORDER BY patient.DateFirstVisit
) A;
Patient contact info for patients not seen since a certain date - Submitted by Jorge Bonilla, DMD.
/*49 Patient contact info for patients not seen since a certain date*/
/*Query code written/modified: 02/15/2018*/
SET @Date='2017-12-31';
SET @pos = 0;
SELECT @pos := @pos + 1 AS 'NumberOfPatients', a.*
FROM (
SELECT p.LName,
p.FName,
p.Address,
p.Address2,
p.City,
p.State,
p.Zip,
p.HmPhone,
p.WirelessPhone,
p.WkPhone,
p.PatStatus,
p.AddrNote,
MAX(pl.ProcDate)
FROM patient p
INNER JOIN procedurelog pl
ON pl.PatNum = p.PatNum
AND pl.ProcStatus = 2 /* Complete */
WHERE p.PatStatus != 4 /* No deleted patients */
GROUP BY pl.PatNum
HAVING MAX(pl.ProcDate) < @Date
ORDER BY p.address, p.address2
) a
Treatment planned procedures
, that are not in a scheduled apt -
/*50 Treatment planned procedures, that are not in a scheduled apt */
SELECT CONCAT(LName, ', ', FName, ' ', MiddleI) AS Patient,
pc.ProcCode AS 'Code',
abbrdesc AS 'Description',
ToothNum,
DATE_FORMAT(pl.ProcDate, '%m-%d-%Y') AS 'Date',
ap.AptStatus,
ProcFee
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum = pl.PatNum
AND ProcStatus = 1
INNER JOIN procedurecode pc ON pl.CodeNum = pc.CodeNum
LEFT JOIN appointment ap ON pl.AptNum = ap.AptNum
WHERE (ISNULL(ap.aptnum) OR AptStatus = 6 OR AptStatus = 3) /*No apt, unscheduled, planned*/
AND PatStatus = 0 /*patient status*/
ORDER BY aptstatus, patient.LName, patient.FName ASC;
Answers the question: during a given period, what is the production generated by different referral sources - For Versions 17.1 and greater. Please
update your version accordingly.Includes net production for each source, limited to the date range.
/*51 Answers the question: during a given period, what is the production generated by different referral sources.*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Includes net production for each source, limited to the date range.*/
/*Query code written/modified: 04/03/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2018-01-01', @ToDate='2018-01-05';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
(
SELECT a.PatientName,
a.FirstVisit,
a.Referror,
FORMAT(a.Fees, 2) AS Fees,
FORMAT(a.Adjustments, 2) AS Adjsutments,
FORMAT(a.WriteOffs, 2) AS WriteOffs,
FORMAT((a.Fees + a.Adjustments - a.Writeoffs), 2) AS NetProduction
FROM (
SELECT CONCAT(p.LName, ', ', p.FName) AS PatientName,
p.DateFirstVisit AS FirstVisit,
CONCAT(r.LName, ', ', r.FName) AS Referror,
SUM(CASE WHEN RawPatTrans.TranType = 'Fee' THEN RawPatTrans.TranAmount ELSE 0 END) AS Fees,
SUM(CASE
WHEN RawPatTrans.TranType = 'Adj' THEN RawPatTrans.TranAmount
ELSE 0 END) AS Adjustments,
SUM(CASE WHEN RawPatTrans.TranType = 'Writeoff' THEN RawPatTrans.TranAmount ELSE 0 END) AS WriteOffs
FROM
/*transaction table*/
(
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,
pl.PatNum PatNum,
pl.ProcDate TranDate,
pl.ProcFee * (pl.UnitQty + pl.BaseUnits) TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus = 2
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType, a.PatNum PatNum, a.AdjDate TranDate, a.AdjAmt TranAmount
FROM adjustment a
WHERE a.AdjDate BETWEEN @FromDate AND @ToDate
UNION ALL
/*Claim writeoffs for the entire office history*/
SELECT 'Writeoff' AS TranType, cp.PatNum PatNum, cp.DateCp TranDate, cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.Status IN (0, 1, 4) /*Not Received yet, Received or Supplemental*/
AND cp.ProcDate BETWEEN @FromDate AND @ToDate
) AS RawPatTrans
INNER JOIN patient p ON p.PatNum = RawPatTrans.PatNum
INNER JOIN refattach ra ON p.PatNum = ra.PatNum
AND ra.RefType = 1 /*RefFrom*/
AND ra.ItemOrder = (
SELECT MIN(ra.ItemOrder)
FROM refattach ra
WHERE ra.RefType = 1 /*RefFrom*/
AND ra.PatNum = p.PatNum
GROUP BY p.PatNum
)
INNER JOIN referral r ON r.ReferralNum = ra.ReferralNum
GROUP BY p.PatNum
) a
WHERE (a.Fees != 0 OR a.Adjustments != 0 OR a.Writeoffs != 0)
)
UNION ALL
(
SELECT CONCAT(' Totals: ',/*< AltKey 255 blank character in string to order last*/SUM(a.PatientName),
' Patients') AS PaitentName,
a.FirstVisit,
CONCAT(COUNT(DISTINCT a.Referror), ' Referrors') AS 'Referror',
FORMAT(SUM(a.Fees), 2) AS 'Fees',
FORMAT(SUM(a.Adjustments), 2) AS 'Adjustments',
FORMAT(SUM(a.WriteOffs), 2) AS 'WriteOffs',
FORMAT((SUM(a.Fees) + SUM(a.Adjustments) - SUM(a.Writeoffs)), 2) AS NetProduction
FROM (
SELECT COUNT(DISTINCT p.PatNum) AS PatientName,
CONCAT(DATEDIFF(@ToDate, @FromDate) + 1, ' Days') AS FirstVisit,
r.ReferralNum AS Referror,
SUM(CASE WHEN RawPatTrans.TranType = 'Fee' THEN RawPatTrans.TranAmount ELSE 0 END) AS Fees,
SUM(CASE
WHEN RawPatTrans.TranType = 'Adj' THEN RawPatTrans.TranAmount
ELSE 0 END) AS Adjustments,
SUM(CASE WHEN RawPatTrans.TranType = 'Writeoff' THEN RawPatTrans.TranAmount ELSE 0 END) AS WriteOffs
FROM
/*transaction table*/
(
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,
pl.PatNum PatNum,
pl.ProcDate TranDate,
pl.ProcFee * (pl.UnitQty + pl.BaseUnits) TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus = 2
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType, a.PatNum PatNum, a.AdjDate TranDate, a.AdjAmt TranAmount
FROM adjustment a
WHERE a.AdjDate BETWEEN @FromDate AND @ToDate
UNION ALL
/*Claim writeoffs for the entire office history*/
SELECT 'Writeoff' AS TranType, cp.PatNum PatNum, cp.DateCp TranDate, cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.Status IN (0, 1, 4) /*Not Received yet, Received or Supplemental*/
AND cp.ProcDate BETWEEN @FromDate AND @ToDate
) AS RawPatTrans
INNER JOIN patient p ON p.PatNum = RawPatTrans.PatNum
INNER JOIN refattach ra ON p.PatNum = ra.PatNum
AND ra.RefType = 1 /*RefFrom*/
AND ra.ItemOrder = (
SELECT MIN(ra.ItemOrder)
FROM refattach ra
WHERE ra.RefType = 1 /*RefFrom*/
AND ra.PatNum = p.PatNum
GROUP BY p.PatNum
)
INNER JOIN referral r ON r.ReferralNum = ra.ReferralNum
GROUP BY p.PatNum
) a
WHERE (a.Fees != 0 OR a.Adjustments != 0 OR a.Writeoffs != 0)
)
ORDER BY PatientName;
Return list of statements sent by mail in last 30 days, or other interval - Change
value in interval statement to a number other than -30 for a different interval, the 30 interval is for the due date and should not be changed, assumes monthly billing
/*52*/
SET @pos = 0;
SELECT @pos := @pos + 1 AS 'Count',
CONCAT(pat.LName, ', ', pat.FName) AS "Patient",
DATE_FORMAT(MAX(DATE(s.DateSent)), '%m/%d/%Y') AS "Last Stmt Date",
DATE_FORMAT(DATE(ADDDATE(MAX(DATE(s.DateSent)), INTERVAL 30 DAY)), '%m/%d/%Y') AS "Due Date"
FROM patient pat,
statement s
WHERE s.PatNum = pat.PatNum
AND DATE(s.DateSent) > DATE(ADDDATE(CURDATE(), INTERVAL -30 DAY))
AND s.Mode_ = 0 /*mail*/
GROUP BY pat.PatNum
ORDER BY "Patient";
Production for date range with pay splits and tooth and surface -
/*53 Production for date range with pay splits and tooth and surface*/
SET @FromDate = '2016-01-01',@ToDate = '2016-01-31';
SELECT CONCAT(LName, ', ', FName, ' ', MiddleI) AS
Patient,
pc.ProcCode,
pl.ProcDate,
pl.ProcFee,
ps.splitamt,
surf,
toothnum
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum = pl.PatNum
AND pl.ProcStatus = 2 #Complete
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
INNER JOIN procedurecode pc ON pl.CodeNum = pc.CodeNum
LEFT JOIN paysplit ps ON pl.ProcNum = ps.ProcNum
ORDER BY patient.LName, patient.FName ASC;
Payments by procedure for date range - Patient Payments by procedure only works if you split the payments by procedure when entering payments, uncommon but there are several offices that
do this, especially if paying providers by income
/*54*/ SET @FromDate = '2007-01-01' , @ToDate = '2007-01-15';
SELECT CONCAT(LName, ', ', FName, ' ', MiddleI) As Patient, pc.ProcCode, pl.ProcDate, pl.ProcFee, ps.SplitAmt
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum = pl.PatNum
AND pl.ProcStatus != 6
INNER JOIN procedurecode pc ON pl.CodeNum = pc.CodeNum
LEFT JOIN paysplit ps ON pl.ProcNum = ps.ProcNum
WHERE pl.ProcDate >= @FromDate
AND pl.ProcDate <= @ToDate
ORDER BY patient.LName, patient.FName ASC;
All insurance claimed procedures with UCR fee for date range, even if a different fee was used or sent , for a specified fee schedule. - Useful for comparisons, you can also add the column pl.ProcFee to see what was actually charged.
/*55 All insurance claimed procedures with UCR fee for date range, even if a different fee was used or sent*/
SET @FromDate='2015-01-01' , @ToDate='2015-01-15';
SET @FeeSchedName = 'Standard';
SELECT c.PatNum, c.DateService, c.ProvTreat, pc.ProcCode, cp.InsPayEst, f.Amount AS '$UCR FEE'
FROM claim c
INNER JOIN claimproc cp ON c.ClaimNum = cp.ClaimNum
INNER JOIN procedurelog pl ON cp.ProcNum = pl.ProcNum
INNER JOIN procedurecode pc ON pl.CodeNum = pc.CodeNum
INNER JOIN fee f ON pc.CodeNum = f.CodeNum
INNER JOIN feesched fs ON f.FeeSched = fs.FeeSchedNum
AND fs.Description LIKE @FeeSchedName
WHERE DateService >= @FromDate
AND DateService <= @ToDate
ORDER BY c.DateService, c.PatNum, pc.ProcCode
Returns all treatment planned procedures (summed by patient
)
for
active
patients
without
a
scheduled
OR
planned
apt
,
with phone nums - usefull for those transitioning to planned appointments
/*56*/ SELECT CONCAT(LName, ', ', FName, ' ', MiddleI) AS Patient,
hmphone,
wkphone,
wirelessphone,
SUM(ProcFee) AS '$FeeSum',
Concat(Address, ' ', Address2) AS Address,
City,
State,
Zip
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum = pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum = pc.CodeNum AND ProcStatus = 1
LEFT JOIN appointment ap ON patient.PatNum = ap.PatNum AND (ap.AptStatus = 1 OR ap.AptStatus = 6)
WHERE ap.AptNum IS NULL
AND patient.PatStatus = 0
GROUP BY patient.PatNum
ORDER BY patient.LName, patient.FName ASC;
Insurance payments received after a certain date, with chart number, sorted by carrier - ChartNum may be easily replaced with PatNum
/*57*/
SELECT patient.ChartNumber,
CONCAT(patient.LName, ', ', patient.FName, ' ', patient.MiddleI) AS Name,
claimpayment.CheckDate,
carrier.CarrierName,
claimpayment.CheckNum,
claimproc.ClaimNum,
SUM(claimproc.InsPayAmt) AS $Amt
FROM claimpayment,
claimproc,
insplan,
patient,
carrier
WHERE claimproc.ClaimPaymentNum = claimpayment.ClaimPaymentNum
AND claimproc.PlanNum = insplan.PlanNum
AND claimproc.PatNum = patient.PatNum
AND carrier.CarrierNum = insplan.CarrierNum
AND (claimproc.Status = '1' OR claimproc.Status = '4')
AND DATE(claimpayment.CheckDate) > '2007-10-29'
GROUP BY claimproc.ClaimNum
ORDER By CarrierName;
Received Lab Cases with sent and received date with patient number -
/*58*/
SELECT PatNum AS PatID, PatNum, Description AS Laboratory, DateTimeSent, DateTimeRecd
FROM labcase lc
INNER JOIN laboratory l ON lc.LaboratoryNum = l.LaboratoryNum
WHERE DateTimeRecd > DateTimeSent;
Patient lifetime revenue and TP'd procedure totals - also includes PatNum and patient age, does NOT include insurance revenue
/*59*/ SELECT PatNum, (CASE WHEN (YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5))<120
THEN (YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) ELSE 'NONE' END)
AS 'Age', (SELECT SUM(SplitAmt)
FROM paysplit WHERE paysplit.PatNum=patient.PatNum) AS '$Lifetime Income',
(SELECT SUM(ProcFee) FROM procedurelog WHERE procedurelog.ProcStatus=1 AND
procedurelog.PatNum=patient.PatNum) AS '$Treatment Planned' FROM
patient ORDER BY LName;
Treatment Planned Procedures with Referror and Insurance -
/*60*/ SELECT pl.PatNum,pc.ProcCode,pl.ProcFee,
pl.Surf,pl.ToothNum,CASE WHEN (patient.HasIns='I') THEN 'Yes' ELSE 'No' END
AS HasInsurance, CONCAT(tmpRef.LName, ', ', tmpRef.FName) AS "Referror"
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum AND pl.ProcStatus = 1
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
LEFT JOIN (SELECT ItemOrder, refattach.ReferralNum, LName, FName, refattach.PatNum FROM refattach INNER JOIN referral ON refattach.ReferralNum =referral.ReferralNum) tmpRef
ON patient.PatNum=tmpRef.PatNum AND tmpRef.ItemOrder = 1
ORDER BY patient.LName, patient.FName ASC;
Query scheduled procedures for code with date range -
/*61 Procedures in a scheduled or ASAP appointment in the date range. Option to filter by specified code(s)*/
/*Query code written/modified 04/11/2018*/
SET @Codes =''; /*Enter exact procedure codes here, separated by a | symbol. Must not end in a | . Will search all if left blank.*/
SET @StartDate='2018-04-01' , @EndDate='2018-04-30'; /*Enter dates here in YYYY-MM-DD format*/
/*---DO NOT MODIFY BELOW THIS LINE---*/
SET @Codes=(CASE WHEN @Codes='' THEN '^' ELSE CONCAT('^',REPLACE(@Codes,'|','$|^'),'$') END);
SELECT CONCAT(LName, ', ',FName, ' ', MiddleI) AS Patient,
GROUP_CONCAT(pc.ProcCode) AS 'Codes',
ap.AptDateTime,
ap.AptStatus
FROM patient
INNER JOIN procedurelog pl
ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc
ON pl.CodeNum= pc.CodeNum
INNER JOIN appointment ap
ON pl.AptNum=ap.AptNum
AND ap.AptStatus IN (1,4) /*Scheduled or ASAP*/
AND ProcCode REGEXP @Codes
AND DATE(ap.AptDateTime) BETWEEN @StartDate AND @EndDate
GROUP BY patient.PatNum, ap.AptNum
ORDER BY aptstatus, patient.LName, patient.FName ASC;
Patients payments by type with patient name (PatNum) for a day - Was useful for a few versions from about 5.4 to 5.6 where insurance checks were not being returned by patient name, this report is included now in standard reports, (daily payments with insurance checks by patient option selected)
/*62*/ SET @StartDate='2010-01-01', @EndDate='2010-12-31';
SELECT paysplit.PatNum,definition.ItemName AS PaymentType, paysplit.DatePay AS 'DatePay',
SUM(paysplit.SplitAmt) AS $PaymentAmt
FROM payment,definition,paysplit
WHERE paysplit.DatePay BETWEEN @StartDate AND @EndDate
AND payment.PayNum=paysplit.PayNum
AND definition.DefNum=payment.PayType
GROUP BY payment.PayType,paysplit.PatNum, paysplit.DatePay
UNION
SELECT PatNum, 'Ins Checks',claimproc.DateCP AS 'DatePay',SUM(claimproc.InsPayAmt) AS $PaymentAmt
FROM claimproc
WHERE claimproc.DateCP BETWEEN @StartDate AND @EndDate
AND (claimproc.Status=1 OR claimproc.Status=4)
GROUP BY PatNum, DatePay
ORDER BY DatePay, PaymentType;
Number of active patients of each age - Doesnot imply that a procedure has been completed on patient
/*64 Active Patient count by age*/
SELECT (YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) AS 'Age', COUNT(DISTINCT p.PatNum) AS 'Patients'
FROM patient p
WHERE p.PatStatus=0
GROUP BY Age;
Shows all records with duplicate first and last name - To see PatNum, choose 'raw' option button in query window
/*65 Possible duplicate accounts */
/*Query code written/modified on: 06/06/2018*/
/*Change the cut off date to only show duplicates if one of them has been made since this date*/
SET @CutOffDate = '2018-01-01';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT CONCAT( -- Build a name string like OD's default
p1.LName,
',',
(CASE WHEN LENGTH(p1.Preferred) > 0 THEN CONCAT(' ''', p1.Preferred,'''') ELSE '' END), -- Display preferred if we have one
' ',
p1.FName,
(CASE WHEN LENGTH(p1.MiddleI) > 0 THEN CONCAT(' ', p1.MiddleI) ELSE '' END) -- Display middle initial if we have one
) AS 'PatientName',
p1.PatNum AS 'PatientNum',
p1.SecDateEntry AS 'DateCreated'
FROM patient p1
INNER JOIN patient p2
ON p1.LName = p2.LName -- Same last name
AND p1.FName = p2.FName -- Same first name
AND p1.PatNum != p2.PatNum -- Not same patient
AND p2.patstatus != 4 -- Deleted
WHERE p1.patstatus != 4 -- Deleted
AND (p1.SecDateEntry >= @CutOffDate OR p2.SecDateEntry >= @CutOffDate) -- One of the accounts was made since the cutoff date
ORDER BY p1.LName, p1.FName;
Active patients list who have seen a hygienist within a date range -
/*66 Active patients list who have seen a hygienist in date range*/
/*Query code written/modified: 02/17/2017*/
SET @pos = 0, @FromDate = '2017-01-01' , @ToDate = '2017-01-15';
SELECT @pos := @pos + 1 AS numberofpatients, A.*
FROM (
SELECT pa.PatNum, MAX(ProcDate) AS 'Last Seen'
FROM patient pa
INNER JOIN procedurelog pl ON pa.PatNum = pl.PatNum
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus = 2 /*Completed*/
INNER JOIN provider pv ON pv.ProvNum = pl.ProvNum
INNER JOIN definition d ON d.DefNum = pv.Specialty
AND d.ItemName LIKE '%hyg%'
WHERE pa.patstatus = '0' /*Patient*/
GROUP BY pa.PatNum
ORDER BY pa.Lname
) A;
Subscribers grouped by employer, gives # of active patients who are subscribers with insurance through each employer - This just gives count, you can get names in query 188
/*67*/
SELECT EmpName AS 'Employer', COUNT(EmpName) AS '# Emp Patients'
FROM insplan i
INNER JOIN employer e ON i.EmployerNum = e.EmployerNum
INNER JOIN inssub iss ON iss.PlanNum = i.PlanNum
INNER JOIN patient p on p.PatNum = iss.Subscriber
WHERE p.PatStatus = 0
GROUP BY EmpName;
New patients for date range with ref source and sum of first visit fees - For Versions 17.1 and greater. Please
update your version accordingly.Will not return patients
with no fees
on first visit date or if there is no referral source listed (designed for lending bank reporting req
)
/*68 New patients for date range with ref source and sum of first visit fees*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/04/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate = '2018-01-01' , @ToDate = '2018-01-05';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SET @pos = 0;
SELECT p.PatNum,
DateFirstVisit,
FORMAT(SUM(ProcFee), 2) AS ProcFee_,
r.LName AS RefLName,
r.FName AS RefFName
FROM patient p
INNER JOIN refattach ra ON p.PatNum = ra.PatNum
AND ra.RefType = 1 /*RefFrom*/
INNER JOIN referral r ON r.ReferralNum = ra.ReferralNum
INNER JOIN procedurelog pl ON p.PatNum = pl.PatNum
AND DATE(pl.ProcDate) = DATE(p.datefirstvisit)
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus = '2' /*Completed*/
GROUP BY p.PatNum
ORDER BY p.LName
Count of patients by Carrier
with procedures completed in date range -
/*69 Count of patients by Carrier with procedures
completed in date range*/
SET @FromDate = '2010-01-01' , @ToDate = '2010-01-31';
/*Adjust above Dates AS needed*/
SELECT carrier.CarrierName, COUNT(DISTINCT claimproc.PatNum) AS 'Patients'
FROM carrier
INNER JOIN insplan ON carrier.CarrierNum = insplan.CarrierNum
INNER JOIN claim ON insplan.PlanNum = claim.PlanNum
INNER JOIN claimproc ON claim.ClaimNum = claimproc.ClaimNum
INNER JOIN procedurelog ON claimproc.ProcNum = procedurelog.ProcNum
INNER JOIN procedurecode ON procedurelog.CodeNum = procedurecode.CodeNum
AND (procedurelog.ProcDate BETWEEN @FromDate AND @ToDate)
AND ProcStatus = 2
GROUP BY CarrierName
ORDER BY CarrierName;
Income by insurance company for date range -
/*70*/
SET @Start = '2007-01-01' , @Before = '2008-01-01';
/*Adjust above Dates as needed*/
SELECT CarrierName, SUM(CheckAmt) AS $Income
FROM claimpayment
WHERE CheckDate >= @Start
AND CheckDate < @Before
GROUP BY CarrierName;
Carrier and patient list seen in date range - to include only active patients add WHERE...AND PatStatus=0
/*71 Carrier and patient list seen in date range*/
SET @Start = '2007-01-01' , @Before = '2008-01-01';
/*Adjust above Dates as needed*/
SET @pos = 0;
SELECT @pos := @pos + 1 AS COUNT, A.*
FROM (
SELECT carrier.CarrierName, patient.PatNum
FROM carrier,
insplan,
claim,
claimproc,
patient
WHERE insplan.PlanNum = claim.PlanNum
AND insplan.CarrierNum = carrier.CarrierNum
AND claimproc.ClaimNum = claim.ClaimNum
AND claimproc.PatNum = patient.PatNum
AND ProcDate >= @Start
AND ProcDate < @Before
/*this is in case we need additional patient information*/
/*you can add any patient or insurance fields to the SELECT statement*/
GROUP BY patient.PatNum, CarrierName
ORDER BY CarrierName
) A
Count of active patients seen in a date range grouped by billing type -
/*72 Count of active patients seen in a date range grouped by billing type*/
/*Query code written/modified: 02/20/2019*/
SET @FromDate = '2008-01-01', @ToDate = '2008-12-31';
SELECT p.BillingType,
COUNT(DISTINCT p.PatNum) AS 'COUNT'
FROM patient p
INNER JOIN procedurelog pl
ON pl.PatNum = p.PatNum
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus = 2 -- Complete
WHERE p.PatStatus = 0 -- Patient
GROUP BY p.BillingType
Recieved Preauths over last X months -
/*73*/ SET @EndDate = CurDate();
SET @StartDate = (CurDate() - INTERVAL 3 MONTH);
SELECT PatNum, DateSent, DateReceived, ClaimFee, InsPayEst, ClaimNote
FROM claim
WHERE claimtype = 'PreAuth'
AND claimstatus = 'R'
AND DateReceived >= @StartDate
AND DateReceived <= @EndDate;
Patient payments in date range -
/*75*/
SET @StartDate = '2007-02-21';
SET @EndDate = '2008-02-21';
SET @PatientNumber = 6179;
SELECT *
FROM paysplit
WHERE DatePay >= @StartDate
AND DatePay <= @EndDate
AND PatNum = @PatientNumber;
New patients in date range with address and ref source - For Versions 17.1 and greater. Please
update your version accordingly.
/*76 New patients in date range with address and ref source*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/04/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2018-01-01' , @ToDate='2018-01-05';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SET @pos = 0;
SELECT p.PatNum,
DATE_FORMAT(p.DateFirstVisit, '%m-%d-%Y') AS FirstVisit,
CONCAT(p.Address, ' ', p.Address2) as Address,
p.city,
p.state,
p.zip,
r.LName as RefLName,
r.FName as RefFName
FROM patient p
LEFT JOIN refattach ra ON p.PatNum = ra.PatNum
LEFT JOIN referral r ON r.ReferralNum = ra.ReferralNum
AND ra.RefType = 1 /*RefFrom*/
WHERE p.DateFirstVisit BETWEEN @FromDate AND @ToDate
ORDER BY p.LName
Returns guarantors of patients who have not recieved an email
with a specific word in subject line within 45 days who have an appointment in a date range - It is too specific for general
use, but gives an idea of how you can use a query to make sure you have sent registration information by email.
/*77*/ SET @DateStart='2008-01-01' , @DateEnd='2008-01-31';
SELECT patient.PatNum
FROM patient
INNER JOIN patient pg ON patient.Guarantor = pg.PatNum
INNER JOIN appointment ON patient.PatNum = appointment.PatNum
AND aptstatus = 1
AND aptdatetime >= @DateStart
AND aptdatetime <= @DateEnd
LEFT JOIN procedurelog ON patient.PatNum = procedurelog.PatNum
AND ProcStatus = 2
LEFT JOIN emailmessage e ON pg.PatNum = e.PatNum
AND e.MsgDateTime >= DATE_SUB(curdate(), INTERVAL 45 DAY)
AND e.Subject LIKE ('%Welcome%')
WHERE ISNULL(procedurelog.ProcDate)
AND ISNULL(e.Subject);
Patients with no scheduled apt who have not been in for a time period with the date of their last scheduled apt. - (From @daysIntervalStart days ago to @daysIntervalEnd days ago, change the interval currently 365 days: 1 year) This is useful for making a patient list before archiving patients, to
call and try one last time.
/*78 Active (status) patients with no scheduled apt who have not been in for a time period with the date of their last completed apt. - (From @daysIntervalStart days ago to @daysIntervalEnd days ago, change the interval currently 365 days: 1 year) This is useful for making a patient list before archiving patients, to call and try one last time.*/
SET @daysIntervalStart=365/*<<<Just normally change this one*/, @daysIntervalEnd=0;
/*------------ DO NOT MODIFY BELOW THIS LINE ------------*/
/*Query code written/modified on: 03/28/2019:RobG*/
#
SET @pos = 0;
SELECT @pos := @pos + 1 AS 'NumberOfPatients',
a.PatNum,
a.HmPhone,
a.Address,
a.City,
a.State,
a.Zip,
a.LastApt,
a.DaysSince
FROM (
SELECT patient.PatNum,
patient.HmPhone,
patient.Address,
patient.City,
patient.State,
patient.Zip,
tmp2.AptDateTime AS LastApt,
(TO_DAYS(CURDATE()) - TO_DAYS(tmp2.AptDateTime)) AS 'DaysSince'
FROM patient
INNER JOIN (
SELECT PatNum,
MAX(AptDateTime) AS 'AptDateTime'
FROM appointment
WHERE AptStatus = 2 -- Complete
GROUP BY PatNum
) tmp2
ON patient.PatNum = tmp2.PatNum
LEFT JOIN (
SELECT DISTINCT PatNum
FROM appointment
WHERE AptStatus = 1 -- Scheduled
)/*patients with scheduled appointments*/ tmp1
ON patient.PatNum = tmp1.PatNum
WHERE tmp1.PatNum IS NULL
AND (TO_DAYS(CURDATE()) - TO_DAYS(tmp2.AptDateTime)) NOT BETWEEN @daysIntervalEnd AND @daysIntervalStart
AND patient.PatStatus = 0 -- Patient
GROUP BY tmp2.PatNum
ORDER BY patient.LName, patient.FName ASC
) a;
Insurance claim procedures with UCR fee, InsEst and InsAmtPaid - Change
date range as needed, does not distinguish between recieved claims, sent claims etc
/*80 Insurance claim procedures with UCR fee, InsEst and InsAmtPaid - Change date range as needed, does not distinguish between recieved claims, sent claims etc*/
SET @StartDate = '2009-08-01' , @EndDate = '2009-08-15';
SET @FeeSched = 'Standard';
-- Enter the exact fee schedule name here
/*------------ DO NOT MODIFY BELOW THIS LINE ------------*/
/*Query code written/modified on: 5/6/2009, 05/16/2019:RobG*/
SELECT claim.PatNum,
DateService,
ProvTreat,
pc.ProcCode,
cp.InsPayEst,
f.Amount AS 'UCR FEE',
cp.inspayamt
FROM claim
INNER JOIN claimproc cp
ON claim.ClaimNum = cp.ClaimNum
INNER JOIN procedurelog pl
ON cp.ProcNum = pl.ProcNum
INNER JOIN procedurecode pc
ON pl.CodeNum = pc.CodeNum
INNER JOIN fee f
ON pc.CodeNum = f.CodeNum
INNER JOIN feesched fs
ON f.FeeSched = fs.FeeSchedNum
AND fs.Description = @FeeSched
WHERE DateService BETWEEN @StartDate AND @EndDate;
All treatment planned and scheduled, all treatment planned total, returns these two dollar amounts, active patients - SEE REPLICATION WARNING for versions before 14.3.1. The second number includes the first, so the relationship beween the two amounts is the percentage of treatment planned work that is scheduled right now
/*81 This is a point in time query, what do I have scheduled, what do I have TP'd for active patients*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS tmp1; /*Create a temp table containing summary info by procedure*/
CREATE TABLE tmp1
SELECT 'TPd And Scheduled' AS ProcCondition, sum(ProcFee) AS $TotalFees
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum = pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum = pc.CodeNum
INNER JOIN appointment ap ON pl.AptNum = ap.AptNum
AND AptStatus = 1 AND PatStatus = 0;
INSERT INTO tmp1(ProcCondition, $TotalFees)
SELECT 'Treatment Planned' as ProcCondition, sum(ProcFee) as $TotalFees
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum = pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum = pc.CodeNum
LEFT JOIN appointment ap ON pl.AptNum = ap.AptNum
WHERE (isnull(ap.aptnum) OR AptStatus = 6 OR AptStatus = 3)
AND PatStatus = 0;
/*Display Results*/
SELECT *
FROM tmp1;
DROP TABLE IF EXISTS tmp1;
Date Range limited: treatment planned and scheduled, treatment planned total, returns these two dollar amounts for all patients - SEE REPLICATION WARNING for versions before 14.3.1. The date range of the first number is applied to the appointment scheduled date, the date range for the second amount limits by what date the TP procedures were made.
/*82 Caution: the results will change depending on how long after the period you run the query*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @StartDate='2008-01-01' , @EndDate='2008-01-15';
DROP TABLE IF EXISTS tmp1; /*Create a temp table containing summary info by procedure*/
CREATE TABLE tmp1
SELECT 'TPd And Scheduled' AS ProcCondition, SUM(ProcFee) AS $TotalFees
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum = pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum = pc.CodeNum
INNER JOIN appointment ap ON pl.AptNum = ap.AptNum
AND DATE(pl.DateTP) >= @StartDate
AND DATE(pl.DateTP) <= @EndDate
AND AptStatus = 1;
INSERT INTO tmp1(ProcCondition, $TotalFees)
SELECT 'Treatment Planned' as ProcCondition, sum(ProcFee) as $TotalFees
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum = pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum = pc.CodeNum
LEFT JOIN appointment ap ON pl.AptNum = ap.AptNum
WHERE (isnull(ap.aptnum) OR AptStatus = 6 OR AptStatus = 3)
AND DATE(pl.DateTP) >= @StartDate
AND DATE(pl.DateTP) <= @EndDate;
/*Display Results*/
SELECT *
FROM tmp1;
DROP TABLE IF EXISTS tmp1;
Patients from given city seen in date range - theoretically helpful for splitting practice
/*83. Patients FROM city seen in date range, theoretically helpful for splitting practice*/
/*Caution: the results will change depending on how long after the period you run the query*/
SET @FromDate = '2011-10-01', @ToDate = '2011-10-31';
SELECT DISTINCTROW patient.PatNum,
patient.city
FROM procedurelog
INNER JOIN patient
ON procedurelog.PatNum = patient.PatNum
WHERE ProcStatus = 2
AND ProcDate BETWEEN @FromDate AND @ToDate
AND patient.City LIKE ('%Port%')
Scheduled procedures
with associated appointments and patients for date range for given code -
/*84*/ SET @StartDate = '2008-04-01', @EndDate = '2008-04-30', @Code = '%D0120%';
SELECT pa.PatNum, pc.ProcCode, pl.ProcFee AS $Fee, ap.AptDateTime
FROM patient pa
INNER JOIN procedurelog pl ON pa.PatNum = pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum = pc.CodeNum
INNER JOIN appointment ap ON pl.AptNum = ap.AptNum
WHERE DATE(ap.AptDateTime) >= @StartDate
AND DATE(ap.AptDateTime) <= @EndDate
AND AptStatus = 1
AND pc.ProcCode LIKE (@Code)
ORDER BY pa.LName;
Patient and insurance Payments for date range for given provider -
/*85*/
SET @StartDate = '2013-01-01',@EndDate = '2013-10-31';
SET @ProviderAbbreviation = 'DOC';
SELECT p.PatNum, A.PaymentType, pv.Abbr, A.PaymentAmt AS $PaymentAmt_
FROM patient p
INNER JOIN (
SELECT ps.PatNum,
d.ItemName AS PaymentType,
ps.ProvNum,
SUM(ps.SplitAmt) AS PaymentAmt
FROM payment pm
INNER JOIN definition d ON d.DefNum = pm.PayType
INNER JOIN paysplit ps ON pm.PayNum = ps.PayNum
AND ps.DatePay BETWEEN @StartDate AND @EndDate
GROUP BY ps.PatNum, d.ItemName
UNION
SELECT PatNum, 'Ins Checks' AS PaymentType, ProvNum, SUM(InsPayAmt) AS PaymentAmt
FROM claimproc
WHERE DateCP BETWEEN @StartDate AND @EndDate
AND Status IN (1, 4)
GROUP BY PatNum
) A ON A.PatNum = p.PatNum
INNER JOIN provider pv ON pv.ProvNum = A.ProvNum
AND pv.Abbr LIKE CONCAT('%', @ProviderAbbreviation, '%')
ORDER BY p.LName, p.FName;
Adjustments summed by type -
/*86*/
SET @Start = '2009-01-01' , @End = '2009-12-31';
/*Adjust above Dates as needed*/
SELECT AdjType, SUM(AdjAmt), Count(AdjNum) AS AdjCount
FROM adjustment
WHERE AdjDate >= @Start
AND AdjDate <= @End
GROUP BY AdjType
ORDER BY SUM(AdjAmt);
Sum of payments made by carrier for procedures in a date range -
/*88*/
SET @FromDate = '2008-01-01', @Todate = '2008-01-31';
/*Adjust above Dates as needed*/
SELECT carrier.CarrierName,
COUNT(DISTINCT claimproc.PatNum) AS 'Patients',
SUM(claimproc.InsPayAmt) as 'InsPaidTotal'
FROM carrier
INNER JOIN insplan ON carrier.CarrierNum = insplan.CarrierNum
INNER JOIN claim ON insplan.PlanNum = claim.PlanNum
INNER JOIN claimproc ON claim.ClaimNum = claimproc.ClaimNum
INNER JOIN procedurelog ON claimproc.ProcNum = procedurelog.ProcNum
INNER JOIN procedurecode ON procedurelog.CodeNum = procedurecode.CodeNum
AND procedurelog.ProcDate >= @FromDate
AND procedurelog.ProcDate < @ToDate
AND ProcStatus = 2
GROUP BY CarrierName
ORDER BY CarrierName;
Insurance income for time period summed by guarantor and carrier -
/*90 Sum of payments made by carrier for procedures in a date range*/
/*Query code written/modified: 10/12/2015*/
SET @FromDate = '2011-01-01', @ToDate = '2015-12-31';
SELECT carrier.CarrierName, patient.Guarantor, SUM(claimproc.InsPayAmt) AS '$InsPayAmt_'
FROM patient
INNER JOIN claimproc ON claimproc.PatNum = patient.PatNum
INNER JOIN insplan ON insplan.PlanNum = claimproc.PlanNum
INNER JOIN carrier ON carrier.CarrierNum = insplan.CarrierNum
WHERE patient.PatStatus = 0
AND claimproc.ProcDate BETWEEN @FromDate AND @ToDate
AND (claimproc.Status = 1 OR claimproc.Status = 4)
GROUP BY patient.Guarantor, carrier.CarrierName
ORDER BY carrier.CarrierName;
Aging Report for Balance over 90 with no payment in last 30 - SEE REPLICATION WARNING for versions before 14.3.1.
/*91*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp
SELECT CONCAT(g.LName, ', ', g.FName, ' ', g.MiddleI) AS Guarantor
, g.Bal_0_30
, g.Bal_31_60
, g.Bal_61_90
, g.BalOver90
, g.BalTotal
, g.InsEst
, g.BalTotal - g.InsEst AS $PatPor
,
MAX(paysplit.DatePay) AS LastPayment
FROM patient
INNER JOIN patient g ON patient.Guarantor = g.PatNum
LEFT JOIN paysplit
ON paysplit.PatNum = patient.PatNum
WHERE (patient.patstatus IN (0, 1))
AND (g.BalOver90 > '.005')
GROUP BY patient.Guarantor
ORDER BY g.LName, g.FName;
SELECT Guarantor
, Bal_0_30
, Bal_31_60
, Bal_61_90
, BalOver90 AS $BalOver90
, BalTotal AS $BalanceTotal
, InsEst AS $InsEstimate
, $PatPor AS $PatientPor
,
DATE_FORMAT(LastPayment, '%m/%d/%Y') AS LastPayment
FROM tmp
WHERE DATE(LastPayment) < (CURDATE() - INTERVAL 30 DAY);
DROP TABLE IF EXISTS tmp;
Find an Insurance
check by Check Number - Change check number between the '%%' symbols
/*92*/
SET @Check = '%123%'; /*Change check number between '%%' symbols.*/
SELECT patient.PatNum,
CONCAT(patient.LName, ', ', patient.FName, ' ', patient.MiddleI) AS Name,
claimpayment.CheckDate,
carrier.CarrierName,
claimpayment.CheckNum,
claimproc.ClaimNum,
SUM(claimproc.InsPayAmt) AS $Amt
FROM claimpayment,
claimproc,
insplan,
patient,
carrier
WHERE claimproc.ClaimPaymentNum = claimpayment.ClaimPaymentNum
AND claimproc.PlanNum = insplan.PlanNum
AND claimproc.PatNum = patient.PatNum
AND carrier.CarrierNum = insplan.CarrierNum
AND claimpayment.CheckNum LIKE @Check
GROUP BY claimproc.ClaimNum
ORDER By CarrierName;
EXPORT PATIENT DATA TO IMPORT INTO ANOTHER PROGRAM: - The file created as a result of this query will be c:\TEMP\patients.csv One should ensure that the c:\TEMP folder exists before running this query.
/*95*/ SELECT LName,FName,WkPhone,HmPhone,WirelessPhone
FROM patient WHERE PatStatus=0 INTO OUTFILE "c:\\TEMP\\patients.csv" FIELDS TERMINATED BY ',';
Find an Insurance
check by Amount and Date -
/*96*/ SELECT CarrierName,
Sum(InsPayAmt) as $Patient,
CheckAmt as $CheckAmt,
CheckNum,
CheckDate,
Note,
claimproc.PatNum
FROM claimpayment
LEFT JOIN claimproc ON claimpayment.ClaimPaymentNum = claimproc.ClaimPaymentNum
WHERE CheckDate >= '2008-03-01'
AND CheckAmt = '241.00'
GROUP BY PatNum;
Get Patient info based on subscriber id (or part of it) - Add more fields from patient table as needed
/*97*/ SET @SubscriberID = ('%123%');
SELECT p.PatNum, iss.SubscriberID
FROM patient p
INNER JOIN patplan pp ON pp.PatNum = p.PatNum
INNER JOIN inssub iss ON iss.InsSubNum = pp.InsSubNum
INNER JOIN insplan ip ON ip.PlanNum = iss.PlanNum
WHERE iss.SubscriberID LIKE @SubscriberID
ORDER BY p.LName, p.FName;
Procedures with notes for date range (completed procs) - Note that since we
do not delete notes, there may be multiple entries if notes were altered To see last note only, try query 136 below
/*98*/ SET @FromDate = '2008-01-01', @ToDate = '2008-01-31'; /*change dates here*/
SELECT pl.ProcDate,
CONCAT(pa.LName, ', ', pa.FName, ' ', pa.MiddleI) AS PatName,
ProcCode,
pl.ToothNum,
Note
FROM patient pa,
procedurecode pc,
provider pr,
procedurelog pl
LEFT JOIN procnote pn ON pl.ProcNum = pn.ProcNum
WHERE pl.ProcStatus = '2'
AND pl.CodeNum = pc.CodeNum
AND pa.PatNum = pl.PatNum
AND pr.ProvNum = pl.ProvNum
AND pl.ProcDate >= @FromDate
AND pl.ProcDate <= @ToDate
GROUP BY pl.ProcNum
ORDER BY pl.ProcDate, PatName;
Find insurance plans without assigned benefits - Returns subscribers of plans (vs patients using plan)
/*99 Find insurance plans without assigned benefits*/
SELECT PlanNum, SubScriber
FROM inssub
WHERE AssignBen = 0;
Patients with saved Treatment Plans and date of plan -
/*100*/
SET @FromDate = '2008-01-01', @ToDate = '2008-01-31'; /*change dates here*/
SET @pos = 0;
SELECT @pos := @pos + 1 AS Number, PatNum, DateTP, Heading, Note
FROM treatplan
WHERE DateTP Between @FromDate AND @ToDate;
Patient, provider, balance, like shown in patient payment window - SEE REPLICATION WARNING for versions before 14.3.1.
/*101*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS tempfambal;
CREATE TABLE tempfambal
(
FamBalNum INT NOT NULL AUTO_INCREMENT,
PatNum INT NOT NULL,
Guarantor INT NOT NULL,
ProvNum INT NOT NULL,
AmtBal DOUBLE NOT NULL,
PRIMARY KEY (FamBalNum)
);
INSERT INTO tempfambal (PatNum, Guarantor, ProvNum, AmtBal)
SELECT patient.PatNum, patient.Guarantor, procedurelog.ProvNum, SUM(ProcFee)
FROM procedurelog,
patient
WHERE patient.PatNum = procedurelog.PatNum
AND ProcStatus = 2
GROUP BY patient.PatNum, ProvNum;
INSERT INTO tempfambal (PatNum, Guarantor, ProvNum, AmtBal)
SELECT patient.PatNum, patient.Guarantor, claimproc.ProvNum, -SUM(InsPayAmt) - SUM(Writeoff)
FROM claimproc,
patient
WHERE patient.PatNum = claimproc.PatNum
AND (STATUS = 1 OR STATUS = 4 OR STATUS = 5)/*received,supplemental,capclaim*/
GROUP BY patient.PatNum, ProvNum;
INSERT INTO tempfambal (PatNum, Guarantor, ProvNum, AmtBal)
SELECT patient.PatNum, patient.Guarantor, adjustment.ProvNum, SUM(AdjAmt)
FROM adjustment,
patient
WHERE patient.PatNum = adjustment.PatNum
GROUP BY patient.PatNum, ProvNum;
INSERT INTO tempfambal (PatNum, Guarantor, ProvNum, AmtBal)
SELECT patient.PatNum, patient.Guarantor, paysplit.ProvNum, -SUM(SplitAmt)
FROM paysplit,
patient
WHERE patient.PatNum = paysplit.PatNum
AND paysplit.PayPlanNum = 0
GROUP BY patient.PatNum, ProvNum;
/*payplan princ reduction*/
/*Version 1: Payment plan principal for the entire office history for those using the original payplans accounting*/
INSERT INTO tempfambal (PatNum, Guarantor, ProvNum, AmtBal)
SELECT patient.PatNum, patient.Guarantor, payplancharge.ProvNum, -(pp.CompletedAmt)
FROM payplancharge,
patient,
payplan pp
WHERE patient.PatNum = payplancharge.PatNum
AND pp.PatNum = patient.PatNum
AND pp.CompletedAmt != 0
GROUP BY patient.PatNum, payplancharge.ProvNum;
SELECT tempfambal.Guarantor, tempfambal.PatNum, tempfambal.ProvNum, SUM(AmtBal) AS $AmtBal
FROM tempfambal
INNER JOIN patient guarantor ON guarantor.PatNum = tempfambal.Guarantor
GROUP BY tempfambal.PatNum, tempfambal.ProvNum
/*Exclude Zero Balances, Optional, remove row to return all*/
HAVING (SUM(AmtBal) > 0.009 OR SUM(AmtBal) < (-0.009))
ORDER BY guarantor.LName, guarantor.FName, tempfambal.ProvNum;
DROP TABLE IF EXISTS tempfambal;
CommLog notes by Type -
/*102*/
SELECT commlog.PatNum, Note, ItemName
FROM commlog
INNER JOIN definition ON commlog.CommType = definition.DefNum
INNER JOIN patient ON commlog.PatNum = patient.PatNum
WHERE ItemName Like 'Financial'
OR ItemName Like 'Insurance'
ORDER BY patient.LName, patient.FName
New patients
with Clinic and Referral source for date range - For Versions 17.1 and greater.Please
update your version accordingly.Excludes patients who have never actually had a procedure completed.
/*103 New patients with Clinic and Referral source for date range*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/04/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2018-01-01' , @ToDate='2018-01-05';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SET @pos = 0;
SELECT p.PatNum,
DATE_FORMAT(p.DateFirstVisit, '%m-%d-%Y') AS FirstVisit,
c.Description,
r.LName as RefLName,
r.FName as RefFName
FROM patient p
INNER JOIN procedurelog pl on pl.PatNum = p.PatNum
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus = 2 /*Completed*/
AND pl.ProcFee > 0 /*Remove procs with no charge*/
LEFT JOIN refattach ra ON p.PatNum = ra.PatNum
LEFT JOIN referral r ON r.ReferralNum = ra.ReferralNum
AND ra.RefType = 1 /*RefFrom*/
LEFT JOIN clinic c ON p.ClinicNum = c.ClinicNum
WHERE p.DateFirstVisit BETWEEN @FromDate AND @ToDate
AND p.PatStatus = 0 /*Patient - active*/
GROUP BY p.PatNum
ORDER BY c.Description, p.LName;
Count of new patients by clinic - Exludes patients who have never actually had a procedure performed
/*104*/
SET @FromDate = '2008-01-01' , @ToDate = '2008-01-31';
(SELECT IFNULL(c.Description, 'None') AS 'Clinic', IFNULL(COUNT(DISTINCT p.PatNum), 0) AS 'Patients'
FROM patient p
INNER JOIN procedurelog pl on pl.PatNum = p.PatNum
LEFT JOIN clinic c ON p.ClinicNum = c.ClinicNum
WHERE p.DateFirstVisit BETWEEN @FromDate AND @ToDate
AND p.PatStatus = 0
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus = 2
AND pl.ProcFee > 0
GROUP BY c.Description)
UNION ALL
(SELECT Concat('Total: ', @FromDate, ' to ', @ToDate) AS 'Clinic',
(SELECT COUNT(DISTINCT p.PatNum)
FROM patient p
INNER JOIN procedurelog pl on pl.PatNum = p.PatNum
WHERE p.DateFirstVisit BETWEEN @FromDate AND @ToDate
AND p.PatStatus = 0
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus = 2
AND pl.ProcFee > 0) AS 'Patients');
Patients names, addresses & phone(s) seen today -
/*105*/
SELECT CONCAT(pa.LName, ', ', pa.FName, ' ', pa.MiddleI) AS PatName,
CONCAT(pa.Address, pa.Address2, " ", pa.City, ", ", pa.State, " ", pa.zip) AS Address,
hmphone,
wkphone,
wirelessphone
FROM patient pa
LEFT JOIN procedurelog pl ON pa.PatNum = pl.PatNum
WHERE pl.ProcStatus = '2'
AND pl.ProcDate = DATE(curdate())
GROUP BY PatName
ORDER BY PatName
New Patient count, insured and not insured over date range - Also see
#545 for breakdown by month over a long period
/*106*/
SET @FromDate = '2008-06-01' , @ToDate = '2008-06-31';
SELECT SUM(Z.INSUREDCOUNT) AS InsuredCountByDate, SUM(Z.NOTINSUREDCOUNT) AS NotInsuredCountByDate
FROM (SELECT COUNT(DISTINCT PatNum) AS INSUREDCOUNT, 0 AS NOTINSUREDCOUNT
FROM procedurelog
WHERE PatNum IN (SELECT A.PatNum
FROM patient A,
patplan B
WHERE A.PatNum = B.PatNum
AND (A.datefirstvisit BETWEEN @FromDate AND @ToDate)
AND B.Ordinal = 1)
UNION
SELECT 0 AS INSUREDCOUNT, COUNT(DISTINCT PatNum) AS NOTINSUREDCOUNT
FROM procedurelog
WHERE PatNum IN (SELECT PatNum
FROM patient
WHERE PatNum NOT IN (SELECT PatNum FROM patplan)
AND datefirstvisit BETWEEN @FromDate AND @ToDate)) Z;
Referred procedures by date range -
/*107*/
SET @FromDate = '2008-01-01' , @ToDate = '2008-01-31';
SELECT CONCAT(LName, ', ', FName, ' ', MiddleI) As Patient,
pc.ProcCode as 'Code',
abbrdesc as 'Description',
DATE_FORMAT(pl.ProcDate, '%m-%d-%Y') AS 'Date',
ProcFee
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum = pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum = pc.CodeNum
WHERE pl.ProcStatus = 5
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
ORDER BY pl.ProcDate, patient.LName, patient.FName ASC;
Patients with NO images - (nonindexed table, so will take a VERY long time to run, upward of one minute) , also not to useful post version 5.6 since images also include statement PDFs, and in any version, scanned images et, generally used for determining missing files
/*108*/
SELECT p.PatNum
FROM patient p
LEFT JOIN document a ON p.PatNum = a.PatNum
WHERE a.PatNum IS NULL;
Patients' image count - (only returns patients with images, runs fast), note that images include PDFs stored by Open Dental
/*109*/ SELECT document.PatNum, CONCAT(p.LName,', ',p.FName,' ',p.MiddleI) AS PatName,
COUNT(document.PatNum) AS 'Images'
FROM document
LEFT JOIN patient p ON document.PatNum=p.PatNum
GROUP BY document.PatNum
ORDER BY p.LName, p.FName;
Procedures with date and description where the sum fee paid is greater than the fee - helpful for incorrect medicaid estimates
/*110*/ SET @StartDate='2008-01-01' , @EndDate='2008-06-15';
SELECT claim.PatNum,DateService,pc.ProcCode,ProcFee,f.Amount as 'UCR FEE', SUM(cp.inspayamt)
FROM claim
INNER JOIN claimproc cp ON claim.ClaimNum=cp.ClaimNum
INNER JOIN procedurelog pl ON cp.ProcNum=pl.ProcNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
INNER JOIN fee f ON pc.CodeNum=f.CodeNum
INNER JOIN definition d ON f.FeeSched=d.DefNum AND d.ItemName='Standard'
WHERE DateService>=@StartDate AND
DateService<=@EndDate AND (cp.Status=1 OR cp.Status=1)
GROUP BY cp.ProcNum
HAVING SUM(cp.InsPayAmt)>ProcFee;
Procs with date and description w/ sum fee paid > fee and patient acct credit - Same query as 110, but adds condition: Patient balances < 0 (account credits) helpful for incorrect medicaid estimates, uses last balance from updated aging claimproc status is recieved or supplemental
/*111*/ SET @StartDate='2008-01-01' , @EndDate='2008-06-15';
SELECT claim.PatNum,DateService,pc.ProcCode,ProcFee,f.Amount as 'UCR FEE', SUM(cp.inspayamt), ga.BalTotal
FROM claim
INNER JOIN claimproc cp ON claim.ClaimNum=cp.ClaimNum
INNER JOIN procedurelog pl ON cp.ProcNum=pl.ProcNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
INNER JOIN patient pa ON pa.PatNum=pl.PatNum
INNER JOIN patient ga ON pa.Guarantor=ga.PatNum
INNER JOIN fee f ON pc.CodeNum=f.CodeNum
INNER JOIN definition d ON f.FeeSched=d.DefNum AND d.ItemName='Standard'
WHERE DateService>=@StartDate AND
DateService<=@EndDate AND ga.BalTotal<0 AND (cp.Status=1 OR cp.Status=4)
GROUP BY cp.ProcNum
HAVING SUM(cp.InsPayEst)-ProcFee>.01;
Returns procedures with estimated insurance greater than charged fee claim proc status is not recieved AND the proc is complete AND the status of the claim is sent -
/*112*/ SET @StartDate='2008-01-01' , @EndDate='2008-06-15';
SELECT claim.PatNum,DateService,pc.ProcCode,ProcFee, SUM(cp.inspayest)
FROM claim
INNER JOIN claimproc cp ON claim.ClaimNum=cp.ClaimNum
INNER JOIN procedurelog pl ON cp.ProcNum=pl.ProcNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
WHERE DateService>=@StartDate AND
DateService<=@EndDate AND cp.Status=0 AND pl.ProcStatus=2 AND ClaimStatus='S'
GROUP BY cp.ProcNum
HAVING SUM(cp.InsPayEst)-ProcFee>.01
Outstanding insurance claims by carrier -
/*113*/ SELECT cl.PatNum,cl.DateSent, ca.CarrierName, ca.Phone FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE cl.ClaimStatus='S'
ORDER BY ca.CarrierName,p.LName;
Outstanding insurance claims for a particular carrier -
/*114*/ SET @Carrier='%Blue Cross%';
SELECT cl.PatNum,cl.DateSent,cl.DateService, ca.CarrierName, ca.Phone FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE cl.ClaimStatus='S' AND ca.CarrierName LIKE @Carrier
ORDER BY ca.CarrierName,p.LName;
Guarantors of families where no payment has been made in 1 Month and they are over 90 days past due -
/*115 Guarantors of families where no payment has been made in 1 Month and they are over 90 days past due,
period can be changed, you can use terms like 1 MONTH or 45 DAY for the interval*/
SELECT g.PatNum AS 'Number',CONCAT(g.LName, ", ", g.FName) AS 'Name', g.BalOver90 AS '$FamBalOver90',
DATE_FORMAT(MAX(ps.DatePay), '%m-%d-%Y') AS 'DateLastPay' , g.BalTotal AS '$FamBalTotal'
FROM patient g
INNER JOIN patient p ON p.Guarantor=g.PatNum
LEFT JOIN paysplit ps ON ps.PatNum=p.PatNum
WHERE g.BalOver90>1
GROUP BY g.PatNum
HAVING MAX(ps.DatePay)<(CURDATE()-INTERVAL 1 MONTH)
ORDER BY g.LName, g.FName;
Anticipated and incurred Writeoffs - USE with production report to get real production if you want to count writeoffs as the claim is made, not when they come in (New report available in 5.7.0+ gives these PPO numbers without this query)
/*116*/ SET @Start='2008-04-01', @End='2008-04-30';
SELECT PatNum,ProvNum,PlanNum,WriteOff AS $Amt,DATE_FORMAT(ProcDate,'%m/%d/%Y') AS Proc_Date,DATE_FORMAT(DateEntry,'%m/%d/%Y') AS Entry_Date
FROM claimproc
WHERE (WriteOff >0)
AND (ProcDate BETWEEN @Start AND @END)
AND (Status=0 OR Status = 1 OR Status = 4) /*includes sent, recieved and supplemental claims*/
ORDER BY ProcDate;
Total Anticipated and incurred writeoffs for procedures completed in range - Like 116 but sum only
/*117*/ SET @Start='2008-04-01', @End='2008-04-30';
SELECT SUM(WriteOff) AS '$TotalWriteoffs'
FROM claimproc
WHERE WriteOff >0
AND (ProcDate BETWEEN @Start AND @END)
AND (Status=0 OR Status = 1 OR Status = 4) /*includes sent, recieved and supplemental claims*/
ORDER BY ProcDate
Mailing list of guarantors of patients with a particular carrier - Unlike some others, returns the guarantors of all patients with plan, not the subscriber, also if you drop the plan it goes off the list
/*118 Mailing list of guarantors of patients with a particular carrier, unlike some others, returns the guarantors of all patients with plan, not the subscriber, also if you drop the plan it goes off the list*/
/*Query code written/modified: 09/28/2015*/
SET @CarrierName='%PLAN%';
SELECT DISTINCTROW gu.salutation, gu.LName, gu.FName, gu.Address,
gu.Address2, gu.City, gu.State, gu.zip, gu.Birthdate, ib.DateEffective, ca.CarrierName
FROM patient p
INNER JOIN patplan pp ON pp.PatNum=p.PatNum
INNER JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
INNER JOIN insplan ip ON ip.PlanNum=ib.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=ip.CarrierNum
INNER JOIN patient gu ON p.Guarantor=gu.PatNum
WHERE ca.CarrierName LIKE @CarrierName
ORDER BY ca.CarrierName, gu.LName;
Completed procedures for date range showing tooth surface - Change dates to change range
/*119 Completed procedures in the date range showing tooth surface*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate = '2016-04-19', @ToDate = '2016-04-21';
/*-------------------- Do not modify under this line --------------------*/
SELECT
CONCAT(patient.LName, ', ',patient.FName, ' ', patient.MiddleI) AS Patient,
pl.ProcDate,
pv.Abbr,
pc.ProcCode,
pc.AbbrDesc,
toothnum,
surf,
pl.ProcFee
FROM patient
INNER JOIN procedurelog pl
ON patient.PatNum = pl.PatNum
INNER JOIN procedurecode pc
ON pl.CodeNum = pc.CodeNum
INNER JOIN provider pv
ON pl.ProvNum = pv.ProvNum
WHERE pl.ProcStatus = 2 -- Complete
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
ORDER BY ProcDate,patient.LName, patient.FName ASC;
List of Guarantor's Fname and LName, Guarantor's Email address and the FName of those patient under that guarantor's account - excludes inactive patients
/*120*/
SELECT g.LName, g.FName, p.FName AS 'Patient', g.eMail
FROM patient p
INNER JOIN patient g ON p.Guarantor = g.PatNum
WHERE p.PatStatus = 0
AND g.EMail LIKE ('%@%')
ORDER BY g.LName, g.FName;
List of active patients referred to you or from you in date range - For Versions 17.1 and greater. Please
update your version accordingly.
/*121 List of active patients referred to you or from you in date range.*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/04/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2018-01-01' , @ToDate='2018-01-05';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SET @pos = 0;
SELECT @pos := @pos + 1 AS 'Count', -- Count returned rows
A.* -- Display all fields from FROM subquery
FROM ( -- Begin FROM subquery
SELECT p.PatNum, -- Get patient numbers/names
CONCAT(rf.LName, ", ", rf.FName) AS Referral, -- Get referral last and first name
ra.RefType, -- Returns True if their referral is referred from the referral, otherwise False
DATE_FORMAT(ra.RefDate, '%m/%d/%Y') AS RefDate -- Get the date referral was made
FROM patient p -- Start with patients
INNER JOIN refattach ra ON p.PatNum = ra.PatNum -- Get attached referrals for the patient
AND ra.RefDate BETWEEN @FromDate AND @ToDate -- For referrals created in your date range
INNER JOIN referral rf ON ra.ReferralNum = rf.ReferralNum -- Get the referrals information
AND p.PatStatus = '0' -- Only patients with a "Patient" status
) A -- End FROM subquery
ORDER BY A.Referral -- Sort in order of referral name
Count of active patients
with each insurance plan (not subscribers) - NOTE:will not sum to total patients as some patients may have no insurance some may have more than one
/*122*/ SELECT carrier.CarrierName, COUNT(DISTINCT p.PatNum) AS 'Patients'
FROM carrier
INNER JOIN insplan ip ON carrier.CarrierNum = ip.CarrierNum
INNER JOIN inssub ib ON ib.PlanNum = ip.PlanNum
INNER JOIN patplan pp ON pp.InsSubNum = ib.InsSubNum
INNER JOIN patient p ON pp.PatNum = p.PatNum
WHERE p.PatStatus = 0
GROUP BY CarrierName
ORDER BY CarrierName;
Patients seen in time period with column indicating recall and non recall procs and if the apt was recall only - SEE REPLICATION WARNING for versions before 14.3.1. Useful for dentists trying to sell non recall procs
/*123 Counts procedures as recall where they match list*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @pos = 0;
SET @FromDate = '2008-06-01' , @ToDate = '2008-06-31';/*Change Dates here */
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp
SELECT PatNum,
ProcDate,
ProcCode,
ProcNum,
(CASE
WHEN ProcCode IN ('D0120', 'D1120', 'D1110', 'D1203', 'D1204', 'D0270', 'D0272', 'D0273', 'D0274', 'D0330')
THEN 1
ELSE 0 END) AS SetRecall
FROM procedurelog pl
INNER JOIN procedurecode pc ON pl.CodeNum = pc.CodeNum
WHERE (ProcDate BETWEEN @FromDate AND @ToDate)
AND ProcStatus = 2;
/* now get summed results as cannot do a case statement on grouped procs*/
SELECT @pos := @pos + 1 as 'Count',
PatNum,
DATE_FORMAT(MAX(ProcDate), '%m/%d/%Y') AS LastProcDate,
(COUNT(SetRecall)) AS 'ProcCount',
SUM(SetRecall) AS 'Recall Procs',
(CASE WHEN ((COUNT(SetRecall) - SUM(SetRecall)) = 0) THEN 'Yes' ELSE 'No' END) AS 'Recall Only?'
FROM tmp
GROUP BY PatNum
ORDER BY LastProcDate;
DROP TABLE IF EXISTS tmp;
CommLog Entries for Date Range -
/*124*/
SET @pos = 0, @FromDate = '2008-06-01' , @ToDate = '2008-06-31';
SELECT @pos := @pos + 1 as 'Count', commlog.PatNum, CommDateTime, Note, ItemName
FROM commlog
INNER JOIN definition ON commlog.CommType = definition.DefNum
INNER JOIN patient ON commlog.PatNum = patient.PatNum
WHERE DATE(CommDateTime) BETWEEN @FromDate AND @ToDate
ORDER BY patient.LName, patient.FName
Hygiene Production For Time Period -
/*125*/ SET @FromDate = '2008-06-01' , @ToDate = '2008-06-30';
SELECT CONCAT(patient.LName, ', ', patient.FName, ' ', patient.MiddleI) As Patient,
pl.ProcDate,
pv.Abbr,
pc.ProcCode,
pc.AbbrDesc,
pl.ProcFee
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum = pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum = pc.CodeNum
INNER JOIN provider pv ON pl.ProvNum = pv.ProvNum
WHERE pl.ProcStatus = '2'
AND (pl.ProcDate >= @FromDate
AND pl.ProcDate <= @ToDate)
AND pc.IsHygiene = 1
ORDER BY ProcDate, patient.LName, patient.FName ASC;
Hygiene Summed by Procedure for Date range -
/*126 Hygiene Summed by Procedure for Date range*/
SET @FromDate = '2016-01-01' , @ToDate = '2016-01-31'; -- Allows for a date range
SELECT COUNT(*), -- Counts all returned rows
pv.Abbr, -- Shows the provider abbreviation
pc.ProcCode, -- Shows the procedure code
pc.AbbrDesc, -- Shows the procedure code abbreviation
AVG(pl.ProcFee) AS '$Ave. Fee', -- Averages all the fees
SUM(pl.ProcFee) AS '$Tot. Prod' -- Sums up all the fees for a gross total
FROM patient -- Start with patients
INNER JOIN procedurelog pl ON patient.PatNum = pl.PatNum -- Includes procedures for the patient
AND pl.ProcStatus = 2 -- Only for completed procedures
AND (pl.ProcDate >= @FromDate AND pl.ProcDate <= @ToDate) -- Only for procedures completed in the date range
INNER JOIN procedurecode pc
ON pl.CodeNum = pc.CodeNum -- Includes procedure code information for the procedures
AND pc.IsHygiene = 1 -- Only for hygiene procedure codes
INNER JOIN provider pv ON pl.ProvNum = pv.ProvNum -- Includes provider info on the procedure
GROUP BY pc.ProcCode, pv.ProvNum -- One row per procedure code, per provider
ORDER BY ProcCode; -- In order by procedure code
List of active patients who have never had one of a user-defined list of procedures. Includes last visit date and total procs completed on patient. -
/*127*/
SELECT patient.PatNum,
DATE_FORMAT(MAX(ProcDate), '%m/%d/%Y') AS 'LastVisit',
COUNT(procedurelog.ProcNum) AS '# Procs Total'
FROM patient,
procedurelog
WHERE patient.PatNum NOT IN
(SELECT DISTINCT p.PatNum
FROM patient p
INNER JOIN procedurelog pl ON p.PatNum = pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum = pc.CodeNum
AND pc.ProcCode IN ('D0120', 'D1110', 'D1204') #edit procedures here
WHERE pl.ProcStatus = '2')
AND procedurelog.PatNum = patient.PatNum
AND procedurelog.ProcStatus = 2
AND patient.PatStatus = 0
GROUP BY procedurelog.PatNum
ORDER BY patient.LName, patient.FName
Count of Patients seen by each provider in date range - A patient will count once for each provider seen in the date range.
/*128 Count of Patients seen by each provider in date range*/
/*Query code written/modified: 02/21/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @StartDate= '2018-01-01', @EndDate= '2018-01-31';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT Abbr AS 'Provider',
COUNT(DISTINCT patient.PatNum) AS 'Patients Seen'
FROM patient
INNER JOIN procedurelog
ON procedurelog.PatNum = patient.PatNum
AND procedurelog.ProcStatus = 2 /*Completed Procedures*/
AND procedurelog.ProcDate BETWEEN @StartDate AND @EndDate
INNER JOIN provider
ON procedurelog.ProvNum = provider.ProvNum
WHERE patient.patstatus = 0 /*Active Patients*/
GROUP BY provider.Abbr
ORDER BY provider.Abbr
Guarantor
(Mailing)
info for New Patients with last seen Date of any dependent - SEE REPLICATION WARNING for versions before 14.3.1. for Pedo practice mailing letter to parents of new patients
/*129*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp
SELECT DISTINCT PatNum, Guarantor
FROM patient
WHERE PatStatus = 0;
/*this creates a tmp table with all patnums and the patnum of the guarantor*/
SET @pos = 0, @FromDate = '2008-07-01' , @ToDate = '2008-07-31';
SELECT @pos := @pos + 1 as 'Count',
LName,
FName,
DATE_FORMAT(MAX(ProcDate), '%m/%d/%Y') AS 'LastVisit',
Address,
Address2,
City,
State,
Zip
FROM patient
INNER JOIN tmp ON patient.PatNum = tmp.PatNum
INNER JOIN procedurelog ON procedurelog.PatNum = patient.PatNum
WHERE procedurelog.ProcStatus = 2
AND DateFirstVisit BETWEEN @FromDate AND @ToDate
GROUP BY tmp.Guarantor
ORDER BY LName;
DROP TABLE IF EXISTS tmp;
Patients not seen since a date plus proc count -
/*130*/
SELECT patient.PatNum,
DATE_FORMAT(MAX(ProcDate), '%m/%d/%Y') AS 'LastVisit',
COUNT(procedurelog.ProcNum) AS '# Procs Total'
FROM patient,
procedurelog
WHERE procedurelog.PatNum = patient.PatNum
AND procedurelog.ProcStatus = 2
AND patient.PatStatus = 0
GROUP BY procedurelog.PatNum
HAVING MAX(ProcDate) < '2008-01-15'
ORDER BY patient.LName, patient.FName
Subscribers
with insurance of specific employer(s) - If you only want one employer, duplicate name in both fields -
Replace the text between the % signs, you can use any part of employer name, not case specific
/*131 Subscribers with insurance of specific employers, uses insurance employer(s) you should repeat the employer name if you only want one, many times employers are listed more than one way, like HP and Hewlett Packard*/
SELECT EmpName AS 'Employer', PatNum, p.address, p.address2, p.city, p.state, p.zip
FROM patient p
INNER JOIN inssub iss ON iss.Subscriber = p.PatNum
INNER JOIN insplan i ON i.PlanNum = iss.PlanNum
INNER JOIN employer e ON i.EmployerNum = e.EmployerNum
WHERE p.PatStatus = 0
AND ((empname like ('%IBM%')) OR (empname like ('%Frijole Taco Stand%')))
ORDER By EmpName, p.lname;
Active patients who have never had any procedure(s)completed - note that active means that this is the status of those patients. The idea being that you may wish to review these accounts to follow up and try and schedule work or deactivate them.
/*132*/ SELECT p.PatNum FROM patient p
LEFT JOIN procedurelog pl ON p.PatNum=pl.PatNum AND ProcStatus=2
WHERE (pl.PatNum IS NULL) AND p.PatStatus=0
ORDER BY LName;
Outstanding insurance claims by Date of Service not including Preauths -
/*133*/
SELECT cl.PatNum, cl.DateService, cl.DateSent, ca.CarrierName, ca.Phone
FROM claim cl
INNER JOIN patient p ON p.PatNum = cl.PatNum
INNER JOIN insplan i ON i.PlanNum = cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum = i.CarrierNum
WHERE cl.ClaimStatus = 'S'
AND DateService < (CURDATE() - INTERVAL 30 DAY)
AND ClaimType <> 'PreAuth'
ORDER BY ca.CarrierName, p.LName;
Preauths recieved in last year but procedures not scheduled -
/*134*/
SELECT pl.PatNum,
pl.ProcFee,
pc.ProcCode,
c.DateReceived,
ca.CarrierName,
(SELECT SUM(InsPayEst)
FROM claimproc
WHERE claimproc.ProcNum = pl.ProcNum AND claimproc.Status = 2) AS 'InsPayEst'
FROM claim c
INNER JOIN claimproc cp ON c.ClaimNum = cp.ClaimNum AND c.ClaimType = 'PreAuth' AND c.ClaimStatus = 'R'
INNER JOIN insplan i ON cp.PlanNum = i.PlanNum
INNER JOIN carrier ca ON i.CarrierNum = ca.CarrierNum
INNER JOIN procedurelog pl ON cp.ProcNum = pl.ProcNum
INNER JOIN procedurecode pc ON pl.CodeNum = pc.CodeNum
WHERE AptNum = 0
AND DateReceived > (CURDATE() - INTERVAL 12 MONTH)
AND pl.ProcStatus = 1;
Completed procedures for date range, limited to specified procedures - Enter procedure codes separated by a | character. If left blank this will search for all ProcCodes. Must not end with a |
/*135 Completed procedures for a date range, limited to specific procedures*/
/*Query code written/modified: 02/20/2018*/
SET @FromDate = '2017-01-01' , @ToDate = '2018-01-31';
SET @Codes = 'D0220|D0110|D1234' /*Enter procedure codes here, separated by a | character. If left blank this will search for all ProcCodes. Must not end with a | */;
/*---DO NOT MODIFY BELOW THIS LINE---*/
SET @Codes = (CASE WHEN @Codes = '' THEN '^' ELSE CONCAT('^', REPLACE(@Codes, '|', '$|^'), '$') END);
SELECT CONCAT(patient.LName, ', ', patient.FName, ' ', patient.MiddleI) AS Patient,
pl.ProcDate,
pv.Abbr,
pc.ProcCode,
pc.AbbrDesc,
ToothNum,
FORMAT(pl.ProcFee * (pl.UnitQty + pl.BaseUnits), 2) AS ProcFee_
FROM patient
INNER JOIN procedurelog pl
ON patient.PatNum = pl.PatNum
AND pl.ProcStatus = 2 /*Completed procedures*/
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
INNER JOIN procedurecode pc
ON pl.CodeNum = pc.CodeNum
AND pc.ProcCode REGEXP @Codes
INNER JOIN provider pv
ON pl.ProvNum = pv.ProvNum
ORDER BY ProcDate, patient.LName, patient.FName ASC;
Returns all notes for procedures in given range (check 98) - SEE REPLICATION WARNING for versions before 14.3.1. Great for reviewing the days notes, export to view full, longer notes
/*136*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @pos = 0, @FromDate = '2013-01-17' , @ToDate = '2013-01-17';
DROP TABLE IF EXISTS tmp1;
CREATE TABLE tmp1
SELECT pl.PatNum,
ProcDate,
Max(pn.EntryDateTime) AS 'NoteEntered',
pc.ProcCode,
pl.ProcNum,
p.LName
FROM procedurelog pl
INNER JOIN procedurecode pc ON pl.CodeNum = pc.CodeNum
INNER JOIN procnote pn ON pl.ProcNum = pn.ProcNum
INNER JOIN patient p ON pl.PatNum = p.PatNum
WHERE DATE(pn.EntryDateTime) BETWEEN @FromDate AND @ToDate
AND LENGTH(Note) > 0
GROUP BY pn.ProcNum;
SELECT @pos := @pos + 1 as 'Count', tmp1.PatNum, tmp1.ProcDate, tmp1.ProcCode, tmp1.NoteEntered, pn.Note
FROM tmp1
INNER JOIN procnote pn ON tmp1.ProcNum = pn.ProcNum AND (pn.EntryDateTime) = (tmp1.NoteEntered)
ORDER BY tmp1.LName;
DROP TABLE IF EXISTS tmp1;
New Patients in Date Range with Date of last visit and Procedure Count -
/*137*/
SET @pos = 0, @FromDate = '2008-06-01' , @ToDate = '2008-06-31';
SELECT @pos := @pos + 1 as 'Count',
patient.PatNum,
LName,
FName,
DATE_FORMAT(MAX(ProcDate), '%m/%d/%Y') AS 'LastVisit',
COUNT(procedurelog.ProcNum) AS '# Procs Total'
FROM patient
INNER JOIN procedurelog ON procedurelog.PatNum = patient.PatNum
WHERE procedurelog.ProcStatus = 2
AND patient.PatStatus = 0
AND DateFirstVisit BETWEEN @FromDate AND @ToDate
GROUP BY procedurelog.PatNum
ORDER BY LName;
Patients with given insurance fee schedule-revised for new table 'feesched' -
/*138*/
SELECT carrier.CarrierName, p.PatNum, feesched.Description AS 'FeeSchedule'
FROM carrier
INNER JOIN insplan ip ON carrier.CarrierNum = ip.CarrierNum
INNER JOIN inssub iss ON ip.PlanNum = iss.PlanNum
INNER JOIN patplan pp ON iss.InsSubNum = pp.InsSubNum
INNER JOIN patient p ON pp.PatNum = p.PatNum
INNER JOIN feesched ON ip.FeeSched = feesched.FeeSchedNum
WHERE p.PatStatus = 0
AND feesched.Description LIKE ('%Standard%')
ORDER BY CarrierName;
Check secondary claims received in date range for writeoff amounts -
/*139*/ SET @pos = 0, @FromDate = '2008-06-01' , @ToDate = '2008-06-31';
SELECT @pos := @pos + 1 as 'Count',
cl.PatNum,
WriteOff,
cl.DateReceived,
ca.CarrierName,
ca.Phone
FROM claim cl
INNER JOIN patient p ON p.PatNum = cl.PatNum
INNER JOIN insplan i ON i.PlanNum = cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum = i.CarrierNum
WHERE cl.ClaimStatus = 'R'
AND DateReceived Between @FromDate and @ToDate
AND ClaimType = 'S'
ORDER BY cl.DateReceived;
Mailing List for patients with TP procs without a scheduled apt -
/*140*/
SELECT LName,
FName,
Address,
Address2,
City,
State,
Zip,
SUM(ProcFee)
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum = pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum = pc.CodeNum
LEFT JOIN appointment ap ON pl.AptNum = ap.AptNum
WHERE (isnull(ap.aptnum) OR AptStatus = 6 OR AptStatus = 3)
AND ProcStatus = 1
AND Length(Zip) > 1
AND PatStatus = 0
GROUP BY patient.PatNum
ORDER BY patient.LName, patient.FName ASC;
Recall information with e-mail -
/*141*/
SELECT p.LName, p.FName, p.BirthDate, p.BillingType, p.Email, r.DateDue, d.ItemName AS 'RecallStatus'
FROM patient p
INNER JOIN recall r ON p.PatNum = r.PatNum
LEFT JOIN definition d ON r.RecallStatus = d.DefNum
Count of complete appointments in date range -
/*142*/ SET @Start = '2008-08-01', @End = '2008-08-31';
SELECT Count(*)
FROM appointment
WHERE aptstatus = 2
AND AptDateTime BETWEEN @Start AND @End + INTERVAL 1 DAY;
Treatment planned procedures for patients with no scheduled apt with specified carrier - (see also #50 & #56)
/*143*/ SET @Carrier='%delta%';
SELECT CONCAT(LName, ', ',FName, ' ', MiddleI) As Patient,
pc.ProcCode as 'Code', abbrdesc as 'Description', ToothNum,
DATE_FORMAT(pl.ProcDate,'%m-%d-%Y') AS 'Date',
c.CarrierName, ProcFee
FROM carrier c
INNER JOIN insplan ip ON c.CarrierNum=ip.CarrierNum
INNER JOIN inssub ib ON ib.PlanNum=ip.PlanNum
INNER JOIN patplan pp ON ib.InsSubNum=pp.InsSubNum
INNER JOIN patient p ON pp.PatNum=p.PatNum
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
LEFT JOIN appointment ap ON pl.AptNum=ap.AptNum
WHERE (isnull(ap.aptnum) OR AptStatus=6 OR AptStatus=3)
AND ProcStatus=1 AND
c.CarrierName Like(@Carrier)
ORDER BY aptstatus, p.LName, p.FName ASC;
Treatment Planned procedures that were treatment planned in a specific date range and which provider treatment planned it -
/*144 Treatment Planned procedures that were treatment planned in a specific date range and which provider treatment planned it*/
SET @pos=0, @FromDate='2008-09-01' , @ToDate='2008-09-31';
SELECT @pos:=@pos+1 AS 'Count', A.*
FROM (
SELECT pa.PatNum,
pc.ProcCode AS 'Code', abbrdesc AS 'Description', ToothNum, DATE_FORMAT(pl.DateTP,'%m-%d-%Y') AS 'DateTP',
pr.Abbr, ProcFee
FROM patient pa
INNER JOIN procedurelog pl ON pa.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
INNER JOIN provider pr ON pl.ProvNum=pr.ProvNum
WHERE ProcStatus=1 AND
(DateTP BETWEEN @FromDate AND @ToDate)
ORDER BY DateTP,pa.LName, pa.FName ASC
)A;
Patient list of Sum of the Fees of all Treatment planned and all scheduled procedures - SEE REPLICATION WARNING for versions before 14.3.1.
/*145 Patient list of Sum of the Fees of all Treatment planned and all scheduled procedures*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS tmp1; /*Create a temp table containing summary info by procedure*/
CREATE TABLE tmp1
SELECT patient.PatNum, sum(ProcFee) AS '$Scheduled', 0 AS '$TP' FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
INNER JOIN appointment ap ON pl.AptNum=ap.AptNum
AND AptStatus=1 AND PatStatus=0 GROUP BY patient.PatNum;
INSERT INTO tmp1(PatNum, $Scheduled, $TP)
SELECT patient.PatNum, 0 AS '$Scheduled', sum(ProcFee) AS '$TP' FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
LEFT JOIN appointment ap ON pl.AptNum=ap.AptNum
WHERE (isnull(ap.aptnum) OR AptStatus=6 OR AptStatus=3)
AND PatStatus=0 GROUP BY patient.PatNum;
/*Display Results*/
SELECT PatNum, SUM($Scheduled), SUM($TP) FROM tmp1
GROUP BY PatNum HAVING SUM($TP)>0
ORDER BY SUM($TP) DESC;
DROP TABLE IF EXISTS tmp1;
Active patients who have had recall disabled -
/*146 Active patients who have had recall disabled*/
/*------------ DO NOT MODIFY BELOW THIS LINE ------------*/
/*Query code written/modified on: 05/06/2009, 05/13/2019:RobG*/
#
SET @pos=0;
SELECT
@pos:=@pos+1 AS 'Count',
rep.PatNum AS 'Pat Num',
rep.PatNum,
rep.Description,
rep.DatePrevious
FROM (
SELECT
p.PatNum,
DatePrevious,
rt.Description
FROM patient p
INNER JOIN recall r
ON p.PatNum = r.PatNum
INNER JOIN recalltype rt
ON r.RecallTypeNum = rt.RecallTypeNum
WHERE IsDisabled = 1 -- True
AND PatStatus = 0 -- Patient
ORDER BY p.LName, p.FName
) rep
Treatment Planned procedures that match codes in list, for patients with no scheduled appts containing the specified codes -
/*147 Treatment Planned procedures that match codes in list, for patients with no scheduled appts containing the specified codes*/
/*Put desired list into SQL below, like ('D0120','D0140','D0220','D1223')*/
SELECT CONCAT(LName, ', ',FName, ' ', MiddleI) AS Patient,
pc.ProcCode AS 'Code',
pc.AbbrDesc AS 'Description',
pl.ToothNum,
DATE_FORMAT(pl.ProcDate,'%m-%d-%Y') AS 'ProcDate',
DATE_FORMAT(pl.DateTP,'%m-%d-%Y') AS 'DateTP',
ap.AptStatus,
pl.ProcFee
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
LEFT JOIN appointment ap ON pl.AptNum=ap.AptNum
WHERE (ISNULL(ap.AptNum) OR ap.AptStatus=6 OR ap.AptStatus=3)
AND pl.ProcStatus=1
AND patient.PatStatus=0
AND (pc.ProcCode IN('D0120','D0140','D0220'))
ORDER BY ap.AptStatus, patient.LName, patient.FName ASC;
Daily procedures call list - Runs for 'today'
/*148 Daily procedures call list*/
SELECT pl.ProcDate,pa.PatNum, AbbrDesc,pr.Abbr, pa.HmPhone, pa.WirelessPhone, pa.WkPhone
FROM patient pa,procedurecode pc, provider pr, procedurelog pl
LEFT JOIN claimproc ON pl.ProcNum=claimproc.ProcNum
AND claimproc.Status='7'
WHERE pl.ProcStatus = '2'
AND pl.CodeNum=pc.CodeNum
AND pa.PatNum=pl.PatNum
AND pr.ProvNum=pl.ProvNum
AND pl.ProcDate =CURDATE()
ORDER BY pa.PatNum
Insurance estimates and paid amounts of claims that were created in Date Range -
/*149 Insurance estimates and paid amounts of claims that were created in Date Range*/
SET @pos=0, @FromDate='2008-09-01' , @ToDate='2008-09-31';
SELECT @pos:=@pos+1 as 'Count',c.PatNum, c.DateService, c.ClaimStatus, c.DateSent, ca.CarrierName, c.InsPayEst, c.InsPayAmt FROM claim c
INNER JOIN insplan i ON c.PlanNum = i.PlanNum
INNER JOIN carrier ca ON i.CarrierNum=ca.CarrierNum
INNER JOIN patient p ON c.PatNum=p.PatNum
WHERE c.DateService BETWEEN @FromDate AND @ToDate
ORDER BY p.LName, p.FName;
End of day call back list for completed procedures - can be edited to only include certain procedures by using pc.ProcCode IN ('D1234', 'D5678')
/*150 End of day call back list for completed procedures*/
SELECT pl.ProcDate,pa.PatNum, AbbrDesc,pr.Abbr, pa.HmPhone, pa.WirelessPhone, pa.WkPhone
FROM patient pa,procedurecode pc, provider pr, procedurelog pl
LEFT JOIN claimproc ON pl.ProcNum=claimproc.ProcNum
AND claimproc.Status='7'
WHERE pl.ProcStatus = '2'
AND pl.CodeNum=pc.CodeNum
AND pa.PatNum=pl.PatNum
AND pr.ProvNum=pl.ProvNum
AND pl.ProcDate =CURDATE()
ORDER BY pa.PatNum
Patients who have given carrier with date of last treatment - limits to last treatment being before or after a given date, as is shows after ...As written only shows patients seen after 2007
/*151 Patients who have given carrier with date of last treatment */
Set @Carrier='%Delta%', @SeenAfterDate='2009-12-31';
SELECT p.PatNum, DATE_FORMAT(MAX(ProcDate),'%m/%d/%Y') AS 'LastVisit', COUNT(pl.ProcNum) AS '# Procs Total', c.CarrierName
FROM carrier c
INNER JOIN insplan ip ON c.CarrierNum=ip.CarrierNum
INNER JOIN inssub ib ON ib.PlanNum=ip.PlanNum
INNER JOIN patplan pp ON ib.InsSubNum=pp.InsSubNum
INNER JOIN patient p ON pp.PatNum=p.PatNum
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
WHERE pl.ProcStatus=2 AND p.PatStatus=0 AND
c.CarrierName Like(@Carrier)
GROUP BY pl.PatNum
HAVING MAX(ProcDate)>@SeenAfterDate
ORDER BY p.LName, p.FName;
Addresses (with insurance) of active patients with tp procs with no sched apt -
/*154 Addresses (with insurance) of active patients with tp procs with no sched apt*/
SELECT LName,FName, MiddleI,Address, Address2, City, State, Zip FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum AND ProcStatus=1
LEFT JOIN appointment ap ON patient.PatNum=ap.PatNum AND (ap.AptStatus=1 OR ap.AptStatus=6 )
WHERE ap.AptNum IS NULL AND patient.PatStatus=0 AND
LENGTH(ZIP)>4 AND
patient.HasIns='I'
GROUP BY patient.PatNum
ORDER BY LName, FName;
Addresses of active patients (with no insurance) with tp procs with no sched apt -
/*155 Addresses of active patients (with no insurance) with tp procs with no sched apt*/
SELECT LName,FName, MiddleI,Address, Address2, City, State, Zip FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum AND ProcStatus=1
LEFT JOIN appointment ap ON patient.PatNum=ap.PatNum AND (ap.AptStatus=1 OR ap.AptStatus=6 )
WHERE ap.AptNum IS NULL AND patient.PatStatus=0 AND
LENGTH(ZIP)>4 AND
patient.HasIns<>'I'
GROUP BY patient.PatNum
ORDER BY LName, FName;
Treatment Plans Master - SEE REPLICATION WARNING for versions before 14.3.1. This will give you a summary of all of your save treatment plans... See comments in query
/*156 Treatment Plans Master. This includes the following columns:
PatNum - Name or number of patient,
TPHeading - Name of treatment plan,
DateTP - The date the plan was created
Proposed- total fee of each saved TP (subtracts anticipated PPO discounts, total amount done ever and total tp does not take into account writeoffs)
NextVisit - Total fees of procedures that the patient accepted for her next visit,
Done - Total fees of completed procedures in TP, (subtracts anticipated PPO discounts, total amount done ever and total tp does not take into account writeoffs)
TotTP - Total amount of treatment planned work in actual chart (default TP)
DoneEver - Total fees of all completed procedures for patient,
Totals at the bottom are fairly meaningless, really they are, export to excel if you need to see
*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS tmp1;
/*sub sub sub SELECT becomes confusing, so a sub table of next appointments for all people with save treatment plans gets created first*/
CREATE TABLE tmp1
SELECT a1.PatNum,
a1.AptNum,
a1.AptDateTime
FROM appointment a1
INNER JOIN appointment a2 ON a1.PatNum=a2.PatNum
WHERE a1.AptStatus=1
AND a2.AptStatus=1
AND a2.AptDateTime>=CURDATE()
GROUP BY a1.AptNum, a1.AptDateTime
HAVING a1.AptDateTime=MIN(a2.AptDateTime);
/*now the main query*/
SELECT p.PatNum,
tp.Heading,
DATE_FORMAT(tp.DateTP,'%m-%d-%Y') AS DateTP,
SUM(pt.FeeAmt-pt.Discount) AS $Proposed,
(
SELECT SUM(pt1.FeeAmt)
FROM proctp pt1
INNER JOIN procedurelog pl1 ON pt1.ProcNumOrig=pl1.ProcNum
WHERE pt1.TreatPlanNum=tp.TreatPlanNum
AND pl1.AptNum IN (SELECT AptNum FROM tmp1 WHERE tmp1.PatNum=p.PatNum)
GROUP BY pt1.TreatPlanNum
) AS '$NextVisit',
(
SELECT SUM(pt1.FeeAmt-pt1.Discount)
FROM proctp pt1
INNER JOIN procedurelog pl ON pt1.ProcNumOrig=pl.ProcNum
WHERE pl.ProcStatus=2
AND tp.TreatPlanNum=pt1.TreatPlanNum
) AS '$Done',
(SELECT SUM(pl.ProcFee) FROM procedurelog pl WHERE pl.ProcStatus=1 AND pl.PatNum=p.PatNum) AS '$TotTP',
(SELECT SUM(pl.ProcFee) FROM procedurelog pl WHERE pl.ProcStatus=2 AND pl.PatNum=p.PatNum) AS '$DoneEver'
FROM patient p
INNER JOIN treatplan tp ON tp.PatNum=p.PatNum
INNER JOIN proctp pt ON pt.TreatPlanNum=tp.TreatPlanNum
/*Limit to current patients with saved treatment plans*/
WHERE p.PatStatus=0
/*If nothing on default (or actual) treatment plan, then the saved TPs are just detritus*/
AND (SELECT SUM(pl.ProcFee) FROM procedurelog pl WHERE pl.ProcStatus=1 AND pl.PatNum=p.PatNum)>0
GROUP BY tp.TreatPlanNum
ORDER BY p.LName, tp.DateTP;
DROP TABLE IF EXISTS tmp1;
Outstanding insurance claims by Date of Service, secondary claims ONLY -
/*158 Outstanding insurance claims by Date of Service, secondary claims ONLY*/
SELECT cl.PatNum,cl.DateService,cl.DateSent, ca.CarrierName, ca.Phone FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE cl.ClaimStatus='S' AND
DateService<(CURDATE()-INTERVAL 30 DAY) AND
ClaimType='S'
ORDER BY ca.CarrierName,p.LName;
Balance and Fee for every procedure for a given patient - (useful when entering procedure split payments)
/*159 Balance and Fee for every procedure for a given patient (useful when entering procedure split payments)*/
/*Query code written/modified: 04/14/2017*/
SET @PatNum=74491; /*Enter patient id here*/
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT pl.ProcDate,
ProcCode,
ToothNum,
pl.ProcFee $ProcFee_,
cp.DateCP,
IFNULL(cp.InsPayAmt,0) AS $InsPaid_,
IFNULL(cp.WriteOff,0) AS $InsWriteOff_,
ps.DatePay,
IFNULL(SUM(ps.SplitAmt),0) AS $PatPaid_,
IF((pl.ProcFee)-(IFNULL(cp.InsPayAmt,0)+IFNULL(cp.WriteOff,0)+IFNULL(SUM(ps.SplitAmt),0)) = 0, '0.00',
(pl.ProcFee)-(IFNULL(cp.InsPayAmt,0)+IFNULL(cp.WriteOff,0)+IFNULL(SUM(ps.SplitAmt),0))) AS $ProcBal_
FROM procedurelog pl
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
LEFT JOIN paysplit ps ON ps.ProcNum=pl.ProcNum
LEFT JOIN (
SELECT cp.ProcNum,
cp.DateCP,
SUM(cp.InsPayAmt) InsPayAmt,
SUM(cp.WriteOff) WriteOff
FROM claimproc cp
WHERE cp.PatNum = @PatNum
GROUP BY cp.ProcNum
) cp ON cp.ProcNum=pl.ProcNum
WHERE pl.ProcStatus=2 /*complete*/
AND pl.ProcFee>0 /*only fee>0*/
AND pl.PatNum=@PatNum
GROUP BY pl.ProcNum
ORDER BY pl.ProcDate;
Patients that have Service Year instead of Calander Year insurance benefit - with count of service year benefits
/*160 Patients that have Service Year instead of Calander Year insurance benefit*/
SELECT p.PatNum, c.CarrierName, COUNT(*) AS 'NumServYearBens'
FROM carrier c
INNER JOIN insplan ip ON c.CarrierNum=ip.CarrierNum
INNER JOIN inssub ib ON ip.PlanNum=ib.PlanNum
INNER JOIN patplan pp ON ib.InsSubNum=pp.InsSubNum
INNER JOIN patient p ON pp.PatNum=p.PatNum
INNER JOIN benefit b ON ip.PlanNum=b.PlanNum
WHERE p.PatStatus=0 AND
b.TimePeriod=1
GROUP BY p.PatNum, c.CarrierName
ORDER BY p.LName, p.FName, c.CarrierName;
Count number of Active patients in each billing type. -
/*161 Count number of Active patients in each billing type.*/
SELECT BillingType, COUNT(*)
FROM patient
WHERE PatStatus=0
GROUP BY BillingType;
Production and Income for a particular patient - (with adjustments, insurance income by inspay date and writeoffs)
/*162 Production and Income for a particular patient (with adjustments, insurance income by inspay date and writeoffs)
By more narrow date range if desired, as is will return all income and production for patient*/
SET @PatNum='2836', @FROMDate='' , @ToDate='2020-10-10';
SELECT
(SELECT SUM(InsPayAmt) FROM claim c WHERE c.PatNum=p.PatNum AND c.DateReceived BETWEEN @FROMDate AND @ToDate) AS '$InsProcPay',
(SELECT SUM(Writeoff) FROM claim c WHERE c.PatNum=p.PatNum AND c.DateReceived BETWEEN @FROMDate AND @ToDate) AS '$WriteOff',
(SELECT SUM(SplitAmt) FROM paysplit WHERE p.PatNum=paysplit.PatNum AND (DatePay BETWEEN @FROMDate AND @ToDate)) AS '$PatientPay',
(SELECT SUM(AdjAmt) FROM adjustment WHERE p.PatNum=adjustment.PatNum AND (adjdate BETWEEN @FROMDate AND @ToDate)) AS '$PatAdj',
SUM(pl.procfee) AS '$Production'
FROM patient p
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum AND pl.ProcStatus=2
WHERE p.PatNum=@PatNum AND pl.ProcDate BETWEEN @FROMDate AND @ToDate
GROUP BY p.PatNum;
List of active patients with each insurance plan (not just subscribers) includes only matching carrier(s) - Carrier Names and group names are cutoff for space consideration Check RAW button to show both PatNum and Patient Name
/*163 List of active patients with each insurance plan (not just subscribers), includes only matching carrier(s),
Carrier Names and group names are cutoff for space consideration
Check RAW button to show both PatNum and Patient Name*/
SET @CarrierName='%aetna%';
SELECT LEFT(carrier.CarrierName, 15) AS CarrierName, LEFT(GroupName, 15) AS GroupName,
(CASE WHEN ip.PlanType='c' THEN 'Capitation'
WHEN ip.PlanType='p' THEN 'PPO Percentage'
WHEN ip.PlanType='' THEN 'Category Percentage'
WHEN ip.PlanType='f' THEN 'Medicaid/Flat Copay'
ELSE 'Unknown' END) AS PlanType, p.PatNum, CONCAT(p.LName,', ',p.FName,' ',p.MiddleI) AS PatName, SubscriberId
FROM carrier
INNER JOIN insplan ip ON carrier.CarrierNum=ip.CarrierNum
INNER JOIN inssub ib ON ib.PlanNum=ip.PlanNum
INNER JOIN patplan pp ON pp.InsSubNum=ib.InsSubNum
INNER JOIN patient p ON pp.PatNum=p.PatNum
WHERE p.PatStatus=0 AND CarrierName LIKE @CarrierName
ORDER BY ip.PlanType, CarrierName, GroupName, p.LName;
Returns all treatment planned procedures for active patients without a scheduled OR planned apt, who were last seen in a given date range - SEE REPLICATION WARNING for versions before 14.3.1. with phone numbers, useful for those transitioning to planned appointments (this differs FROM #56 largely in that it is date limited and lists out the treatment)
/*164 Returns all treatment planned procedures for active patients without a scheduled OR planned apt, who were last seen in a given date range
with phone numbers, useful for those transitioning to planned appointments (this differs FROM #56 largely in that it is date limited and lists out the treatment)*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS tmp1;
DROP TABLE IF EXISTS tmp2;
SET @FROMDate='2008-06-15' , @ToDate='2008-10-10';
CREATE TABLE tmp1 AS SELECT patient.PatNum, CONCAT(LName, ', ',FName, ' ', MiddleI) AS PatName, HmPhone, WkPhone,
WirelessPhone AS Wireless, ProcFee, pc.ProcCode FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum AND ProcStatus=1
LEFT JOIN appointment ap ON patient.PatNum=ap.PatNum AND (ap.AptStatus=1 OR ap.AptStatus=6 )
WHERE ap.AptNum IS NULL AND patient.PatStatus=0;
CREATE TABLE tmp2 AS SELECT p.PatNum, DATE_FORMAT(MAX(ProcDate),'%m/%d/%Y') AS 'LastVisit', MAX(ProcDate) AS 'DateLast'
FROM patient p
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
WHERE pl.ProcStatus=2 AND p.PatStatus=0
GROUP BY pl.PatNum;
SELECT PatName,Left(HmPhone,15) AS HmPhone,Left(WkPhone,21) As WKPhone,Left(Wireless,15) AS Wireless, ProcCode, ProcFee AS '$Fee', LastVisit
FROM tmp1 INNER JOIN tmp2 ON tmp1.PatNum=tmp2.PatNum
WHERE DateLast BETWEEN @FROMDate AND @ToDate
ORDER BY PatName;
DROP TABLE IF EXISTS tmp1;
DROP TABLE IF EXISTS tmp2;
New patients for a time span, defined more tightly. New patient is someone who comes in once for a exam with a specific code - (in this case D0150) and has completed procedures on subsequent visit, (you must use code only for new patients, e.g. D0150N, 6th digit will not go to ins)
/*165 New patients for a time span, defined more tightly. New patient is someone who comes in once for an exam with a specific code (in this case D0150)
and has at least one completed charged procedures on a subsequent visit. This is not a great criteria for new patients, as it requires a second visit and so should only be used on recent date ranges*/
SET @FromDate='2008-03-01',@ToDate='2008-09-31';
SET @CompExamCode='D0150';
SET @pos=0;
SELECT @pos:=@pos+1 AS numberofpatients, B.* FROM
(
SELECT p.PatNum,DATE_FORMAT(A.CompExamDate,'%m-%d-%Y') AS CompExamDate, DATE_FORMAT(MIN(pl.ProcDate),'%m-%d-%Y') AS SecondVisit
FROM patient p
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum AND pl.ProcStatus=2 AND pl.ProcFee>0
INNER JOIN
(
SELECT pl.PatNum, MIN(pl.ProcDate) AS CompExamDate
FROM procedurelog pl
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
WHERE pc.ProcCode=@CompExamCode
AND (pl.ProcDate BETWEEN @FromDate AND @ToDate)
GROUP BY pl.PatNum
) A ON p.PatNum=A.PatNum AND A.CompExamDate<pl.ProcDate
WHERE p.PatStatus=0
GROUP BY p.PatNum
ORDER BY A.CompExamDate
) B;
Recieved insurance claims FROM a particular carrier showing estimated vs paid amounts -
/*166 Recieved insurance claims FROM a particular carrier showing estimated vs paid amounts*/
SET @Carrier='%Blue Cross%';
SELECT cl.PatNum,cl.DateSent, ca.CarrierName, ca.Phone, cl.ClaimStatus, cl.InsPayEst,InsPayAmt FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE cl.ClaimStatus='R' AND ca.CarrierName LIKE @Carrier
ORDER BY ca.CarrierName,p.LName;
On Hold insurance claims -
/*167 On Hold insurance claims*/
SELECT cl.PatNum,cl.DateSent, ca.CarrierName, ca.Phone, cl.ClaimStatus, cl.InsPayEst,InsPayAmt FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE cl.ClaimStatus='H'
ORDER BY ca.CarrierName,p.LName;
Patients seen in date range who have had non-diagnostic work - SEE REPLICATION WARNING for versions before 14.3.1. (procedure codes not starting with D0) Mailing list limits to one person per guarantor and to those who have zip codes
/*168 Patients seen in date range year who have had non-diagnostic work (procedure codes not starting with D0)
Mailing list limits to one person per guarantor and to those who have zip codes*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp SELECT DISTINCT PatNum, Guarantor FROM patient WHERE PatStatus=0;
SET @pos=0, @FromDate='2007-09-01' , @ToDate='2008-09-31';
SELECT @pos:=@pos+1 as 'Count', LName, FName, Address, Address2, City, State, Zip FROM patient
INNER JOIN tmp ON patient.PatNum=tmp.PatNum
INNER JOIN procedurelog ON procedurelog.PatNum=patient.PatNum
INNER JOIN procedurecode pc ON procedurelog.CodeNum=pc.CodeNum
WHERE procedurelog.ProcStatus=2
AND ProcDate BETWEEN @FromDate AND @ToDate
AND Length(Zip)>4
AND ProcCode NOT LIKE ('D0%')
GROUP BY tmp.Guarantor
ORDER BY LName;
DROP TABLE IF EXISTS tmp;
Daily Patient Payment Report - Cannot Export Patient payment report as of version 6.0.4, so this is a way to get the data exported
/*169 Daily Patient Payment Report*/
SET @date='2008-10-01';
SELECT PayDate,ItemName As 'Pay Type',PayAmt,CheckNum,BankBranch
FROM payment INNER JOIN definition ON payment.PayType=definition.DefNum
WHERE PayDate = @date
UNION
SELECT Date(@date) AS 'PayDate',CONCAT('Tot ', definition.ItemName) AS 'Pay Type',
SUM(paysplit.SplitAmt) AS PayAmt,'none','none'
FROM payment,definition,paysplit
WHERE paysplit.DatePay=@date
AND payment.PayNum=paysplit.PayNum
AND definition.DefNum=payment.PayType
GROUP BY payment.PayType
UNION
SELECT Date(@date) AS 'PayDate','Tot InsChecks' AS 'Pay Type',
SUM(claimproc.InsPayAmt) AS PayAmt ,'none','none'
FROM claimproc
WHERE claimproc.DateCP=@date
AND (claimproc.Status=1 OR claimproc.Status=4)
ORDER BY 'Pay Type';
Active Patients listed with Insurance Carrier -
/*170 Active Patients listed with Insurance Carrier*/
SELECT p.PatNum,carrier.CarrierName
FROM carrier
INNER JOIN insplan ip ON carrier.CarrierNum=ip.CarrierNum
INNER JOIN inssub ib ON ib.PlanNum=ip.PlanNum
INNER JOIN patplan pp ON ib.InsSubNum=pp.InsSubNum
INNER JOIN patient p ON pp.PatNum=p.PatNum
WHERE p.PatStatus=0
ORDER BY CarrierName,p.LName, p.FName;
Lists all patients with billing type indicated and how much they have paid total, ever - NOTE: user inputs any part of billing type, replace CASH with your billing type
/*171 Lists all patients with billing type indicated and how much they have paid total, ever
NOTE: user inputs any part of billing type, replace CASH with your billing type*/
SELECT p.PatNum, ItemName, SUM(SplitAmt) AS TotPayAmt,PatStatus
FROM patient p
INNER JOIN paysplit ps ON p.PatNum=ps.PatNum
INNER JOIN definition d ON p.BillingType=d.DefNum
WHERE ItemName LIKE('%CASH%')
GROUP BY p.PatNum
ORDER BY p.LName,FName;
Insurance Payments recieved in a given period, summed by carrier -
/*172 Insurance Payments recieved in a given period, summed by carrier*/
SET @FromDate='2008-01-01', @ToDate='2008-01-31' ;/*change dates here*/
SELECT c.CarrierName AS 'Carrier', SUM(cp.InsPayAmt) AS '$PaymentEntered'
FROM insplan ip
INNER JOIN carrier c ON c.CarrierNum=ip.CarrierNum
INNER JOIN claimproc cp ON ip.PlanNum=cp.PlanNum
WHERE
(cp.DateCP BETWEEN @FromDate AND @Todate) AND
(cp.Status=1 OR cp.Status=4)/*payment or supplemental payment*/
GROUP BY c.CarrierName;
Insurance Payments entered and Checks recieved in a given period - not summed by carrier, useful for finding discrepancies*
/*173 Insurance Payments entered and Checks recieved in a given period, not summed by carrier, useful for finding discrepancies*/
SET @FromDate='2008-01-01', @ToDate='2008-01-31' ;/*change dates here*/
SELECT c.CarrierName,cp.PatNum, cp.InsPayAmt AS '$PaymentEntered', (SELECT SUM(cpy.CheckAmt) FROM claimpayment cpy WHERE cpy.CarrierName=c.CarrierName AND cpy.CheckDate BETWEEN @FromDate AND @Todate) AS '$CheckTotals'
FROM insplan ip
INNER JOIN carrier c ON c.CarrierNum=ip.CarrierNum
INNER JOIN claimproc cp ON ip.PlanNum=cp.PlanNum
WHERE
(cp.DateCP BETWEEN @FromDate AND @Todate) AND
(cp.Status=1 OR cp.Status=4)
ORDER BY c.CarrierName;
Last visit before given date for all active patients with phone numbers -
/*174 Last visit before given date for all active patients with phone numbers*/
SET @BeforeDate='2016-01-02';
SELECT p.PatNum,
WkPhone,
HmPhone,
WirelessPhone AS CellPhone,
LastVisit.MaxProcDate AS DateLastVisit,
@BeforeDate AS DateBefore
FROM patient p
INNER JOIN (
SELECT pl.PatNum, MAX(pl.ProcDate) AS MaxProcDate
FROM procedurelog pl
WHERE pl.ProcStatus=2
GROUP BY pl.PatNum
HAVING MAX(pl.ProcDate)<=@BeforeDate
) LastVisit ON p.PatNum=LastVisit.PatNum
WHERE PatStatus=0
GROUP BY p.PatNum
ORDER BY p.LName,p.FName;
Patients of specifed age range and gender -
/*175 Patients of specifed age range and gender*/
SET @Young='1', @Old='100'; #Change age range here.
SET @Gender='1'; #Change gender here. 0-Male, 1-Female, 2-Unknown
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count', PatNum,
(YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) AS 'Age',
(CASE WHEN Gender=0 THEN 'M' WHEN Gender=1 THEN 'F' ELSE 'U' END) AS 'Gender'
FROM patient
WHERE ((YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5))) BETWEEN @Young AND @Old
AND Gender=@Gender
AND PatStatus=0
ORDER BY LName, FName;
Patients (Active) that have Service Year instead of Calander Year insurance benefits -
/*176 Patients (Active) that have Service Year instead of Calendar Year insurance benefits*/
/*Showing the month the insurance plan was renewed*/
/*Query code written/modified: 06/03/2016*/
SELECT p.PatNum, -- Shows patient
c.CarrierName, -- Shows the patients current primary insurance carrier
ip.MonthRenew -- Shows the month in which the patients insurance plan renews
FROM carrier c -- Start with insurance carriers
INNER JOIN insplan ip ON c.CarrierNum=ip.CarrierNum -- Include insurance plans for the carrier
INNER JOIN inssub ib ON ip.PlanNum=ib.PlanNum -- Include the subscriber on the insurance plans information
INNER JOIN patplan pp ON ib.InsSubNum=pp.InsSubNum -- Show the patient the plan is for (Can be different from subscriber)
INNER JOIN patient p ON pp.PatNum=p.PatNum -- Include the patient information for the insurance plan
INNER JOIN benefit b ON ip.PlanNum=b.PlanNum -- Include the benefit information for the insurance plan
WHERE p.PatStatus=0 -- Only for active patients (Patient status)
AND b.TimePeriod=1 -- Only for patients with a Month renewal vs. Calendar year
GROUP BY p.PatNum, c.CarrierName -- One row per patient per carrier
ORDER BY ip.MonthRenew, p.LName, p.FName, c.CarrierName; -- Showing in order of month renewal, patient name, then carrier
Active Patients who have had a particular proc completed relative to Active patients who have had any proc completed within a given date range -
/*177 Active Patients who have had a particular proc completed relative to Active patients who have had any proc completed
within a given date range*/
SET @CodeCompleted='D0120%';/*change code here*/
SET @FromDate='2008-01-01', @ToDate='2008-12-31' ;/*change dates here*/
SELECT
(SELECT COUNT(DISTINCT p.PatNum)
FROM procedurelog pl
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
INNER JOIN patient p ON p.PatNum=pl.PatNum
WHERE pl.ProcStatus=2 AND p.PatStatus=0 AND
pc.ProcCode LIKE(@CodeCompleted) AND (ProcDate Between @FromDate AND @ToDate)) AS 'PatsCompParticProc',
(SELECT COUNT(DISTINCT p.PatNum)
FROM procedurelog pl
INNER JOIN patient p ON p.PatNum=pl.PatNum
WHERE pl.ProcStatus=2 AND p.PatStatus=0 AND (ProcDate Between @FromDate AND @ToDate)) AS 'ActPatients',
FORMAT(100*(SELECT (PatsCompParticProc / ActPatients)),1) AS '% with proc';
Patient count by Zipcode, with at least 1 completed procedure - limits to count(zipcodes)>3 as outliers, can be changed to 0 to include all
/*178 Patient count by Zipcode, with at least 1 completed procedure,
limits to count(zipcodes)>3 as outliers, can be changed to 0 to include all*/
SELECT LEFT(Zip,5) AS ZipCode, COUNT(DISTINCT p.PatNum) AS 'Patients'
FROM procedurelog pl
INNER JOIN patient p ON p.PatNum=pl.PatNum
WHERE pl.ProcStatus=2 AND p.PatStatus=0
GROUP BY ZipCode
HAVING patients>3;
Patient count by city, with at least 1 completed procedure -
/*179 Patient count by city, with at least 1 completed procedure*/
SELECT City, COUNT(DISTINCT p.PatNum) AS 'Patients'
FROM procedurelog pl
INNER JOIN patient p ON p.PatNum=pl.PatNum
WHERE pl.ProcStatus=2 AND p.PatStatus=0
GROUP BY City;
Patients without any recall -
/*180 Patients without any recall*/
SELECT PatNum FROM patient p WHERE p.PatNum NOT IN (SELECT PatNum FROM recall);
Guarantors (heads of households) of patients with no ins - with address
/*181 Guarantors (heads of households) of patients with no ins, with address*/
SELECT g.LName, g.FName, g.Address, g.Address2, g.City, g.Zip
FROM patient p INNER JOIN patient g ON p.Guarantor=g.PatNum
WHERE p.PatStatus=0/*Active patient*/ AND
p.HasIns<>'I'
GROUP BY g.PatNum;
Patient contact information verification list for appointments on given date - does not list state as that is not an issue if the zip and address are correct abbreviates to first 15 chars of carrier to save space
/*182 Patient contact information verification list for appointments on given date*/
/*does not list state as that is not an issue if the zip and address are correct*/
/*abbreviates to first 15 chars of carrier to save space*/
SET @Date='2008-09-29';/*set this date*/
SELECT p.PatNum, CONCAT(p.Address, p.Address2, " ", p.City, ", ", p.zip) AS Address,
CONCAT(HmPhone, " - ", WkPhone, " - ",WirelessPhone) AS 'Phone Numbers',
LEFT(CarrierName,15) AS 'Carrier (abbr)'
FROM appointment a
INNER JOIN patient p ON a.PatNum=p.PatNum
LEFT JOIN patplan pp ON p.PatNum=pp.PatNum AND ORDINAL=1
LEFT JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=ib.PlanNum
LEFT JOIN carrier c ON c.CarrierNum=ip.CarrierNum
WHERE DATE(a.AptDateTime) LIKE @Date
GROUP BY p.PatNum
ORDER BY LName, FName;
Completed Production in Appointments by Assistant -
/*183 Production by assistant, ONLY COUNTS completed production in appointments!*/
/*Query code written/modified: 03/21/2018*/
SET @FromDate='2017-01-01', @ToDate='2017-01-31' ;/*change dates here*/
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT ProcDate,
SUM(ProcFee*(pl.UnitQty+pl.BaseUnits)) AS $Production__,
CONCAT(e.FName, ' ',e.LName) AS Assistant
FROM procedurelog pl
INNER JOIN appointment a
ON a.AptNum=pl.AptNum
INNER JOIN employee e
ON a.Assistant=e.EmployeeNum
WHERE ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus = 2 /*Complete*/
GROUP BY ProcDate, a.Assistant;
Mailing list of guarantors of patients with a particular insplan - similar to 118 but also requires group number, returns the guarantors of all patients with plan, not the subscriber, also if you drop the plan it goes off the list
/*184 Mailing list of guarantors of patients with a particular insplan, similar to 118 but also requires group number, returns the guarantors of all
patients with plan, not the subscriber, also if you drop the plan it goes off the list*/
SET @Carrier='%comp%',@GroupNum='%6%';
SELECT DISTINCTROW gu.LName, gu.FName, gu.Address,
gu.Address2, gu.City, gu.zip, ca.CarrierName, ip.GroupNum
FROM patient p
INNER JOIN patplan pp ON pp.PatNum=p.PatNum
INNER JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
INNER JOIN insplan ip ON ip.PlanNum=ib.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=ip.CarrierNum
INNER JOIN patient gu ON p.Guarantor=gu.PatNum
WHERE ca.CarrierName LIKE(@Carrier) AND ip.GroupNum LIKE(@GroupNum)
ORDER BY ca.CarrierName, gu.LName;
Scheduled treatment for date range with apt notes includes fee and patient portion - SEE REPLICATION WARNING for versions before 14.3.1. useful for start of day apt query, also counts each porcedure as new patient procedure, recall procedure or other
/*186 Scheduled treatment for date range with apt notes includes fee and patient portion*/
/*useful for start of day apt query, also counts each porcedure as new patient procedure, recall procedure or other*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @FromDate='2009-01-01' , @ToDate='2009-01-30';
SET @NewProcCount=0, @RecallProcCount=0,@OtherProcCount=0;
DROP TABLE IF EXISTS tmp1;
CREATE TABLE tmp1 SELECT CONCAT(pv.LName, ', ',pv.FName) AS Provider, patient.PatNum,
pc.ProcCode, LEFT(AbbrDesc,13) AS AbbrDesc, LEFT(a.Note, 30) AS AbrAptNote, a.AptDateTime, pl.ProcFee AS $Fee, pl.ProcFee-(SUM(cp.InsPayEst)+SUM(cp.WriteOff)) AS $PatPort FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
INNER JOIN provider pv ON pv.ProvNum=pl.ProvNum
INNER JOIN appointment a ON a.AptNum=pl.AptNum AND AptStatus=1
LEFT JOIN claimproc cp ON cp.ProcNum=pl.ProcNum AND cp.Status=6 /*estimate*/
WHERE DATE(a.AptDateTime) >=@FromDate
AND DATE(a.AptDateTime)<=@ToDate
GROUP BY pl.ProcNum
ORDER BY pv.LName,pv.FName,a.AptDateTime;
SELECT (CASE WHEN ProcCode LIKE('D0150')/*put new patient only proc here, like comp exam*/
THEN @NewProcCount:=@NewProcCount+1 END) AS New,
(CASE WHEN ProcCode IN('D0120','D0120','D1110','D0140')/*put list of recall procs here, usually several procs, this could be queried, but recall types are several*/
THEN @RecallProcCount:=@RecallProcCount+1 END) AS Rec,
(CASE WHEN ProcCode NOT IN('D0120','D0120','D1110','D0140','D0150' )/*put list of procs to avoid for Other here*/
THEN @OtherProcCount:=@OtherProcCount+1 END) AS Oth,
Provider, tmp1.PatNum, AptDateTime, ProcCode, AbbrDesc, $Fee,$PatPort, AbrAptNote FROM tmp1;
DROP TABLE IF EXISTS tmp1;
New Patients with referral source, production diagnosed on first visit and total of payments for that day - For Versions 17.1 and greater. Please update your version accordingly. Does not fit quite on one page, export as a file and print.
/*187 New Patients with referral source, production diagnosed on first visit and total of payments for that day.*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/04/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2018-01-01' , @ToDate='2018-01-05';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count',
patient.DateFirstVisit,
patient.PatNum,
r.LName AS RefLName,
r.FName AS RefFName,
FORMAT((SELECT SUM(procedurelog.ProcFee) FROM procedurelog WHERE procedurelog.PatNum=patient.PatNum AND procedurelog.DateTP=DateFirstVisit AND procedurelog.ProcStatus!=6),2) AS 'Diagnosed' ,
FORMAT((SELECT SUM(SplitAmt) FROM paysplit WHERE DatePay=DateFirstVisit AND paysplit.PatNum=patient.PatNum),2) AS 'Accepted',
gender,
POSITION,
(YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) AS 'Age',
patient.Zip
FROM patient
LEFT JOIN refattach ra ON patient.PatNum=ra.PatNum
LEFT JOIN referral r ON r.ReferralNum=ra.ReferralNum
AND ra.RefType = 1 /*RefFrom*/
WHERE patient.PatStatus=0 /*Patient status*/
AND patient.DateFirstVisit BETWEEN @FromDate AND @ToDate
ORDER BY patient.DateFirstVisit, patient.LName, Patient.FName;
Subscribers grouped by employer - lists active patients who are subscribers with insurance through each employer like 67, but lists each subscriber instead of count
/*188 Subscribers grouped by employer, lists active patients who are subscribers with insurance through each employer*/
/*like 67, but lists each subscriber instead of count*/
SELECT EmpName AS 'Employer', PatNum FROM patient p
INNER JOIN inssub iss ON iss.Subscriber=p.PatNum
INNER JOIN insplan i ON i.PlanNum=iss.PlanNum
INNER JOIN employer e ON i.EmployerNum=e.EmployerNum
WHERE p.PatStatus IN (0,1) ORDER BY EmpName;
Adjustments of non-zero amounts - change date range as needed
/*190 Adjustments of non-zero amounts*/
SET @FromDate='2008-10-01' , @ToDate='2008-10-31';
SELECT AdjDate, PatNum, AdjAmt, AdjType, AdjNote
FROM adjustment
WHERE AdjDate
BETWEEN @FromDate AND @ToDate AND AdjAmt>0
EMail Addresses of Active Patients -
/*191 EMail Addresses of Active Patients*/
SELECT LName, FName, EMail
FROM patient
WHERE LENGTH(EMail)>3 AND PatStatus=0
ORDER BY LName, FName;
Email Addresses of Active Patients Seen in Date Range With Date Last Seen in Date Range -
/*192 Email Addresses of Active Patients Seen in Date Range With Date Last Seen in Date Range*/
SET @FromDate='2008-01-01' , @ToDate='2008-12-31';
SELECT p.PatNum,p.EMail, MAX(pl.ProcDate) AS 'LastSeen' FROM patient p,procedurelog pl
WHERE pl.PatNum=p.PatNum AND LENGTH(EMail)>3 AND
(pl.ProcDate BETWEEN @FromDate AND @ToDate)
AND pl.ProcStatus = '2' AND p.PatStatus=0
GROUP BY pl.PatNum;
Guarantors of patients not seen since a given date - SEE REPLICATION WARNING for versions before 14.3.1.
/*193 Guarantors of patients not seen since a given date*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @pos=0;
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp SELECT Guarantor, MAX(procdate) AS 'LastSeen' FROM patient,procedurelog
WHERE procedurelog.PatNum=patient.PatNum
AND procedurelog.procstatus = '2' AND PatStatus=0
GROUP BY procedurelog.PatNum
HAVING MAX(procdate) < '2008-05-01';
SELECT @pos:=@pos+1 AS 'Cnt', Date_Format(MAX(LastSeen),'%m/%d/%Y') AS 'Last Seen', LName, FName, Address, Address2, City, State, Zip FROM patient, tmp
WHERE patient.PatNum=tmp.Guarantor AND Length(ZIP)>4
GROUP BY patient.PatNum
ORDER BY LName;
DROP TABLE IF EXISTS tmp;
TP Procs with date of treatment plan of patients with no scheduled appointment with date of TP > given date - Like #50 with date limitation
/*194 TP Procs with date of treatment plan of patients with no scheduled appointment with date of TP > given date Like #50 with date limitation*/
/*Query code written/modified: 08/26/2016*/
SET @SinceDate='2016-01-01';
SELECT CONCAT(LName, ', ',FName, ' ', MiddleI) AS Patient,
pc.ProcCode AS 'Code',
abbrdesc AS 'Description',
ToothNum,
DATE_FORMAT(pl.ProcDate,'%m-%d-%Y') AS 'Date',
ap.AptStatus,
ProcFee
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
LEFT JOIN appointment ap ON pl.AptNum=ap.AptNum
WHERE (ISNULL(ap.aptnum) OR AptStatus=6 OR AptStatus=3)
AND pl.DateTP >= @SinceDate
AND ProcStatus=1
AND PatStatus=0
ORDER BY aptstatus, patient.LName, patient.FName ASC;
Patients with appointment in date range who had no procedure completed in the given interval prior to the scheduled appointment - Possible useful to show patients who need an extra reminder in order to show up, not hugely practical (add address2 if you use that field)
/*195 Patients with appointment in date range who had no procedure completed in the given interval prior to the scheduled appointment
Possible useful to show patients who need an extra reminder in order to show up, not hugely practical (add address2 if you use that field)*/
SET @pos=0, @StartDate='2008-11-13' , @EndDate='2008-12-13', @DaysSinceLastSeen=21;
SELECT @pos:=@pos+1 AS 'Count', LName,FName, Address, City, State, Zip, ap.AptDateTime,
(SELECT DATE_FORMAT(MAX(ProcDate),'%m/%d/%Y') FROM patient INNER JOIN procedurelog
ON procedurelog.PatNum=patient.PatNum WHERE procedurelog.ProcStatus=2 AND patient.PatStatus=0 AND p.PatNum=patient.PatNum
GROUP BY procedurelog.PatNum) AS LastVisit
FROM patient p
INNER JOIN appointment ap ON p.PatNum=ap.PatNum AND ap.AptStatus=1
WHERE (DATE(ap.AptDateTime) BETWEEN @StartDate AND @EndDate) AND
((SELECT MAX(ProcDate) FROM patient INNER JOIN procedurelog
ON procedurelog.PatNum=patient.PatNum WHERE procedurelog.ProcStatus=2 AND patient.PatStatus=0 AND p.PatNum=patient.PatNum
GROUP BY procedurelog.PatNum) < DATE_SUB(ap.AptDateTime, INTERVAL @DaysSinceLastSeen DAY))
ORDER BY aptstatus, p.LName, p.FName ASC;
Referred out patients in a date range, with specialty and status - For Versions 17.1 and greater. Please update your version accordingly.
/*196 Referred out patients in a date range, with specialty and status.*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/04/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @StartDate='2017-01-01' , @EndDate='2018-01-05';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SET @pos=0;
SELECT @pos:=@pos+1 AS 'RowCount',
A.*
FROM(
SELECT p.PatNum AS PatID,
p.LName AS PatLast,
p.FName AS PatFirst,
(CASE WHEN ra.RefToStatus=0 THEN 'None'
WHEN ra.RefToStatus=1 THEN 'Declined'
WHEN ra.RefToStatus=2 THEN 'Scheduled'
WHEN ra.RefToStatus=3 THEN 'Consulted'
WHEN ra.RefToStatus=4 THEN 'InTreatment'
ELSE 'Complete' END) AS 'Status',
r.LName AS RefLast,
r.FName AS RefFirst,
DATE_FORMAT(ra.RefDate,'%m/%d/%Y') AS RefDate,
def.ItemName AS 'Specialty'
FROM patient p
INNER JOIN refattach ra ON ra.PatNum = p.PatNum
AND ra.RefType = 0 /*RefTo*/
AND ra.RefDate BETWEEN @StartDate AND @EndDate
INNER JOIN referral r ON r.ReferralNum=ra.ReferralNum
INNER JOIN definition def ON def.DefNum=r.Specialty
WHERE p.PatStatus = 0 /*Patient status*/
)A
ORDER BY A.PatLast, A.PatFirst, A.RefDate;
Mailing Info Active patients who have no email address for either themselves or guarantor -
/*198 Mailing Info Active patients who have no email address for either themselves or guarantor*/
SELECT p.LName, p.FName, p.Address, p.Address2, p.City, p.State, p.Zip
FROM patient p
WHERE p.PatStatus=0 /*active*/
AND LENGTH(p.Zip)>4 /*valid zipcode*/
AND p.PatNum NOT IN(SELECT p.PatNum FROM patient p
INNER JOIN patient g ON g.PatNum=p.Guarantor
WHERE p.PatStatus=0 /*active patients*/
AND (p.Email LIKE '%@%' OR g.Email LIKE '%@%') /*with email for themselves or the guarantor*/)
ORDER BY p.LName, p.FName;
Phone Numbers for Active patients who have no email address for either themselves or guarantor - SEE REPLICATION WARNING for versions before 14.3.1. usefull in conjunction with #197
/*199 Phone Numbers for Active patients who have no email address for either themselves or guarantor*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp SELECT DISTINCT Guarantor, Email
FROM patient WHERE PatStatus =0 AND NOT (EMail LIKE ('%@%'));/*no patient email*/
SELECT LName, FName, HmPhone, WirelessPhone AS 'Cell', WkPhone FROM patient, tmp
WHERE patient.PatNum=tmp.Guarantor AND Length(ZIP)>4 ORDER BY LName;
DROP TABLE IF EXISTS tmp;
Patients of given appointment confirmation status having appointments of a certain date range that have been completed or are scheduled - replace date and set confirmed status to desired value, like @ConfirmStat='%confirmed%'
/*200 Patients of given appointment confirmation status having appointments of a certain date range that have been completed or are scheduled*/
/*replace date and set confirmed status to desired value, like @ConfirmStat='%confirmed%'*/
SET @pos=0, @StartDate='2008-09-13' , @EndDate='2008-12-13', @ConfirmStat='%not%';
SELECT @pos:=@pos+1 AS 'Count',
p.PatNum,
AptStatus,
DATE_FORMAT(AptDateTime, '%m/%d %l:%i %p ') AS AptSched,
LEFT(HmPhone, 15) AS HmPhone,
LEFT(WirelessPhone, 15) AS Cell,
LEFT(WkPhone, 15) AS WkPhone,
LEFT(Note, 20) AS 'AptNote(abr)'
FROM appointment a
INNER JOIN patient p ON a.PatNum=p.PatNum
INNER JOIN definition d ON a.Confirmed=d.DefNum
WHERE AptDateTime BETWEEN @StartDate AND @EndDate+INTERVAL 1 DAY
AND d.ItemName LIKE(@ConfirmStat)
AND AptStatus IN(1,2)
Recall info for patients with a specific insurance carrier, and specific date range, with date of last visit - Change dates and carrier AS needed in first line of query, for blue cross you could use @Carrier='%Blue%'
/*201 Recall info for patients with a specific insurance carrier, and specific date range, with date of last visit*/
/*Change dates and carrier AS needed in first line of query, for blue cross you could use @Carrier='%Blue%'*/
SET @pos=0, @StartDate='2010-06-01' , @EndDate='2010-12-01', @Carrier='%Delta%';
SELECT @pos:=@pos+1 AS 'Count',p.LName, p.FName, r.DateDue, d.ItemName AS 'RecallStatus',
(SELECT DATE_FORMAT(MAX(ProcDate),'%m/%d/%Y') FROM patient INNER JOIN procedurelog
ON procedurelog.PatNum=patient.PatNum WHERE procedurelog.ProcStatus=2 AND patient.PatStatus=0 AND p.PatNum=patient.PatNum
GROUP BY procedurelog.PatNum) AS 'LastVisit(any)', c.CarrierName
FROM patient p
INNER JOIN recall r ON p.PatNum=r.PatNum
INNER JOIN patplan pp ON pp.PatNum=p.PatNum
INNER JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
INNER JOIN insplan ip ON ip.PlanNum=ib.PlanNum
INNER JOIN carrier c ON c.CarrierNum=ip.CarrierNum
LEFT JOIN definition d ON r.RecallStatus=d.DefNum
WHERE (DateDue BETWEEN @StartDate AND @EndDate)
AND c.CarrierName LIKE(@Carrier)
ORDER BY p.LName, p.FName;
Patients seen in date range with age, zip and sum of fees for procs completed - (apx production, as it neglects writeoffs)
/*202 Patients seen in date range with age, zip and sum of fees for procs completed (apx production, neglects writeoffs) */
SET @pos=0, @StartDate='2008-12-01', @EndDate='2014-12-06';
SELECT @pos:=@pos+1 AS 'Count', A.*
FROM(
SELECT p.PatNum, p.Zip,
(YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) AS 'Age',
SUM(pl.ProcFee) AS $Prod_
FROM patient p INNER JOIN procedurelog pl ON pl.PatNum = p.PatNum
AND p.patstatus = '0'
AND (pl.ProcDate BETWEEN @StartDate AND @EndDate)
AND pl.ProcStatus=2
GROUP BY p.PatNum
ORDER BY p.LName, p.FName
)A;
Aging with Outstanding Insurance Claim info and Patient Balances -
/*203 Aging with Outstanding Insurance Claim info and Patient Balances*/
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count', p.PatNum AS PatID, p.PatNum, EstBalance AS '$Bal-', BalTotal AS '$Fam-',
Bal_0_30 AS '$0-30-', Bal_31_60 AS '$31-60-', Bal_61_90 '$61-90-', BalOver90 AS '$+90-',
(SELECT COUNT(*) FROM claim WHERE claim.PatNum=p.PatNum AND (claim.ClaimStatus='W' OR claim.ClaimStatus='S') AND claim.ClaimType<>'PreAuth') AS '#Clms',
(SELECT SUM(ClaimFee) FROM claim WHERE claim.PatNum=p.PatNum AND (claim.ClaimStatus='W' OR claim.ClaimStatus='S')AND claim.ClaimType<>'PreAuth') AS '$Clms-',
(SELECT SUM(InsPayEst) FROM claim WHERE claim.PatNum=p.PatNum AND (claim.ClaimStatus='W' OR claim.ClaimStatus='S')AND claim.ClaimType<>'PreAuth') AS '$InsEst-'
FROM patient p WHERE EstBalance<>0 OR BalTotal<>0 ORDER BY LName, FName;
Aging with Outstanding Insurance Claim info and Family Balances, Summed by Guarantor - SEE REPLICATION WARNING for versions before 14.3.1.
/*204 Aging with Outstanding Insurance Claim info and Family Balances, Summed by Guarantor*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @pos=0;
DROP TABLE IF EXISTS tmp1;
CREATE TABLE tmp1
SELECT p.PatNum, p.Guarantor, BalTotal ,
Bal_0_30, Bal_31_60, Bal_61_90, BalOver90,
(SELECT COUNT(*) FROM claim WHERE claim.PatNum=p.PatNum AND (claim.ClaimStatus='W' OR claim.ClaimStatus='S') AND claim.ClaimType<>'PreAuth') AS 'Claims',
(SELECT SUM(ClaimFee) FROM claim WHERE claim.PatNum=p.PatNum AND (claim.ClaimStatus='W' OR claim.ClaimStatus='S')AND claim.ClaimType<>'PreAuth') AS 'ClaimAmts',
(SELECT SUM(InsPayEst) FROM claim WHERE claim.PatNum=p.PatNum AND (claim.ClaimStatus='W' OR claim.ClaimStatus='S')AND claim.ClaimType<>'PreAuth') AS 'InsEst'
FROM patient p WHERE EstBalance<>0 OR BalTotal<>0;
SELECT @pos:=@pos+1 AS 'Count',tmp1.Guarantor,
SUM(tmp1.BalTotal) AS '$Fam-',
SUM(tmp1.Bal_0_30) AS '$0-30-',
SUM(tmp1.Bal_31_60) AS '$31-60-',
SUM(tmp1.Bal_61_90)AS '$61-90-',
SUM(tmp1.BalOver90)AS '$+90-',
SUM(tmp1.Claims) AS '#Claims',
SUM(tmp1.ClaimAmts) AS '$Claims-',
SUM(tmp1.InsEst) AS '$InsEst-'
FROM tmp1
INNER JOIN patient p ON tmp1.Guarantor=p.PatNum GROUP BY tmp1.Guarantor
ORDER BY p.LName, p.FName;
Mailing List of Guarantors of Patients seen in date range where sum of fees for procs completed (apx production, neglects writeoffs) for family exceeds some amount - say $200, (highly active patients)
/*205 Mailing List of Guarantors of Patients seen in date range
where sum of fees for procs completed (apx production, neglects writeoffs)
for family exceeds some amount, say $200, (highly active patients)*/
SET @pos=0, @StartDate='2008-01-01', @EndDate='2008-12-31';
SELECT @pos:=@pos+1 AS 'Count', g.LName, g.FName,
g.Address, g.Address2, g.City, g.State,g.Zip,
SUM(pl.ProcFee) AS '$Prod-'
FROM patient p
INNER JOIN procedurelog pl ON pl.PatNum = p.PatNum
INNER JOIN patient g ON g.PatNum=p.Guarantor
AND p.patstatus = '0'
AND (pl.ProcDate BETWEEN @StartDate AND @EndDate)
AND pl.ProcStatus=2
GROUP BY g.PatNum
HAVING SUM(pl.ProcFee)>400
ORDER BY g.LName, g.FName;
Birthdate query for mailing including year -
/*206 Birthdate query for mailing including year*/
SET @StartDate='1950-01-01', @EndDate='1990-02-31';
SELECT LName,FName,Address,Address2,City,State,Zip,Birthdate
FROM patient
WHERE (Birthdate BETWEEN @StartDate AND @EndDate)
AND PatStatus=0
ORDER BY LName,FName
Referred out patients by doctor - For Versions 17.1 and greater. Please update your version accordingly. Editable user date range filter for referral date.
/*207 Referred out patients by doctor, use large date range if none needed*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/04/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @StartDate='2018-01-01', @EndDate='2018-01-15';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SET @pos=0;
SELECT @pos:=@pos+1 AS COUNT,
p.PatNum AS PatID,
p.LName AS PatLast,
p.FName AS PatFirst,
(CASE WHEN ra.RefToStatus=0 THEN 'None'
WHEN ra.RefToStatus=1 THEN 'Declined'
WHEN ra.RefToStatus=2 THEN 'Scheduled'
WHEN ra.RefToStatus=3 THEN 'Consulted'
WHEN ra.RefToStatus=4 THEN 'InTreatment'
ELSE 'Complete'
END) AS STATUS,
r.LName AS RefLast,
r.FName AS RefFirst,
ra.Note
FROM patient p
INNER JOIN refattach ra ON ra.PatNum = p.PatNum
AND ra.RefType = 0 /*RefTo*/
AND (ra.RefDate BETWEEN @StartDate AND @EndDate)
INNER JOIN referral r ON r.ReferralNum=ra.ReferralNum
WHERE p.PatStatus=0 /*Patient status*/
ORDER BY ra.RefDate;
Patient count by age, with at least 1 completed procedure -
/*208 Patient count by age, with at least 1 completed procedure*/
SELECT (YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) AS 'Age', COUNT(DISTINCT p.PatNum) AS 'Patients'
FROM procedurelog pl
INNER JOIN patient p ON p.PatNum=pl.PatNum
WHERE pl.ProcStatus=2 AND p.PatStatus=0
GROUP BY Age;
Aging report which only includes families who do NOT have a balance >90 days AND who have a positive balance (owe) -
/*209 Aging report which only includes families who do NOT have a balance >90 days
AND who have a positive balance (owe)*/
SELECT PatNum,Bal_0_30,Bal_31_60,Bal_61_90,
BalTotal AS $BalTot_,InsEst AS $InsEst_,BalTotal-InsEst AS $pat_
FROM patient
WHERE PatStatus != 4
AND (Bal_0_30 > '.005' OR Bal_31_60 > '.005' OR Bal_61_90 > '.005') AND BalOver90 < '.005'
ORDER BY LName,FName;
Returns patients with unscheduled Treament Planned procedures - leaves out diagnostic and preventative (D0*, D1*)
/*210 Returns patients with unscheduled Treament Planned procedures, leaves out diagnostic and preventative (D0*, D1*)*/
SELECT patient.PatNum, HmPhone, WkPhone, WirelessPhone, SUM(ProcFee) AS '$FeeSum' FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum AND ProcStatus=1
LEFT JOIN appointment ap ON patient.PatNum=ap.PatNum AND ap.AptStatus=1/*scheduled apt*/
WHERE ap.AptNum IS NULL AND patient.PatStatus=0 AND
(NOT (pc.ProcCode LIKE('D0%'))) AND (NOT (pc.ProcCode LIKE('D1%')))
GROUP BY patient.PatNum
HAVING SUM(ProcFee)>0
ORDER BY patient.LName, patient.FName ASC;
Referred out patients for a specific ref source - For Versions 17.1 and greater. Please update your version accordingly. Editable user date range filter for referral date.
/*211 Referrered out patients for a specific ref source*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/09/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @StartDate='2018-01-01', @EndDate='2018-01-05';
/*Change LName of referral source below, leave '%%' to run for all sources*/
SET @RefLName='%%';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SET @pos = 0;
SELECT @pos:= @pos+1 AS COUNT,
p.PatNum AS PatID,
p.LName AS PatLast,
p.FName AS PatFirst,
(CASE WHEN ra.RefToStatus=0 THEN 'None'
WHEN ra.RefToStatus=1 THEN 'Declined'
WHEN ra.RefToStatus=2 THEN 'Scheduled'
WHEN ra.RefToStatus=3 THEN 'Consulted'
WHEN ra.RefToStatus=4 THEN 'InTreatment'
ELSE 'Complete'
END) AS STATUS,
r.LName AS RefLast,
r.FName AS RefFirst,
ra.Note
FROM patient p
INNER JOIN refattach ra ON ra.PatNum = p.PatNum
INNER JOIN referral r ON r.ReferralNum=ra.ReferralNum
AND ra.RefType = 0 /*RefTo*/
AND (ra.RefDate BETWEEN @StartDate AND @EndDate)
AND r.LName LIKE(@RefLName)
WHERE p.PatStatus=0 /*Patient status*/
ORDER BY ra.RefDate;
Day Summary, may also be used for date ranges - note that only payment associated with EACH DATE are returned and only if there was service on THAT DATE, does not return insurance payments as payments are not recieved on service date and this is intended for day sheet use
/*213 Day Summary, may also be used for date ranges*/
SET @FromDate='2010-12-21' , @ToDate='2010-12-21';
/*Day Summary, may also be used for date ranges, note that only payment associated with
EACH DATE are returned and only if there was service on THAT DATE, does not return insurance payments
as payments are not recieved on service date and this is intended for day sheet use*/
SELECT DATE(pl.ProcDate) AS 'DateServ' ,p.PatNum, SUM(pl.procfee) AS '$Product',
(SELECT SUM(InsPayEst) FROM claim c WHERE c.PatNum=p.PatNum AND (Date(c.DateService)=Date(pl.ProcDate))) AS '$InsEst_', /*extra underscores increas column width*/
(SELECT SUM(Writeoff) FROM claim c WHERE c.PatNum=p.PatNum AND (Date(c.DateService)=(Date(pl.ProcDate)))) AS '$PPO',
(SELECT SUM(SplitAmt) FROM paysplit WHERE p.PatNum=paysplit.PatNum AND (Date(DatePay)=(Date(pl.ProcDate)))) AS '$PatPay',
(SELECT SUM(AdjAmt) FROM adjustment WHERE p.PatNum=adjustment.PatNum AND (Date(AdjDate)=(Date(pl.ProcDate)))) AS '$PatAdj',
(SELECT GROUP_CONCAT(DISTINCT ItemName) FROM paysplit INNER JOIN payment ON paysplit.PayNum=payment.PayNum INNER JOIN definition d ON payment.PayType=d.DefNum
WHERE p.PatNum=paysplit.PatNum AND (Date(DatePay)=(Date(pl.ProcDate)))) AS 'HowPaid', /*(how patient paid)*/
p.EstBalance AS '$PatBal', p.EstBalance-(SELECT SUM(cp.InsPayEst+cp.WriteOff) FROM claimproc cp WHERE cp.status=0 /*not received*/ AND cp.PatNum=p.PatNum) AS '$PatEst',
(SELECT g.BalTotal FROM patient g WHERE p.Guarantor=g.PatNum) AS '$FamTotB',(SELECT g.BalTotal-g.InsEst FROM patient g WHERE p.Guarantor=g.PatNum) AS '$FamEstB'
FROM patient p
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum AND pl.ProcStatus=2
WHERE pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY pl.ProcDate,p.PatNum
ORDER BY pl.ProcDate,p.LName, p.FName;
Day Summary for Today - note that only payment associated with Today are returned and only if there was service Today, does not return insurance payments as payments are not recieved on service date and this is intended for day sheet use
/*214 Day Summary, note that only payment associated with
Today are returned and only if there was service Today, does not return insurance payments
as payments are not received on service date and this is intended for day sheet use*/
SELECT DATE(pl.ProcDate) AS 'DateServ' ,p.PatNum, SUM(pl.procfee) AS '$Product',
(SELECT SUM(InsPayEst) FROM claim c WHERE c.PatNum=p.PatNum AND (Date(c.DateService)=Date(pl.ProcDate))) AS '$InsEst_', /*extra underscores increas column width*/
(SELECT SUM(Writeoff) FROM claim c WHERE c.PatNum=p.PatNum AND (Date(c.DateService)=(Date(pl.ProcDate)))) AS '$PPO',
(SELECT SUM(SplitAmt) FROM paysplit WHERE p.PatNum=paysplit.PatNum AND (Date(DatePay)=(Date(pl.ProcDate)))) AS '$PatPay',
(SELECT SUM(AdjAmt) FROM adjustment WHERE p.PatNum=adjustment.PatNum AND (Date(AdjDate)=(Date(pl.ProcDate)))) AS '$PatAdj',
(SELECT GROUP_CONCAT(DISTINCT ItemName) FROM paysplit INNER JOIN payment ON paysplit.PayNum=payment.PayNum INNER JOIN definition d ON payment.PayType=d.DefNum
WHERE p.PatNum=paysplit.PatNum AND (Date(DatePay)=(Date(pl.ProcDate)))) AS 'HowPaid', /*(how patient paid)*/
p.EstBalance AS '$PatBal', p.EstBalance-(SELECT SUM(cp.InsPayEst+cp.WriteOff) FROM claimproc cp WHERE cp.Status=0 /*not received*/ AND cp.PatNum=p.PatNum) AS '$PatEst',
(SELECT g.BalTotal FROM patient g WHERE p.Guarantor=g.PatNum) AS '$FamTotB',(SELECT g.BalTotal-g.InsEst FROM patient g WHERE p.Guarantor=g.PatNum) AS '$FamEstB'
FROM patient p
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum AND pl.ProcStatus=2
WHERE pl.ProcDate =CURDATE()
GROUP BY pl.ProcDate,p.PatNum
ORDER BY pl.ProcDate,p.LName, p.FName;
Appointments in the past that are scheduled but not complete or broken or unscheduled -
/*215 Appointments in the past that are scheduled but not complete or broken or unscheduled*/
SELECT PatNum, AptDateTime FROM appointment WHERE AptStatus=1 AND AptDateTime<CURDATE() ORDER BY AptDateTime;
Patients who need followup - Patients with a procedure in a given list completed in date range but no other procedures on another date, apts are counted by procedures summed by date, so it works even if you so not use appointments
/*217 Patients who need followup-Patients with a procedure in a given list completed in date range but no other procedures on another date,
apts are counted by procedures summed by date, so it works even if you so not use appointments*/
SET @FromDate='2008-12-01' , @ToDate='2008-12-30';
SELECT patient.PatNum, DATE_FORMAT(MAX(ProcDate),'%m/%d/%Y') AS 'LastVisit', COUNT(DISTINCT procedurelog.ProcDate) AS '#Apts'
FROM patient,procedurelog
WHERE patient.PatNum IN
(SELECT DISTINCT p.PatNum FROM patient p
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum AND pc.ProcCode IN('D0120','D1110','D1204')
WHERE pl.ProcStatus='2')
AND procedurelog.PatNum=patient.PatNum AND procedurelog.ProcStatus=2 AND patient.PatStatus=0
GROUP BY procedurelog.PatNum
HAVING (MIN(ProcDate) BETWEEN @FromDate AND @ToDate) AND COUNT(DISTINCT procedurelog.ProcDate)=1
ORDER BY patient.LName, patient.FName;
List of all procedures of status 'Existing Current Provider' in date range -
/*218 List of all procedures of status 'Existing Current Provider' in date range*/
SET @FromDate='2007-12-01' , @ToDate='2008-12-30';
SELECT p.PatNum, pc.ProcCode, pc.Descript,pl.ProcDate, pl.ProcFee
FROM patient p
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
WHERE pl.ProcStatus=3 AND p.PatStatus=0 /*ProcStatus=3 means existing cur prov*/
AND (pl.ProcDate BETWEEN @FromDate AND @ToDate)
ORDER BY p.LName, p.FName, pl.ProcDate;
List of all completed work with fee of $0 and with 'D Code' in date range with standard fee listed -
/*219 List of all completed work with fee of $0 and with 'D Code' in date range with standard fee listed*/
SET @FromDate='2007-12-01' , @ToDate='2008-12-30';
SELECT p.PatNum, pc.ProcCode, LEFT(pc.Descript, 35) AS 'Description(first 35 chars)',pl.ProcDate, pl.ProcFee, fee.Amount AS $UCR
FROM patient p
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
INNER JOIN provider pv ON pl.ProvNum=pv.ProvNum
INNER JOIN fee ON fee.FeeSched=pv.FeeSched AND pc.CodeNum=fee.CodeNum
WHERE pl.ProcStatus=2 AND p.PatStatus=0
AND (pl.ProcDate BETWEEN @FromDate AND @ToDate)
AND pl.ProcFee=0 AND pc.ProcCode LIKE ('D%')
ORDER BY p.LName, p.FName, pl.ProcDate;
List of active patients with sum of treatment fees in given time period with referral source - For Versions 17.1 and greater. Please update your version accordingly
/*220 List of active patients with sum of treatment fees in given time period with referral source*/
/*For Versions 17.1 and greater. Please update your version accordingly*/
/*Query code written/modified: 04/09/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2018-01-01' , @ToDate='2018-01-15';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT p.PatNum,
SUM(ProcFee) AS $Treatment__,
GROUP_CONCAT(DISTINCT IF(r.FName = '', r.LName, CONCAT(r.LName, ', ',r.FName)) ORDER BY ra.ItemOrder SEPARATOR ' | ' ) AS 'Refferal Source'
FROM patient p
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum
AND pl.ProcStatus=2 /*complete work*/
LEFT JOIN refattach ra ON ra.PatNum = p.PatNum
AND ra.RefType = 1 /*RefFrom*/
LEFT JOIN referral r ON r.ReferralNum=ra.ReferralNum
WHERE p.PatStatus=0 /*patient status*/
AND (pl.ProcDate BETWEEN @FromDate AND @ToDate)
GROUP BY p.PatNum
HAVING SUM(ProcFee)>0 /*remove pat with no production on total of completed procs*/
ORDER BY SUM(ProcFee) DESC;
Referrals 'To' of a given status and key word in referral attachment note - to get a patient/referral on this list, for instance, set referral attachment status to Scheduled and put the word xray or x-ray somewhere in the ref attach notes
/*221 Referrals 'To' of a given status and key word in referral attachment note*/
/*to get a patient/referral on this list, for instance, set referral attachment status
to Scheduled and put the word xray or x-ray somewhere in the ref attach notes*/
SELECT ra.PatNum,RefDate, r.LName, r.FName,r.Telephone, LEFT(ra.Note,35) AS 'Note (first 30 chars)'
FROM
refattach ra
INNER JOIN referral r ON r.ReferralNum=ra.ReferralNum
WHERE ra.RefToStatus=2 /*status of 2 indicated Scheduled, Enum:ReferralToStatus 0=None,1=Declined,2=Scheduled,3=Consulted,4=InTreatment,5=Complete*/
AND ra.Note LIKE('%ray%')
ORDER BY RefDate DESC;
New Patients, Count per week for a given date range. Active patients only. -
/*223 New Patients, Count per week for a given date range. Active patients only.*/
SET @FromDate='2008-01-01', @ToDate='2008-12-31';
SELECT Year(DateFirstVisit) AS Year, WeekofYear(DateFirstVisit) AS Week, COUNT(DISTINCT patient.PatNum) AS 'New Patients'
FROM patient, procedurelog
WHERE procedurelog.PatNum = patient.PatNum
AND patient.patstatus = '0'
AND procedurelog.ProcDate BETWEEN @FromDate
AND @ToDate
AND procedurelog.ProcStatus=2
AND patient.DateFirstVisit >= @FromDate
AND procedurelog.ProcFee > 0
GROUP BY WeekofYear(DateFirstVisit)
ORDER BY patient.DateFirstVisit;
Income by ref source for date range, only includes referrals received and income collected during that period, also returns TP fee total - For versions 16.4 and below. SEE REPLICATION WARNING for versions before 14.3.1. Submitted by Steve Gershkowitz
/*224 Income by ref source for date range*/
/*Only includes referrals received and income collected during that period, and TP fee total*/
/*Submitted by Steve Gershkowitz*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
/*For versions 16.4 and below*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate = '2008-09-01', @ToDate = '2008-12-30';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
DROP TABLE IF EXISTS insurance_pay;
CREATE TEMPORARY TABLE insurance_pay(
PatNum MEDIUMINT UNSIGNED NOT NULL,
Payment DOUBLE NOT NULL,
PRIMARY KEY (PatNum));
INSERT INTO insurance_pay
SELECT clm.PatNum, SUM(clm.InsPayAmt) AS InsPaid
FROM claimproc clm
WHERE clm.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY clm.PatNum;
DROP TABLE IF EXISTS planned_proc;
CREATE TEMPORARY TABLE planned_proc
(PatNum MEDIUMINT UNSIGNED NOT NULL,
PlannedFee DOUBLE NOT NULL,
PRIMARY KEY (PatNum));
INSERT INTO planned_proc
SELECT plog.PatNum, SUM(plog.ProcFee) AS Planned_Fee
FROM procedurelog plog
WHERE plog.ProcStatus=1 /* TP Planned */
AND plog.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY plog.PatNum;
DROP TABLE IF EXISTS var_payments;
CREATE TEMPORARY TABLE var_payments(
PatNum MEDIUMINT UNSIGNED NOT NULL,
PayAmt DOUBLE NOT NULL,
PRIMARY KEY (PatNum));
INSERT INTO var_payments
SELECT pay.PatNum , SUM( pay.PayAmt ) AS Total
FROM payment pay
WHERE pay.PayDate BETWEEN @FromDate AND @ToDate
GROUP BY pay.PatNum;
DROP TABLE IF EXISTS referred;
CREATE TEMPORARY TABLE referred(
PatNum MEDIUMINT UNSIGNED NOT NULL,
RefSource VARCHAR(255)NOT NULL);
INSERT INTO referred
SELECT ra.PatNum,
CASE
WHEN NotPerson=1 /* true */
THEN re.LName
ELSE CONCAT( re.Fname, ' ', re.LName )
END AS Source
FROM referral re, refattach ra
WHERE re.ReferralNum = ra.ReferralNum
AND ra.RefDate BETWEEN @FromDate AND @ToDate
AND ra.IsFrom = 1 /* true */;
SELECT
ref.RefSource AS Source, COUNT(DISTINCT ref.PatNum) AS HowMany,
COALESCE(SUM(ins.Payment),0) AS "Insurance Collected",
COALESCE(SUM(pay.PayAmt),0) AS "Cash, CC, Checks, Financing",
COALESCE(COALESCE(SUM(ins.Payment),0) + COALESCE(SUM(payAmt),0)) AS "Total Collected",
COALESCE(SUM(pln.PlannedFee),0) AS "Treatment Planned"
FROM referred ref
LEFT OUTER JOIN insurance_pay ins ON ref.PatNum = ins.PatNUm
LEFT OUTER JOIN var_payments pay ON ref.PatNum = pay.PatNum
LEFT OUTER JOIN planned_proc pln ON ref.PatNum = pln.PatNum
GROUP BY ref.RefSource
ORDER BY ref.RefSource;
DROP TABLE IF EXISTS insurance_pay;
DROP TABLE IF EXISTS var_payments;
DROP TABLE IF EXISTS referred;
DROP TABLE IF EXISTS planned_proc;
Total production in Date Range for a list of specific procedure codes -
/*225 Total production in Date Range for a list of specific procedure codes*/
/*Query code written/modified: 02/27/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2017-01-01', @ToDate='2017-01-31';
/*Enter procedure codes separated by a '|' without the quotes. To see all leave blank as ""*/
SET @Codes = 'D0120|D1206|D1351|D2962|D4341|D4342|D4355|D6010|D7288|D8040|D8040.01|D9000|D9248|D9940|D9941|D9975|D9976|D9980|D9981';
/*---DO NOT MODIFY BELOW THIS LINE---*/
SET @Codes=(CASE WHEN @Codes='' THEN '^' ELSE CONCAT('^',REPLACE(@Codes,'|','$|^'),'$') END);
SELECT SUM(procedures.ProcFee*(procedures.UnitQty+procedures.BaseUnits)) AS Production,
ProcCode
FROM (
SELECT c.ProcCode,
p.ProcFee,
p.UnitQty,
p.BaseUnits,
p.ProcDate
FROM procedurecode c
INNER JOIN procedurelog p
ON p.CodeNum=c.CodeNum
AND p.ProcStatus=2
AND p.ProcDate BETWEEN @FromDate AND @ToDate
WHERE c.ProcCode REGEXP @Codes
) AS procedures
GROUP BY ProcCode;
Production by Carrier for date range (or current day) with sum of patient portion estimate (does not include writeoffs) - Also includes uninsured total production, and for pat portion, insurance estimates, sent and received claims are considered
/*227 Production by Carrier for date range (or current day) with sum of patient portion estimate
Also includes uninsured total production, and for pat portion, insurance estimates, sent and received claims are considered*/
/*Query code written/modified: 03/28/2017*/
SET @FromDate='2016-12-01' , @ToDate='2016-12-31';
SELECT (CASE WHEN ISNULL(carrier.CarrierName) THEN 'No Insurance' ELSE (carrier.CarrierName) END) AS 'InsCarrier', SUM(cp.InsPayEst) AS '$InsPayEst_',
(CASE WHEN ISNULL(carrier.CarrierName) THEN SUM(pl.ProcFee) ELSE (SUM(pl.ProcFee)-SUM(cp.InsPayEst)) END) AS '$Patient_',
SUM(pl.procfee) AS '$TotProd_'
FROM patient p
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum
AND (pl.ProcDate BETWEEN @FromDate AND @ToDate)
AND pl.ProcStatus=2
LEFT JOIN patplan pp ON pp.PatNum=p.PatNum
LEFT JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=ib.PlanNum
LEFT JOIN carrier ON carrier.CarrierNum=ip.CarrierNum
LEFT JOIN (
SELECT claimproc.ProcNum, claimproc.Status, claimproc.PlanNum, SUM(claimproc.InsPayEst) AS InsPayEst
FROM claimproc
WHERE (claimproc.Status=6 OR claimproc.Status=0 OR claimproc.Status=1)
GROUP BY claimproc.ProcNum, claimproc.PlanNum
)cp ON cp.ProcNum=pl.ProcNum
AND cp.PlanNum=ip.PlanNum
WHERE (ISNULL(carrier.CarrierName) OR pp.Ordinal=1)
GROUP BY InsCarrier
Sum of differences in fee billed and any given fee schedule for all procs completed in a date range for a given carrier, like medicaid - useful in calculating medicaid 'writeoffs', only valid after version 6.1.0
/*228 Sum of differences in fee billed and any given fee schedule for all procs completed in a date range for a given carrier, like medicaid*/
SET @FromDate='2009-01-01' , @ToDate='2009-01-31';
/*Sum of differences in fee billed and any given fee schedule for all procs completed in a date range for a given carrier, like medicaid*/
/*useful in calculating medicaid 'writeoffs', only valid after version 6.1.0*/
SELECT claim.PatNum,DateService,ProvTreat,pc.ProcCode,f.Amount AS '$UCRFee', pl.ProcFee AS '$FeeCharged',
f.Amount-pl.Procfee AS '$FeeDiff', ca.CarrierName
FROM claim
INNER JOIN claimproc cp ON claim.ClaimNum=cp.ClaimNum
INNER JOIN procedurelog pl ON cp.ProcNum=pl.ProcNum
INNER JOIN insplan ip ON claim.PlanNum=ip.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=ip.CarrierNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
INNER JOIN fee f ON pc.CodeNum=f.CodeNum
INNER JOIN feesched fs ON f.FeeSched=fs.FeeSchedNum AND fs.Description='Standard' /*replace 'Standard' with fee sched name*/
WHERE (DateService BETWEEN @FromDate AND @ToDate) AND
ca.CarrierName LIKE('%Delta%');/*replace '%Delta%' with carrier name or part of it enclosed in % signs*/
Patient count by Zipcode, with at least 1 completed procedure in date range - limits to count(zipcodes)>3 as outliers, can be changed to 0 to include all like #178 but with date range
/*229 Patient count by Zipcode, with at least 1 completed procedure in date range*/
SET @FromDate='2009-01-01' , @ToDate='2009-01-31';
/*Patient count by Zipcode, with at least 1 completed procedure in date range
limits to count(zipcodes)>3 as outliers, can be changed to 0 to include all
like #178 but with date range*/
SELECT LEFT(Zip,5) AS ZipCode, COUNT(DISTINCT p.PatNum) AS 'Patients'
FROM procedurelog pl
INNER JOIN patient p ON p.PatNum=pl.PatNum
WHERE pl.ProcStatus=2 AND p.PatStatus=0 AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY ZipCode
HAVING patients>3;
Patients with NO previous date OR Calculated Date in Recall List and who HAD A PROCEDURE COMPLETED in given date range - not really needed after version 6.5
/*230 Patients with NO previous date OR Calculated Date in Recall List
and who HAD A PROCEDURE COMPLETED in given date range, not really needed after version 6.5*/
/*Query code written/modified: 05/25/2017, 04/03/2019:RobG*/
SET @FromDate='2007-01-01', @ToDate='2018-01-31' , @pos=0;/*change dates here*/
SELECT @pos:=@pos+1 AS 'Count',p.PatNum, LEFT(WkPhone,16) AS WkPhone, LEFT(HmPhone,16) AS HmPhone, LEFT(WirelessPhone,16) AS CellPhone, DATE_FORMAT(MAX(ProcDate),'%m/%d/%Y') AS 'LastVisit'
FROM patient p
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
WHERE pl.ProcStatus=2 AND p.PatStatus=0 AND (pl.ProcDate BETWEEN @FromDate AND @ToDate)
AND p.PatNum IN (SELECT PatNum FROM recall WHERE DateDueCalc = '0001-01-01' AND DatePrevious= '0001-01-01')
GROUP BY pl.PatNum;
Patients that don't have Previous date and Calculated Date in Recall List and HAD AN APPOINTMENT in date range, whether apt was completed or not -
/*231 Patients that don't have Previous date and Calculated Date in Recall List
and HAD AN APPOINTMENT in date range, whether apt was completed or not*/
/*Query code written/modified: 05/25/2017*/
SET @FromDate='2007-01-01', @ToDate='2009-01-31' , @pos=0;/*change dates here*/
SELECT @pos:=@pos+1 as 'Count',p.PatNum, LEFT(WkPhone,16) AS WkPhone, LEFT(HmPhone,16) AS HmPhone, LEFT(WirelessPhone,16) AS CellPhone, DATE_FORMAT(MAX(AptDateTime),'%m/%d/%Y') AS 'LastVisit'
FROM patient p
INNER JOIN appointment a ON a.PatNum=p.PatNum
WHERE p.PatStatus=0 AND (a.AptDateTime BETWEEN @FromDate AND @ToDate)
AND p.PatNum NOT IN (SELECT PatNum FROM recall WHERE DateDueCalc = '0001-01-01' AND DatePrevious= '0001-01-01')
GROUP BY a.PatNum;
Procedures completed for patients of a given age range in a given date range with primary insurance carrier and fee - considers AGE AT TIME OF SERVICE, other tables are includes to make it easy to get ins payment, estimate etc
/*232 Procedures completed for patients of a given age range in a given date range with primary insurance carrier and fee*/
/*considers AGE AT TIME OF SERVICE, other tables are includes to make it easy to get ins payment, estimate etc*/
SET @StartAge=1, @EndAge=12;
SET @FromDate='2008-01-01' , @ToDate='2009-12-31';
SELECT p.PatNum, pl.ProcNum,(YEAR(pl.ProcDate)-YEAR(Birthdate)) - (RIGHT(pl.ProcDate,5)<RIGHT(Birthdate,5)) AS 'AgeAtApt',
(CASE WHEN ISNULL(carrier.CarrierName) THEN '*No Insurance' ELSE (carrier.CarrierName) END) AS 'PriCarrier',
pc.ProcCode, pl.ProcFee AS '$ProcFee' ,pl.ProcDate
FROM patient p
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum AND (pl.ProcDate BETWEEN @FromDate AND @ToDate) AND pl.ProcStatus=2
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
LEFT JOIN patplan pp ON pp.PatNum=p.PatNum AND ORDINAL=1/*by current primary insurance*/
LEFT JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=ib.PlanNum
LEFT JOIN carrier ON carrier.CarrierNum=ip.CarrierNum
LEFT JOIN claimproc cp ON cp.ProcNum=pl.ProcNum AND (cp.Status=6 OR cp.Status=0 OR cp.Status=1) AND ip.PlanNum=cp.PlanNum
WHERE ((YEAR(pl.ProcDate)-YEAR(Birthdate)) - (RIGHT(pl.ProcDate,5)<RIGHT(Birthdate,5)) BETWEEN @StartAge AND @EndAge)
ORDER BY p.LName, p.FName;
Treatment planned procedures with date and fee for patients without a planned or scheduled appointment, excludes codes in user defined list - Edit list as needed
/*233 Treatment planned procedures with date and fee for patients without a planned or scheduled appointment, excludes codes in user defined list*/
SELECT patient.PatNum, pl.DateTP,pc.ProcCode, pc.AbbrDesc, pl.ProcFee
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum AND ProcStatus=1/*treatment planned*/
WHERE (SELECT COUNT(ap.PatNum) FROM appointment ap WHERE patient.PatNum=ap.PatNum AND
(ap.AptStatus=1 OR ap.AptStatus=6 ))=0 /*no planned or scheduled appt*/
AND patient.PatStatus=0 /*Active patients*/
AND pc.ProcCode NOT IN('D0120', 'D0150','D1120', 'D1110','D1203','D1204', 'D1206', 'D0272','D0274')/*Edit this list as needed, these codes are excluded*/
ORDER BY patient.LName, patient.FName, pl.DateTP, pc.ProcCode ASC;
Treatment planned procedures for patients with neither planned nor scheduled apt, where code is in a user defined list with age and phone numbers - address can be added if needed, but will not fit on one page with phone numbers
/*234 Treatment planned procedures for patients with neither planned nor scheduled apt,
where code is in a user defined list with age and phone numbers
address can be added if needed, but will not fit on one page with phone numbers*/
SET @CodeLike='D2%'; /*change this D2% to whatever pattern match you want, in this case the query will
return all treatment planned procedures that start with D2, like fillings*/
SELECT patient.PatNum, (YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) AS 'Age',
pl.DateTP,pc.ProcCode,LEFT(WkPhone,16) AS WkPhone, LEFT(HmPhone,16) AS HmPhone, LEFT(WirelessPhone,16) AS CellPhone
/* these fields are sometimes desired: pc.AbbrDesc, pl.ProcFee*/
/* address fields are: Address,Address2,City,State,Zip */
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum AND ProcStatus=1/*treatment planned*/
WHERE (SELECT COUNT(ap.PatNum) FROM appointment ap WHERE patient.PatNum=ap.PatNum AND
(ap.AptStatus=1 OR ap.AptStatus=6 ))=0 /*no planned or scheduled appt*/
AND patient.PatStatus=0 /*Active patients*/
AND pc.ProcCode LIKE(@CodeLike)
ORDER BY patient.LName, patient.FName, pl.DateTP, pc.ProcCode ASC;
Procedures completed for day(or date range) with latest procedure note and tooth surface(s) - SEE REPLICATION WARNING for versions before 14.3.1. Also shows whether the note is signed
/*235 Procedures completed for day(or date range) with latest procedure note and tooth surface(s), and whether the note is signed*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS tmp1;
SET @FromDate='2010-03-22' , @ToDate='2010-03-30';/*use @FromDate=CURDATE(), @ToDate=CURDATE(); for current date only */
CREATE TABLE tmp1 SELECT
Max(procnote.EntryDateTime) AS 'NoteEntered',
procedurelog.ProcDate,
provider.LName AS `Dr`,
patient.PatNum,
patient.LName,
procedurelog.ToothNum,
procedurelog.Surf,
procedurelog.ProcNum,
procedurecode.ProcCode,
procedurecode.AbbrDesc
FROM
procedurelog
Inner Join procedurecode ON procedurelog.CodeNum = procedurecode.CodeNum
Inner Join provider ON provider.ProvNum = procedurelog.ProvNum
Inner Join patient ON patient.PatNum = procedurelog.PatNum
LEFT Join procnote ON procnote.ProcNum = procedurelog.ProcNum
WHERE
procedurelog.ProcDate BETWEEN @FromDate AND @ToDate AND
procedurelog.ProcStatus = '2' /*complete*/
GROUP BY procedurelog.ProcNum;
SELECT ProcDate, Dr AS 'Dr.', tmp1.PatNum, ToothNum AS 'T#', Surf, ProcCode, AbbrDesc,
(CASE WHEN NOT ISNULL(tmp1.NoteEntered) THEN
(SELECT (CASE WHEN length(pn.Signature)>0 THEN 'Signed' ELSE 'No' END) AS 'Test' FROM procnote pn WHERE tmp1.ProcNum=pn.ProcNum AND pn.EntryDateTime=tmp1.NoteEntered)
ELSE 'None' END) AS 'Signed',
(CASE WHEN NOT ISNULL(tmp1.NoteEntered) THEN
(SELECT pn.Note FROM procnote pn WHERE tmp1.ProcNum=pn.ProcNum AND pn.EntryDateTime=tmp1.NoteEntered)
ELSE 'None' END) AS 'Note'
FROM tmp1
ORDER BY
`Dr.` ASC,
LName ASC,
ProcCode ASC;
DROP TABLE IF EXISTS tmp1;
Outstanding Preauths by Date Sent with PatNum -
/*236 Outstanding Preauths by Date of Sent
*/
SELECT cl.PatNum, p.PatNum AS 'RawPatNum',cl.DateSent, ca.CarrierName, ca.Phone, cl.ClaimFee FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE
cl.ClaimType='PreAuth' AND cl.ClaimStatus<>'R'
ORDER BY ca.CarrierName,p.LName;
Annual production and income report For all providers - SEE REPLICATION WARNING for versions before 14.3.1. This is similar to the included P&I Report
/*237 Annual production and income report For all providers*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
/*Query code written/modified: 12/16/2015*/
DROP TABLE IF EXISTS t1,t2;
SET @FromDate='2013-01-01' , @ToDate='2014-12-31';
CREATE TABLE t1(
YEAR INT NOT NULL,
MONTH INT NOT NULL,
$Production DOUBLE NOT NULL,
$Adjustments DOUBLE NOT NULL,
$WriteOff DOUBLE NOT NULL,
$TotProd DOUBLE NOT NULL,
$PatIncome DOUBLE NOT NULL,
$InsIncome DOUBLE NOT NULL,
$TotIncome DOUBLE NOT NULL);
/*Prod*/
INSERT INTO t1(MONTH,YEAR,$Production)
SELECT MONTH(pl.ProcDate) AS 'Month',
YEAR(pl.ProcDate) AS 'Year',
SUM(pl.procfee) AS '$Production'
FROM procedurelog pl WHERE pl.ProcStatus=2 AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY YEAR(pl.ProcDate),MONTH(pl.ProcDate);
/*Adj*/
CREATE TABLE t2
SELECT MONTH(a.AdjDate) AS 'Month',
YEAR(a.ProcDate) AS 'Year',
SUM(a.AdjAmt) AS 'Adjustments' FROM adjustment a
WHERE a.AdjDate BETWEEN @FromDate AND @ToDate
GROUP BY YEAR(a.ProcDate),MONTH(a.AdjDate);
UPDATE t1,t2 SET t1.$Adjustments=t2.Adjustments WHERE t1.Month=t2.Month AND t1.Year = t2.Year;
DROP TABLE IF EXISTS t2;
/*PatInc*/
CREATE TABLE t2
SELECT MONTH(pp.DatePay) AS 'Month',
YEAR(pp.DatePay) AS 'Year',
SUM(pp.SplitAmt) AS 'PatIncome' FROM paysplit pp
WHERE pp.DatePay BETWEEN @FromDate AND @ToDate
GROUP BY YEAR(pp.DatePay),MONTH(pp.DatePay);
UPDATE t1,t2 SET t1.$PatIncome=t2.PatIncome WHERE t1.Month=t2.Month AND t1.Year = t2.Year;
DROP TABLE IF EXISTS t2;
/*InsIncome*/
CREATE TABLE t2
SELECT MONTH(cp.DateCP) AS 'Month',
YEAR(cp.DateCP) AS 'YEAR',
SUM(cp.InsPayAmt) AS 'InsIncome',
SUM(cp.WriteOff) AS 'WriteOff'
FROM claim c
INNER JOIN claimproc cp ON c.ClaimNum=cp.ClaimNum
WHERE cp.DateCP BETWEEN @FromDate AND @ToDate /*vs c.DateReceived*/
GROUP BY YEAR(cp.DateCP),MONTH(cp.DateCP);
UPDATE t1 LEFT JOIN t2 ON t1.Month=t2.Month AND t1.Year=t2.Year
SET t1.$InsIncome=t2.InsIncome,
t1.$WriteOff=-t2.WriteOff,
t1.$TotProd=t1.$Production+t1.$Adjustments-IFNULL(t2.WriteOff,0),
t1.$TotIncome=IFNULL(t2.InsIncome,0)+t1.$PatIncome;
DROP TABLE IF EXISTS t2;
SELECT * FROM t1
ORDER BY YEAR,MONTH;
DROP TABLE IF EXISTS t1;
DROP TABLE IF EXISTS t2;
Annual production and income report as it would have been pre version 5.6 on a certain date for a given year For designated providers - SEE REPLICATION WARNING for versions before 14.3.1. Pre 5.6 equivalent P&I report for one specified provider
/*238 Annual production and income report as it would have been pre version 5.5 on a certain date for a given year
For designated providers*/
/*Pre 5.6 equivalent P&I report for one specified provider*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS t1,t2;
SET @RunDate='2006-01-01', @FromDate='2005-01-01' , @ToDate='2005-12-31';
CREATE TABLE t1(
Month int NOT NULL,
$Production double NOT NULL,
$Adjustments double NOT NULL,
$WriteOff double NOT NULL,
$TotProd double NOT NULL,
$PatIncome double NOT NULL,
$InsIncome double NOT NULL,
$TotIncome double NOT NULL);
/*Prod*/
INSERT INTO t1(Month,$Production)
SELECT MONTH(pl.ProcDate) AS 'Month',
SUM(pl.procfee) AS 'Production'
FROM procedurelog pl WHERE pl.ProcStatus=2 AND pl.ProcDate BETWEEN @FromDate AND @ToDate
AND provnum IN (1)/*three different providers*/
GROUP BY MONTH(pl.ProcDate);
/*Adj*/
CREATE TABLE t2
SELECT MONTH(a.AdjDate) AS 'Month',
SUM(a.AdjAmt) AS 'Adjustments' FROM adjustment a
WHERE a.AdjDate BETWEEN @FromDate AND @ToDate
AND provnum IN (1)/*three different providers*/
GROUP BY MONTH(a.AdjDate);
UPDATE t1,t2 SET t1.$Adjustments=t2.Adjustments WHERE t1.Month=t2.Month;
DROP TABLE IF EXISTS t2;
/*PatInc*/
CREATE TABLE t2
SELECT MONTH(pp.DatePay) AS 'Month',
SUM(pp.SplitAmt) AS 'PatIncome' FROM paysplit pp
WHERE pp.DatePay BETWEEN @FromDate AND @ToDate
AND provnum IN (1)/*three different providers, 1, 3 & 4 are all Perri*/
GROUP BY MONTH(pp.DatePay);
UPDATE t1,t2 SET t1.$PatIncome=t2.PatIncome WHERE t1.Month=t2.Month;
DROP TABLE IF EXISTS t2;
/*InsIncome*/
CREATE TABLE t2
SELECT MONTH(cp.ProcDate) AS 'Month',
(CASE WHEN ISNULL(SUM(cp.InsPayAmt)) THEN 0 ELSE SUM(cp.InsPayAmt) END) AS 'InsIncome',
(CASE WHEN ISNULL(SUM(cp.WriteOff)) THEN 0 ELSE SUM(cp.WriteOff) END) AS 'WriteOff'
FROM claim c
INNER JOIN claimproc cp ON c.ClaimNum=cp.ClaimNum
WHERE cp.ProcDate BETWEEN @FromDate AND @ToDate /*vs cp.DateCP*/
AND cp.DateCP<@RunDate
AND cp.provnum IN (1)/*three different providers*/
GROUP BY MONTH(cp.ProcDate);/*here we use date of service for writeoffs and ins payments*/
UPDATE t1,t2 SET t1.$InsIncome=t2.InsIncome,
t1.$WriteOff=-t2.WriteOff,
t1.$TotProd=t1.$Production+t1.$Adjustments-t2.WriteOff,
t1.$TotIncome=t2.InsIncome+t1.$PatIncome
WHERE t1.Month=t2.Month;
DROP TABLE IF EXISTS t2;
SELECT * FROM t1;
DROP TABLE IF EXISTS t1;
DROP TABLE IF EXISTS t2;
Aging with Outstanding Insurance Claim info and Family Balances, summed by guarantor, includes procedure date of oldest outstanding sent claim, last statement date and last payment made - WARNING: This query could lock up your database if you have a large database.
/*239 Aging with Outstanding Insurance Claim info and Family Balances, summed by
guarantor, includes procedure date of oldest outstanding sent claim, last statement date and
last payment made, does not fit on one sheet*/
/*WARNING: This query could lock up your database if you have a large database.*/
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count', B.*
FROM (
SELECT A.Guarantor,
SUM(A.BalTotal) AS '$Fam-',
SUM(A.Bal_0_30) AS '$0-30-',
SUM(A.Bal_31_60) AS '$31-60-',
SUM(A.Bal_61_90)AS '$61-90-',
SUM(A.BalOver90)AS '$+90-',
SUM(A.Claims) AS '#Claims',
SUM(A.ClaimAmts) AS '$Claims-',
MIN(LastClaim) AS 'OldestCL', MAX(LastPay) AS 'LastPay', MAX(LastStmnt) AS 'LastStmnt',
pn.FamFinancial
FROM (
SELECT p.PatNum, p.Guarantor, BalTotal ,
Bal_0_30, Bal_31_60, Bal_61_90, BalOver90,
(SELECT COUNT(*) FROM claim WHERE claim.PatNum=p.PatNum AND
(claim.ClaimStatus='W' OR claim.ClaimStatus='S') AND
claim.ClaimType<>'PreAuth') AS 'Claims',
(SELECT SUM(ClaimFee) FROM claim WHERE claim.PatNum=p.PatNum AND
(claim.ClaimStatus='W' OR claim.ClaimStatus='S')AND
claim.ClaimType<>'PreAuth') AS 'ClaimAmts',
(SELECT SUM(InsPayEst) FROM claim WHERE claim.PatNum=p.PatNum AND
(claim.ClaimStatus='W' OR claim.ClaimStatus='S')AND
claim.ClaimType<>'PreAuth') AS 'InsEst',
(SELECT MIN(DateService) FROM claim WHERE claim.PatNum=p.PatNum AND
claim.ClaimStatus='S' AND claim.ClaimType<>'PreAuth')
AS 'LastClaim', /*proc date of oldest sent claim outstanding*/
(SELECT MAX(DatePay) FROM paysplit WHERE paysplit.PatNum=p.PatNum)
AS 'LastPay',
(SELECT MAX(DateSent) FROM statement WHERE statement.PatNum=p.PatNum OR statement.PatNum=p.Guarantor) AS
'LastStmnt'
FROM patient p WHERE EstBalance>0 OR BalTotal>0
) A
INNER JOIN patient p ON A.Guarantor=p.PatNum
INNER JOIN patientnote pn ON A.Guarantor=pn.PatNum
GROUP BY A.Guarantor
ORDER BY p.LName, p.FName
) B;
Patients to Archive: Last visit X days ago for all active patients with balance less than given amount - helpful for archiving patients
/*240 Patients to Archive: Last visit X days ago for all active patients with balance < given amount
helpful for archiving patients*/
SET @BeforeDate=CURDATE()-INTERVAL 60 DAY;
SELECT p.PatNum, DATE_FORMAT(MAX(pl.ProcDate),'%m/%d/%Y') AS 'LastVisit',
g.BalTotal AS 'Family Balance'
FROM patient p
INNER JOIN patient g ON p.Guarantor=g.PatNum
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
LEFT JOIN adjustment adj ON adj.PatNum=p.PatNum
WHERE p.PatStatus=0 AND g.BalTotal<5 AND
/*it has been two months since last proc with balance<$5*/
pl.ProcDate<@BeforeDate AND pl.ProcStatus=2/*completed*/
GROUP BY pl.PatNum
ORDER BY p.LName, p.FName;
Patients with a specified insurance seen in date range -
/*241 Patients with a specified insurance seen in date range*/
SET @Start='2008-01-01' , @End='2009-01-30';
/*Adjust above Dates as needed*/
SET @pos=0;
SELECT @pos:=@pos+1 AS Count, carrier.CarrierName, patient.PatNum
FROM carrier, insplan, claim, claimproc, patient
WHERE insplan.PlanNum=claim.PlanNum AND
insplan.CarrierNum=carrier.CarrierNum AND
claimproc.ClaimNum=claim.ClaimNum AND
claimproc.PatNum=patient.PatNum AND
carrier.CarrierName LIKE('%delta%') AND
/*this is in case we need additional patient information*/
/*you can add any patient or insurance fields to the SELECT statement*/
ProcDate Between @Start AND @End
GROUP BY patient.PatNum, CarrierName
ORDER BY LName, FName;
Patients with a specified insurance seen in date range Who have a balance greater than given amoun -
/*242 Patients with a specified insurance seen in date range*/
/*Who have a balance greater than given amount*/
SET @Start='2008-01-01' , @End='2009-01-30';
/*Adjust above Dates as needed, adjust BalanceGreaterThan as needed in $*/
SET @Carrier='%delta%', @BalanceGreaterThan=5;
/*Change insurance carrier as needed, any part of carrier name like '%delta%'*/
SET @pos=0;
SELECT @pos:=@pos+1 AS Count, carrier.CarrierName, patient.PatNum, patient.EstBalance as '$PatBalance'
FROM carrier, insplan, claim, claimproc, patient
WHERE insplan.PlanNum=claim.PlanNum AND
insplan.CarrierNum=carrier.CarrierNum AND
claimproc.ClaimNum=claim.ClaimNum AND
claimproc.PatNum=patient.PatNum AND
carrier.CarrierName LIKE(@Carrier) AND
/*this is in case we need additional patient information*/
/*you can add any patient or insurance fields to the SELECT statement*/
(ProcDate Between @Start AND @End)
AND patient.EstBalance>@BalanceGreaterThan
GROUP BY patient.PatNum, CarrierName
ORDER BY LName, FName;
Returns inactive, archived, deceased and nonpatients that have scheduled appointment with apt date and time - Limits to appointments scheduled for Today or later
/*243 Returns inactive, archived, deceased and nonpatients that have scheduled appointment with apt date and time
Limits to appointments scheduled for Today or later*/
SELECT p.PatNum, PatStatus, AptDateTime
FROM patient p
INNER JOIN appointment a ON p.PatNum=a.PatNum AND AptStatus=1
WHERE p.PatStatus<>0 AND AptDateTime>=CURDATE();
Outstanding Claims by Date of Service with PatNum, Amount billed insurance, Amount billed patient and Date sent - Edit Interval number if you want to change minimum time outstanding
/*245 Outstanding Claims by Date of Service with PatNum, Amount billed insurance, Amount billed patient and Date sent
Edit Interval number if you want to change minimum time outstanding*/
SELECT cl.PatNum, p.PatNum AS 'RawPatNum',cl.DateService,cl.DateSent,
ca.CarrierName, ca.Phone, cl.ClaimFee,
(SELECT SUM(ProcFee)-SUM(cp.WriteOff) FROM procedurelog pl INNER JOIN claimproc cp ON pl.ProcNum=cp.ProcNum WHERE cp.ClaimNum=cl.ClaimNum) AS '$PatBilled'
FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE
cl.ClaimType<>'PreAuth' AND cl.ClaimStatus<>'R' AND
DateService<(CURDATE()-INTERVAL 30 DAY)
ORDER BY ca.CarrierName,p.LName;
Claims of status 'Sent' or 'Received' by Date of Service with PatNum, Amount billed insurance, Amount billed patient and Date sent - Edit Dates to change date of service range
/*246 Claims of status 'Sent' or 'Received' by Date of Service with PatNum, Amount billed insurance, Amount billed patient and Date sent
Edit Dates to change date of service range*/
SET @FromDate='2009-01-01' , @ToDate='2009-01-31';
/*------------ DO NOT MODIFY BELOW THIS LINE ------------*/
/*Query code written/modified on: 02/07/2019*/
SELECT cl.PatNum, p.PatNum AS 'RawPatNum',cl.DateService,cl.DateSent,
ca.CarrierName, ca.Phone, cl.ClaimFee,
(SELECT SUM(pl.ProcFee*(pl.BaseUnits+pl.UnitQty))-SUM(cp.WriteOff) FROM procedurelog pl INNER JOIN claimproc cp ON pl.ProcNum=cp.ProcNum WHERE cp.ClaimNum=cl.ClaimNum) AS '$PatBilled'
FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE
cl.ClaimType<>'PreAuth' AND (cl.ClaimStatus='R' OR cl.ClaimStatus='S') AND
(DateService BETWEEN @FromDate AND @ToDate)
ORDER BY ca.CarrierName,p.LName;
List of patients with appointments for a date range (in future or past) with primary insurance carrier listed - Also lists sum of fees for day and insurance type
/*247 List of patients with appointments for a date range (in future or past) with primary insurance carrier listed
Also lists sum of fees for day and insurance type*/
SET @FromDate='2010-01-01' , @ToDate='2010-01-31';
SELECT p.PatNum, a.AptDateTime,
(CASE WHEN ISNULL(carrier.CarrierName) THEN '*No Insurance' ELSE (carrier.CarrierName) END) AS 'PriCarrier', SUM(pl.ProcFee) AS '$Fees',
(CASE WHEN ip.PlanType='' THEN 'Category Percentage'
WHEN ip.PlanType='p' THEN 'PPO'
WHEN ip.PlanType='f' THEN 'FlatCopay'
WHEN ip.PlanType='c' THEN 'Capitation'
ELSE 'Unknown' END) AS PlanType
FROM appointment a
INNER JOIN procedurelog pl ON a.AptNum=pl.AptNum
LEFT JOIN patient p ON p.PatNum=a.PatNum /*just in case we need field FROM patient table*/
LEFT JOIN patplan pp ON pp.PatNum=p.PatNum AND ORDINAL=1/*by current primary insurance*/
LEFT JOIN inssub ON pp.InsSubNum=inssub.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=inssub.PlanNum
LEFT JOIN carrier ON carrier.CarrierNum=ip.CarrierNum
WHERE (DATE(a.AptDateTime) BETWEEN @FromDate AND @ToDate) AND a.AptStatus IN (1,2,4)
GROUP BY a.AptNum
ORDER BY a.AptDateTime;
List of patients with appointments for Today with primary insurance carrier listed - Also lists sum of fees for day and insurance type
/*248 List of patients with appointments for Today with primary insurance carrier listed
Also lists sum of fees for day and insurance type*/
SET @FromDate=CURDATE() , @ToDate=CURDATE();
SELECT p.PatNum, a.AptDateTime,
(CASE WHEN ISNULL(carrier.CarrierName) THEN '*No Insurance' ELSE (carrier.CarrierName) END) AS 'PriCarrier', SUM(pl.ProcFee) AS '$Fees',
(CASE WHEN ip.PlanType='' THEN 'Category Percentage'
WHEN ip.PlanType='p' THEN 'PPO'
WHEN ip.PlanType='f' THEN 'FlatCopay'
WHEN ip.PlanType='c' THEN 'Capitation'
ELSE 'Unknown' END) AS PlanType
FROM appointment a
INNER JOIN patient p ON p.PatNum=a.PatNum /*just in case we need field from patient table*/
INNER JOIN procedurelog pl ON a.AptNum=pl.AptNum AND (DATE(a.AptDateTime) BETWEEN @FromDate AND @ToDate) AND a.AptStatus IN (1,2,4)
LEFT JOIN patplan pp ON pp.PatNum=p.PatNum AND ORDINAL=1/*by current primary insurance*/
LEFT JOIN inssub iss ON pp.InsSubNum=iss.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=iss.PlanNum
LEFT JOIN carrier ON carrier.CarrierNum=ip.CarrierNum
GROUP BY a.AptNum
ORDER BY a.AptDateTime;
Lifetime income from new patients that started in date range - Also includes patient address and date of first visit
/*249 Lifetime income from new patients that started in date range
Also includes patient address and date of first visit*/
SET @FromDate='2009-01-01' , @ToDate='2009-1-31';
SELECT patient.PatNum, patient.Address, patient.Address2, patient.City, patient.State, patient.zip, patient.DateFirstVisit,
(YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) AS 'Age',
(SELECT SUM(SplitAmt) FROM paysplit WHERE paysplit.PatNum=patient.PatNum GROUP BY patient.patnum) AS '$Pat Revenue',
(SELECT SUM(InsPayAmt)
FROM claim WHERE claim.PatNum=patient.PatNum) AS '$Ins Revenue',
(SELECT SUM(ProcFee) FROM procedurelog WHERE procedurelog.ProcStatus=1 AND procedurelog.PatNum=patient.PatNum GROUP BY patient.patnum) As '$Treatment Planned' FROM patient
WHERE DateFirstVisit BETWEEN @FromDate AND @ToDate;
Patient lifetime revenue and insurance revenue and TP'd procedure totals - (also includes PatNum and patient age, demographic marketing query) Like 59 but also shows insurance income associated with patient
/*250 Patient lifetime revenue and insurance revenue and TP'd procedure totals (also
includes PatNum and patient age, demographic marketing query) Like 59 but also shows insurance income associated with patient*/
SELECT PatNum, (YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) AS 'Age', (SELECT SUM(SplitAmt)
FROM paysplit WHERE paysplit.PatNum=patient.PatNum) AS '$PatientPaySum',
(SELECT SUM(InsPayAmt)
FROM claim WHERE claim.PatNum=patient.PatNum) AS '$InsPaySum',
(SELECT SUM(ProcFee) FROM procedurelog WHERE procedurelog.ProcStatus=1 AND
procedurelog.PatNum=patient.PatNum) AS '$Treatment Planned' FROM
patient ORDER BY LName;
Active Patients listed with primary Insurance Carrier, Birthdate, Name and Address - Sorted by day of month for birthday, can be easily change, Add Address2 if needed
/*251 Active Patients listed with primary Insurance Carrier, Birthdate, Name and Address*/
/*Sorted by day of month for birthday, can be easily change, Add Address2 if needed*/
SET @BirthMonth = 2; /*Change to desired month*/
SELECT p.LName, p.FName,
(YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) AS 'Age',
p.BirthDate,p.Address, p.Address2, p.City, p.State, p.ZIP, LEFT(carrier.CarrierName,15) AS 'Ins Abbr'
FROM carrier
INNER JOIN insplan ip ON carrier.CarrierNum=ip.CarrierNum
INNER JOIN inssub i ON i.PlanNum=ip.PlanNum
INNER JOIN patplan pp ON pp.InsSubNum=i.InsSubNum
INNER JOIN patient p ON pp.PatNum=p.PatNum
AND ordinal=1
WHERE p.PatStatus=0
AND MONTH(p.BirthDate) = @BirthMonth
ORDER BY DAY(BirthDate),CarrierName,p.LName, p.FName;
Treatment planned work totalled by patient with annual ins max, ins used and name of carrier - Warning - may be slow
/*252 Treatment planned work totalled by patient with annual ins max, ins used and name of carrier*/
SELECT p.PatNum AS 'Pat#',
p.LName,
p.FName,
annualmax.AnnualMax '$AnnualMax_',
used.AmtUsed '$AmountUsed_',
annualmax.AnnualMax-COALESCE(used.AmtUsed,0) '$AmtRemaining_',
planned.AmtPlanned '$TreatmentPlan_',
c.CarrierName
FROM patient p
INNER JOIN patplan ON p.PatNum=patplan.PatNum
INNER JOIN inssub ON inssub.InsSubNum=patplan.InsSubNum
INNER JOIN insplan ip ON ip.PlanNum=inssub.PlanNum
INNER JOIN carrier c ON c.CarrierNum=ip.CarrierNum
INNER JOIN (
SELECT benefit.PlanNum,
MAX(benefit.MonetaryAmt) AS AnnualMax
FROM benefit
LEFT JOIN covcat ON covcat.CovCatNum = benefit.CovCatNum
WHERE benefit.BenefitType = 5 /* limitation */
AND benefit.TimePeriod = 2 /* calendar year */
AND (covcat.EbenefitCat=1 OR ISNULL(covcat.EbenefitCat))
AND benefit.MonetaryAmt > 0 /* (-1) indicates empty */
GROUP BY benefit.PlanNum
) annualmax ON annualmax.PlanNum=inssub.PlanNum
INNER JOIN (
SELECT patient.PatNum,SUM(pl.ProcFee) AS AmtPlanned
FROM patient
INNER JOIN (
SELECT PatNum,ProcFee FROM procedurelog WHERE ProcStatus=1 /*treatment planned*/ AND ProcFee!=0
) pl ON patient.PatNum=pl.PatNum
WHERE patient.PatStatus=0 /* Patient */
GROUP BY patient.PatNum
) planned ON planned.PatNum=p.PatNum AND planned.AmtPlanned>0
LEFT JOIN (
SELECT patplan.PatPlanNum,
SUM(claimproc.InsPayAmt) AS AmtUsed
FROM claimproc
INNER JOIN inssub ON claimproc.InsSubNum=inssub.InsSubNum
INNER JOIN patplan ON inssub.InsSubNum=patplan.InsSubNum
AND patplan.PatNum=claimproc.PatNum
WHERE claimproc.Status IN (1, 3, 4) -- Rec, Adj, Supp.
AND YEAR(claimproc.ProcDate)=YEAR(CURDATE())
AND claimproc.InsPayAmt!=0
GROUP BY patplan.PatPlanNum
) used ON used.PatPlanNum=patplan.PatPlanNum
WHERE PatStatus=0
ORDER BY c.CarrierName;
Aging report only including families that have any member of family with a particular carrier - SEE REPLICATION WARNING for versions before 14.3.1. Also includes # of open claims and the sum of the open claim amounts
/*253 Aging report only including families that have any member of family with a particular carrier
Also includes # of open claims and the sum of the open claim amounts*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @pos=0, @CarrierString='%delta%';/*change carrier name here*/
DROP TABLE IF EXISTS tmp1;
CREATE TABLE tmp1
SELECT p.PatNum, p.Guarantor, BalTotal ,
Bal_0_30, Bal_31_60, Bal_61_90, BalOver90,
(SELECT COUNT(*) FROM claim WHERE claim.PatNum=p.PatNum AND
(claim.ClaimStatus='W' OR claim.ClaimStatus='S') AND
claim.ClaimType<>'PreAuth') AS 'Claims',
(SELECT SUM(ClaimFee) FROM claim WHERE claim.PatNum=p.PatNum AND
(claim.ClaimStatus='W' OR claim.ClaimStatus='S')AND
claim.ClaimType<>'PreAuth') AS 'ClaimAmts',
(SELECT SUM(InsPayEst) FROM claim WHERE claim.PatNum=p.PatNum AND
(claim.ClaimStatus='W' OR claim.ClaimStatus='S')AND
claim.ClaimType<>'PreAuth') AS 'InsEst',
(SELECT COUNT(*) FROM patplan
LEFT JOIN inssub ib ON ib.InsSubNum=patplan.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=ib.PlanNum
LEFT JOIN carrier c ON c.CarrierNum=ip.CarrierNum
WHERE CarrierName LIKE (@CarrierString) AND
p.PatNum=patplan.PatNum AND ordinal=1) AS PatPlanCount
FROM patient p;
SELECT @pos:=@pos+1 AS 'Count',tmp1.Guarantor,
SUM(tmp1.BalTotal) AS '$Fam-',
SUM(tmp1.Bal_0_30) AS '$0-30-',
SUM(tmp1.Bal_31_60) AS '$31-60-',
SUM(tmp1.Bal_61_90)AS '$61-90-',
SUM(tmp1.BalOver90)AS '$+90-',
SUM(tmp1.Claims) AS '#Claims',
SUM(tmp1.ClaimAmts) AS '$Claims-',
SUM(tmp1.PatPlanCount) AS 'PatPlansMatch'
FROM tmp1
INNER JOIN patient p ON tmp1.Guarantor=p.PatNum
WHERE p.BalTotal>0.009
GROUP BY tmp1.Guarantor
HAVING SUM(tmp1.PatPlanCount)>0
ORDER BY p.LName, p.FName;
DROP TABLE IF EXISTS tmp1;
ALL Fee Schedules all procedures, arranged by category with fees - Set fee schedule name at top
/*254 ALL Fee Schedules all procedures, arranged by category with fees
usually you will have to export to spreadsheet to view, format in spreadsheet*/
SET @FeeSched='%%';
SELECT fee.FeeSched, d.ItemName AS 'Category',pc.Descript,pc.ProcCode, fee.Amount
FROM fee
INNER JOIN feesched fs ON fee.FeeSched= fs.FeeSchedNum AND fs.Description LIKE @FeeSched
INNER JOIN ProcedureCode pc ON fee.CodeNum = pc.CodeNum
INNER JOIN definition d ON d.DefNum = pc.ProcCat
ORDER BY fs.Description,Category, pc.ProcCode
Production by patient, procedures completed Today with primary insurance carrier listed - Also lists sum of fees for day and insurance type, does not consider adjustments or writeoffs
/*255 Production by patient, procedures completed Today with primary insurance carrier listed
Also lists sum of fees for day and insurance type, does not consider adjustments or writeoffs*/
SET @FromDate=CURDATE()-interval 30 Day , @ToDate=CURDATE();
SELECT p.PatNum,
(CASE WHEN ISNULL(carrier.CarrierName) THEN '*No Insurance' ELSE (carrier.CarrierName) END) AS 'PriCarrier', SUM(pl.ProcFee) AS '$Fees',
(CASE WHEN ip.PlanType='' THEN 'Category Percentage'
WHEN ip.PlanType='p' THEN 'PPO'
WHEN ip.PlanType='f' THEN 'FlatCopay'
WHEN ip.PlanType='c' THEN 'Capitation'
ELSE 'Unknown' END) AS PlanType
FROM procedurelog pl
INNER JOIN patient p ON p.PatNum=pl.PatNum /*just in case we need field from patient table*/
LEFT JOIN patplan pp ON pp.PatNum=p.PatNum
LEFT JOIN inssub ib ON pp.InsSubNum=ib.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=ib.PlanNum
LEFT JOIN carrier ON carrier.CarrierNum=ip.CarrierNum
WHERE pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus=2/* complete*/
AND pp.ORDINAL=1/*by current primary insurance*/
GROUP BY p.PatNum;
Appointments that are broken for a date range, with note -
/*256 Appointments that are broken for a date range, with note*/
SET @FromDate='2009-01-01', @ToDate='2009-02-28' ;/*change dates here*/
SELECT p.LName,p.FName, p.PatNum AS 'Pat#', a.AptDateTime, a.Note
FROM appointment a
INNER JOIN patient p ON a.PatNum=p.PatNum
WHERE DATE(a.AptDateTime) BETWEEN @FromDate AND @ToDate
AND a.AptStatus=5
ORDER BY a.AptDateTime;
Procedures completed with claims made to a specified insurance carrier in date range matching the procedures in list - with patient name and date of procedure, fee, amount paid
/*257 Procedures completed with claims made to a specified insurance carrier in date range
matching the procedures in list with patient name and date of procedure, fee, amount paid*/
SET @FromDate='2008-01-01', @Todate='2008-12-31', @Carrier='%delta%';
/*Adjust above Dates and Carier as needed*/
SELECT carrier.CarrierName, claimproc.PatNum, DATE_FORMAT(procedurelog.ProcDate,'%m/%d/%Y') AS 'Service Date',
procedurecode.ProcCode,
claimproc.InsPayAmt as 'InsPaid', procedurelog.ProcFee as 'Fee'
FROM carrier
INNER JOIN insplan ON carrier.CarrierNum=insplan.CarrierNum
INNER JOIN claim ON insplan.PlanNum=claim.PlanNum
INNER JOIN claimproc ON claim.ClaimNum=claimproc.ClaimNum
INNER JOIN procedurelog ON claimproc.ProcNum=procedurelog.ProcNum
INNER JOIN procedurecode ON procedurelog.CodeNum=procedurecode.CodeNum
AND procedurelog.ProcDate >= @FromDate
AND procedurelog.ProcDate < @ToDate
AND ProcStatus=2
AND carrier.CarrierName LIKE(@Carrier)
AND ProcCode IN('D3310', 'D3320','D3330')
ORDER BY CarrierName;
New Patients with referral source, gross production completed in date range with ZIP and Age - For Versions 17.1 and greater. Please update your version accordingly
/*258 New Patients with referral source, gross production completed in date range with ZIP and Age*/
/*For Versions 17.1 and greater. Please update your version accordingly*/
/*Query code written/modified: 04/11/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2018-01-01', @ToDate='2018-01-31';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SET @pos=0;
SELECT @pos:=@pos+1 AS '#',
pattable.*
FROM (
SELECT DateFirstVisit,
patient.PatNum,
r.LName AS RefLName,
r.FName AS RefFName,
(
SELECT SUM(procedurelog.ProcFee)
FROM procedurelog
WHERE ProcStatus=2
AND procedurelog.PatNum=patient.PatNum
AND procedurelog.ProcDate BETWEEN @FromDate AND @ToDate
) AS '$Complete__' ,
(YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) AS 'Age',
patient.PatStatus,
patient.Zip
FROM patient
LEFT JOIN refattach ra ON patient.PatNum=ra.PatNum
LEFT JOIN referral r ON r.ReferralNum=ra.ReferralNum
AND ra.RefType = 1 /*RefFrom*/
WHERE DateFirstVisit BETWEEN @FromDate AND @ToDate
ORDER BY DateFirstVisit, patient.LName, Patient.FName
)pattable;
Outstanding insurance total for a time period, insurance estimates, writeoffs, with carrier information -
/*259 Outstanding insurance total for a time period, insurance estimates, writeoffs, with carrier information*/
SET @FromDate='2009-02-01' , @ToDate='2009-02-28';
SELECT cl.PatNum,cl.InsPayEst,cl.ClaimFee, cl.Writeoff,cl.DateService,cl.DateSent, ca.CarrierName, ca.Phone FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE cl.ClaimStatus='S' AND
(DateService BETWEEN @FromDate AND @ToDate) AND
ClaimType<>'PreAuth'
ORDER BY ca.CarrierName,p.LName;
Get questionaire results for export and analysis - Replace term 'married' with desired search term or eliminate all between the %% to return all questions
/*260 Get questionaire results for export and analysis
Replace term 'married' with desired search term or eliminate all between the %% to return all questions*/
SELECT Description, Answer, COUNT(Answer) FROM question WHERE description LIKE ('%married%') GROUP BY Description, Answer
Last visit before given date for all active patients with phone - Also shows last seen date for 1 specified provider
/*261 Last visit before given date for all active patients with phone
Also shows last seen date for 1 specified provider*/
SET @pos=0, @FromDate='2008-01-01'; /*Change Date Here*/
SELECT @pos:=@pos+1 AS '#', p.PatNum, LEFT(WkPhone,16) AS WkPhone,
LEFT(HmPhone,16) AS HmPhone, LEFT(WirelessPhone,16) AS CellPhone,
DATE_FORMAT(MAX(ProcDate),'%m/%d/%Y') AS 'LastVis-Any',
(SELECT DATE_FORMAT(MAX(pl2.ProcDate),'%m/%d/%Y')
FROM procedurelog pl2 WHERE pl2.ProcStatus=2 AND p.PatNum=pl2.PatNum
AND pl2.ProvNum =4 /*set provnum here, 4*/) AS 'LastVisit-Spec'
FROM patient p
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
WHERE (pl.ProcStatus=2) AND (p.PatStatus=0) AND (pl.ProcDate<=@FromDate)
GROUP BY pl.PatNum
ORDER BY p.LName, p.FName;
Insurance plans for patients of a given carrier, with guarantor, social security number and birth date -
/*262 Insurance plans for patients of a given carrier, with guarantor, social security number and birth date*/
Set @Carrier='%delta%';
SELECT p.PatNum, c.CarrierName, p.SSN, p.BirthDate
FROM carrier c
INNER JOIN insplan ip ON c.CarrierNum=ip.CarrierNum
INNER JOIN inssub ib ON ib.PlanNum=ip.PlanNum
INNER JOIN patplan pp ON pp.InsSubNum=ib.InsSubNum
INNER JOIN patient p ON pp.PatNum=p.PatNum
WHERE
c.CarrierName Like(@Carrier)
ORDER BY p.LName, p.FName;
claim count by insurance carrier for date range with sum of fees, estimates and paid amounts -
/*263 Claim count by insurance carrier for date range with sum of fees, estimates and paid amounts*/
SET @FromDate='2009-01-01' , @ToDate='2009-01-31';
SELECT ca.CarrierName, ca.Phone, COUNT(cl.ClaimNum) AS '#Claims',
FORMAT(100*(COUNT(cl.ClaimNum)/(SELECT COUNT(claim.ClaimNum) FROM claim WHERE DateService BETWEEN @FromDate AND @ToDate)),2) AS '%Claims',
SUM(cl.ClaimFee) AS '$ClaimFees',
SUM(cl.InsPayEst) AS '$InsPayEst',
SUM(cl.InsPayAmt) AS '$InsPaidAmt'
FROM claim cl
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE
cl.ClaimType<>'PreAuth' AND (cl.ClaimStatus='R' OR cl.ClaimStatus='S') AND
(DateService BETWEEN @FromDate AND @ToDate)
GROUP BY ca.CarrierName
ORDER BY ca.CarrierName;
List of procedures for a date range with patient name, service date, procedure code, primary insurance carrier, fee, sum of ins est, sum ins paid -
/*264 List of procedures for a date range with patient name, service date, procedure code,
primary insurance carrier, fee, sum of ins est, sum ins paid*/
SET @FromDate='2009-01-01' , @ToDate='2009-1-31'; /* change date here, change list of proc codes below*/
SELECT p.PatNum, pl.ProcDate, pc.ProcCode,CarrierName AS 'PriInsName',pl.ProcFee,
(SELECT SUM(cp.InsPayEst) FROM claimproc cp WHERE cp.ProcNum=pl.ProcNum AND cp.Status IN (0,1,4)) AS '$InsPayEst',
(SELECT SUM(cp.InsPayAmt) FROM claimproc cp WHERE cp.ProcNum=pl.ProcNum AND cp.Status IN (1,4)) AS '$InsPaidAmt'
FROM procedurelog pl
INNER JOIN patient p ON p.PatNum=pl.PatNum /*just in case we need field from patient table*/
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
LEFT JOIN patplan pp ON pp.PatNum=p.PatNum AND ORDINAL=1/*by current primary insurance*/
LEFT JOIN inssub iss ON pp.InsSubNum=iss.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=iss.PlanNum
LEFT JOIN carrier ON carrier.CarrierNum=ip.CarrierNum
WHERE pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus=2 /*AND pc.ProcCode IN('D1310', 'D3320','D3330') un-comment and change to limit to specific procedures*/
GROUP BY pl.ProcNum
ORDER BY pl.ProcDate, p.LName,p.FName;
All referrals in date range, with additional referral information - For Versions 17.1 and greater. Please update your version accordingly. Columns may be added or removed. As is you need to export to a spreadsheet to print due to width.
/*265 All referrals in date range, with additional referral information*/
/*For Versions 17.1 and greater. Please update your version accordingly*/
/*Query code written/modified: 04/11/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2018-01-01', @ToDate='2018-01-31';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count',
reftable.*
FROM (
SELECT p.PatNum,
rf.FName,
rf.LName,
rf.Address,
rf.City,
rf.St,
rf.Zip,
rf.Telephone,
ra.RefType,
rf.Specialty,
DATE_FORMAT(ra.RefDate,'%m/%d/%Y') AS RefDate
FROM patient p
INNER JOIN refattach ra ON p.PatNum=ra.PatNum
AND ra.RefDate BETWEEN @FromDate AND @ToDate
INNER JOIN referral rf ON ra.ReferralNum=rf.ReferralNum
ORDER BY rf.LName, rf.FName
)reftable;
Monthly production and income report - SEE REPLICATION WARNING for versions before 14.3.1. counts insurance writeoffs by procedure date (PPO) For all providers
/*266 Monthly production and income report counts insurance writeoffs by procedure date (PPO) For all providers*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS t1,t2;
SET @FromDate='2009-03-01' , @ToDate='2009-03-31';
CREATE TABLE t1(
Day int NOT NULL,
Date date,
DayOfWeek varchar(10),
$Production double NOT NULL DEFAULT 0,
$Adjustments double NOT NULL DEFAULT 0,
$WriteOffs double NOT NULL DEFAULT 0,
$TotProduction double NOT NULL DEFAULT 0,
$PatIncome double NOT NULL DEFAULT 0,
$InsIncome double NOT NULL DEFAULT 0,
$TotIncome double NOT NULL DEFAULT 0);
/*Load Days of month*/
INSERT INTO t1(Day)
VALUES (1),(2),(3),(4),(5),(6),(7),(8),(9),(10),(11),(12),(13),(14),(15),(16),(17),(18),(19),(20),(21),(22),(23),(24),(25),(26),(27),(28),(29),(30),(31);
DELETE FROM t1 WHERE Day>DAY(LAST_DAY(@FromDate));
UPDATE t1 SET Date=STR_TO_DATE(CONCAT(MONTH(@FromDate), '/', Day, '/', YEAR(@FromDate)),'%c/%e/%Y');
UPDATE t1 SET DayOfWeek=DATE_FORMAT(Date, '%W');
/*Prod*/
CREATE TABLE t2
SELECT DAYOFMONTH(pl.ProcDate) AS 'Day',
SUM(pl.procfee) AS 'Production'
FROM procedurelog pl WHERE pl.ProcStatus=2 AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY DAYOFMONTH(pl.ProcDate);
UPDATE t1,t2 SET t1.$Production=t2.Production WHERE t1.Day=t2.Day;
DROP TABLE IF EXISTS t2;
/*Adj*/
CREATE TABLE t2
SELECT DAYOFMONTH(a.AdjDate) AS 'Day',
SUM(a.AdjAmt) AS 'Adjustments' FROM adjustment a
WHERE a.AdjDate BETWEEN @FromDate AND @ToDate
GROUP BY DAYOFMONTH(a.AdjDate);
UPDATE t1,t2 SET t1.$Adjustments=t2.Adjustments WHERE t1.Day=t2.Day;
DROP TABLE IF EXISTS t2;
/*PatInc*/
CREATE TABLE t2
SELECT DAYOFMONTH(pp.DatePay) AS 'Day',
SUM(pp.SplitAmt) AS 'PatIncome' FROM paysplit pp
WHERE pp.DatePay BETWEEN @FromDate AND @ToDate
GROUP BY DAYOFMONTH(pp.DatePay);
UPDATE t1,t2 SET t1.$PatIncome=t2.PatIncome WHERE t1.Day=t2.Day;
DROP TABLE IF EXISTS t2;
/*InsIncome*/
CREATE TABLE t2
SELECT DAYOFMONTH(cp.ProcDate) AS 'Day',
SUM(cp.WriteOff) AS 'WriteOffs'
FROM claimproc cp
WHERE (cp.Status=1 OR cp.Status=4 OR cp.Status=0)
AND cp.ProcDate BETWEEN @FromDate AND @ToDate /*vs DateCP if not counting writeoffs by procdate*/
GROUP BY DAYOFMONTH(cp.ProcDate);
UPDATE t1,t2 SET
t1.$WriteOffs=-t2.WriteOffs
WHERE t1.Day=t2.Day;
DROP TABLE IF EXISTS t2;
/*InsIncome*/
CREATE TABLE t2
SELECT DAYOFMONTH(cpay.CheckDate) AS 'Day',
SUM(cp.InsPayAmt) AS 'InsIncome'
FROM claimproc cp
INNER JOIN claimpayment cpay ON cpay.ClaimPaymentNum=cp.ClaimPaymentNum
WHERE cpay.CheckDate BETWEEN @FromDate AND @ToDate AND
cp.Status IN(1,4)
GROUP BY DAYOFMONTH(cpay.CheckDate);
UPDATE t1,t2 SET t1.$InsIncome=t2.InsIncome
WHERE t1.Day=t2.Day;
UPDATE t1 SET
$TotProduction=$Production+$Adjustments+$WriteOffs,
$TotIncome=$InsIncome+$PatIncome ;
DROP TABLE IF EXISTS t2;
ALTER TABLE t1 DROP Day;
SELECT * FROM t1;
DROP TABLE IF EXISTS t1;
Phone numbers and status of patients in a given zipcode -
/*267 Phone numbers and status of patients in a given zipcode*/
SELECT PatNum, ZIP, LEFT(WkPhone, 15) AS WkPhone, LEFT(WirelessPhone, 15) AS 'CellPhone', LEFT(HmPhone, 15) AS HmPhone, PatStatus FROM Patient
WHERE ZIP LIKE '85747%'
ORDER BY PatStatus, LName, FName;
Basic deposit query, returns date of deposit and amount in given date range - Change date range as needed
/*268 Very basic deposit query, returns date of deposit and amount in given date range
Change date range as needed*/
SET @FromDate='2009-02-01', @ToDate='2014-02-28';
SELECT DateDeposit, Amount
FROM deposit
WHERE DateDeposit BETWEEN @FromDate AND @ToDate
ORDER BY DateDeposit
new patient count by zip code - with total
/*269 New patient count by zip code
with total*/
SET @NewSinceDate='2009-02-01';
SELECT ZIP, Count(ZIP) AS '#New Patients' FROM Patient
WHERE PatStatus=0 AND DateFirstVisit>=@NewSinceDate
GROUP BY ZIP
UNION
SELECT 'Total', Count(ZIP) AS '#New Patients' FROM Patient
WHERE PatStatus=0 AND DateFirstVisit>=@NewSinceDate;
Outstanding Preauth Procedures by Date of Service with Procedure Codes - Edit interval if desired, currently older than 30 days
/*270 Outstanding Preauth Procedures by Date of Service
with Procedure Codes, edit interval if desired, currently older than 30 days*/
SELECT cl.PatNum, p.PatNum AS 'RawPatNum',cl.DateSent, ca.CarrierName, ca.Phone, pl.ProcFee, pc.ProcCode FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
INNER JOIN claimproc cp ON cp.ClaimNum=cl.ClaimNum
INNER JOIN procedurelog pl ON pl.ProcNum=cp.ProcNum
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
WHERE
cl.ClaimType='PreAuth' AND cl.ClaimStatus='S' AND
DateSent<(CURDATE()-INTERVAL 30 DAY)
ORDER BY DateSent, p.LName, p.FName;
Outstanding insurance claims by Date of Service not including Preauths with fee total and insurance payment estimate -
/*271 Outstanding insurance claims by Date of Service not including Preauths with fee total and insurance payment estimate*/
SELECT cl.PatNum,cl.DateService,cl.DateSent, cl.ClaimFee, cl.InsPayEst, ca.CarrierName, ca.Phone FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE cl.ClaimStatus='S' AND
DateService<(CURDATE()-INTERVAL 30 DAY) AND
ClaimType<>'PreAuth'
ORDER BY cl.DateService;
Calculate current or historical accounts receivable, collectible, outstanding insurance estimates - SEE REPLICATION WARNING for versions before 14.3.1.
/*272 Calculate current or historical accounts receivable, collectible, outstanding insurance estimates
note that when compared to an aging report, the ins estimate includes ins from accounts with both positive
and negative balances*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @AsOf='2009-02-28'; /*use this instead to always show today SET @AsOf=CURDATE(); */
/*first create transaction table*/
DROP TABLE IF EXISTS tmp1, tmp2, tmp3, tmp4;
CREATE TABLE tmp1
(PatNum INT DEFAULT 0,
TranDate DATE DEFAULT '0001-01-01',
TranAmount DOUBLE DEFAULT 0);
/*Get the completed procedure dates and charges for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2;
/*Paysplits for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/;
/*Get the adjustment dates and amounts for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount
FROM adjustment a;
/*Claim payments and capitation writeoffs for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT cp.PatNum PatNum,
cp.DateCp TranDate,-cp.InsPayAmt-cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.status IN (1,4,5,7);/*received, supplemental, CapClaim or CapComplete*/
/*Payment plan principal for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT pp.PatNum PatNum,
pp.PayPlanDate TranDate,
-pp.CompletedAmt TranAmount
FROM payplan pp;
/*now we need to include the anticipated insurance (sum of payments and writeoffs)
note that if you use PPO type, your anticipated writeoff numbers will have updated to
match your actual writeoff numbers... your best bet is to keep backups or paper copies of your
reports if that change is bothersome */
/*Now Note that as we get these numbers we are summing by family, when really we
are looking for a grand total, this is to make it easier to get the details should we need them
from the tmp tables*/
CREATE TABLE tmp3 SELECT p.Guarantor,SUM(cp.InsPayEst) InsPayEst,
(CASE WHEN ISNULL(SUM(cp.Writeoff)) THEN 0 ELSE SUM(cp.WriteOff) END) WriteOff
FROM patient p INNER JOIN claimproc cp ON cp.PatNum=p.PatNum
WHERE ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR /* still not recieved and procedure completed before the date*/
(cp.Status IN(1,4) AND cp.DateCP>@AsOf AND cp.ProcDate<=@AsOf)) /*was received after the date of interes and completed before it*/
/*AND p.PatStatus NOT IN(4,3) not archived*/
GROUP BY p.Guarantor;
CREATE TABLE tmp2
SELECT Guarantor, SUM(TranAmount) AS 'FamBal' FROM patient
INNER JOIN tmp1 ON tmp1.PatNum=Patient.PatNum
WHERE TranDate<=@AsOf
GROUP BY Guarantor;
CREATE TABLE tmp4
SELECT 'AccountsReceivable' AS 'Description', SUM(FamBal) '$Value' FROM tmp2
WHERE FamBal>0
UNION
SELECT 'AccountsPayable' AS 'Description', SUM(FamBal) '$Value' FROM tmp2
WHERE FamBal<0
UNION
SELECT 'TotPracticeBalance' AS 'Description', SUM(FamBal) '$Value' FROM tmp2
UNION
SELECT 'TotInsPayEst' AS 'Description', SUM(InsPayEst) '$Value' FROM tmp3
UNION
SELECT 'TotWriteOffEst' AS 'Description', SUM(WriteOff) '$Value' FROM tmp3
UNION
SELECT 'TotPatPortEst' AS 'Description',
(SUM(tmp2.FamBal)-SUM(tmp3.InsPayEst)-SUM(tmp3.WriteOff)) AS '$Value'
FROM tmp2 LEFT JOIN tmp3 ON tmp2.Guarantor=tmp3.Guarantor;
SELECT * FROM tmp4;
DROP TABLE IF EXISTS tmp1, tmp2, tmp3, tmp4;
Insurance (Estimates or Paid) for a month (by date of service) -
/*273 Insurance (Estimates or Paid) for a month (by date of service)*/
SET @FromDate='2009-03-01' , @ToDate='2009-03-31';
SELECT cl.PatNum,cl.InsPayEst,cl.InsPayAmt,cl.ClaimFee, cl.Writeoff AS '$Writeoff',cl.DateService,cl.DateSent, ca.CarrierName, ca.Phone FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE (cl.ClaimStatus='S' OR cl.ClaimStatus = 'R' OR cl.Claimstatus='W') AND
(cl.DateService BETWEEN @FromDate AND @ToDate) AND
ClaimType<>'PreAuth'
ORDER BY ca.CarrierName,p.LName;
Estimated Writeoffs Outstanding -
/*274 Estimated Writeoffs Outstanding*/
SELECT cl.PatNum,cl.InsPayEst,cl.InsPayAmt,cl.ClaimFee, cl.Writeoff AS '$Writeoff',cl.DateService,cl.DateSent, ca.CarrierName, ca.Phone FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE (cl.ClaimStatus='S' OR cl.Claimstatus='W') AND
ClaimType<>'PreAuth'
ORDER BY ca.CarrierName,p.LName;
Patients with balances who do not have insurance - (not family balance, patient balance)
/*275 Patients with balances who do not have insurance (not family balance, patient balance)*/
SELECT PatNum, EstBalance FROM patient p WHERE p.HasIns<>'I' AND p.EstBalance>0
Count Per Doctor of incoming referrals in date range with last referral date - For Versions 17.1 and greater. Please update your version accordingly
/*276 Count per doctor of incoming referrals in date range with last referral date.*/
/*For Versions 17.1 and greater. Please update your version accordingly*/
/*Query code written/modified: 04/11/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2017-01-01' , @ToDate='2017-12-31';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT SUM(RefType) AS '#InRange',
rf.FName,
rf.LName,
rf.Address,
rf.City,
rf.St,
rf.Zip,
DATE_FORMAT(MAX(ra.RefDate),'%m/%d/%Y') AS LastRefDate
FROM refattach ra
INNER JOIN referral rf ON ra.ReferralNum=rf.ReferralNum
WHERE ra.RefType = 1 /*RefFrom*/
AND ra.RefDate BETWEEN @FromDate AND @ToDate
GROUP BY rf.ReferralNum
ORDER BY rf.LName, rf.FName;
Incoming referrals with refdate for a doctor with a specific last name and (optional) first name - For Versions 17.1 and greater. Please update your version accordingly
/*277 Incoming referrals with refdate for a doctor with a specific last name and (optional) first name*/
/*For Versions 17.1 and greater. Please update your version accordingly*/
/*Query code written/modified: 04/11/2018*/
/*Change search term between '%%' symbols or leave as '%%' to run for all*/
SET @RefLName = '%%';
SET @RefFName = '%%';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT rf.FName,
rf.LName,
DATE_FORMAT(ra.RefDate,'%m/%d/%Y') RefDate,
ra.PatNum
FROM refattach ra
INNER JOIN referral rf ON ra.ReferralNum=rf.ReferralNum
AND rf.LName LIKE @RefLName AND rf.FName LIKE @RefFName
WHERE RefType = 1 /*RefFrom*/
ORDER BY rf.LName, rf.FName;
Pull patients with prescriptions for a specific drug in given Date range -
/*278 Pull patients with prescriptions for a specific drug in given Date range*/
SET @FromDate='2009-01-01' , @ToDate='2009-12-31';
SELECT PatNum, RxDate, Drug, Disp, Refills, ProvNum FROM rxpat
WHERE drug LIKE ('%Amoxicillin%') AND
RxDate BETWEEN @FromDate AND @ToDate;
Patient Refunds in Date Range -
/*279 Patient Refunds in Date Range */
SET @FromDate='2009-01-01' , @ToDate='2009-12-31';
select ps.PatNum, p.PayDate, ps.SplitAmt, p.CheckNum, p.PayNote FROM paysplit ps INNER JOIN payment p ON ps.PayNum=p.PayNum
WHERE ps.SplitAmt<0 AND p.PayDate BETWEEN @FromDate AND @ToDate;
Verification list for appointments on given date - Includes Carrier Phone and Procedures in Apt abbreviates to first 15 chars of carrier to save space
/*281 Verification list for appointments on given date*/
/*Includes Carrier Phone and Procedures in Apt
abbreviates to first 15 chars of carrier to save space*/
SET @Date='2009-04-28';/*set this date*/
SELECT p.PatNum, c.Phone,
GROUP_CONCAT(pc.AbbrDesc) AS ProceduresInApt,
LEFT(CarrierName,15) AS 'Carrier (abbr)'
FROM appointment a
INNER JOIN patient p ON a.PatNum=p.PatNum
LEFT JOIN patplan pp ON p.PatNum=pp.PatNum
LEFT JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum AND pp.ORDINAL=1
LEFT JOIN insplan ip ON ip.PlanNum=ib.PlanNum
LEFT JOIN carrier c ON c.CarrierNum=ip.CarrierNum
LEFT JOIN procedurelog pl ON pl.AptNum=a.AptNum
LEFT JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
WHERE DATE(a.AptDateTime) LIKE @Date
GROUP BY p.PatNum
ORDER BY LName, FName;
Number of procedures of each code completed with claims made to a specified insurance carrier in date range by provider - Includes Count, ave fee, sum of fees, sum amount paid
/*282 Number of procedures of each code completed with claims made to a specified insurance carrier in date range
by provider, Count, ave fee, sum of fees, sum amount paid*/
SET @FromDate='2008-03-01', @Todate='2009-02-28', @Carrier='%ryan%';
/*Adjust above Dates and Carier as needed*/
SELECT provider.Abbr AS 'Prov',carrier.CarrierName, procedurecode.ProcCode,
COUNT(procedurelog.ProcNum) AS '#Proc', SUM(procedurelog.ProcFee)/COUNT(procedurelog.ProcNum) AS '$FeeAve',
SUM(procedurelog.ProcFee) AS '$FeeTot',
SUM(claimproc.InsPayAmt) AS '$InsPayTot',SUM(claimproc.InsPayAmt)/COUNT(procedurelog.ProcNum) AS '$InsPayAve'
FROM carrier
INNER JOIN insplan ON carrier.CarrierNum=insplan.CarrierNum
INNER JOIN claim ON insplan.PlanNum=claim.PlanNum
INNER JOIN claimproc ON claim.ClaimNum=claimproc.ClaimNum
INNER JOIN procedurelog ON claimproc.ProcNum=procedurelog.ProcNum
INNER JOIN procedurecode ON procedurelog.CodeNum=procedurecode.CodeNum
INNER JOIN provider ON procedurelog.ProvNum=provider.ProvNum
WHERE procedurelog.ProcDate >= @FromDate
AND procedurelog.ProcDate < @ToDate
AND ProcStatus=2
AND carrier.CarrierName LIKE(@Carrier)
GROUP BY procedurelog.ProvNum, carrier.CarrierName, procedurecode.ProcCode
ORDER BY provider.Abbr,carrier.CarrierName, procedurecode.ProcCode;
Number of procedures of each code group (grouped by first two letters of proccode) completed with claims made to a specified insurance carrier in date range by provider - Includes Count, ave fee, sum of fees, sum amount paid
/*283 Number of procedures of each code group (grouped by first two letters of proccode)
completed with claims made to a specified insurance carrier in date range
by provider, Count, ave fee, sum of fees, sum amount paid*/
SET @FromDate='2008-03-01', @Todate='2009-02-28', @Carrier='%ryan%';
/*Adjust above Dates and Carier as needed*/
SELECT provider.Abbr AS 'Prov',carrier.CarrierName, LEFT(procedurecode.ProcCode,2) AS 'ProcGroup',
COUNT(procedurelog.ProcNum) AS '#Proc', SUM(procedurelog.ProcFee)/COUNT(procedurelog.ProcNum) AS '$FeeAve',
SUM(procedurelog.ProcFee) AS '$FeeTot',
SUM(claimproc.InsPayAmt) AS '$InsPayTot',SUM(claimproc.InsPayAmt)/COUNT(procedurelog.ProcNum) AS '$InsPayAve'
FROM carrier
INNER JOIN insplan ON carrier.CarrierNum=insplan.CarrierNum
INNER JOIN claim ON insplan.PlanNum=claim.PlanNum
INNER JOIN claimproc ON claim.ClaimNum=claimproc.ClaimNum
INNER JOIN procedurelog ON claimproc.ProcNum=procedurelog.ProcNum
INNER JOIN procedurecode ON procedurelog.CodeNum=procedurecode.CodeNum
INNER JOIN provider ON procedurelog.ProvNum=provider.ProvNum
WHERE procedurelog.ProcDate >= @FromDate
AND procedurelog.ProcDate < @ToDate
AND ProcStatus=2
AND carrier.CarrierName LIKE(@Carrier)
GROUP BY procedurelog.ProvNum, carrier.CarrierName, LEFT(procedurecode.ProcCode,2)
ORDER BY provider.Abbr,carrier.CarrierName, ProcGroup;
Labs received in the last 60 days with instructions - interval can be changed
/*284 Labs received in the last 60 days with instructions, interval can be changed*/
SELECT PatNum, l.Description, DateTimeSent,DateTimeRecd, ProvNum,Instructions
FROM labcase INNER JOIN laboratory l ON l.LaboratoryNum=labcase.LaboratoryNum WHERE DateTimeRecd >=curdate()-Interval 60 day
Archived and Inactive patients - with last seen date and completed procedure count
/*285 Archived and Inactive patients with last seen date and completed procedure count*/
SET @pos=0;
SELECT @pos:=@pos+1 as 'Count',A.* FROM
(SELECT patient.PatNum, LName, FName, DATE_FORMAT(MAX(ProcDate),'%m/%d/%Y') AS 'LastVisit',
COUNT(procedurelog.ProcNum) AS '# Procs Total' , PatStatus
FROM patient
INNER JOIN procedurelog ON procedurelog.PatNum=patient.PatNum
WHERE procedurelog.ProcStatus=2 AND patient.PatStatus IN(2,3)
GROUP BY procedurelog.PatNum
ORDER BY LName) A;
Accounts Receivable WHERE payments have not been made in last X days (30 by default) - summed by guarantor, includes last statement date and last payment made
/*286 Accounts Receivable WHERE payments have not been made in last X days (30 by default),
summed by guarantor, includes last statement date and
last payment made*/
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count', B.*
FROM (
SELECT p.Guarantor, A.BalTotal,
(SELECT MAX(DateSent) FROM statement WHERE statement.PatNum=p.PatNum) AS 'LastStatement',
MAX(ps.DatePay) 'LastPay',pn.FamFinancial
FROM (/*guarantors who have balances*/
SELECT p.Guarantor,
p.BalTotal
FROM patient p
WHERE p.BalTotal>=0.01 /*sometimes very small balances so 1 penny min*/
) A
INNER JOIN patient p ON A.Guarantor=p.Guarantor
LEFT JOIN paysplit ps ON ps.PatNum=p.PatNum
LEFT JOIN patientnote pn ON p.Guarantor=pn.PatNum
GROUP BY p.Guarantor
HAVING (CURDATE()-INTERVAL 30 DAY > IFNULL(MAX(ps.DatePay),'1900-01-01') )
)B;
Active patients - with PatNum, Date of First Visit and Address
/*287 Active patients with PatNum, Date of First Visit and Address*/
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count',A.*
FROM (
SELECT PatNum AS 'Pat#',PatNum,DateFirstVisit,Address,Address2,City,State,Zip
FROM patient
WHERE PatStatus=0
ORDER BY LName,FName
) A;
Treatment planned work that has not been saved to a treatment plan - excludes listed procedure code matches, like preventative work
/*288 Treatment planned work that has not been saved to a treatment plan
excludes listed procedure code matches, like preventative work*/
SET @FromDate='2009-05-01', @Todate='2009-05-31';
SELECT p.PatNum, pl.DateTp, pl.ToothNum, pc.ProcCode, pc.AbbrDesc, pl.ProcFee FROM patient p
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum AND p.PatStatus=0 AND pl.ProcStatus=1/*active patient w tp proc*/
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
LEFT JOIN treatplan tp ON tp.PatNum=p.PatNum
LEFT JOIN proctp pt ON pt.TreatPlanNum=tp.TreatPlanNum
/*Limit to current patients with saved treatment plans*/
WHERE ISNULL(pt.TreatPlanNum) AND pl.DateTP BETWEEN @FromDate AND @ToDate
AND pc.ProcCode NOT LIKE ('D1%') AND pc.ProcCode NOT LIKE('D0%') /*not preventative, cleaning etc, this condition can be easily remove*/
ORDER BY p.LName, p.FName,pl.DateTP,pl.ToothNum;
Questionaire results for export and analysis - Frequency distribution of answers for specified question(s)
/*289 Questionaire results for export and analysis, Frequency distribution of answers for specified question(s)
Replace 'medical' with desired search term or eliminate to return all*/
SELECT Description, Answer, COUNT(Answer) FROM question WHERE description LIKE ('%medical%') GROUP BY Description, Answer
List of patients with appointments for a date range - (in future or past) with primary insurance carrier listed Also lists Fees, Insurance payment estimate and patient portion
/*290 List of patients with appointments for a date range (in future or past) with primary insurance carrier listed
Also lists Fees, Insurance payment estimate and patient portion*/
SET @FromDate='2017-04-01' , @ToDate='2017-04-03';
SELECT a.AptDateTime, p.PatNum,
(CASE WHEN ISNULL(carrier.CarrierName) THEN '*No Insurance' ELSE (carrier.CarrierName) END) AS 'PriCarrier',
SUM(pl.ProcFee) AS '$Fees',
COALESCE(SUM(CASE
WHEN cp.Status=1 OR cp.Status=4 THEN(cp.InsPayAmt)
WHEN cp.Status=0 THEN (cp.InsPayEst)
WHEN cp.Status=6 THEN (CASE WHEN cp.InsEstTotalOverride=-1 THEN(cp.InsEstTotal) ELSE (cp.InsEstTotalOverride)END)
END),0) AS '$InsPayEst',
COALESCE(SUM(CASE
WHEN cp.Status=1 OR cp.Status=4 THEN (cp.WriteOff)
ELSE(CASE WHEN cp.WriteOffEstOverride=-1 THEN (CASE WHEN cp.WriteOffEst=-1 THEN 0 ELSE cp.WriteOffEst END) ELSE (cp.WriteOffEstOverride)END)
END),0) '$Writeoff',
/*Procfee - Writeoff - Insurance Estimate*/
(SUM(pl.ProcFee))
-(COALESCE(SUM(CASE
WHEN cp.Status=1 OR cp.Status=4 THEN(cp.WriteOff)
ELSE(CASE WHEN cp.WriteOffEstOverride=-1 THEN (CASE WHEN cp.WriteOffEst=-1 THEN 0 ELSE cp.WriteOffEst END) ELSE (cp.WriteOffEstOverride)END)
END),0))
-(COALESCE(SUM(CASE
WHEN cp.Status=1 OR cp.Status=4 THEN(cp.InsPayAmt)
WHEN cp.Status=0 THEN (cp.InsPayEst)
WHEN cp.Status=6 THEN (CASE WHEN cp.InsEstTotalOverride=-1 THEN (cp.InsEstTotal) ELSE (cp.InsEstTotalOverride)END)
END),0)) AS '$PatPorEst'
FROM appointment a
INNER JOIN patient p ON p.PatNum=a.PatNum /*just in case we need field FROM patient table*/
INNER JOIN procedurelog pl ON a.AptNum=pl.AptNum
AND a.AptDateTime BETWEEN @FromDate AND @ToDate+ INTERVAL 1 DAY AND a.AptStatus IN (1,2,4)/*appointment 1=sched, 2=complete or 4=ASAP */
LEFT JOIN patplan pp ON pp.PatNum=p.PatNum
AND ORDINAL=1/*by current primary insurance*/
LEFT JOIN inssub iss ON pp.InsSubNum=iss.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=iss.PlanNum
LEFT JOIN carrier ON carrier.CarrierNum=ip.CarrierNum
LEFT JOIN claimproc cp ON cp.ProcNum=pl.ProcNum
AND cp.Status IN (0,1,4,6)
AND cp.PlanNum = ip.PlanNum
GROUP BY a.AptNum
ORDER BY a.AptDateTime;
Claims representing service provided in a given time period for a given carrier - with phone number, claim status, Ins Est and Ins Paid
/*292 insurance claims representing service provided in a given time period for a given carrier with phone number, claim status, Ins Est and Ins Paid*/
/*can easily be modified to use date sent instead of date service*/
SET @FromDate='2009-01-01' , @ToDate='2009-03-31';
SET @Carrier='%Blue Cross%';
SELECT cl.PatNum,cl.DateService,cl.DateSent, LEFT(ca.CarrierName, 20) AS 'Carrier Abbr', ca.Phone, cl.ClaimStatus, cl.InsPayEst,InsPayAmt FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE (cl.ClaimStatus='R' OR cl.ClaimStatus='S') AND ca.CarrierName LIKE @Carrier AND
(cl.DateService BETWEEN @FromDate AND @ToDate)
ORDER BY ca.CarrierName,p.LName;
Call back List for given procedures for given date range - uses guarantor home phone, other numbers can easily be added
/*293 Call back List for given procedures for given date range, uses guarantor home phone, other numbers can easily be added */
SET @FromDate='2009-11-01' , @ToDate='2009-11-31';
SELECT (CASE WHEN ISNULL(ap.AptDateTime) THEN 'No Apt Attached' ELSE ap.AptDateTime END) AS AptDateTime,
pa.PatNum, LEFT(pc.Descript, 20) AS 'Procedure', pl.ToothNum AS 'Tooth', pl.Surf, ga.HmPhone,CONCAT(ga.LName, ', ', ga.FName) AS Guarantor
FROM procedurelog pl
INNER JOIN patient pa ON pl.PatNum=pa.PatNum
INNER JOIN patient ga ON pa.Guarantor=ga.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
LEFT JOIN appointment ap ON pl.AptNum=ap.AptNum
WHERE pl.ProcStatus = '2' /*complete*/
AND (pc.ProcCode LIKE ('D2%') OR pc.ProcCode LIKE ('D7%'))
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
ORDER BY AptDateTime ASC;
Specified procedures representing service provided in a given time period for a given carrier - with phone number, claim status, Ins Est and Ins Paid
/*294 Specified procedures representing service provided in a given time period for a given carrier with phone number, claim status, Ins Est and Ins Paid*/
/*can easily be modified to use date sent instead of date service*/
SET @FromDate='2018-01-01' , @ToDate='2018-12-31';
SET @Carrier='%%'; /*set carrier here, set proc list below*/
SET @ProcCode = '%%'; /* Change to the Procedure Code to filter by */
SELECT
cl.PatNum,
pc.ProcCode,
DATE_FORMAT(cl.DateService,'%m/%d') AS 'SDate',
cl.DateSent,
LEFT(ca.CarrierName, 20) AS 'Carrier Abbr',
ca.Phone,
cl.ClaimType 'Type',
cl.ClaimStatus 'Status',
cp.InsPayEst,
cp.InsPayAmt
FROM claim cl
INNER JOIN patient p
ON p.PatNum=cl.PatNum
INNER JOIN insplan i
ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca
ON ca.CarrierNum=i.CarrierNum
INNER JOIN claimproc cp
ON cl.ClaimNum=cp.ClaimNum
INNER JOIN procedurelog pl
ON pl.ProcNum=cp.ProcNum
INNER JOIN procedurecode pc
ON pc.CodeNum=pl.CodeNum
WHERE (cl.ClaimStatus='R' OR cl.ClaimStatus='S')
AND ca.CarrierName LIKE @Carrier
AND (cl.DateService BETWEEN @FromDate AND @ToDate)
AND pc.ProcCode LIKE @ProcCode
ORDER BY ca.CarrierName,p.LName;
Home and wireless Phone numbers - of active, non and inactive patients, perhaps for uploading to your phone
/*295 Home and wireless Phone numbers of active, non and inactive patients, perhaps for uploading to your phone*/
SELECT LName, FName, HmPhone, WirelessPhone FROM patient WHERE (HmPhone<>"" OR WirelessPhone<>"")
AND PatStatus NOT IN(4,5,6) ORDER BY LName, FName
Patient Mailing info with given carrier seen since given date -
/*296 Patient Mailing info with given carrier seen since given date*/
Set @Carrier='%medicaid%', @SeenAfterDate='2007-12-31';
SELECT p.LName,p.FName,p.Address,p.Address2,p.City,p.State,p.zip, DATE_FORMAT(MAX(ProcDate),'%m/%d/%Y') AS 'LastVisit'
FROM carrier c
INNER JOIN insplan ip ON c.CarrierNum=ip.CarrierNum
INNER JOIN inssub ib ON ib.PlanNum=ip.PlanNum
INNER JOIN patplan pp ON ib.InsSubNum=pp.InsSubNum
INNER JOIN patient p ON pp.PatNum=p.PatNum
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
WHERE pl.ProcStatus=2 AND p.PatStatus=0 AND
c.CarrierName LIKE @Carrier
GROUP BY pl.PatNum
HAVING MAX(ProcDate)>@SeenAfterDate
ORDER BY p.LName, p.FName;
Aging report for no payment in last 30 days - SEE REPLICATION WARNING for versions before 14.3.1. Unusual query that includes days since last specified procedure (the procedure is 'M1112' in this example)
/*297 Aging report for no payment in last 30 days and shows days since last specified procedure*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp SELECT CONCAT(g.LName,', ',g.FName,' ',g.MiddleI) AS Guarantor
,g.Bal_0_30,g.Bal_31_60,g.Bal_61_90,g.BalOver90
,g.BalTotal,g.InsEst,g.BalTotal-g.InsEst AS $PatPor,
MAX(paysplit.DatePay) AS LastPayment,
(SELECT MAX(pl.ProcDate) FROM procedurelog pl INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
WHERE pc.ProcCode ='M1112' AND pl.PatNum=patient.PatNum) AS 'LastAdjDate'
FROM patient
INNER JOIN patient g ON patient.Guarantor=g.PatNum
LEFT JOIN paysplit
ON paysplit.PatNum=patient.PatNum
WHERE (patient.patstatus IN (0,1))
AND (g.BalOver90 > '.005')
GROUP BY patient.Guarantor
ORDER BY g.LName,g.FName;
SELECT Guarantor
,Bal_0_30,Bal_31_60,Bal_61_90,BalOver90
,BalTotal,InsEst, $PatPor, DATEDIFF(CURDATE(), LastAdjDate) AS 'DaysSince',
DATE_FORMAT(LastPayment,'%m/%d/%Y') AS LastPayment FROM tmp WHERE DATE(LastPayment)<(CURDATE()- INTERVAL 30 DAY);
DROP TABLE IF EXISTS tmp;
New patients with no complete procedures -
/*298 new patients with no complete procedures*/
SET @FromDate='2009-01-01' , @ToDate='2009-05-31';
SELECT p.PatNum, p.DateFirstVisit FROM patient p
LEFT JOIN procedurelog pl ON pl.PatNum=p.PatNum AND pl.ProcStatus=2 /*complete*/
WHERE p.DateFirstVisit BETWEEN @FromDate AND @ToDate
GROUP BY p.PatNum
HAVING COUNT(pl.ProcNum)<1;
Insurance effective dates with carriername - for active patients matching a carrier name criteria
/*299 Insurance effective dates with carriername for active patients matching a carrier name criteria (specify all or part of carrier name)
Note: edit the CarrierName LIKE ('%Blue Cross%') section below with deired carrier name*/
SELECT p.PatNum, c.CarrierName, ib.DateEffective, ib.DateTerm
FROM patient p
INNER JOIN patplan pp ON pp.PatNum=p.PatNum
INNER JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
INNER JOIN insplan ip ON ip.PlanNum=ib.PlanNum
INNER JOIN carrier c ON ip.CarrierNum=c.CarrierNum
WHERE p.PatStatus=0 /*Active Patients*/
AND CarrierName LIKE '%Blue Cross%';
Broken Appointment Production for date range - Appointments can be moved to later in the day or another op, but do not delete the broken apt. Production is only accurate until you schedule those procedures to a new apt
/*300 Broken Appointment Production for date range
(Appointments can be moved to later in the day or another op, but do not delete the broken apt. Production is only accurate until you schedule those procedures to a new apt)*/
SET @FromDate='2009-05-01' , @ToDate='2009-06-31';
SELECT a.PatNum,DATE_FORMAT(a.AptDateTime,'%m/%d/%Y') AS AptDate, SUM(pl.ProcFee) AS '$Production'
FROM appointment a
LEFT JOIN procedurelog pl ON a.AptNum=pl.AptNum
WHERE a.AptStatus=5 AND (DATE(a.AptDateTime) BETWEEN @FromDate AND @ToDate)
GROUP BY a.AptNum
ORDER BY DATE(a.AptDateTime);
End of day check - For Versions 17.1 and greater. Please update your version accordingly. Returns patient name, first visit, referror, sum fee, sum adjust, sum writeoff for date range with next appointment, if none then planned or unsched or recall
/*301 Great end of day check! Returns patient name, first visit, referror, sum fee, sum adjust, sum writeoff for date range with next appointment, if none then planned or unsched or recall)
Much like 51 but with next appointment, may run slow for large databases with greater than 1 day range unless you index the refattach table*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/16/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2018-01-01', @ToDate='2018-01-31';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT AllInfo.*,
(CASE WHEN SchedApts.NextApt IS NOT NULL THEN SchedApts.NextApt
WHEN OtherApts.CountPlanned>0 THEN 'Planned'
WHEN OtherApts.CountUnSch>0 THEN 'Unscheduled'
WHEN OtherApts.CountASAP>0 THEN 'ASAP'
ELSE 'None-Recall' END
) AS NextApt
FROM (
SELECT SumTrans.PatNum,SumTrans.TranDate AS DATE,
CONCAT(r.LName,', ',r.FName) AS Referror,
SumTrans.Prod-SumTrans.Capitat AS $Production_,
SumTrans.Adj AS $Adjustments_,
SumTrans.Writeoff AS $Writeoff_
FROM (
SELECT Trans.PatNum,Trans.TranDate,
SUM(CASE WHEN Trans.TranType='Fee' THEN Trans.TranAmount ELSE 0 END) AS Prod,
SUM(CASE WHEN Trans.TranType='Adj' THEN Trans.TranAmount ELSE 0 END) AS Adj,
SUM(CASE WHEN Trans.TranType='Writeoff' THEN Trans.TranAmount ELSE 0 END) AS Writeoff,
SUM(CASE WHEN Trans.TranType='Capitat' THEN Trans.TranAmount ELSE 0 END) AS Capitat
FROM (
/*transactions*/
/*fees*/
SELECT 'Fee' AS TranType,pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2 /*Complete*/
UNION ALL
/*Adj*/
SELECT 'Adj' AS TranType,a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount
FROM adjustment a
UNION ALL
/*Claim writeoffs for the entire office history*/
SELECT 'Writeoff' AS TranType,cp.PatNum PatNum,cp.DateCP TranDate,cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4)/*received, supplemental*/
UNION ALL
/*Capitation*/
SELECT 'Capitat' AS TranType,cp.PatNum PatNum,cp.DateCP TranDate,cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.Status=7 /*CapComplete*/
) Trans
WHERE Trans.TranDate BETWEEN @FromDate AND @ToDate
GROUP BY Trans.PatNum,Trans.TranDate
) SumTrans
LEFT JOIN refattach ra ON ra.PatNum=SumTrans.PatNum
AND ra.RefType=1 /*RefFrom*/
LEFT JOIN referral r ON r.ReferralNum=ra.ReferralNum
GROUP BY SumTrans.PatNum,SumTrans.TranDate
) AllInfo
/*Get next scheduled apt date if exists*/
LEFT JOIN (
SELECT a.PatNum,MIN(a.AptDateTime) AS NextApt
FROM appointment a
WHERE a.AptStatus=1 /*Scheduled*/
AND DATE(a.AptDateTime)>CURDATE()
GROUP BY a.PatNum
) SchedApts ON SchedApts.PatNum=AllInfo.PatNum
/*Get count of planned or asap or unscheduled apts, in case no scheduled*/
LEFT JOIN (
SELECT a.PatNum,SUM(CASE WHEN a.AptStatus=3 THEN 1 ELSE 0 END) AS CountUnSch,
SUM(CASE WHEN a.AptStatus=4 THEN 1 ELSE 0 END) AS CountASAP,
SUM(CASE WHEN a.AptStatus=6 THEN 1 ELSE 0 END) AS CountPlanned
FROM appointment a
WHERE a.AptStatus IN(3,4,6) /*Unscheduled,ASAP,Planned*/
GROUP BY a.PatNum
) OtherApts ON OtherApts.PatNum=AllInfo.PatNum
LEFT JOIN patient p ON p.PatNum=AllInfo.PatNum
WHERE ABS(AllInfo.$Production_)>0.005
OR ABS(AllInfo.$Adjustments_)>0.005
OR ABS(AllInfo.$Writeoff_)>0.005
ORDER BY p.LName,p.FName;
Incomplete procedure notes for date range with provider -
/*302 Incomplete procedure notes for date range with provider*/
/*Query code written/modified: 04/09/2018 RJ*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate= '2018-04-01', @ToDate='2018-04-05';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT procedurelog.ProcDate,
procedurelog.ProvNum,
CONCAT(patient.LName,', ',patient.FName) AS 'PatientName',
procedurecode.ProcCode,
procedurecode.AbbrDesc,
procedurelog.ToothNum,
LEFT(n1.Note, 30) AS 'First 30 characters of Note'
FROM procedurelog,patient,procedurecode,procnote n1
WHERE procedurelog.PatNum = patient.PatNum
AND procedurelog.CodeNum = procedurecode.CodeNum
AND procedurelog.ProcStatus = 2 /*Complete*/
AND procedurelog.ProcDate BETWEEN @FromDate AND @ToDate
AND procedurelog.ProcNum=n1.ProcNum
AND (n1.Note LIKE '%\"\"%' OR n1.Note LIKE '"%"')
AND n1.EntryDateTime= (
SELECT MAX(n2.EntryDateTime)
FROM procnote n2
WHERE n1.ProcNum = n2.ProcNum
)
ORDER BY procedurelog.ProvNum, procedurelog.ProcDate;
List of active patients with no appointments in date range - includes phone numbers and address
/*303 List of active patients with no appointments in date range, includes phone numbers and address*/
SET @FromDate='2009-07-01' , @ToDate='2009-07-31'; SELECT CONCAT(p.LName, ', ',p.FName, ' ', p.MiddleI) AS Patient, CONCAT(" ", LEFT(p.HmPhone,13), "- ", LEFT(p.WkPhone,13), "- ",LEFT(p.WirelessPhone,13)) AS 'Phone Hm-Wk-Cell', CONCAT(p.Address, " ", p.Address2, ", ", p.City, ", ",p.State, " ", p.ZIP) AS 'Full Address' FROM patient p LEFT JOIN appointment ap ON p.PatNum=ap.PatNum AND (DATE(ap.AptDateTime) BETWEEN @FromDate AND @ToDate) AND ap.AptStatus IN (1,2) /*sched or complete*/
WHERE ISNULL(ap.aptnum) AND p.PatStatus=0 ORDER BY p.LName, p.FName ASC;
Active patients who have a specific code in treatment plan - with addresses
/*304 Active patients who have a specific code in treatment plan, with addresses*/
SET @pos=0;
SELECT @pos:=@pos+1 AS COUNT, pc.ProcCode, p.LName, p.FName, p.Address, p.Address2, p.City, p.State, p.Zip
FROM patient p
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum AND pl.ProcStatus=1 /*treatment planned*/
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
WHERE pc.ProcCode IN('D0120') /* NOTE: put as many procedurecodes as you like, in single quotes separated by commas*/
AND p.PatStatus=0 /*Active patients*/
Patients with date of first visit in given range - For Versions 17.1 and greater. Please update your version accordingly. With referral source and additional entry for each out referral.
/*305 Patients with date of first visit in given range, with referral source and additional entry for each out referral*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/16/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2018-01-01', @ToDate='2018-01-31';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SET @pos=0;
SET SQL_BIG_SELECTS=1;
SELECT @pos:=@pos+1 AS '#',
patfirst.*
FROM (
SELECT p.PatNum,
p.DateFirstVisit,
CONCAT(rFROM.LName, ", ", rFROM.FName) AS ReferredFROM,
CONCAT(rto.LName, ", ", rto.FName) AS ReferredTo
FROM patient p
LEFT JOIN refattach raFROM ON p.PatNum=raFROM.PatNum
AND raFROM.RefType = 1 /*RefFrom*/
AND raFROM.ItemOrder=(SELECT MIN(rat.ItemOrder)
FROM refattach rat
WHERE rat.RefType = 1 /*RefFrom*/
AND p.PatNum=rat.PatNum)
LEFT JOIN referral rFROM ON rFROM.ReferralNum=raFROM.ReferralNum
LEFT JOIN refattach rato ON p.PatNum=rato.PatNum
AND rato.RefType = 0 /*RefTo*/
LEFT JOIN referral rto ON rto.ReferralNum=rato.ReferralNum
WHERE DateFirstVisit BETWEEN @FromDate AND @ToDate
ORDER BY DateFirstVisit, p.LName, p.FName
)patfirst;
Commlog entries for the day that have notes -
/*306 Commlog entries for the day that have notes*/
SELECT PatNum, CommDateTime,Note FROM commlog
WHERE Date(CommDateTime)=CurDate() AND Length(Note)>1 ORDER BY Note, CommDateTime;
Commlog entries for date range that have notes -
/*307 Commlog entries for date range that have notes*/
SET @FromDate='2009-06-01', @ToDate='2009-07-01';
SELECT PatNum, CommDateTime,Note FROM commlog
WHERE Date(CommDateTime) BETWEEN @FromDate AND @ToDate AND Length(Note)>1 ORDER BY Note, CommDateTime;
Commlog entries with a key word -
/*308 Commlog entries with a key word*/
SET @Note = '%%'; -- Enter note text between %'s. Leave blank for any note.
/*-------------------- Do not modify under this line --------------------*/
/*Query code written/modified: 12/18/2018 MattG*/
SELECT
PatNum,
CommDateTime,Note
FROM commlog
WHERE NOTE LIKE @Note
AND LENGTH(Note)>1
ORDER BY DATE(CommDateTime) DESC, Note;
Patients with status of active and non-patient with no email and who referred them - For Versions 17.1 and greater. Please update your version accordingly.
/*309 patients with no email and who referred them*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/16/2018*/
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SET @pos=0;
SELECT @pos:=@pos+1 AS '#',
patnoemail.*
FROM (
SELECT p.PatNum, p.Email,
CONCAT(rFROM.LName, ", ", rFROM.FName) AS ReferredFROM
FROM patient p
LEFT JOIN refattach raFROM ON p.PatNum=raFROM.PatNum
AND raFROM.RefType = 1 /*RefFrom*/
AND raFROM.ItemOrder=(
SELECT MIN(rat.ItemOrder)
FROM refattach rat
WHERE rat.RefType = 1 /*RefFrom*/
AND p.PatNum=rat.PatNum
)
LEFT JOIN referral rFROM ON rFROM.ReferralNum=raFROM.ReferralNum
WHERE p.Email NOT LIKE ('%@%')
AND p.PatStatus IN(0,1) /*Patient, NonPatient*/
ORDER BY p.LName, p.FName
)patnoemail;
List of all of patients with dual coverage, with guarantor and names of carriers - fixed for 7.5+
/*310 List of all of patients with dual coverage, with guarantor and names of carriers*/
SELECT p.Guarantor,p.PatNum,p.PatStatus,
ca1.CarrierName AS PriCarrier,
ca2.CarrierName AS SecCarrier
FROM patient p
LEFT JOIN patplan pp1 ON p.PatNum=pp1.PatNum AND pp1.Ordinal=1 /*primary*/
LEFT JOIN inssub ib1 ON ib1.InsSubNum=pp1.InsSubNum
LEFT JOIN insplan ip1 ON ip1.PlanNum=ib1.PlanNum
LEFT JOIN carrier ca1 ON ip1.CarrierNum=ca1.CarrierNum
LEFT JOIN patplan pp2 ON p.PatNum=pp2.PatNum AND pp2.Ordinal=2 /*secondary*/
LEFT JOIN inssub ib2 ON ib2.InsSubNum=pp2.InsSubNum
LEFT JOIN insplan ip2 ON ip2.PlanNum=ib2.PlanNum
LEFT JOIN carrier ca2 ON ip2.CarrierNum=ca2.CarrierNum
WHERE (NOT ISNULL(ca1.CarrierName) AND NOT ISNULL(ca2.CarrierName));
All patients with values for a specified patient field def name - (full or partial field def name, all results, for summary see 312)
/*311 All patients with values for a specified patient field def name (full or partial field def name, all results, for summary see*/
/* Just use @FieldName='%%'; to get all fields, note that this is a limiter for the FIELD NAME not the Value you would enter by patient*/
SET @FieldName='%Field Name%';
SET @pos=0;
SELECT @pos:=@pos+1 AS '#', PatNum, FieldName, FieldValue FROM patfield WHERE FieldName LIKE @FieldName;
Summary of All Patient Field Def Entries - Grouped by fieldname and value
/*312 Summary of All Patient Field Def Entries, Grouped by fieldname and value*/
SELECT COUNT(*), FieldName, FieldValue
FROM patfield
GROUP BY FieldName, FieldValue
ORDER BY FieldName, FieldValue;
Summary of Patient Field Def Entries, for field names matching given criteria - grouped by fieldname and value
/*313 Summary of Patient Field Def Entries, for field names matching given criteria, grouped by fieldname and value*/
SELECT COUNT(*) AS Quantity, FieldName, FieldValue
FROM patfield WHERE FieldName LIKE('%Specialty%') /*change value here*/
GROUP BY FieldName, FieldValue
Order BY FieldName, Quantity DESC;
Mailing information with birthdate - for patients seen in last x months whose birthday falls in date range
/*314 Mailing information with birthdate for patients seen in last x months whose birthday falls in date range*/
SET @BDStart='07-05', @BDEnd='07-21'; /*Change bday here, use format like '03-23' for march 23rd*/
SELECT p.LName, p.FName, DATE_FORMAT(MAX(pl.ProcDate), '%m/%d/%Y') AS 'LastSeen',p.Birthdate, p.Address, p.Address2, p.City, p.State, p.Zip FROM patient p
LEFT JOIN procedurelog pl ON pl.PatNum=p.PatNum
WHERE (SUBSTRING(p.BirthDate,6,5) >= @BDStart
AND SUBSTRING(p.BirthDate,6,5) <= @BDEnd)
AND pl.ProcDate>(CURDATE()-INTERVAL 24 MONTH)
AND pl.ProcStatus = '2' AND p.PatStatus=0
GROUP BY pl.PatNum;
List of patients without a referral "from". - For Versions 17.1 and greater. Please update your version accordingly
/*315 List of patients without a referral "from".*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/16/2018*/
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT PatNum,
LName, FName,
HmPhone,
WkPhone,
WirelessPhone,
Email
FROM patient
WHERE (PatStatus < 2) /*Patient, NonPatient*/
AND (PatNum NOT IN (SELECT DISTINCT PatNum FROM refattach WHERE RefType = 1 /*RefFrom*/ ))
ORDER BY LName, FName;
Show feeschedule for each patient - whether through primary insurance, patient level feesched or provider fee schedule
/*316 Show feeschedule for each patient, whether through primary insurance, patient level feesched or provider fee schedule*/
SELECT p.PatNum, IFNULL(fs.Description,
IFNULL((SELECT fs1.Description FROM feesched fs1 WHERE fs1.FeeSchedNum=p.FeeSched),
(SELECT fs2.Description FROM feesched fs2,provider WHERE p.PriProv=provider.ProvNum AND fs2.FeeSchedNum=provider.FeeSched)
)) AS FeeSchedule
FROM patient p
LEFT JOIN patplan pp ON p.PatNum=pp.PatNum AND pp.Ordinal=1 /*only primary insurance matters here*/
LEFT JOIN inssub iss ON iss.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=iss.PlanNum
LEFT JOIN feesched fs ON ip.FeeSched=fs.FeeSchedNum
WHERE p.PatStatus=0 /*Active Patients*/
ORDER BY p.LName,p.FName;
Show count of active patients using each fee schedule - SEE REPLICATION WARNING for versions before 14.3.1. Whether through primary insurance, patient level feesched or provider fee schedule
/*317 Show count of active patients using each fee schedule whether through primary insurance, patient level feesched or provider fee schedule*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp SELECT p.PatNum, IFNULL(fs.Description,
IFNULL((SELECT fs1.Description FROM feesched fs1 WHERE fs1.FeeSchedNum=p.FeeSched),
(SELECT fs2.Description FROM feesched fs2,provider WHERE p.PriProv=provider.ProvNum AND fs2.FeeSchedNum=provider.FeeSched)
)) AS FeeSchedule
FROM patient p
LEFT JOIN patplan pp ON p.PatNum=pp.PatNum AND pp.Ordinal=1 /*only primary insurance matters here*/
LEFT JOIN inssub iss ON iss.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=iss.PlanNum
LEFT JOIN feesched fs ON ip.FeeSched=fs.FeeSchedNum
WHERE p.PatStatus=0 /*Active Patients*/
ORDER BY p.LName, p.FName;
SELECT FeeSchedule, COUNT(FeeSchedule) FROM tmp
GROUP BY FeeSchedule
ORDER BY FeeSchedule ASC;
DROP TABLE IF EXISTS tmp;
Inactive and Archived Patients who had a particular insurance carrier - Will not fit on a report page, needs to be exported as .xls
/*318 Inactive and archived patients who had a particular insurance carrier.*/
/*Query code written/modified: 01/16/2018*/
SET @CarrierName = ''; /*Change carrier names here, separated by a | */
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SET @CarrierName=(CASE WHEN @CarrierName="" THEN ".*" ELSE CONCAT('^',REPLACE(@CarrierName,"|","$|^"),"$") END);
SELECT p.PatNum,
p.PatStatus,
c.CarrierName,
ib.DateEffective,
ib.DateTerm,
CONCAT(p.HmPhone," - ",p.WkPhone," - ",p.WirelessPhone) AS 'Phone Hm-Wk-Cell',
p.Address,
p.Address2,
p.City,
p.State,
p.ZIP
FROM patient p
INNER JOIN patplan pp ON pp.PatNum=p.PatNum
INNER JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
INNER JOIN insplan ip ON ip.PlanNum=ib.PlanNum
INNER JOIN carrier c ON ip.CarrierNum=c.CarrierNum
WHERE p.PatStatus IN (2,3) /*Inactive and archived Patients only*/
AND CarrierName REGEXP @CarrierName
ORDER BY p.LName, p.FName;
Accounts Receivable and aging WHERE billing type is other than 'Standard' or other given billing type - SEE REPLICATION WARNING for versions before 14.3.1. Summed by guarantor, includes last statement date and last payment made
/*319 Accounts Receivable and aging WHERE billing type is other than 'Standard' or other given billing type,
summed by guarantor, includes last statement date and last payment made*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @pos=0;
DROP TABLE IF EXISTS tmp1;
CREATE TABLE tmp1
SELECT p.PatNum, p.Guarantor,
(SELECT MAX(DatePay) FROM paysplit WHERE paysplit.PatNum=p.PatNum)
AS 'LastPay',
(SELECT MAX(DateSent) FROM statement WHERE statement.PatNum=p.PatNum) AS
'LastStmnt'
FROM patient p;
SELECT @pos:=@pos+1 AS '#',tmp1.Guarantor,
p.BalTotal AS '$Fam-',p.Bal_0_30,p.Bal_31_60,p.Bal_61_90,
p.BalOver90,
MAX(LastPay) AS 'LastPay',
MAX(LastStmnt) AS 'LastStmnt',d.ItemName,
pn.FamFinancial
FROM tmp1
INNER JOIN patient p ON tmp1.Guarantor=p.PatNum
INNER JOIN patientnote pn ON tmp1.Guarantor=pn.PatNum
INNER JOIN definition d ON p.BillingType=d.DefNum
WHERE d.ItemName NOT LIKE('%Standard%')
AND p.BalTotal>=0.01 /*sometimes very small balances so 1 penny min*/
GROUP BY tmp1.Guarantor
ORDER BY p.LName, p.FName;
DROP TABLE IF EXISTS tmp1;
Lists all patients with billing type indicated with contact info - NOTE: user inputs any part of billing type, replace 'Bad' with your billing type
/*320 Lists all patients with billing type indicated with contact info
NOTE: user inputs any part of billing type, replace 'Bad' with your billing type*/
SELECT p.PatNum, CONCAT(p.Address, ' ', p.Address2) AS 'Address', p.City, LEFT(p.State,2) AS 'State', p.Zip,
CONCAT(" ", LEFT(p.HmPhone,13), "- ", LEFT(p.WkPhone,13), "- ",LEFT(p.WirelessPhone,13)) AS 'Phone Hm-Wk-Cell'
FROM patient p
INNER JOIN definition d ON p.BillingType=d.DefNum
WHERE ItemName LIKE('%Bad%')
AND p.PatNum=p.Guarantor /*guarantors only*/
ORDER BY p.LName,FName;
Appointments in date range for a given provider - with appointment status, age, and procedures
/*322 Appointments in date range for a given provider with appointment status, age, and procedures*/
SET @ProvAbbr='%Doc%';/*Set provider here*/
SET @FromDate='2009-01-01' , @ToDate='2009-01-31';/*set date range here*/
SELECT p.PatNum,a.AptDateTime,
(CASE WHEN (YEAR(CURDATE())-YEAR(p.Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(p.Birthdate,5))<200
THEN(YEAR(CURDATE())-YEAR(p.Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(p.Birthdate,5)) ELSE 0 END) AS 'Age',
GROUP_CONCAT(pc.AbbrDesc) AS ProceduresInApt,op.OpName,
(CASE WHEN a.AptStatus=1 THEN 'Scheduled'
WHEN a.AptStatus=2 THEN 'Complete'
ELSE 'Broken' END) AS 'AptStatus', pv.Abbr
FROM appointment a
INNER JOIN patient p ON a.PatNum=p.PatNum
INNER JOIN provider pv ON pv.ProvNum=a.ProvNum
LEFT JOIN operatory op ON op.OperatoryNum=a.Op
LEFT JOIN procedurelog pl ON pl.AptNum=a.AptNum
LEFT JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
WHERE
DATE(a.AptDateTime) BETWEEN @FromDate AND @ToDate AND
a.AptStatus IN(1,2,5)/*1sched, 2complete 5broken*/ AND
pv.Abbr LIKE(@ProvAbbr)
GROUP BY a.AptNum
ORDER BY a.AptDateTime
Calculate Sum unpaid balances on procedures completed before given date - SEE REPLICATION WARNING for versions before 14.3.1. This is NOT quite like an aging report because we are considering only work completed before a given date but we account for all payments adjustments, writeoffs etc through current date
/*324 Calculate Sum unpaid balances on procedures completed before given date. This is NOT quite like an aging report because we are considering only work completed before a given date but we account for all payments adjustments, writeoffs etc through current date
-Assumes oldest procedures paid first*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @AsOf='2009-01-01';
/*first create transaction table*/
DROP TABLE IF EXISTS tmp1, tmp2, tmp3, tmp4;
CREATE TABLE tmp1
(PatNum INT DEFAULT 0,
TranDate DATE DEFAULT '0001-01-01',
TranAmount DOUBLE DEFAULT 0);
/*Get the completed procedure dates and charges for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2 AND pl.ProcDate<=@AsOf;
/*Paysplits for the entire office without date consideration*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/;
/*Get the adjustment dates and amounts for the entire office history*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount
FROM adjustment a;
/*Claim payments and capitation writeoffs for the entire office history for procedures conmpleted on or before given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT cp.PatNum PatNum,
cp.DateCp TranDate,-cp.InsPayAmt-cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.status IN (1,4,5,7) AND cp.ProcDate<=@AsOf;/*received, supplemental, CapClaim or CapComplete*/
/*Payment plan principal for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT pp.PatNum PatNum,
pp.PayPlanDate TranDate,
-pp.CompletedAmt TranAmount
FROM payplan pp;
/*now we need to include the anticipated insurance (sum of payments and writeoffs)
note that if you use PPO type, your anticipated writeoff numbers will have updated to
match your actual writeoff numbers... your best bet is to keep backups or paper copies of your
reports if that change is bothersome */
/*Now Note that as we get these numbers we are summing by family, when really we
are looking for a grand total, this is to make it easier to get the details should we need them
FROM the tmp tables*/
CREATE TABLE tmp3 SELECT p.Guarantor,SUM(cp.InsPayEst) AS InsPayEst,
0 AS WriteOff
FROM patient p INNER JOIN claimproc cp ON cp.PatNum=p.PatNum
WHERE (cp.Status=0 AND cp.ProcDate<=@AsOf) /* still not recieved and procedure completed before the date*/
/*AND p.PatStatus NOT IN(4,3) not archived*/
GROUP BY p.Guarantor;
INSERT INTO tmp3
SELECT p.Guarantor,0 AS InsPayEst,
(CASE WHEN ISNULL(SUM(cp.Writeoff)) THEN 0 ELSE SUM(cp.WriteOff) END) AS WriteOff
FROM patient p INNER JOIN claimproc cp ON cp.PatNum=p.PatNum
WHERE ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR /* still not recieved and procedure completed before the date*/
(cp.Status IN(1,4) AND cp.DateCP>@AsOf AND cp.ProcDate<=@AsOf)) /*was received after the date of interest and completed before it*/
/*AND p.PatStatus NOT IN(4,3) not archived*/
GROUP BY p.Guarantor;
CREATE TABLE tmp2
SELECT Guarantor, SUM(TranAmount) AS 'FamBal' FROM patient
INNER JOIN tmp1 ON tmp1.PatNum=Patient.PatNum
GROUP BY Guarantor;
CREATE TABLE tmp4
SELECT 'SumUnpaidBalances' AS 'Description', SUM(FamBal) '$Value' FROM tmp2
WHERE FamBal>0
UNION
SELECT 'TotInsPayEst' AS 'Description', SUM(InsPayEst) '$Value' FROM tmp3
UNION
SELECT 'TotWriteOffEst' AS 'Description', SUM(WriteOff) '$Value' FROM tmp3;
SELECT * FROM tmp4;
DROP TABLE IF EXISTS tmp1, tmp2, tmp3, tmp4;
Work treatment planned in a date range - and status (is it complete or TP) and whether accepted (scheduled or complete) or just TP and not accepted (not scheduled)
/*325 Work treatment planned in a date range, and status (is it complete or TP) and whether accepted (scheduled or complete) or just TP and not accepted (not scheduled)*/
/*Query code written/modified: 11/17/2015*/
SET @pos=0, @FromDate='2015-07-01' , @ToDate='2015-07-31';
SELECT @pos:=@pos+1 AS 'Count',A.*
FROM (
SELECT pa.PatNum,pc.ProcCode AS 'Code', abbrdesc AS 'Description', ToothNum,
DATE_FORMAT(pl.DateTP,'%m-%d-%Y') AS 'DateTP',pr.Abbr, ProcFee,
IF(pl.AptNum, IF(pl.ProcStatus=2, 'Complete', IF(pl.Procstatus=1, 'Scheduled', 'Other')), IF(pl.ProcStatus=2, 'Complete','TP')) AS 'Status'
FROM patient pa
INNER JOIN procedurelog pl ON pa.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
INNER JOIN provider pr ON pl.ProvNum=pr.ProvNum
WHERE pl.ProcStatus IN(1,2) AND
(DateTP BETWEEN @FromDate AND @ToDate)
ORDER BY DateTP,pa.LName, pa.FName ASC
) A;
Work treatment planned Today, and status (is it complete or TP) and whether accepted (scheduled or complete) or just TP and not accepted (not scheduled) -
/*326 Work treatment planned Today, and status (is it complete or TP) and whether accepted (scheduled or complete) or just TP and not accepted (not scheduled)*/
SET @pos=0, @FromDate=CurDate() , @ToDate=CurDate();
SELECT @pos:=@pos+1 as 'Count', pa.PatNum,
pc.ProcCode as 'Code', abbrdesc as 'Description', ToothNum, DATE_FORMAT(pl.DateTP,'%m-%d-%Y') AS 'DateTP',
pr.Abbr, ProcFee, IF(pl.AptNum, IF(pl.ProcStatus=2, 'Complete', IF(pl.Procstatus=1, 'Scheduled', 'Other')), IF(pl.ProcStatus=2, 'Complete','TP')) AS 'Status'
FROM patient pa
INNER JOIN procedurelog pl ON pa.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
INNER JOIN provider pr ON pl.ProvNum=pr.ProvNum
WHERE pl.ProcStatus IN(1,2) AND
(DateTP BETWEEN @FromDate AND @ToDate)
ORDER BY DateTP,pa.LName, pa.FName ASC;
Procedures on received claims with zero payment -
/*327 Procedures on received claims with zero payment*/
SET @FromDate='2009-01-01' , @ToDate='2009-12-31';
SELECT p.PatNum, cl.DateService,pc.ProcCode, pl.ToothNum
FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
INNER JOIN claimproc cp ON cl.ClaimNum=cp.ClaimNum
INNER JOIN procedurelog pl ON pl.ProcNum=cp.ProcNum
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
WHERE (cl.ClaimStatus='R') AND
(cl.DateService BETWEEN @FromDate AND @ToDate)
GROUP BY pl.ProcNum
HAVING SUM(cp.InsPayAmt)=0
ORDER BY cl.DateService,p.LName,p.FName;
Production and Income for a particular patient (with adjustments, insurance income and writeoffs) - All by service date (which means the results change as new ins payments are received, except patient payments and adjustments, which is by payment date as there is not always a link between payment and procedure, note that this is in contrast to #162 wh
/*328 Production and Income for a particular patient (with adjustments, insurance income and writeoffs)
All by service date (which means the results change as new ins payments are received, except patient payments and adjustments,
which is by payment date as there is not always a link between payment and procedure, note that this is in contrast to #162 which is by ledger date*/
SET @PatNum='2836', @FromDate='2008-01-01' , @ToDate='2009-12-31';
SELECT p.PatNum,
(SELECT SUM(InsPayAmt) FROM claimproc cp WHERE cp.PatNum=p.PatNum AND cp.Status IN(1,4,7) AND cp.ProcDate BETWEEN @FromDate AND @ToDate) AS '$InsProcPay',
(SELECT SUM(Writeoff) FROM claimproc cp WHERE cp.PatNum=p.PatNum AND cp.Status IN(1,4,7) AND cp.ProcDate BETWEEN @FromDate AND @ToDate) AS '$WriteOff',
(SELECT SUM(SplitAmt) FROM paysplit WHERE p.PatNum=paysplit.PatNum AND (DatePay BETWEEN @FromDate AND @ToDate)) AS '$PatientPay',
(SELECT SUM(AdjAmt) FROM adjustment WHERE p.PatNum=adjustment.PatNum AND (adjdate BETWEEN @FromDate AND @ToDate)) AS '$PatAdj',
SUM(pl.procfee) AS '$Production'
FROM patient p
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum AND pl.ProcStatus=2
WHERE p.PatNum=@PatNum AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY p.PatNum;
List of patients insured with carrier, group name and group number for a given fee schedule, ordered by carrier and then group name - SEE REPLICATION WARNING for versions before 14.3.1.
/*329 List of patients insured with carrier, group name and group number for a given fee schedule, ordered by carrier and then group name*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp SELECT p.PatNum, c.CarrierName,ip.GroupName, ip.GroupNum,IFNULL(fs.Description,
IFNULL((SELECT fs1.Description FROM feesched fs1 WHERE fs1.FeeSchedNum=p.FeeSched),
(SELECT fs2.Description FROM feesched fs2,provider WHERE p.PriProv=provider.ProvNum AND fs2.FeeSchedNum=provider.FeeSched)
)) AS FeeSchedule
FROM patient p
LEFT JOIN patplan pp ON p.PatNum=pp.PatNum AND pp.Ordinal=1 /*only primary insurance matters here*/
LEFT JOIN inssub iss ON iss.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=iss.PlanNum
LEFT JOIN carrier c ON ip.CarrierNum=c.CarrierNum
LEFT JOIN feesched fs ON ip.FeeSched=fs.FeeSchedNum
WHERE p.PatStatus=0 /*Active Patients*/
ORDER BY p.LName, p.FName;
SELECT * FROM tmp
WHERE FeeSchedule LIKE('%MyFeeSchedule%')
ORDER BY CarrierName, GroupName;
DROP TABLE IF EXISTS tmp;
Treatment planned total for active patients with benefits remaining who have NO SCHEDULED appointments - calender year benefits, general ins maximum only, comment address lines if you do not need. Warning - slow query.
/*330 Treatment planned total for active patients with benefits remaining who have NO SCHEDULED appointments, calender year benefits, general ins maximum only. Comment address lines if you do not need*/
SELECT p.LName,
p.FName,
SUM(annualmax.AnnualMax) AS "$AnnualMax",
SUM(used.AmtUsed) AS "$AmountUsed",
(CASE WHEN ISNULL(SUM(used.AmtUsed)) THEN (SUM(annualmax.AnnualMax)) ELSE (SUM(annualmax.AnnualMax)-SUM(used.AmtUsed)) END) AS $AmtRemaining,
planned.AmtPlanned AS "$TreatPlanned",
p.Address,
p.Address2,
p.City,
p.State,
p.Zip
FROM patient p
INNER JOIN patplan ON p.PatNum=patplan.PatNum
INNER JOIN inssub ON inssub.InsSubNum=patplan.InsSubNum
INNER JOIN (
SELECT benefit.PlanNum,
MAX(benefit.MonetaryAmt) AS AnnualMax
FROM benefit
LEFT JOIN covcat ON covcat.CovCatNum = benefit.CovCatNum
WHERE benefit.BenefitType = 5 /* limitation */
AND benefit.TimePeriod = 2 /* calendar year */
AND (covcat.EbenefitCat=1 OR ISNULL(covcat.EbenefitCat))
AND benefit.MonetaryAmt > 0 /* (-1) indicates empty */
GROUP BY benefit.PlanNum
) annualmax ON annualmax.PlanNum=inssub.PlanNum
INNER JOIN (
SELECT procedurelog.PatNum, SUM(procedurelog.ProcFee) AS AmtPlanned
FROM procedurelog
INNER JOIN patient ON patient.PatNum=procedurelog.PatNum AND patient.PatStatus=0 /* Patient */
LEFT JOIN appointment a ON procedurelog.PatNum=a.PatNum AND a.AptStatus=1/*sched*/
WHERE procedurelog.ProcStatus = 1 /*treatment planned*/
AND ISNULL(a.AptNum)
GROUP BY patient.PatNum
) planned ON planned.PatNum=p.PatNum
LEFT JOIN (
SELECT patplan.PatPlanNum,
SUM(IFNULL(claimproc.InsPayAmt,0)) AS AmtUsed
FROM claimproc
INNER JOIN inssub ON claimproc.InsSubNum=inssub.InsSubNum
INNER JOIN patplan ON inssub.InsSubNum=patplan.InsSubNum
AND patplan.PatNum=claimproc.PatNum
WHERE claimproc.Status IN (1, 3, 4) -- Rec, Adj, Supp.
AND YEAR(claimproc.ProcDate)=YEAR(CURDATE()) /*current calendar year*/
GROUP BY patplan.PatPlanNum
) used ON used.PatPlanNum=patplan.PatPlanNum
WHERE planned.AmtPlanned>0
AND (CASE WHEN ISNULL(used.AmtUsed) THEN (annualmax.AnnualMax) ELSE (annualmax.AnnualMax-used.AmtUsed) END)>.01
AND p.PatStatus=0
GROUP BY p.PatNum
ORDER BY p.LName, p.FName;
Show count of active patients using each special 'Allowed' type fee schedule through primary insurance -
/*331 Show count of active patients using each special 'Allowed' type fee schedule through primary insurance*/
SELECT COALESCE(fs.Description,'none') AS AllowedFeeSchedule,COUNT(DISTINCT p.PatNum) AS 'Count'
FROM patient p
LEFT JOIN patplan pp ON p.PatNum=pp.PatNum AND pp.Ordinal=1 /*only primary insurance matters here*/
LEFT JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip ON ib.PlanNum=ip.PlanNum
LEFT JOIN feesched fs ON ip.AllowedFeeSched=fs.FeeSchedNum
WHERE p.PatStatus=0 /*Active Patients*/
GROUP BY fs.Description
ORDER BY COALESCE(fs.Description,'none') ASC;
Returns information about procedures where the amount paid+writeoff is greater than fee charged patient - Now a standard report
/*332 Returns information about procedures where the amount paid+writeoff is greater than fee charged patient*/
/*now a standard report*/
SELECT procedurelog.PatNum,procedurecode.ProcCode,procedurelog.ProcDate,procedurelog.ProcFee,SUM(claimproc.InsPayAmt + claimproc.Writeoff) AS
$PaidAndWriteoff
FROM procedurelog
LEFT JOIN claimproc ON procedurelog.ProcNum=claimproc.ProcNum
LEFT JOIN procedurecode ON procedurelog.CodeNum=procedurecode.CodeNum
WHERE procedurelog.ProcStatus=2/*complete*/
GROUP BY procedurelog.ProcNum
HAVING procedurelog.ProcFee+.005 < SUM(claimproc.InsPayAmt + claimproc.Writeoff);
Active Patients who HAVE had procedures completed with a specified provider but not in the past two years - SEE REPLICATION WARNING for versions before 14.3.1.
/*333 Active Patients who HAVE had procedures completed with a specified provider but not in the past two years*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @Latest = (CURDATE() - INTERVAL 2 YEAR);
DROP TABLE IF EXISTS tmp1;
CREATE TABLE tmp1 /* Table of patients not to include */
SELECT p.PatNum FROM patient p
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum AND pl.ProcStatus=2 /*Complete*/
INNER JOIN provider ON pl.ProvNum=provider.ProvNum
WHERE p.PatStatus=0
AND provider.Abbr='DOC1'
AND pl.ProcDate >= @Latest
GROUP BY p.PatNum;
ALTER TABLE tmp1 ADD INDEX(PatNum);
SELECT p.PatNum, Date_Format(MAX(procdate),'%m/%d/%Y') AS 'LastSeen', provider.Abbr AS 'Provider'
FROM patient p
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum AND pl.ProcStatus=2 /*Complete*/
INNER JOIN provider ON pl.ProvNum=provider.ProvNum
LEFT JOIN tmp1 ON p.PatNum=tmp1.PatNum /* Will be null on patients we want. */
WHERE p.PatStatus=0
AND provider.Abbr='DOC1'
AND ISNULL(tmp1.PatNum)
GROUP BY p.PatNum ;
DROP TABLE IF EXISTS tmp1;
Fees and details for completed procedures, for a week with user defined starting date. - Filtered by specific Primary carrier name, e.g. any starting with Medicaid.
/*334 Fees and details for completed procedures, for a week with user defined
starting date. Filtered by specific Primary carrier name, e.g. any starting with Medicaid.*/
/* PatNum, ProcDate, ProcCode, ProcFee, ProcDate, ToothNum,
Surf, Descript, ProvNum, CarrierName */
SET @FromDate = '2009-11-01';
SET @ToDate = @FromDate + INTERVAL 1 WEEK;/*or put user defined date here*/
SET @CarrierFilter = '%Medicaid%';/*change carrier here*/
SELECT p.PatNum, pc.ProcCode, pl.ProcFee, pl.ProcDate, pl.ToothNum,
pl.Surf, pc.Descript, pl.ProvNum, ca.CarrierName
FROM patient p
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
INNER JOIN patplan pp ON pp.PatNum=p.PatNum AND pp.Ordinal=1
INNER JOIN inssub iss ON iss.InsSubNum=pp.InsSubNum
INNER JOIN insplan ip ON ip.PlanNum=iss.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=ip.CarrierNum
WHERE pl.ProcDate BETWEEN @FromDate AND @ToDate
AND ca.CarrierName LIKE @CarrierFilter
AND pl.ProcStatus=2;
All non-zero family account balances, normally use aging report, this is for troubleshooting or automated reporting. - SEE REPLICATION WARNING for versions before 14.3.1. Can also edit to view transactions that comprise an aging report.
/*335 All non-zero family account balances, normally use aging report, this is for troubleshooting or automated reporting, can also edit to view transactions that comprise an aging report*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @AsOf='2010-03-23';
/*first create transaction table*/
DROP TABLE IF EXISTS tmp1, tmp2, tmp3, tmp4, tmpTotals;
CREATE TABLE tmp1
(TranType VARCHAR(10), PatNum INT DEFAULT 0,
TranDate DATE DEFAULT '0001-01-01',
TranAmount DOUBLE DEFAULT 0);
/*Get the completed procedure dates and charges for the entire office history on or before the given date*/
INSERT INTO tmp1 (TranType,PatNum,TranDate,TranAmount)
SELECT 'Fee' AS TranType, pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2;
/*Paysplits for the entire office history on or before the given date*/
INSERT INTO tmp1 (TranType,PatNum,TranDate,TranAmount)
SELECT 'Pay' AS TranType,ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/;
/*Get the adjustment dates and amounts for the entire office history on or before the given date*/
INSERT INTO tmp1 (TranType,PatNum,TranDate,TranAmount)
SELECT 'Adj' AS TranType, a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount
FROM adjustment a;
/*Claim payments for the entire office history on or before the given date*/
INSERT INTO tmp1 (TranType,PatNum,TranDate,TranAmount)
SELECT 'InsPay' AS TranType,cp.PatNum PatNum,
cp.DateCp TranDate,-cp.InsPayAmt TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4);/*received, supplemental*/
/*Claim payments the entire office history on or before the given date*/
INSERT INTO tmp1 (TranType,PatNum,TranDate,TranAmount)
SELECT 'Writeoff' AS TranType,cp.PatNum PatNum,
cp.DateCp TranDate,-cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4);/*received, supplemental*/
/*Claim capitation payments and capitation writeoffs for the entire office history on or before the given date*/
INSERT INTO tmp1 (TranType,PatNum,TranDate,TranAmount)
SELECT 'Capitat' AS TranType,cp.PatNum PatNum,
cp.DateCp TranDate,-cp.InsPayAmt-cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.Status IN (5,7);/* CapClaim or CapComplete*/
/*Payment plan principal for the entire office history on or before the given date*/
INSERT INTO tmp1 (TranType,PatNum,TranDate,TranAmount)
SELECT 'PayPlan' AS TranType,pp.PatNum PatNum,
pp.PayPlanDate TranDate,
-pp.CompletedAmt TranAmount
FROM payplan pp;
SELECT g.PatNum,SUM(TranAmount) AS $TranAmount FROM tmp1
INNER JOIN patient p ON p.PatNum=tmp1.PatNum
INNER JOIN patient g ON g.PatNum=p.Guarantor
WHERE TranDate<=@AsOf
GROUP BY g.PatNum
HAVING (SUM(TranAmount)>0.001 OR SUM(TranAmount)<-.001)
ORDER BY g.LName, g.FName;
DROP TABLE IF EXISTS tmp1, tmp2, tmp3, tmp4, tmpTotals;
Active patients with scheduled or completed appointments described like "%Prophy%" within a date range, with a specifically named employer (of guarantor). - Gives name, guarantor's employer, appointment status, appt date, appt note.
/*336 Active patients with scheduled or completed appointments described like "%Prophy%"
within a date range, with a specifically named employer (of guarantor).
Gives name, guarantor's employer, appointment status, appt date, appt note
*/
SET @FromDate='2009-01-01', @ToDate='2009-12-31';
SET @Employer='%Cisco%'; /* @Employer='%%' if you don't want to filter by employer*/
SELECT p.LName, p.FName, emp.EmpName, ap.AptStatus, ap.AptDateTime, ap.Note
FROM patient p
INNER JOIN patient g ON p.Guarantor=g.PatNum
INNER JOIN appointment ap ON ap.PatNum = p.PatNum
INNER JOIN employer emp ON emp.EmployerNum=g.EmployerNum
WHERE (ap.AptStatus=1 OR ap.AptStatus=2)
AND p.PatStatus=0
AND ap.ProcDescript LIKE '%Prophy%'
AND AptDateTime BETWEEN @FromDate AND @ToDate
AND emp.EmpName LIKE @Employer;
Completed procedures in date range, with fees and provider ordered by patient. -
/*337 Completed procedures in date range, with fees and provider ordered by patient */
SET @FromDate='2009-10-01' , @ToDate='2009-10-31';
SELECT CONCAT(LName, ', ',FName, ' ', MiddleI) As Patient, pc.ProcCode, pl.ProcDate, pl.ProcFee, pl.ProvNum FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
WHERE pl.ProcDate >=@FromDate
AND pl.ProcDate <= @ToDate
AND pl.ProcStatus=2
ORDER BY patient.LName, patient.FName ASC;
Completed procs in date range, with fees summed by patient. -
/*338 Completed procs in date range, with fees summed by patient */
SET @FromDate='2009-10-01' , @ToDate='2009-10-31';
SELECT CONCAT(LName, ', ',FName, ' ', MiddleI) As Patient, SUM(pl.ProcFee) AS ProcFee FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
LEFT JOIN paysplit ps ON pl.ProcNum=ps.ProcNum
WHERE pl.ProcDate >=@FromDate
AND pl.ProcDate <= @ToDate
AND pl.ProcStatus=2
GROUP BY pl.PatNum;
Referrers, along with the names of patients who they have referred, within a given date range. - For Versions 17.1 and greater. Please update your version accordingly. Tells whether they are a patient (have a PatNum) or not. Set the date range and the name of the referrer (optional) at top.
/*339 Referrers, along with the names of patients who they have referred, within a given date range.*/
/*Tells whether they are a patient (have a PatNum) or not,*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/16/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate = '2017-01-01';
SET @ToDate = '2018-01-31';
SET @ReferrerLName='%%';/*Leave as '%%' to see all*/
SET @ReferrerFName='%%';/*Leave as '%%' to see all*/
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT IF(rf.PatNum,'Yes','No') AS IsPatient,
CONCAT(rf.LName,', ', rf.FName) AS Referrer,
p.FName,
p.LName,
ra.RefDate
FROM referral rf
LEFT JOIN refattach ra ON ra.ReferralNum=rf.ReferralNum
LEFT JOIN patient p ON ra.PatNum=p.PatNum
WHERE ra.RefType = 1 /*RefFrom*/
AND rf.LName LIKE @ReferrerLName
AND rf.FName LIKE @ReferrerFName
AND ra.RefDate BETWEEN @FromDate AND @ToDate;
List of Patients with more than one insurance. -
/*340 List of Patients with more than one insurance*/
SELECT PatNum, COUNT(*) 'Number of Plans'
FROM patplan
GROUP BY PatNum
HAVING COUNT(*)>1;
New patients for a time span, with billing type. - New patient date based on completed procedure with fee>0.
/*341 New patients for a time span, with billing type, email, phone, (new patient date based on completed procedure with fee>0)*/
SET @FromDate='2015-01-01', @ToDate='2015-12-31';
SET @pos=0;
SELECT @pos:=@pos+1 AS PatCount, A.*
FROM
(SELECT patient.PatNum, patient.email, patient.WirelessPhone, DATE_FORMAT(MIN(procedurelog.ProcDate),'%m-%d-%Y') AS FirstVisit,
patient.BillingType
FROM patient, procedurelog
WHERE procedurelog.PatNum = patient.PatNum
AND patient.patstatus = '0'
AND procedurelog.ProcStatus=2
AND procedurelog.ProcFee > 0
GROUP BY patient.PatNum
HAVING
MIN(DATE(procedurelog.ProcDate)) BETWEEN @FromDate
AND @ToDate
ORDER BY MIN(DATE(procedurelog.ProcDate))
)A;
Carrier Phone List for Printing, only includes carriers with active patients using them -
/*342 Carrier Phone List for Printing, only includes carriers with active patients using them*/
SELECT carrier.CarrierName, COUNT(DISTINCT p.PatNum) AS 'Patients', carrier.Phone
FROM carrier
INNER JOIN insplan ip ON carrier.CarrierNum=ip.CarrierNum
INNER JOIN inssub ib ON ip.PlanNum=ib.PlanNum
INNER JOIN patplan pp ON ib.InsSubNum=pp.InsSubNum
INNER JOIN patient p ON pp.PatNum=p.PatNum
WHERE p.PatStatus=0
GROUP BY CarrierName
ORDER BY CarrierName;
Outstanding insurance claims for date of service date range defined by user. - This is different than the usual interval as it can cut off older claims if you want.
/*343 Outstanding insurance claims for date of service date range defined by user
(this is different than the usual interval as it can cut off older claims if you want)*/
SET @FromDate='2009-01-01' , @ToDate='2009-12-31';/*Change dates here*/
SELECT cl.PatNum,cl.DateService,cl.DateSent, ca.CarrierName, ca.Phone FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE cl.ClaimStatus='S' AND
DateService>@FromDate AND DateService<@ToDate AND
ClaimType<>'PreAuth'
ORDER BY ca.CarrierName,p.LName;
Show families with remaining debt FROM a previous set date. - SEE REPLICATION WARNING for versions before 14.3.1. Assumes FIFO (first in first out).
/*344 Show families with remaining debt FROM a previous set date
assumes FIFO (first in first out)*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @AsOf='2008-06-31';
SET @ReportDate=CurDate();
/*first create transaction table*/
DROP TABLE IF EXISTS tmp1, tmp2, tmp3, tmp4, tmp5;
CREATE TABLE tmp1
(PatNum INT DEFAULT 0,
TranDate DATE DEFAULT '0001-01-01',
TranAmount DOUBLE DEFAULT 0,
TranType VARCHAR(10));
/*Get the completed procedure dates and charges for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount,TranType)
SELECT pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount, 'Proc'
FROM procedurelog pl
WHERE pl.ProcStatus=2;
/*Paysplits for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount,TranType)
SELECT ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount, 'Pay'
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/;
/*Get the adjustment dates and amounts for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount,TranType)
SELECT a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount, 'Adj'
FROM adjustment a;
/*Claim payments and capitation writeoffs for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount,TranType)
SELECT cp.PatNum PatNum,
cp.DateCp TranDate,-cp.InsPayAmt-cp.Writeoff TranAmount, 'InsPay'
FROM claimproc cp
WHERE cp.Status IN (1,4,5,7);/*received, supplemental, CapClaim or CapComplete*/
/*Payment plan principal for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount,TranType)
SELECT pp.PatNum PatNum,
pp.PayPlanDate TranDate,
-pp.CompletedAmt TranAmount,'PP'
FROM payplan pp;
/*now we need to include the anticipated insurance (sum of payments and writeoffs)
note that if you use PPO type, your anticipated writeoff numbers will have updated to
match your actual writeoff numbers... your best bet is to keep backups or paper copies of your
reports if that change is bothersome */
/*Now Note that as we get these numbers we are summing by family, when really we
are looking for a grand total, this is to make it easier to get the details should we need them
FROM the tmp tables*/
CREATE TABLE tmp3 SELECT p.Guarantor,SUM(cp.InsPayEst) InsPayEst,
(CASE WHEN ISNULL(SUM(cp.Writeoff)) THEN 0 ELSE SUM(cp.WriteOff) END) WriteOff
FROM patient p INNER JOIN claimproc cp ON cp.PatNum=p.PatNum
WHERE ((cp.Status=0 AND cp.ProcDate<=@ReportDate) OR /* still not received and procedure completed before the date*/
(cp.Status IN(1,4) AND cp.DateCP>@ReportDate AND cp.ProcDate<=@ReportDate)) /*was received after the date of interest and completed before it*/
/*AND p.PatStatus NOT IN(4,3) not archived*/
GROUP BY p.Guarantor;
CREATE TABLE tmp2
SELECT Guarantor, SUM(TranAmount) AS 'CurFamBal'
FROM patient
INNER JOIN tmp1 ON tmp1.PatNum=patient.PatNum
WHERE TranDate<=@ReportDate
GROUP BY Guarantor;
CREATE TABLE tmp5
SELECT Guarantor,
SUM(TranAmount) AS 'PaymentsMade'
FROM patient
INNER JOIN tmp1 ON tmp1.PatNum=patient.PatNum
WHERE TranDate>@AsOf AND TranDate<=@ReportDate AND TranType IN('Proc','Adj') AND TranAmount>0
GROUP BY Guarantor;
CREATE TABLE tmp4
SELECT tmp2.Guarantor, CurFamBal AS '$CurFamBal', WriteOff AS '$WriteOffEst',InsPayEst AS '$InsPayEst',
(CurFamBal-IFNULL(WriteOff,0)-IFNULL(InsPayEst,0)) AS '$CurPatPortion', (CurFamBal-IFNULL(PaymentsMade,0)) AS '$BalLeftPreviousPeriod'
FROM tmp2
LEFT JOIN tmp3 ON tmp2.Guarantor=tmp3.Guarantor
LEFT JOIN tmp5 ON tmp2.Guarantor=tmp5.Guarantor
WHERE (CurFamBal-IFNULL(PaymentsMade,0))>0.01;
SELECT * FROM tmp4;
DROP TABLE IF EXISTS tmp1, tmp2, tmp3, tmp4, tmp5;
Insurance claim procedures with UCR fee, InsEst and InsAmtPaid. - Change date range as needed, does not distinguish between received claims, sent claims etc.
/*345 Insurance claim procedures with UCR fee, InsEst and InsAmtPaid - Change date range as needed, does not distinguish between received claims, sent claims etc*/
/* Much Like #80 but with Carrier Name, you must also specify your UCR fee schedule name*/
SET @StartDate='2009-08-01' , @EndDate='2009-08-15';
SELECT claim.PatNum,DateService,ProvTreat,pc.ProcCode,cp.InsPayEst,f.Amount as 'UCR FEE', cp.inspayamt, car.CarrierName
FROM claim
INNER JOIN claimproc cp ON claim.ClaimNum=cp.ClaimNum
INNER JOIN insplan ip ON ip.PlanNum=claim.PlanNum
INNER JOIN carrier car ON car.CarrierNum= ip.CarrierNum
INNER JOIN procedurelog pl ON cp.ProcNum=pl.ProcNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
INNER JOIN fee f ON pc.CodeNum=f.CodeNum
INNER JOIN feesched fs ON f.FeeSched=fs.FeeSchedNum AND fs.Description='Standard'
WHERE DateService>=@StartDate AND
DateService<=@EndDate;
Sum of appointment lengths for time period. - Helps measure utilization.
/*346 Sum of appointment lengths for time period
helps measure utilization*/
SET @StartDate='2011-04-01' , @EndDate='2011-04-07';
SELECT o.OpName,
FORMAT(SUM(LENGTH(a.Pattern))/12,1) AS 'AptTime(hrs)',
FORMAT(SUM(LENGTH(a.Pattern)-LENGTH(REPLACE(a.Pattern,'X','')))/12,1) AS 'ProvTime(hrs)'
FROM appointment a
INNER JOIN operatory o ON o.OperatoryNum=a.Op
WHERE DATE(a.AptDateTime) BETWEEN @StartDate AND @EndDate
AND (a.AptStatus=2 OR a.AptStatus=1)
GROUP BY o.OpName;
Monthly Production and Income Report with Insurance Income & Writeoffs by Date of Service. - SEE REPLICATION WARNING for versions before 14.3.1. CAUTION This is an unusual report, read the title carefully.
/*347 Monthly Production and Income Report with Insurance Income & Writeoffs by Date of Service
CAUTION THIS IS an unusual report, read the title carefully */
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS t1,t2;
SET @FromDate='2009-03-01' , @ToDate='2009-03-31';
CREATE TABLE t1(
Day int NOT NULL,
Date date,
DayOfWeek varchar(10),
$Production double NOT NULL DEFAULT 0,
$Adjustments double NOT NULL DEFAULT 0,
$WriteOffs double NOT NULL DEFAULT 0,
$TotProduction double NOT NULL DEFAULT 0,
$PatIncome double NOT NULL DEFAULT 0,
$InsIncome double NOT NULL DEFAULT 0,
$TotIncome double NOT NULL DEFAULT 0);
/*Load Days of month*/
INSERT INTO t1(Day)
VALUES (1),(2),(3),(4),(5),(6),(7),(8),(9),(10),(11),(12),(13),(14),(15),(16),(17),(18),(19),(20),(21),(22),(23),(24),(25),(26),(27),(28),(29),(30),(31);
DELETE FROM t1 WHERE Day>DAY(LAST_DAY(@FromDate));
UPDATE t1 SET Date=STR_TO_DATE(CONCAT(MONTH(@FromDate), '/', Day, '/', YEAR(@FromDate)),'%c/%e/%Y');
UPDATE t1 SET DayOfWeek=DATE_FORMAT(Date, '%W');
/*Prod*/
CREATE TABLE t2
SELECT DAYOFMONTH(pl.ProcDate) AS 'Day',
SUM(pl.procfee) AS 'Production'
FROM procedurelog pl WHERE pl.ProcStatus=2 AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY DAYOFMONTH(pl.ProcDate);
UPDATE t1,t2 SET t1.$Production=t2.Production WHERE t1.Day=t2.Day;
DROP TABLE IF EXISTS t2;
/*Adj*/
CREATE TABLE t2
SELECT DAYOFMONTH(a.AdjDate) AS 'Day',
SUM(a.AdjAmt) AS 'Adjustments' FROM adjustment a
WHERE a.AdjDate BETWEEN @FromDate AND @ToDate
GROUP BY DAYOFMONTH(a.AdjDate);
UPDATE t1,t2 SET t1.$Adjustments=t2.Adjustments WHERE t1.Day=t2.Day;
DROP TABLE IF EXISTS t2;
/*PatInc*/
CREATE TABLE t2
SELECT DAYOFMONTH(pp.DatePay) AS 'Day',
SUM(pp.SplitAmt) AS 'PatIncome' FROM paysplit pp
WHERE pp.DatePay BETWEEN @FromDate AND @ToDate
GROUP BY DAYOFMONTH(pp.DatePay);
UPDATE t1,t2 SET t1.$PatIncome=t2.PatIncome WHERE t1.Day=t2.Day;
DROP TABLE IF EXISTS t2;
/*InsWriteoffs*/
CREATE TABLE t2
SELECT DAYOFMONTH(cp.ProcDate) AS 'Day',
SUM(cp.WriteOff) AS 'WriteOffs'
FROM claimproc cp
WHERE (cp.Status=1 OR cp.Status=4 OR cp.Status=0)
AND cp.ProcDate BETWEEN @FromDate AND @ToDate /*vs DateCP if not counting writeoffs by procdate*/
GROUP BY DAYOFMONTH(cp.ProcDate);
UPDATE t1,t2 SET
t1.$WriteOffs=-t2.WriteOffs
WHERE t1.Day=t2.Day;
DROP TABLE IF EXISTS t2;
/*InsIncome*/
CREATE TABLE t2
SELECT DAYOFMONTH(cp.ProcDate) AS 'Day',
SUM(cp.InsPayAmt) AS 'InsIncome'
FROM claimproc cp
WHERE (cp.Status=1 OR cp.Status=4)
AND cp.ProcDate BETWEEN @FromDate AND @ToDate /*DateCP if not counting writeoffs by procdate*/
GROUP BY DAYOFMONTH(cp.ProcDate);
UPDATE t1,t2 SET t1.$InsIncome=t2.InsIncome
WHERE t1.Day=t2.Day;
UPDATE t1 SET
$TotProduction=$Production+$Adjustments+$WriteOffs,
$TotIncome=$InsIncome+$PatIncome ;
DROP TABLE IF EXISTS t2;
ALTER TABLE t1 DROP Day;
SELECT * FROM t1;
DROP TABLE IF EXISTS t1;
Outstanding Insurance Claims (not preauths) with patient, date sent, plan number, claimfee and ins estimate for a given carrier. -
/*348 Outstanding Insurance Claims (not preauths) with patient, date sent, plan number, claimfee and ins estimate for a given carrier*/
SET @Carrier = '%DC%';
SELECT cl.PatNum,cl.DateSent, i.plannum, cl.claimfee, cl.inspayest
FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE cl.ClaimStatus='S' AND ca.CarrierName LIKE @Carrier
GROUP BY cl.ClaimNum
ORDER BY ca.CarrierName,p.LName;
Payment Report like 169 except for date range, without providers listed. - SEE REPLICATION WARNING for versions before 14.3.1. Similar to Daily Payment Report.
/*349 Payment Report like 169 except for date range, without providers listed, similar to Daily Payment Report*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @FromDate='2012-01-01', @ToDate='2012-01-31' ;
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp SELECT paysplit.PatNum, definition.ItemName AS PaymentType, payment.CheckNum, DATE(paysplit.DatePay) AS 'DatePay',
SUM(paysplit.SplitAmt) AS $PaymentAmt
FROM payment,definition,paysplit
WHERE (paysplit.DatePay BETWEEN @FromDate
AND @ToDate)
AND payment.PayNum=paysplit.PayNum
AND definition.DefNum=payment.PayType
GROUP BY paysplit.PatNum, definition.ItemName
UNION ALL
SELECT PatNum, 'Ins Checks' as PaymentType, cpy.CheckNum, claimproc.DateCP AS 'DatePay', SUM(claimproc.InsPayAmt) AS $PaymentAmt
FROM claimproc
INNER JOIN claimpayment cpy ON cpy.ClaimPaymentNum=claimproc.ClaimPaymentNum
WHERE claimproc.DateCP>=@FromDate
AND claimproc.DateCP<=@ToDate
AND (claimproc.Status=1 OR claimproc.Status=4)
GROUP BY PatNum;
SELECT tmp.PatNum, PaymentType, DatePay, $PaymentAmt FROM tmp, patient
WHERE tmp.PatNum=patient.PatNum
ORDER BY DatePay ASC, patient.LName;
DROP TABLE IF EXISTS tmp;
Claims of status 'Sent' or 'received' by Date of Service For a particular carrier with PatNum, Amount billed insurance, Amount billed patient and Date sent Edit Dates to change date of service range -
/*350 Claims of status 'Sent' or 'received' by Date of Service For a particular carrier
with PatNum, Amount billed insurance, Amount billed patient and Date sent Edit Dates to change date of service range*/
Set @Carrier='%TMHP%';
SET @FromDate='2009-01-01' , @ToDate='2009-01-31';
SELECT cl.PatNum, p.PatNum AS 'RawPatNum',cl.DateService,cl.DateSent,
ca.CarrierName, ca.Phone, cl.ClaimFee,
(SELECT SUM(ProcFee)-SUM(cp.WriteOff) FROM procedurelog pl
INNER JOIN claimproc cp ON pl.ProcNum=cp.ProcNum WHERE cp.ClaimNum=cl.ClaimNum) AS '$PatBilled'
FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE
cl.ClaimType<>'PreAuth' AND (cl.ClaimStatus='R' OR cl.ClaimStatus='S') AND
(DateService BETWEEN @FromDate AND @ToDate)
AND ca.CarrierName LIKE @Carrier
ORDER BY ca.CarrierName,p.LName;
Count of Hygiene Appointments and Distinct Hygiene Patients in Date Range, only a count. - Hygiene appointments are defined as appointments with one or more hygiene procedures. There are other tables joined here to allow for easy additional information.
/*351 Count of Hygiene Appointments and Distinct Hygiene Patients in Date Range, only a count*/
/*Query code written/modified: 02/10/2017*/
SET @FromDate='2016-01-01' , @ToDate='2016-12-31';
/*Options: 'YES' or 'NO' . When 'YES" will only consider procedure codes that have the "Is Hygiene" checked.*/
SET @ProcCodesMarkedHyg="YES";
/*Separate procedures with a pipe character | */
SET @HygCodes='D1110|D1120';
/*Hygiene appointments are defined as appointments with one or more hygiene procedures.
There are other tables joined here to allow for easy additional information.
This query works for historical data that came from a conversion.*/
SELECT COUNT(DISTINCT (CASE pl.AptNum WHEN 0 THEN NULL ELSE pl.AptNum END)) AS 'Hyg Apt Count' ,
COUNT(DISTINCT pl.PatNum) AS 'Hyg Pat Count'
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
AND pl.ProcStatus = '2' /*Completed*/
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
AND (CASE @ProcCodesMarkedHyg WHEN "YES" THEN pc.IsHygiene=1 ELSE pc.ProcCode REGEXP @HygCodes END)
What amount of family balance is for work completed before a user provided date in the past. - SEE REPLICATION WARNING for versions before 14.3.1. Gives OldDebtBalance and OldInsuranceEstimate and allows you to set paid thru date, also shows current family balance and Insurance Estimate.
/*352 What amount of family balance is for work completed before a user provided date in the past
Gives OldDebtBalance and OldInsuranceEstimate and allows you to set paid thru date,
also shows current family balance and Insurance Estimate */
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @AsOf='2010-02-01';
SET @PaidThru='2010-04-16';
/*Calculate family level unpaid balances on procedures completed before given date
this is NOT quite like an aging report because we are considering only work completed before a given date
but we account for all payments adjustments, writeoffs etc through current date or Paid Thru Date
-Assumes oldest procedures paid first, the paid thru date should be greater than the AsOf Date*/
/*first create transaction table*/
DROP TABLE IF EXISTS tmp1, tmp2, tmp3, tmp4;
CREATE TABLE tmp1
(PatNum INT DEFAULT 0,
TranDate DATE DEFAULT '0001-01-01',
TranAmount DOUBLE DEFAULT 0);
/*Get the completed procedure dates and charges for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2 AND pl.ProcDate<=@AsOf;
/*Paysplits for the entire office on or before specified @PaidThru date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
AND ps.ProcDate<=@PaidThru;
/*Get the adjustment dates and amounts for the entire office history*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount
FROM adjustment a
WHERE a.AdjDate<=@PaidThru;
/*Claim payments and capitation writeoffs for the entire office history for procedures conmpleted on or before given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT cp.PatNum PatNum,
cp.DateCp TranDate,-cp.InsPayAmt-cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4,5,7) AND cp.ProcDate<=@AsOf
AND cp.DateCp<=@PaidThru;/*received, supplemental, CapClaim or CapComplete*/
/*Payment plan principal for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT pp.PatNum PatNum,
pp.PayPlanDate TranDate,
-pp.CompletedAmt TranAmount
FROM payplan pp WHERE pp.PayPlanDate<=@PaidThru;
/*now we need to include the anticipated insurance (sum of payments and writeoffs)
note that if you use PPO type, your anticipated writeoff numbers will have updated to
match your actual writeoff numbers... your best bet is to keep backups or paper copies of your
reports if that change is bothersome */
/*Now Note that as we get these numbers we are summing by family, when really we
are looking for a grand total, this is to make it easier to get the details should we need them
FROM the tmp tables*/
CREATE TABLE tmp3 SELECT p.Guarantor,SUM(cp.InsPayEst) AS InsPayEst,
0 AS WriteOff
FROM patient p INNER JOIN claimproc cp ON cp.PatNum=p.PatNum
WHERE (cp.Status=0 AND cp.ProcDate<=@AsOf) /* still not received and procedure completed before the date*/
/*AND p.PatStatus NOT IN(4,3) not archived*/
GROUP BY p.Guarantor;
INSERT INTO tmp3
SELECT p.Guarantor,0 AS InsPayEst,
(CASE WHEN ISNULL(SUM(cp.Writeoff)) THEN 0 ELSE SUM(cp.WriteOff) END) AS WriteOff
FROM patient p INNER JOIN claimproc cp ON cp.PatNum=p.PatNum
WHERE ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR /* still not received and procedure completed before the date*/
(cp.Status IN(1,4) AND cp.DateCP>@AsOf AND cp.ProcDate<=@AsOf)) /*was received after the date of interest and completed before it*/
/*AND p.PatStatus NOT IN(4,3) not archived*/
GROUP BY p.Guarantor;
CREATE TABLE tmp2
SELECT patient.Guarantor, SUM(tmp1.TranAmount) AS 'FamBal' FROM patient
INNER JOIN tmp1 ON tmp1.PatNum=Patient.PatNum
GROUP BY patient.Guarantor;
CREATE TABLE tmp4
SELECT 'SumUnpaidBalances' AS 'Description', SUM(FamBal) '$Value' FROM tmp2
WHERE FamBal>0
UNION ALL
SELECT 'TotInsPayEst' AS 'Description', SUM(InsPayEst) '$Value' FROM tmp3
UNION ALL
SELECT 'TotWriteOffEst' AS 'Description', SUM(WriteOff) '$Value' FROM tmp3;
SELECT tmp2.Guarantor, p.PatNum AS GuarPatNum, tmp2.FamBal as '$OldDebtFamBal', p.BalTotal AS '$CurBalTotal', t3.InsPayEst+t3.WriteOff AS $OldInsPayEst,
p.InsEst AS '$CurTotInsEst'
FROM tmp2
LEFT JOIN (SELECT Guarantor,SUM(InsPayEst) AS InsPayEst, SUM(WriteOff) AS WriteOff FROM tmp3 GROUP BY Guarantor) t3 ON t3.Guarantor=tmp2.Guarantor
LEFT JOIN patient p ON tmp2.Guarantor=p.PatNum
WHERE tmp2.FamBal>.001
ORDER BY LName, FName;
/* uncomment this line to get summary SELECT * FROM tmp4;*/
DROP TABLE IF EXISTS tmp1, tmp2, tmp3, tmp4;
Show all transactions that comprise an aging report - SEE REPLICATION WARNING for versions before 14.3.1. IMPORTANT: accounts for writeoffs on insurance payment date
/*353 Show all transactions that comprise an aging report*/
/*IMPORTANT: accounts for writeoffs on insurance payment date*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @AsOf='2009-07-31';
/*first create transaction table*/
DROP TABLE IF EXISTS tmp1, tmp2, tmp3, tmp4, tmpTotals;
CREATE TABLE tmp1
(TranType VARCHAR(10), PatNum INT DEFAULT 0,
TranDate DATE DEFAULT '0001-01-01',
TranAmount DOUBLE DEFAULT 0);
/*Get the completed procedure dates and charges for the entire office history on or before the given date*/
INSERT INTO tmp1 (TranType,PatNum,TranDate,TranAmount)
SELECT 'Fee' AS TranType, pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2;
/*Paysplits for the entire office history on or before the given date*/
INSERT INTO tmp1 (TranType,PatNum,TranDate,TranAmount)
SELECT 'Pay' AS TranType,ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/;
/*Get the adjustment dates and amounts for the entire office history on or before the given date*/
INSERT INTO tmp1 (TranType,PatNum,TranDate,TranAmount)
SELECT 'Adj' AS TranType, a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount
FROM adjustment a;
/*Claim payments for the entire office history on or before the given date*/
INSERT INTO tmp1 (TranType,PatNum,TranDate,TranAmount)
SELECT 'InsPay' AS TranType,cp.PatNum PatNum,
cp.DateCp TranDate,-cp.InsPayAmt TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4);/*received, supplemental*/
/*Claim payments the entire office history on or before the given date*/
INSERT INTO tmp1 (TranType,PatNum,TranDate,TranAmount)
SELECT 'Writeoff' AS TranType,cp.PatNum PatNum,
cp.DateCp TranDate,-cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4);/*received, supplemental*/
/*Claim capitation payments and capitation writeoffs for the entire office history on or before the given date*/
INSERT INTO tmp1 (TranType,PatNum,TranDate,TranAmount)
SELECT 'Capitat' AS TranType,cp.PatNum PatNum,
cp.DateCp TranDate,-cp.InsPayAmt-cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.Status IN (5,7);/* CapClaim or CapComplete*/
/*Payment plan principal for the entire office history on or before the given date*/
INSERT INTO tmp1 (TranType,PatNum,TranDate,TranAmount)
SELECT 'PayPlan' AS TranType,pp.PatNum PatNum,
pp.PayPlanDate TranDate,
-pp.CompletedAmt TranAmount
FROM payplan pp;
SELECT patient.Guarantor,TranType, TranDate, TranAmount AS $TranAmount FROM tmp1
INNER JOIN patient ON patient.PatNum=tmp1.PatNum
INNER JOIN patient g ON patient.Guarantor = g.PatNum
WHERE TranAmount<> 0 AND TranDate<=@AsOf
ORDER BY g.LName, g.FName;
DROP TABLE IF EXISTS tmp1, tmp2, tmp3, tmp4, tmpTotals;
Ortho or other marked patient Monthly Production and Income - SEE REPLICATION WARNING for versions before 14.3.1. Change the name match from p.LName LIKE '%Ortho%' to p.LName LIKE '%*%' If the * symbol is what you are using to indicate ortho. Counts insurance writeoffs by procedure date (PPO) For all providers
/*354 Ortho or other marked patient Monthly Production and Income*/
/*Change the name match from p.LName LIKE '%Ortho%' to p.LName LIKE '%*%' If the * symbol is what you are using to indicate ortho
counts insurance writeoffs by procedure date (PPO) For all providers ;*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS t1,t2;
SET @FromDate='2009-03-01' , @ToDate='2009-03-31';
CREATE TABLE t1(
Day int NOT NULL,
Date date,
DayOfWeek varchar(10),
$Production double NOT NULL DEFAULT 0,
$Adjustments double NOT NULL DEFAULT 0,
$WriteOffs double NOT NULL DEFAULT 0,
$TotProduction double NOT NULL DEFAULT 0,
$PatIncome double NOT NULL DEFAULT 0,
$InsIncome double NOT NULL DEFAULT 0,
$TotIncome double NOT NULL DEFAULT 0);
/*Load Days of month*/
INSERT INTO t1(Day)
VALUES (1),(2),(3),(4),(5),(6),(7),(8),(9),(10),(11),(12),(13),(14),(15),(16),(17),(18),(19),(20),(21),(22),(23),(24),(25),(26),(27),(28),(29),(30),(31);
DELETE FROM t1 WHERE Day>DAY(LAST_DAY(@FromDate));
UPDATE t1 SET Date=STR_TO_DATE(CONCAT(MONTH(@FromDate), '/', Day, '/', YEAR(@FromDate)),'%c/%e/%Y');
UPDATE t1 SET DayOfWeek=DATE_FORMAT(Date, '%W');
/*Prod*/
CREATE TABLE t2
SELECT DAYOFMONTH(pl.ProcDate) AS 'Day',
SUM(pl.procfee) AS 'Production'
FROM procedurelog pl
INNER JOIN patient p on p.PatNum=pl.PatNum WHERE pl.ProcStatus=2 AND
p.LName LIKE '%Ortho%'
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY DAYOFMONTH(pl.ProcDate);
UPDATE t1,t2 SET t1.$Production=t2.Production WHERE t1.Day=t2.Day;
DROP TABLE IF EXISTS t2;
/*Adj*/
CREATE TABLE t2
SELECT DAYOFMONTH(a.AdjDate) AS 'Day',
SUM(a.AdjAmt) AS 'Adjustments' FROM adjustment a
INNER JOIN patient p on a.PatNum=p.PatNum WHERE
p.LName LIKE '%Ortho%' AND a.AdjDate BETWEEN @FromDate AND @ToDate
GROUP BY DAYOFMONTH(a.AdjDate);
UPDATE t1,t2 SET t1.$Adjustments=t2.Adjustments WHERE t1.Day=t2.Day;
DROP TABLE IF EXISTS t2;
/*PatInc*/
CREATE TABLE t2
SELECT DAYOFMONTH(pp.DatePay) AS 'Day',
SUM(pp.SplitAmt) AS 'PatIncome' FROM paysplit pp
INNER JOIN patient p on pp.PatNum=p.PatNum WHERE
p.LName LIKE '%Ortho%' AND pp.DatePay BETWEEN @FromDate AND @ToDate
GROUP BY DAYOFMONTH(pp.DatePay);
UPDATE t1,t2 SET t1.$PatIncome=t2.PatIncome WHERE t1.Day=t2.Day;
DROP TABLE IF EXISTS t2;
/*InsIncome*/
CREATE TABLE t2
SELECT DAYOFMONTH(cp.ProcDate) AS 'Day',
SUM(cp.WriteOff) AS 'WriteOffs'
FROM claimproc cp
INNER JOIN patient p on p.PatNum=cp.PatNum WHERE
p.LName LIKE '%Ortho%' AND (cp.Status=1 OR cp.Status=4 OR cp.Status=0)
AND cp.ProcDate BETWEEN @FromDate AND @ToDate /*vs DateCP if not counting writeoffs by procdate*/
GROUP BY DAYOFMONTH(cp.ProcDate);
UPDATE t1,t2 SET
t1.$WriteOffs=-t2.WriteOffs
WHERE t1.Day=t2.Day;
DROP TABLE IF EXISTS t2;
/*InsIncome*/
CREATE TABLE t2
SELECT DAYOFMONTH(cpay.CheckDate) AS 'Day',
SUM(cp.InsPayAmt) AS 'InsIncome'
FROM claimproc cp
INNER JOIN claimpayment cpay ON cpay.ClaimPaymentNum=cp.ClaimPaymentNum
WHERE cpay.CheckDate BETWEEN @FromDate AND @ToDate AND
cp.Status IN(1,4)
GROUP BY DAYOFMONTH(cpay.CheckDate);
UPDATE t1,t2 SET t1.$InsIncome=t2.InsIncome
WHERE t1.Day=t2.Day;
UPDATE t1 SET
$TotProduction=$Production+$Adjustments+$WriteOffs,
$TotIncome=$InsIncome+$PatIncome ;
DROP TABLE IF EXISTS t2;
ALTER TABLE t1 DROP Day;
SELECT * FROM t1;
DROP TABLE IF EXISTS t1;
List of patients of a given age range with count of completed procedures(at any time) -
/*355 List of patients of a given age range with count of procedures completed (at any time)*/
/*Query code written/modified: 05/17/2018*/
SET @StartAge=0, @EndAge=20; /*Enter age range here*/
/*---DO NOT MODIFY BELOW THIS LINE---*/
/*Count of completed procedures per patient within the specified age range. Displays patient's age*/
SELECT PatNum, Procedures, Age
FROM (
SELECT p.PatNum,
COUNT(pl.ProcNum) AS 'Procedures',
TIMESTAMPDIFF(YEAR,p.Birthdate,CURDATE()) AS 'Age'
FROM patient p
INNER JOIN procedurelog pl
ON pl.PatNum = p.PatNum
AND pl.ProcStatus = 2 -- completed procedures
WHERE TIMESTAMPDIFF(YEAR,p.Birthdate,CURDATE()) BETWEEN @StartAge AND @EndAge -- Age limitation
GROUP BY p.PatNum
ORDER BY p.LName, p.FName
) results
UNION ALL
/*Get a total count of completed procedures and a count of patients in the specified age range*/
SELECT 'Total' AS PatNum, SUM(results.Procedures) AS 'Procedures', COUNT(results.PatNum) AS 'Age'
FROM (
SELECT p.PatNum,
COUNT(pl.ProcNum) AS 'Procedures',
TIMESTAMPDIFF(YEAR,p.Birthdate,CURDATE()) AS 'Age'
FROM patient p
INNER JOIN procedurelog pl
ON pl.PatNum = p.PatNum
AND pl.ProcStatus = 2 -- completed procedures
WHERE TIMESTAMPDIFF(YEAR,p.Birthdate,CURDATE()) BETWEEN @StartAge AND @EndAge -- Age limitation
GROUP BY p.PatNum
ORDER BY p.LName, p.FName
) results
List of Patients that have not been since a specific date that have insurance benefits remaining. - Includes Insurance Carrier's Name, Patient's Name, Three Phone Numbers, Benefits Remaining, TP Remaining and Last seen date. Assumes everyone has calendar year benefits. Warning - may be slow
/*356 List of Patients that have not been in since a specific date that have insurance benefits remaining.
Includes Insurance Carrier's Name, Patient's Name, Three Phone Numbers, Benefits Remaining,
TP Remaining and Last seen date. Assumes everyone has calendar year benefits*/
SET @FromDate='2013-10-08';
SELECT p.PatNum AS 'Pat#',
p.LName,
p.FName,
p.HmPhone,
p.WkPhone,
p.WirelessPhone,
DATE_FORMAT(lastseen.LastSeen,'%m/%d/%Y')AS LastSeen,
annualmax.AnnualMax '$AnnualMax_',
used.AmtUsed '$AmountUsed_',
annualmax.AnnualMax-COALESCE(used.AmtUsed,0) '$AmtRemaining_',
planned.AmtPlanned '$TreatmentPlan_',
c.CarrierName
FROM patient p
INNER JOIN patplan ON p.PatNum=patplan.PatNum
INNER JOIN inssub ON inssub.InsSubNum=patplan.InsSubNum
INNER JOIN insplan ip ON ip.PlanNum=inssub.PlanNum
INNER JOIN carrier c ON c.CarrierNum=ip.CarrierNum
INNER JOIN (
SELECT benefit.PlanNum,
MAX(benefit.MonetaryAmt) AS AnnualMax
FROM benefit
LEFT JOIN covcat ON covcat.CovCatNum = benefit.CovCatNum
WHERE benefit.BenefitType = 5 /* limitation */
AND benefit.TimePeriod = 2 /* calendar year */
AND (covcat.EbenefitCat=1 OR ISNULL(covcat.EbenefitCat))
AND benefit.MonetaryAmt > 0 /* (-1) indicates empty */
GROUP BY benefit.PlanNum
) annualmax ON annualmax.PlanNum=inssub.PlanNum
INNER JOIN (
SELECT patient.PatNum,SUM(pl.ProcFee) AS AmtPlanned
FROM patient
INNER JOIN (
SELECT PatNum,ProcFee FROM procedurelog WHERE ProcStatus=1 /*treatment planned*/ AND ProcFee!=0
) pl ON patient.PatNum=pl.PatNum
WHERE patient.PatStatus=0 /* Patient */
GROUP BY patient.PatNum
) planned ON planned.PatNum=p.PatNum AND planned.AmtPlanned>0
LEFT JOIN (
SELECT patplan.PatPlanNum,
SUM(claimproc.InsPayAmt) AS AmtUsed
FROM claimproc
INNER JOIN inssub ON claimproc.InsSubNum=inssub.InsSubNum
INNER JOIN patplan ON inssub.InsSubNum=patplan.InsSubNum
AND patplan.PatNum=claimproc.PatNum
WHERE claimproc.Status IN (1, 3, 4) -- Rec, Adj, Supp.
AND YEAR(claimproc.ProcDate)=YEAR(CURDATE())
AND claimproc.InsPayAmt!=0
GROUP BY patplan.PatPlanNum
) used ON used.PatPlanNum=patplan.PatPlanNum
INNER JOIN (
SELECT p.PatNum,
MAX(procdate) AS LastSeen
FROM patient p
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
AND pl.ProcStatus=2 /*complete*/
AND p.PatStatus=0 /*active patient*/
GROUP BY pl.PatNum
) lastseen ON lastseen.PatNum=p.PatNum AND lastseen.LastSeen<@FromDate
WHERE PatStatus=0
ORDER BY c.CarrierName;
Treatment planned procedures WHERE code matches a pattern or is a specific code with age and phone numbers. - Address can be added if needed, but will not fit on one page with phone numbers.
/*357 Treatment planned procedures WHERE code matches a pattern or is a specific code with age and phone numbers
address can be added if needed, but will not fit on one page with phone numbers*/
SET @CodeLike='D2%'; /*change this D2% to whatever pattern match you want, in this case the query will
return all treatment planned procedures that start with D2, like fillings*/
SELECT patient.PatNum, (YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) AS 'Age',
pl.DateTP,pc.ProcCode,LEFT(WkPhone,16) AS WkPhone, LEFT(HmPhone,16) AS HmPhone, LEFT(WirelessPhone,16) AS CellPhone
/* these fields are sometimes desired: pc.AbbrDesc, pl.ProcFee*/
/* address fields are: Address,Address2,City,State,Zip */
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum AND ProcStatus=1/*treatment planned*/
WHERE patient.PatStatus=0 /*Active patients*/
AND pc.ProcCode LIKE(@CodeLike)
ORDER BY patient.LName, patient.FName, pl.DateTP, pc.ProcCode ASC;
Production by Carrier for date range (or current day) with sum of patient portion estimate - Also includes uninsured total production and writeoffs, and for pat portion, insurance estimates, sent and received claims are considered.
/*358 Production by Carrier for date range (or current day) with sum of patient portion estimate
Also includes uninsured total production and writeoffs, and for pat portion, insurance estimates, sent and received claims are considered*/
SET @FromDate='2009-01-01' , @ToDate='2009-12-31';/*use this for Today @FromDate=CURDATE() , @ToDate=CURDATE(); */
SELECT
/*carrier.carriernum,*/
(CASE WHEN ISNULL(carrier.CarrierName) THEN '*No Insurance' ELSE (carrier.CarrierName) END) AS 'InsCarrier',
/* pl.procnum,
p.PatNum, */
SUM(cp.InsPayEst) AS '$InsPayEst',
SUM(cp.WriteOff) AS $WriteOff,
(CASE WHEN ISNULL(carrier.CarrierName) THEN SUM(pl.ProcFee) ELSE (SUM(pl.ProcFee)-SUM(cp.InsPayEst)) END) AS '$Patient',
SUM(pl.procfee) AS '$TotProd'
FROM patient p
INNER JOIN procedurelog pl
ON p.PatNum = pl.PatNum
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus = 2 -- Complete
LEFT JOIN patplan pp
ON pp.PatNum = p.PatNum
LEFT JOIN inssub
ON inssub.InsSubNum = pp.InsSubNum
LEFT JOIN insplan ip
ON ip.PlanNum = inssub.PlanNum/*by primary insurance*/
LEFT JOIN carrier
ON carrier.CarrierNum = ip.CarrierNum
LEFT JOIN claimproc cp
ON cp.ProcNum = pl.ProcNum
AND (cp.Status = 6 -- Estimate
OR cp.Status = 0 -- Not Received
OR cp.Status = 1) -- Received
AND cp.PlanNum = ip.PlanNum
WHERE (ISNULL(carrier.CarrierName) -- No insurance
OR pp.Ordinal = 1) -- Primary insurance plan
GROUP BY InsCarrier;
Empty Appointments for date range. -
/*359 Empty Appointments for date range*/
SET @FromDate='2009-10-05' , @ToDate='2010-04-05';
SELECT p.PatNum, a.AptDateTime FROM appointment a
INNER JOIN patient p ON p.PatNum=a.PatNum
LEFT JOIN procedurelog pl ON pl.AptNum=a.AptNum
WHERE pl.procnum IS NULL
AND p.PatStatus=0
AND Date(a.AptDateTime) Between @FromDate AND @ToDate
ORDER BY p.LName, p.FName,a.AptDateTime;
Anticipated new patient production in date range. -
/*360 Anticipated new patient production in date range*/
SET @FromDate='2009-10-01' , @ToDate='2009-12-15';
SELECT p.PatNum as 'Pat Num',LName, FName, a.AptDateTime, SUM(pl.ProcFee) AS '$TotFirstFees' FROM patient p
INNER JOIN appointment a ON p.PatNum=a.PatNum
INNER JOIN procedurelog pl ON a.AptNum=pl.AptNum
WHERE
(DATE(a.AptDateTime) BETWEEN @FromDate AND @ToDate)
AND DATE(a.AptDateTime)=p.DateFirstVisit
AND a.AptStatus=1
GROUP BY p.PatNum;
List of active patients in alphabetical order with last appt, and next future appt. -
/*361 List of active patients in alphabetical order with last appt, and next future appt.*/
SELECT p.PatNum AS 'Pat Num', p.LName, p.FName,(SELECT MAX(a.AptDateTime) FROM appointment a WHERE a.PatNum=p.PatNum AND a.AptStatus=2) AS LastSeen,
(SELECT MIN(a.AptDateTime) FROM appointment a WHERE a.PatNum=p.PatNum AND a.AptStatus=1 AND a.AptDateTime>=NOW() ) AS NextSchedApt
FROM patient p
WHERE p.PatStatus=0
ORDER BY p.LName, p.FName;
List of patients who have had a given procedure done on a tooth but not another. Like root canal without a crown. - FName, LName and their guarantors FName and LName and address
/*362 List of patients who have had a given procedure done on a tooth but not another
like root canal without a crown
(FName, LName and their guarantors FName and LName and address)*/
SELECT p.LName, p.FName,
g.FName AS GuFName, g.LName AS GuLName, g.Address, g.Address2, g.City, g.State, g.Zip
FROM patient p
INNER JOIN patient g ON p.guarantor=g.PatNum
INNER JOIN procedurelog pcomp ON pcomp.PatNum=p.PatNum
INNER JOIN procedurecode pccomp ON pccomp.CodeNum=pcomp.CodeNum AND ProcStatus=2
WHERE (
SELECT COUNT(*) FROM procedurelog pl
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum AND ProcStatus=2
WHERE pl.PatNum=p.PatNum AND
(pc.ProcCode LIKE('D26%')
OR pc.ProcCode LIKE('D27%')
OR pc.ProcCode LIKE('D28%')
OR pc.ProcCode LIKE('D29%'))
AND pl.ToothNum=pcomp.ToothNum
)=0 AND pccomp.ProcCode IN('D3310','D3320','D3330')
Sum of Payments for day or period and sum of patient portion for day or period with sum of family estimated balances for patients seen in period at the specified clinic and individual family after insurance balances. - SEE REPLICATION WARNING for versions before 14.3.1. Usefull to see how well front office is collecting patient payments.
/*363 Sum of Payments for day or period and sum of patient portion for day or period at the specified clinic
with sum of family estimated balances for patients seen in period and individual family after insurance balances
useful to see how well front office is collecting patient payments*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @Date='2016-02-10';
SET @ClinicNum = ''; /*Enter clinic num here. Can be found by going to Lists>Clinics>Double click on clinic. Leave blank to run for all clinics.*/
SET @FromDate=@Date , @ToDate=@Date;/*Replace with actual dates here and eliminate the line SET @Date='2009-10-22;'
if a date range is desired, use CURDATE() if auto current date desired*/
/* first we obtain a list of families (guarantors) for use later
for the rest of the sub selects we use aliased tables, this is too complex however*/
DROP TABLE IF EXISTS tmpguarantor;
CREATE TABLE tmpguarantor
SELECT DISTINCT g.Guarantor
FROM procedurelog pl
INNER JOIN patient g ON g.PatNum=pl.PatNum
WHERE pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus=2
AND (CASE WHEN @ClinicNum = '' THEN TRUE ELSE pl.ClinicNum = @ClinicNum END);
SELECT 'A. Sum of All Pt Portions for procedures completed in Period' AS 'Item',
FORMAT(SUM(A.PatPor),2) AS 'Value_'
FROM
(
SELECT (pl.ProcFee-
(CASE WHEN ISNULL(cps.InsPayEst) THEN 0 ELSE cps.InsPayEst END)-
(CASE WHEN ISNULL(cps.WriteOff) THEN 0 ELSE cps.WriteOff END)) AS PatPor,
pl.ProcFee, pl.PatNum, pl.ClinicNum, pl.ProcDate
FROM procedurelog pl
LEFT JOIN (
SELECT cp.ProcNum, cp.PatNum,
SUM(cp.InsPayEst) AS 'InsPayEst',
SUM(cp.WriteOff) AS 'Writeoff'
FROM claimproc cp
WHERE cp.ProcDate BETWEEN @FromDate AND @ToDate
AND (CASE WHEN @ClinicNum = '' THEN TRUE ELSE cp.ClinicNum = @ClinicNum END)
GROUP BY cp.PatNum, cp.ProcNum
)cps ON pl.ProcNum=cps.ProcNum
WHERE pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus=2
AND (CASE WHEN @ClinicNum = '' THEN TRUE ELSE pl.ClinicNum = @ClinicNum END)
) A
UNION ALL
SELECT 'B. Sum of Patient Payments Accepted in Period' AS 'Item',
FORMAT((
SELECT SUM(ps.SplitAmt)
FROM paysplit ps
WHERE ps.DatePay BETWEEN @FromDate AND @ToDate
AND (CASE WHEN @ClinicNum = '' THEN TRUE ELSE ps.ClinicNum = @ClinicNum END)
),2) AS 'Value_'
UNION ALL
SELECT 'C. Sum of Patient Payments for Families seen in Period' AS 'Item',
FORMAT((
SELECT SUM(ps.SplitAmt)
FROM paysplit ps
INNER JOIN patient p ON p.PatNum=ps.PatNum
INNER JOIN tmpguarantor A ON A.Guarantor=p.Guarantor
WHERE ps.DatePay BETWEEN @FromDate AND @ToDate
AND (CASE WHEN @ClinicNum = '' THEN TRUE ELSE ps.ClinicNum = @ClinicNum END)
),2) AS 'Value_'
UNION ALL
SELECT 'D. Sum of Receivables (after insur. est.) for Families seen in Period' AS 'Item',
FORMAT(SUM(IF(B.PatBal>0, B.PatBal, 0)),2) AS 'Value_'
FROM
(
SELECT (g.BalTotal-g.InsEst) AS PatBal
FROM procedurelog pl
INNER JOIN patient p ON p.PatNum=pl.PatNum
INNER JOIN patient g ON g.PatNum=p.Guarantor
WHERE (pl.ProcDate BETWEEN @FromDate AND @ToDate)
AND pl.ProcStatus=2
AND (CASE WHEN @ClinicNum = '' THEN TRUE ELSE pl.ClinicNum = @ClinicNum END)
GROUP BY g.PatNum
) B
UNION ALL
SELECT 'E. Percent Collected (C/(C+D))' AS 'ITEM',
FORMAT((
SELECT SUM(ps.SplitAmt)
FROM paysplit ps
INNER JOIN patient p ON p.PatNum=ps.PatNum
INNER JOIN tmpguarantor A ON A.Guarantor=p.Guarantor
WHERE ps.DatePay BETWEEN @FromDate AND @ToDate
AND (CASE WHEN @ClinicNum = '' THEN TRUE ELSE ps.ClinicNum = @ClinicNum END)
)*100/((
SELECT SUM(ps.SplitAmt)
FROM paysplit ps
INNER JOIN patient p ON p.PatNum=ps.PatNum
INNER JOIN tmpguarantor A ON A.Guarantor=p.Guarantor
WHERE ps.DatePay BETWEEN @FromDate AND @ToDate
AND (CASE WHEN @ClinicNum = '' THEN TRUE ELSE ps.ClinicNum = @ClinicNum END)
) + (
SELECT SUM(IF(B.PatBal>0, B.PatBal, 0))
FROM(
SELECT (g.BalTotal-g.InsEst) AS PatBal
FROM procedurelog pl
INNER JOIN patient p ON p.PatNum=pl.PatNum
INNER JOIN patient g ON g.PatNum=p.Guarantor
WHERE (pl.ProcDate BETWEEN @FromDate AND @ToDate)
AND pl.ProcStatus=2
AND (CASE WHEN @ClinicNum = '' THEN TRUE ELSE pl.ClinicNum = @ClinicNum END)
GROUP BY g.PatNum
) B
)),2) AS 'Value_'
UNION ALL
SELECT '--Family Balances (after insurance estimates) of patients seen in Period--' AS 'Item',
'' AS 'Value_'
UNION ALL
SELECT CONCAT(g.LName, ', ', g.FName) AS 'Item',
FORMAT(IF((g.BalTotal-g.InsEst)>0,(g.BalTotal-g.InsEst),0),2) AS 'Value_'
FROM procedurelog pl
INNER JOIN patient p ON p.PatNum=pl.PatNum
INNER JOIN patient g ON g.PatNum=p.Guarantor
WHERE (pl.ProcDate BETWEEN @FromDate AND @ToDate)
AND pl.ProcStatus=2
AND (CASE WHEN @ClinicNum = '' THEN TRUE ELSE pl.ClinicNum = @ClinicNum END)
GROUP BY g.PatNum;
DROP TABLE IF EXISTS tmpguarantor;
Mailing List for guarantors of all patients with insurance. -
/*364 Mailing List for guarantors of all patients with insurance*/
SELECT DISTINCTROW gu.salutation, gu.LName, gu.FName, gu.Address,
gu.Address2, gu.City, gu.State, gu.ZIP
FROM patient p
INNER JOIN patient gu ON p.Guarantor=gu.PatNum
WHERE p.HasIns='I'
ORDER BY gu.LName, gu.FName;
Family Balance Outstanding Insurance Claim info,last claim date, last payment date, last statement date, next family appointment and family financial note. - SEE REPLICATION WARNING for versions before 14.3.1. Summed by Guarantor for families with credits.
/*365 Family Balance Outstanding Insurance Claim info,last claim date, last payment date, last statement date, next family appointment
and family financial note summed by Guarantor for families with credits*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @pos=0;
DROP TABLE IF EXISTS tmp1, tmp2;
CREATE TABLE tmp1
SELECT p.PatNum, p.Guarantor, g.BalTotal, g.LName,g.FName FROM patient p
INNER JOIN patient g ON p.Guarantor=g.PatNum WHERE g.BalTotal<-.005;
CREATE TABLE tmp2
SELECT tmp1.PatNum, tmp1.Guarantor, tmp1.BalTotal, tmp1.FName,tmp1.LName,
(SELECT COUNT(*) FROM claim WHERE claim.PatNum=tmp1.PatNum AND
(claim.ClaimStatus='W' OR claim.ClaimStatus='S') AND
claim.ClaimType<>'PreAuth') AS 'Claims',
(SELECT SUM(ClaimFee) FROM claim WHERE claim.PatNum=tmp1.PatNum AND
(claim.ClaimStatus='W' OR claim.ClaimStatus='S')AND
claim.ClaimType<>'PreAuth') AS 'ClaimAmts',
(SELECT SUM(InsPayEst) FROM claim WHERE claim.PatNum=tmp1.PatNum AND
(claim.ClaimStatus='W' OR claim.ClaimStatus='S')AND
claim.ClaimType<>'PreAuth') AS 'InsEst',
(SELECT MIN(DateService) FROM claim WHERE claim.PatNum=tmp1.PatNum AND
claim.ClaimStatus='S' AND claim.ClaimType<>'PreAuth')
AS 'LastClaim', /*proc date of oldest sent claim outstanding*/
(SELECT MAX(DatePay) FROM paysplit WHERE paysplit.PatNum=tmp1.PatNum)
AS 'LastPay',
(SELECT MAX(DateSent) FROM statement WHERE statement.PatNum=tmp1.PatNum) AS
'LastStmnt',
(SELECT DATE(MIN(AptDateTime)) FROM appointment ap WHERE tmp1.PatNum=ap.PatNum AND ap.AptDateTime IS NOT NULL AND ap.AptStatus='1') AS 'NextFamApt'
FROM tmp1;
SELECT @pos:=@pos+1 AS 'Count',tmp2.Guarantor,
tmp2.BalTotal AS '$Fam',
SUM(tmp2.Claims) AS '#Claims',
SUM(tmp2.ClaimAmts) AS '$Claims',
MIN(LastClaim) AS 'LastClaim', MAX(LastPay) AS 'LastPay', MAX(LastStmnt) AS 'LastStmnt',
MIN(NextFamApt) AS NextFamApt,
pn.FamFinancial
FROM tmp2
LEFT JOIN patientnote pn ON tmp2.Guarantor=pn.PatNum
GROUP BY tmp2.Guarantor
ORDER BY tmp2.LName, tmp2.FName;
DROP TABLE IF EXISTS tmp1,tmp2;
Returns treatment planned procedures (excluding diagnostic and preventative) for active patients without a scheduled OR planned apt, who were last seen in a given date range with phone numbers and primary provider. - Useful for those transitioning to planned appointments. (this differs FROM #56 largely in that it is date limited and lists out the treatment and does not include preventative/diag)
/*366 Returns treatment planned procedures (excluding diagnostic and preventative) for active patients without a scheduled OR planned apt,
who were last seen in a given date range
with phone numbers and primary provider, useful for those transitioning to planned appointments
(this differs FROM #56 largely in that it is date limited and lists out the treatment and does not include preventative/diag)*/
SET @StartDate='2014-02-10' , @EndDate='2014-10-11';
SELECT prov.Abbr,
p.PatNum,
CONCAT(p.LName, ', ',p.FName, ' ', MiddleI) AS PatName,
HmPhone,
WkPhone,
WirelessPhone AS Wireless,
ProcFee,
pc.ProcCode,
lastvisit.DateLastVisit
FROM patient p
INNER JOIN provider prov ON prov.ProvNum=p.PriProv
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum AND ProcStatus=1
LEFT JOIN appointment ap ON p.PatNum=ap.PatNum
AND (ap.AptStatus=1 OR ap.AptStatus=6)
INNER JOIN (
SELECT apt.PatNum,MAX(DATE(apt.AptDateTime)) AS DateLastVisit
FROM appointment apt
WHERE apt.AptDateTime BETWEEN @StartDate AND @EndDate+INTERVAL 1 DAY
AND apt.AptStatus=2
GROUP BY apt.PatNum
) lastvisit ON lastVisit.PatNum=p.PatNum
WHERE ap.AptNum IS NULL
AND p.PatStatus=0
AND pc.ProcCode NOT LIKE('D0%')
AND pc.ProcCode NOT LIKE('D1%');
Guarantors of patients with benefits remaining AND treatment planned procedures, with first names of patients and addresses. - Assumes calendar year benefits
/*367 Guarantors of patients with benefits remaining AND treatment planned procedures, with first names of patients and addresses
assumes calendar year benefits*/
SELECT g.FName,
g.LName,
SUM(annualmax.AnnualMax) '$FamSumMax_',
SUM(used.AmtUsed) '$FamSumUsed_',
SUM(planned.AmtPlanned) '$FamSumTrePlan_',
GROUP_CONCAT(DISTINCT p.FName) AS 'FamMembers',
g.Address,
g.Address2,
g.City,
g.State,
g.Zip
FROM patient p
INNER JOIN patient g ON g.PatNum=p.Guarantor
INNER JOIN patplan ON p.PatNum=patplan.PatNum
INNER JOIN inssub ON inssub.InsSubNum=patplan.InsSubNum
INNER JOIN insplan ip ON ip.PlanNum=inssub.PlanNum
INNER JOIN (
SELECT benefit.PlanNum,
MAX(benefit.MonetaryAmt) AS AnnualMax
FROM benefit
LEFT JOIN covcat ON covcat.CovCatNum = benefit.CovCatNum
WHERE benefit.BenefitType = 5 /* limitation */
AND benefit.TimePeriod = 2 /* calendar year */
AND (covcat.EbenefitCat=1 OR ISNULL(covcat.EbenefitCat))
AND benefit.MonetaryAmt > 0 /* (-1) indicates empty */
GROUP BY benefit.PlanNum
) annualmax ON annualmax.PlanNum=inssub.PlanNum
INNER JOIN (
SELECT patient.PatNum,SUM(pl.ProcFee) AS AmtPlanned
FROM patient
INNER JOIN (
SELECT PatNum,ProcFee FROM procedurelog WHERE ProcStatus=1 /*treatment planned*/ AND ProcFee!=0
) pl ON patient.PatNum=pl.PatNum
WHERE patient.PatStatus=0 /* Patient */
GROUP BY patient.PatNum
) planned ON planned.PatNum=p.PatNum AND planned.AmtPlanned>0
LEFT JOIN (
SELECT patplan.PatPlanNum,
SUM(claimproc.InsPayAmt) AS AmtUsed
FROM claimproc
INNER JOIN inssub ON claimproc.InsSubNum=inssub.InsSubNum
INNER JOIN patplan ON inssub.InsSubNum=patplan.InsSubNum
AND patplan.PatNum=claimproc.PatNum
WHERE claimproc.Status IN (1, 3, 4) -- Rec, Adj, Supp.
AND YEAR(claimproc.ProcDate)=YEAR(CURDATE())
AND claimproc.InsPayAmt!=0
GROUP BY patplan.PatPlanNum
) used ON used.PatPlanNum=patplan.PatPlanNum
WHERE p.PatStatus=0
GROUP BY g.PatNum
ORDER BY g.LName, G.FName DESC;
Guarantors of patients with benefits remaining even if there are no treatment planned procedures, with first names of patients and addresses. - Assumes calendar year benefits.
/*368 Guarantors of patients with benefits remaining even if there are no
treatment planned procedures, with first names of patients and addresses
assumes calendar year benefits*/
SELECT g.FName,
g.LName,
SUM(annualmax.AnnualMax) '$FamSumMax_',
SUM(used.AmtUsed) '$FamSumUsed_',
SUM(planned.AmtPlanned) '$FamSumTrePlan_',
GROUP_CONCAT(DISTINCT p.FName) AS 'FamMembers',
g.Address,
g.Address2,
g.City,
g.State,
g.Zip
FROM patient p
INNER JOIN patient g ON g.PatNum=p.Guarantor
INNER JOIN patplan ON p.PatNum=patplan.PatNum
INNER JOIN inssub ON inssub.InsSubNum=patplan.InsSubNum
INNER JOIN insplan ip ON ip.PlanNum=inssub.PlanNum
INNER JOIN (
SELECT benefit.PlanNum,
MAX(benefit.MonetaryAmt) AS AnnualMax
FROM benefit
LEFT JOIN covcat ON covcat.CovCatNum = benefit.CovCatNum
WHERE benefit.BenefitType = 5 /* limitation */
AND benefit.TimePeriod = 2 /* calendar year */
AND (covcat.EbenefitCat=1 OR ISNULL(covcat.EbenefitCat))
AND benefit.MonetaryAmt > 0 /* (-1) indicates empty */
GROUP BY benefit.PlanNum
) annualmax ON annualmax.PlanNum=inssub.PlanNum
LEFT JOIN (
SELECT patient.PatNum,SUM(pl.ProcFee) AS AmtPlanned
FROM patient
INNER JOIN (
SELECT PatNum,ProcFee FROM procedurelog WHERE ProcStatus=1 /*treatment planned*/ AND ProcFee!=0
) pl ON patient.PatNum=pl.PatNum
WHERE patient.PatStatus=0 /* Patient */
GROUP BY patient.PatNum
) planned ON planned.PatNum=p.PatNum
LEFT JOIN (
SELECT patplan.PatPlanNum,
SUM(claimproc.InsPayAmt) AS AmtUsed
FROM claimproc
INNER JOIN inssub ON claimproc.InsSubNum=inssub.InsSubNum
INNER JOIN patplan ON inssub.InsSubNum=patplan.InsSubNum
AND patplan.PatNum=claimproc.PatNum
WHERE claimproc.Status IN (1, 3, 4) -- Rec, Adj, Supp.
AND YEAR(claimproc.ProcDate)=YEAR(CURDATE())
AND claimproc.InsPayAmt!=0
GROUP BY patplan.PatPlanNum
) used ON used.PatPlanNum=patplan.PatPlanNum
WHERE p.PatStatus=0
GROUP BY g.PatNum
ORDER BY g.LName, G.FName DESC;
Count of patients by patient status. - i.e. Active, Inactive, Archived, NonPatient, Deceased, etc.
/*369 Count of patients by patient status (i.e. Active, Inactive, Archived, NonPatient, Deceased, etc.)
WHERE they have had an appointment over a specified date range. */
SET @StartDate = '2009-01-01';
SET @EndDate = '2010-01-01';
SELECT patstatus, count(*) FROM patient
WHERE PatNum IN
(SELECT DISTINCT PatNum FROM appointment
WHERE (AptDateTime BETWEEN DATE(@StartDate) AND DATE(@EndDate)))
GROUP BY patstatus ORDER BY patstatus;
Count of appointments (with specific attached procedures) by patient over a specified date range. - This might be useful in relation to recall.
/*370 Count of appointments (with specific attached procedures) by patient over
a specified date range.
This might be useful in relation to recall. */
SET @StartDate = '2008-04-05';
SET @EndDate = '2011-10-05';
SELECT A.PatNum, count(B.aptnum)
FROM patient A, appointment B
WHERE (A.PatNum = B.PatNum) AND (DATE(B.AptDateTime) BETWEEN @StartDate AND
@EndDate)
AND (
(B.aptnum IN (SELECT DISTINCT A.aptnum FROM procedurelog A, procedurecode B
WHERE (A.CodeNum = B.CodeNum) AND (A.aptnum > 0) AND
(B.proccode IN ('D1110','D1120', 'D4910', 'D4355')) ))
OR
(B.aptnum IN (SELECT DISTINCT A.plannedaptnum FROM procedurelog A, procedurecode
B
WHERE (A.CodeNum = B.CodeNum) AND (A.plannedaptnum > 0) AND
(B.proccode IN ('D1110','D1120', 'D4910', 'D4355')) ))
)
GROUP BY B.PatNum
ORDER BY B.PatNum;
Count of patients with an existing appointment over a date range that has a specific attached procedure. -
/*371 Count of patients with an existing appointment over a date range that has
a specific
attached procedure. */
SET @StartDate = '2008-04-05';
SET @EndDate = '2011-10-05';
SELECT COUNT(*) FROM
(
SELECT DISTINCT B.PatNum
FROM appointment B
WHERE (B.AptDateTime BETWEEN DATE(@StartDate) AND DATE(@EndDate))
AND (
(B.aptnum IN (SELECT DISTINCT A.aptnum FROM procedurelog A, procedurecode B
WHERE (A.CodeNum = B.CodeNum) AND (A.aptnum > 0) AND
(B.proccode IN ('D1110','D1120', 'D4910', 'D4355')) ))
OR
(B.aptnum IN (SELECT DISTINCT A.plannedaptnum FROM procedurelog A, procedurecode
B
WHERE (A.CodeNum = B.CodeNum) AND (A.plannedaptnum > 0) AND
(B.proccode IN ('D1110','D1120', 'D4910', 'D4355')) ))
)
ORDER BY B.PatNum
) A;
Count of future recall entries grouped by recall type (i.e. Prophy, Perio, etc) where the patient has an "Active" status. -
/*372 Count of future recall entries grouped by recall type (i.e. Prophy, Perio,
etc) where
the patient has an "Active" status. */
SELECT count(*), A.recalltypenum, B.description FROM recall A, recalltype B
WHERE (A.recalltypenum = B.recalltypenum) AND (A.datedue > NOW()) AND
(A.PatNum in (SELECT PatNum FROM patient WHERE patstatus = 0))
GROUP BY A.recalltypenum;
Production, procedure and appointment count by time of day (summed hourly), currently set to 7AM to 7PM, can be adjusted, based on apt start time.Production, procedure and appointment count by time of day (summed hourly), can be set to restrict the time - Does not 'spread' production through apt duration could be adjusted to show by provider. Only counts apts with procedures in them.
/*373 Production, procedure and appointment count by time of day (summed hourly), can be set to restrict the time to look at,
based on apt start time. Does not 'spread' production through apt duration could be adjusted to show by provider
Only counts apts with procedures in them*/
SET @StartDate = '2009-09-05';
SET @EndDate = '2009-11-05';
/*-------------------- Do not modify under this line --------------------*/
/*Query code written/modified: 10/05/2018 MattG*/
SELECT
AptHour,
COUNT(DISTINCT AptNum) AS '#Apts',
COUNT(DISTINCT ProcNum) AS '#Procs',
SUM(ProcFee) AS '$GrossProduction'
FROM (
SELECT
DATE_FORMAT(a.AptDateTime,'%h%p') AS AptHour,
(CASE
WHEN (DATE_FORMAT(a.AptDateTime,'%h%p') = '12PM')
THEN 'Noon'
WHEN (DATE_FORMAT(a.AptDateTime,'%h%p') = '12AM')
THEN ' MidNt'
ELSE DATE_FORMAT(a.AptDateTime,'%p')
END) AS AMPM,
a.AptNum,
pl.ProcNum,
pl.ProcFee * (pl.BaseUnits + pl.UnitQty) AS ProcFee,
prov.Abbr
FROM appointment a
INNER JOIN procedurelog pl
ON pl.AptNum = a.AptNum
INNER JOIN provider prov
ON prov.ProvNum = pl.ProvNum
WHERE (DATE(a.AptDateTime) BETWEEN @StartDate AND @EndDate)
AND pl.ProcStatus = 2 /*complete*/
) a
GROUP BY AptHour
ORDER BY AMPM, AptHour ASC;
Active Patients: Patient Name, Balance, Family Balance, SSN, Date of Birth and Last Date of Service -
/*374 Active Patients: Patient Name, Balance, Family Balance, SSN, Date of Birth and Last Date of Service*/
SELECT p.PatNum, p.EstBalance AS '$PatientBal', p.SSN, p.BirthDate,
g.BalTotal AS '$FamBal', g.BalTotal-g.InsEst AS '$FamEstAfterIns',DATE_FORMAT(MAX(ProcDate),'%m/%d/%Y') AS 'LastVisit'
FROM patient p
INNER JOIN patient g ON p.Guarantor=g.PatNum
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
WHERE pl.ProcStatus=2 AND p.PatStatus=0
GROUP BY p.PatNum
ORDER BY p.LName, p.FName;
Patients with birthday in given date range who have a scheduled apt that is also in that date range with date of that apt. -
/*375 Patients with birthday in given date range who have a scheduled apt that is also in that date range with date of that apt*/
SET @FromDate='2009-10-01' , @ToDate='2009-11-31';/*Change dates here*/
SELECT p.PatNum, p.Birthdate, a.AptDateTime FROM patient p
INNER JOIN appointment a ON a.PatNum=p.PatNum
WHERE (SUBSTRING(p.BirthDate,6,5) >= Right(@FromDate,5)
AND SUBSTRING(p.BirthDate,6,5) <= Right(@ToDate,5)) AND
(SUBSTRING(DATE(a.AptDateTime),6,5) >= Right(@FromDate,5)
AND SUBSTRING(DATE(a.AptDateTime),6,5) <= Right(@ToDate,5))
AND a.AptStatus=1 AND p.PatStatus=0
GROUP BY p.PatNum;
Scheduled appointments in a date range, with provider and email address, home and cell phone, PreMed and New patient Flags. - Useful for Televox.
/*376 Scheduled appointments in a date range, with provider and email address, home and cell phone, PreMed and New patient Flags, useful for Televox*/
SET @FromDate='2017-10-01' , @ToDate='2017-11-30';/*Change dates here*/
SELECT /*p.PatNum,*/ p.FName, p.LName,p.Email, p.PreMed,a.IsNewPatient,
p.HmPhone, p.WirelessPhone,prov.Abbr, DATE(a.AptDateTime)AS 'DateApt', DATE_FORMAT(a.AptDateTime,'%H:%i') AS 'TimeApt'
FROM appointment a
INNER JOIN patient p ON a.PatNum=p.PatNum
INNER JOIN provider prov ON a.ProvNum=prov.ProvNum
WHERE DATE(a.AptDateTime) BETWEEN @FromDate AND @ToDate
AND a.AptStatus=1
GROUP BY a.AptNum
ORDER BY LName, FName;
Average daily production for a time period, summed by day of week and overall. - SEE REPLICATION WARNING for versions before 14.3.1.
/*377 Average daily production for a time period, summed by day of week and overall*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @FromDate='2009-01-01' , @ToDate='2009-12-31';/*Change dates here*/
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp SELECT ProcFee, ProcDate, DAYOFWEEK(ProcDate) AS Day
FROM procedurelog WHERE ProcDate BETWEEN @FromDate AND @ToDate AND ProcStatus=2 AND ProcFee>0/*Complete*/;
SELECT (CASE
WHEN Day=1 THEN 'Sunday'
WHEN Day=2 THEN 'Monday'
WHEN Day=3 THEN 'Tuesday'
WHEN Day=4 THEN 'Wednesday'
WHEN Day=5 THEN 'Thursday'
WHEN Day=6 THEN 'Friday'
WHEN Day=7 THEN 'Saturday' ELSE 'Unknown' END) AS 'DayOfWeek',
SUM(ProcFee) AS $Production,
SUM(ProcFee)/COUNT(DISTINCT ProcDate) AS $AveDailyProd FROM tmp
GROUP BY Day
UNION ALL
SELECT 'TOTAL' AS 'DayOfWeek',
SUM(ProcFee) AS $Production,
SUM(ProcFee)/COUNT(DISTINCT ProcDate) AS $AveDailyProd
FROM tmp;
DROP TABLE IF EXISTS tmp;
List of referred procedures in a date range that are in a given list. -
/*378 List of referred procedures in a date range that are in a given list*/
SET @FromDate='2009-06-01' , @ToDate='2010-01-31';
SELECT CONCAT(LName, ', ',FName, ' ', MiddleI) AS Patient,
pc.ProcCode AS 'Code', abbrdesc AS 'Description', DATE_FORMAT(pl.ProcDate,'%m-%d-%Y') AS 'Date',
ProcFee
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
WHERE pl.ProcStatus=5 AND
pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pc.ProcCode IN('D3330') /*put the procedures in this comma delimited list, so like this ('D1232', 'D1234')*/
ORDER BY pl.ProcDate, patient.LName, patient.FName ASC;
Daily production and income report (as of version 6.8). - Counts insurance writeoffs by ins payment date, so assume that any PPOs are entered as Category Percentage. For all providers.
/*379 Daily production and income report (as of version 6.8)
counts insurance writeoffs by ins payment date, so assume that any PPOs are entered as Category Percentage
For all providers*/
/*Query code written/modified: 12/15/2016*/
SET @FromDate='2016-12-01' , @ToDate='2016-12-01';
SELECT A.Date,
CONCAT(p.LName, ', ',p.FName, ' ', p.MiddleI) AS 'Patient',
A.Description,
pr.Abbr AS 'Prov',
A.$Prod_,
A.$Adjust_,
A.$WritOff_,
A.$TotProd_,
A.$PatIncome_,
A.$InsIncome_,
A.$TotIncome_
FROM patient p
INNER JOIN (
/*Prod*/
SELECT pl.ProcDate AS 'Date',
pl.PatNum,
pc.AbbrDesc AS 'Description',
pl.ProvNum,
pl.ProcFee*(pl.UnitQty+pl.BaseUnits)-COALESCE(cp.WriteOff,0) AS '$Prod_',
0 AS '$Adjust_',
0 AS '$WritOff_',
pl.ProcFee AS '$TotProd_',
0 AS '$PatIncome_',
0 AS '$InsIncome_',
0 AS '$TotIncome_'
FROM procedurelog pl
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
LEFT JOIN claimproc cp ON cp.ProcNum=pl.ProcNum
AND cp.Status=7
WHERE pl.ProcStatus=2
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY pl.ProcNum
UNION ALL
/*Adj*/
SELECT a.AdjDate AS 'Date',
a.PatNum,
d.ItemName AS 'Description',
a.ProvNum,
0 AS '$Prod_',
a.AdjAmt AS '$Adjust_',
0 AS '$WritOff_',
a.AdjAmt AS '$TotProd_',
0 AS '$PatIncome_',
0 AS '$InsIncome_',
0 AS '$TotIncome_'
FROM adjustment a
INNER JOIN definition d ON a.AdjType=d.DefNum
WHERE a.AdjDate BETWEEN @FromDate AND @ToDate
AND a.AdjAmt!=0
UNION ALL
/*PatInc*/
SELECT ps.DatePay AS 'Date',
ps.PatNum,
d.ItemName AS 'Description',
ps.ProvNum,
0 AS '$Prod_',
0 AS '$Adjust_',
0 AS '$WritOff_',
0 AS '$TotProd_',
ps.SplitAmt AS '$PatIncome_',
0 AS '$InsIncome_',
ps.SplitAmt AS '$TotIncome_'
FROM paysplit ps
INNER JOIN payment pa ON ps.PayNum=pa.PayNum
INNER JOIN definition d ON pa.PayType=d.DefNum
WHERE ps.DatePay BETWEEN @FromDate AND @ToDate
UNION ALL
/*InsIncome, Writeoffs*/
SELECT cp.DateCP AS 'Date',
cp.PatNum,
carrier.CarrierName AS 'Description',
cp.ProvNum,
0 AS '$Prod_',
0 AS '$Adjust_',
-SUM(cp.WriteOff) AS '$WritOff_',
-SUM(cp.WriteOff) AS '$TotProd_',
0 AS '$PatIncome_',
SUM(cp.InsPayAmt) AS '$InsIncome_',
SUM(cp.InsPayAmt) AS '$TotIncome_'
FROM claimproc cp
LEFT JOIN insplan ip ON ip.PlanNum=cp.PlanNum/*insurance plan*/
LEFT JOIN carrier ON carrier.CarrierNum=ip.CarrierNum
WHERE (cp.Status=1 OR cp.Status=4)/* add OR cp.Status=0) if you want to include anticipated writeoffs*/
AND cp.DateCP BETWEEN @FromDate AND @ToDate /*vs cp.ProcDate if writeoffs by procdate, then you must separate writoffs and payments too*/
GROUP BY cp.ClaimPaymentNum,cp.PatNum
) A ON A.PatNum=p.PatNum
INNER JOIN provider pr ON pr.ProvNum=A.ProvNum
ORDER BY A.DATE, CONCAT(p.LName, ', ',p.FName, ' ', p.MiddleI);
Patients without insurance with treatment planned procedures in a date range. - Includes phone number, numer of procedures, tp fee sum for date range and can easily be edited to show address for mail merge.
/*380 Patients without insurance with treatment planned procedures in a date range.
Includes phone number, numer of procedures, tp fee sum for date range and can
easily be edited to show address for mail merge*/
SET @StartDate='2009-01-01' , @EndDate='2010-01-01';
SELECT CONCAT(LName, ', ',FName, ' ', MiddleI) AS Patient,
HmPhone, WkPhone, WirelessPhone,
/*Concat(Address, ' ', Address2) AS Address, City, State, Zip,*/
pl.DateTP, COUNT(DISTINCT pl.ProcNum) AS 'NumOfProcs', SUM(pl.ProcFee) AS '$TotalFees'
FROM patient p
LEFT JOIN procedurelog pl ON pl.PatNum=p.PatNum
WHERE p.HasIns != 'I'
AND pl.ProcStatus=1
AND DATE(pl.DateTP) >= @StartDate
AND DATE(pl.DateTP) <= @EndDate
GROUP BY p.PatNum;
List of Patients with an appointment assoiciated to a specific clinic and completed in date range. -
/*381 List of Patients with an appointment assoiciated to a specific clinic and completed in date range*/
SET @StartDate='2009-08-01' , @EndDate='2009-08-28';
SELECT a.PatNum, c.Description AS 'Clinic Name'
FROM appointment a, clinic c
WHERE a.ClinicNum=c.ClinicNum
AND a.AptStatus=2
AND DATE (a.AptDateTime) BETWEEN @StartDate AND @EndDate
AND c.description LIKE '%ABC%';
List of patients associated to a specific clinic. -
/*382 List of patients associated to a specific clinic*/
Select CONCAT(p.LName, ' ,',p.FName) AS Patient, c.Description
FROM patient p, clinic c
WHERE p.ClinicNum=c.ClinicNum
AND c.Description='Sunnyside';
Procedures on received claims with zero payment with carrier listed for a particular carrier. -
/*383 Procedures on received claims with zero payment with carrier listed for a particular carrier*/
SET @FromDate='2009-01-01' , @ToDate='2009-12-31';
SELECT p.PatNum, cl.DateService,pc.ProcCode, pl.ToothNum, ca.CarrierName
FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
INNER JOIN claimproc cp ON cl.ClaimNum=cp.ClaimNum
INNER JOIN procedurelog pl ON pl.ProcNum=cp.ProcNum
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
WHERE (cl.ClaimStatus='R') AND
(cl.DateService BETWEEN @FromDate AND @ToDate)
AND ca.CarrierName LIKE('%Aetna%')/*Change Carrier here*/
GROUP BY pl.ProcNum
HAVING SUM(cp.InsPayAmt)=0
ORDER BY cl.DateService,p.LName,p.FName;
List of patients with addresses past due for recall of type prophy or perio. - With recall type with insurance or without insurance with NO scheduled apt.
/*384 List of patients with addresses past due for recall of type prophy or perio
with recall type with insurance or without insurance with NO scheduled apt*/
SET @FromDate='2005-10-01' , @ToDate='2009-12-31';
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count', rt.description,r.DateDue, p.PatNum, p.Address, p.Address2, p.City, p.State, p.ZIP FROM recall r
INNER JOIN recalltype rt ON r.recalltypenum = rt.recalltypenum
INNER JOIN patient p ON p.PatNum=r.PatNum
LEFT JOIN appointment a ON a.PatNum=p.PatNum AND a.AptStatus=1
WHERE p.patstatus = 0 AND (DATE(r.datedue) BETWEEN @FromDate AND @ToDate) AND p.HasIns='I' /*has insurance, change to <>'I' for the uninsured*/
AND (rt.Description LIKE('%perio%') OR rt.Description LIKE('%prophy%')) AND NOT ISNULL(r.DateDue)
AND ISNULL(a.AptNum)/*no sched apt*/ ;
Guarantors of patients with a particular insurance where the guarantor is of a certain age (in this case 21 or over). -
/*385 Guarantors of patients with a particular insurance where the guarantor is of a certain age (in this case 21 or over)*/
SELECT DISTINCTROW gu.salutation, gu.LName, gu.FName, gu.Address,
gu.Address2, gu.City, gu.State, gu.zip, gu.Birthdate, inssub.DateEffective, ca.CarrierName
FROM patient p
INNER JOIN inssub ON inssub.Subscriber=p.PatNum
INNER JOIN insplan ip ON inssub.PlanNum=ip.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=ip.CarrierNum
INNER JOIN patient gu ON p.Guarantor=gu.PatNum
WHERE ca.CarrierName LIKE '%PLAN%' AND
(YEAR(CURDATE())-YEAR(gu.Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(gu.Birthdate,5)) >=21 AND
Length(gu.ZIP)>4
ORDER BY ca.CarrierName, gu.LName;
Utility, missing DateFirstVisit in patient field. -
/*386 Utility, missing DateFirstVisit in patient field*/
SELECT p.PatNum, MIN(pl.procdate)
FROM patient p INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum WHERE
DateFirstVisit<'01/01/1900' AND pl.procstatus=2 GROUP BY p.PatNum;
Treatment Planned Procedures, one specific code. -
/*387 Treatment Planned Procedures, one specific code*/
SELECT PatNum,ProcCode,ProcFee,Surf,ToothNum
FROM procedurelog,procedurecode
WHERE ProcStatus=1
AND procedurecode.ProcCode='D4341'
AND procedurelog.CodeNum=procedurecode.CodeNum
ORDER BY PatNum;
Date and time that a claim was first sent and last sent for a patient as well as count of times claim sent. -
/*388 Date and time that a claim was first sent and last sent for a patient as well as count of times claim sent.*/
SELECT PatNum, MIN(DateTimeTrans) AS 'First Sent', MAX(DateTimeTrans) AS 'Last Sent' , COUNT(*) AS '# of times sent'
FROM etrans WHERE PatNum=5398 /*Change PatNum here*/
GROUP BY ClaimNum;
Deleted Procedures viewer. -
/*389 Deleted Procedures viewer*/
SELECT PatNum, procdate, procfee, surf, toothnum, toothrange, procstatus, proccode, descript FROM procedurelog
INNER JOIN procedurecode on procedurecode.CodeNum=procedurelog.CodeNum
WHERE PatNum=40 /*change PatNum here*/
AND procstatus =6;
Income by Carrier for date range (or current day) With patient payments by type. -
/*390 Income by Carrier for date range (or current day)
With patient payments by type*/
SET @FromDate = '2019-01-01' , @ToDate = '2019-12-31';/*use this for Today @FromDate = CURDATE() , @ToDate = CURDATE(); */
/*------------ DO NOT MODIFY BELOW THIS LINE ------------*/
/*Query code written/modified on: 07/15/2011, 05/08/2019:RobG*/
SELECT
CONCAT('From ', DATE_FORMAT(@FromDate, '%m/%d/%Y'), ' - ', 'To ', DATE_FORMAT(@ToDate, '%m/%d/%Y')) AS PaymentSource,
'' AS '$Paid-------------'
UNION ALL
SELECT
carrier.CarrierName AS PaymentSource,
/*(CASE WHEN ip.PlanType = 'f' THEN 'Public Plans'
ELSE 'Commercial Plans' END) AS PaymentSource, */
SUM(cp.InsPayAmt) AS '$Paid-------------'
FROM claimproc cp
LEFT JOIN insplan ip
ON ip.PlanNum = cp.PlanNum
LEFT JOIN carrier
ON carrier.CarrierNum = ip.CarrierNum
INNER JOIN claimpayment cpa
ON cpa.ClaimPaymentNum = cp.ClaimPaymentNum
WHERE cpa.CheckDate BETWEEN @FromDate AND @ToDate
GROUP BY carrier.CarrierName
UNION ALL
SELECT
d.ItemName AS PaymentSource,
SUM(ps.SplitAmt) AS '$Paid-------------'
FROM paysplit ps
INNER JOIN payment pm
ON ps.PayNum = pm.PayNum
INNER JOIN definition d
ON pm.PayType = d.DefNum
WHERE (ps.DatePay BETWEEN @FromDate AND @ToDate)
GROUP BY d.ItemName;
Returns mailing list of guarantors of patients with unscheduled Treament Planned procedures. - Leaves out diagnostic and preventative (D0*, D1*).
/*391 Returns mailing list of guarantors of patients with unscheduled Treament Planned procedures, leaves out diagnostic and preventative (D0*, D1*)*/
SELECT DISTINCT g.LName,g.FName, g.Address, g.Address2, g.City, g.State, g.Zip
FROM patient p
INNER JOIN patient g ON p.Guarantor=g.PatNum
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum AND ProcStatus=1
LEFT JOIN appointment ap ON p.PatNum=ap.PatNum AND ap.AptStatus=1/*scheduled apt*/
WHERE ap.AptNum IS NULL AND p.PatStatus=0 AND
(NOT (pc.ProcCode LIKE('D0%'))) AND (NOT (pc.ProcCode LIKE('D1%')))
GROUP BY p.PatNum
HAVING SUM(ProcFee)>0
ORDER BY g.LName, g.FName ASC;
Returns completed procedures in a date range where the charged fee does match the primary insurance fee schedule fee for patients who currently have insurance -
/*392 Returns completed procedures in a date range where the charged fee does match the primary insurance fee schedule fee for patients
who currently have insurance*/
SET @FromDate='2009-10-01' , @ToDate='2009-10-31';
SELECT p.PatNum, p.PatNum AS 'Pat Number', pc.ProcCode, pl.ProcFee, fee.Amount, feesched.Description AS 'Ins Fee Sched'
FROM procedurelog pl
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
INNER JOIN patient p ON pl.PatNum=p.PatNum
INNER JOIN patplan pp ON pp.PatNum=p.PatNum AND pp.Ordinal=1
INNER JOIN inssub ON inssub.InsSubNum=pp.InsSubNum
INNER JOIN insplan ip ON inssub.PlanNum=ip.PlanNum
INNER JOIN feesched ON ip.FeeSched=feesched.FeeSchedNum
INNER JOIN fee ON feesched.FeeSchedNum=fee.FeeSched AND pl.CodeNum=fee.CodeNum
WHERE pl.ProcDate BETWEEN @FromDate AND @ToDate AND pl.ProcStatus=2 /*complete*/
AND fee.Amount<>pl.ProcFee;
Names of active patients with appointments on unscheduled list. -
/*393 Names of active patients with appointments on unscheduled list */
SELECT LName, FName FROM patient p, appointment ap WHERE p.PatNum=ap.PatNum AND p.PatStatus=0 AND ap.AptStatus=3;
Compare number with insurance vs number MARKED in patient table as having insurance, should match. - SEE REPLICATION WARNING for versions before 14.3.1.
/*394 Compare number with insurance vs number MARKED in patient table as having insurance, should match*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SELECT (SELECT COUNT( DISTINCT PatNum) FROM patient WHERE HasIns='I' AND PatStatus=0) AS 'HasIns',(SELECT COUNT(DISTINCT p.PatNum)
FROM patient p
INNER JOIN patplan pp ON pp.PatNum=p.PatNum
WHERE PatStatus=0) AS 'Has a Plan';
/* See names of patients that have insurance where patient.HasIns<>'I' */
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp
SELECT p.PatNum FROM patient p
WHERE HasIns='I' AND PatStatus=0;
SELECT p2.PatNum
FROM patient p2
INNER JOIN patplan pp ON pp.PatNum=p2.PatNum
LEFT JOIN tmp ON tmp.PatNum=p2.PatNum
WHERE PatStatus=0
AND ISNULL(tmp.PatNum);
DROP TABLE IF EXISTS tmp;
Outstanding insurance claims older than 30 days (by sent date) not including preauths with PatNum and subscriber ID added to help differentiate between patients with same name. - Telephone number of carrier commented out but can be added back easily, some customers do not need this and still want it to fit one page width.
/*395 Outstanding insurance claims older than 30 days (by sent date) not including preauths with PatNum and subscriber ID added to help differentiate between patients with same name, telephone number of carrier commented out but can be added back easily, some customers do not need this and still want it to fit one page width*/
SELECT cl.PatNum, p.PatNum AS 'Pat Num',inssub.SubscriberID, LEFT(ca.CarrierName,20) AS 'Carrier',cl.DateService,cl.DateSent, cl.ClaimFee, cl.InsPayEst/*, ca.Phone*/ FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN inssub ON inssub.PlanNum=i.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE cl.ClaimStatus='S' AND
DateService<(CURDATE()-INTERVAL 30 DAY) AND
ClaimType<>'PreAuth'
ORDER BY cl.DateService;
Active Patients not seen since a given date (but have had a procedure completed at some point) who have no scheduled appointment. -
/*396 Active Patients not seen since a given date (but have had a procedure completed at some point) who have no scheduled appointment*/
SET @SinceDate='2008-12-25';
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count', A.*
FROM (
SELECT p.PatNum,
p.LName,
p.FName,
p.HmPhone,
p.WkPhone,
p.WirelessPhone,
DATE_FORMAT(MAX(ProcDate),'%m/%d/%Y') AS 'LastVisit'
FROM patient p
LEFT JOIN procedurelog pl ON p.PatNum=pl.PatNum AND pl.ProcStatus=2 /*complete*/
LEFT JOIN appointment ap ON p.PatNum=ap.PatNum AND ap.AptStatus=1 AND DATE(ap.AptDateTime)>=CURDATE()/*Scheduled and in future*/
WHERE ISNULL(ap.aptnum)
AND PatStatus=0
GROUP BY p.PatNum
HAVING (MAX(pl.ProcDate)<=@SinceDate)
) A
ORDER BY A.LName, A.FName ASC;
Active Patients with birthday in current month, with Age, Birthdate, Name, Address, and Email. - Sorted by day of month for birthday.
/*397 Active Patients with birthday in current month, with Age, Birthdate, Name, Address, and Email.
Sorted by day of month for birthday.*/
SELECT p.LName, p.FName,(YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) AS 'Age',
p.BirthDate, p.Address, p.Address2, p.City, p.State, p.ZIP,p.Email
FROM patient p
WHERE p.PatStatus=0 AND MONTH(p.BirthDate)=MONTH(CURDATE())
ORDER BY DAY(BirthDate),p.LName, p.FName;
Patients with no insurance, with address -
/*398 Patients with no insurance, with address*/ SELECT LName, FName, Address, Address2, City, Zip
FROM patient p
WHERE p.PatStatus=0/*Active patient*/ AND
p.HasIns<>'I'
ORDER BY LName, FName;
Addresses for patients who referred other patients in a given month. -
/*399 Addresses for patients who referred other patients in a given month and year.*/
/*Query code written/modified: 02/10/2016*/
SET @RefDate='2016-01-02';
SELECT ra.RefDate, p.FName, p.LName, p.MiddleI, p.Address, p.Address2, p.City, p.State, p.Zip, p.Email FROM patient p
INNER JOIN referral rf ON p.PatNum=rf.PatNum
INNER JOIN refattach ra ON rf.ReferralNum=ra.ReferralNum
WHERE MONTH(ra.RefDate)=MONTH(@RefDate)
AND YEAR(ra.RefDate)=YEAR(@RefDate);
Guarantor address for: Active patient, with insurance plan, no scheduled or planned appts, treatment planned procedures, $0 fam balance. -
/*400 Guarantor address for:
Active patient, with insurance plan, no scheduled or planned appts, treatment planned procedures, $0 fam balance */
SELECT g.LName,g.FName, g.MiddleI, g.Address, g.Address2, g.City, g.State, g.Zip FROM patient p
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum AND ProcStatus=1
LEFT JOIN appointment ap ON p.PatNum=ap.PatNum AND (ap.AptStatus=1 OR ap.AptStatus=6 )
LEFT JOIN patplan pp ON p.PatNum=pp.PatNum
LEFT JOIN patient g ON p.Guarantor=g.PatNum
WHERE ap.AptNum IS NULL AND p.PatStatus=0 AND
pp.PatNum IS NOT NULL AND
LENGTH(g.ZIP)>4 AND
g.baltotal <='.01'
GROUP BY g.PatNum
ORDER BY LName, FName;
Procedures completed with received claims and amount paid=0 with patient name and date of procedure, fee, amount paid. -
/*401 Procedures completed with received claims and amount paid=0 with patient name and date of procedure, fee, amount paid*/
SET @FromDate='2008-01-01', @ToDate='2008-12-31';
/*Adjust above Dates and Carier as needed*/
SELECT carrier.CarrierName, claimproc.PatNum, DATE_FORMAT(procedurelog.ProcDate,'%m/%d/%Y') AS 'Service Date',
procedurecode.ProcCode,
claimproc.InsPayAmt as 'InsPaid', procedurelog.ProcFee as 'Fee'
FROM carrier
INNER JOIN insplan ON carrier.CarrierNum=insplan.CarrierNum
INNER JOIN claim ON insplan.PlanNum=claim.PlanNum
INNER JOIN claimproc ON claim.ClaimNum=claimproc.ClaimNum
INNER JOIN procedurelog ON claimproc.ProcNum=procedurelog.ProcNum
INNER JOIN procedurecode ON procedurelog.CodeNum=procedurecode.CodeNum
AND procedurelog.ProcDate >= @FromDate
AND procedurelog.ProcDate < @ToDate
AND claimproc.InsPayAmt=0
AND ProcStatus=2
AND claim.ClaimStatus='R'
ORDER BY CarrierName;
Mailing list with employers for guarantors of active patients, employer from patient info, including ins carriers. - Shows each carrier name for each plan that a patient is using, so guarantors may be listed more than once, can be edited to only show primary.
/*402 Mailing list with employers for guarantors of active patients, employer from patient info,
including ins carriers. Shows each carrier name for each plan that a patient
is using, so guarantors may be listed more than once, can be edited to only show primary*/
SELECT g.LName, g.FName, g.Address, g.Address2, g.City, g.State, g.Zip, ca.CarrierName, emp.EmpName AS GuarantorEmployer
FROM patient p
INNER JOIN patient g ON p.Guarantor=g.PatNum
INNER JOIN patplan pp ON p.PatNum=pp.PatNum
INNER JOIN inssub ON inssub.InsSubNum=pp.InsSubNum
INNER JOIN insplan ip ON inssub.PlanNum=ip.PlanNum
INNER JOIN carrier ca ON ip.CarrierNum=ca.CarrierNum
INNER JOIN employer emp ON g.EmployerNum=emp.EmployerNum
WHERE p.PatStatus=0
GROUP BY inssub.PlanNum;
Confirmation list for insurance, returns appointments for given date (range), patient name, subscriber id, patients remaining 'general' benefits, carrier , carrier phone organized by carrier, no assumption of calendar year benefits - Only counts patient specific used amounts. Will use patient annual max when both family and patient annual maxes are present for plan.
/*403 Confirmation list for insurance, returns appointments for given date (range), patient name, subscriber id,
patients remaining 'general' benefits, carrier , carrier phone organized by carrier, no assumption of calendar year benefits*/
/*Query code written/modified: 10/02/2015*/
SET @FromDate='2015-09-01' , @ToDate='2015-09-30';/*Change dates here*/
SET @GeneralCoverageCategoryName='General';
SELECT a.PatNum, inssub.SubscriberID,
DATE(a.AptDateTime)AS 'DateApt',
/*Date_Format(a.AptDateTime,'%H:%m') AS 'TimeApt',*/
/*a.ProcDescript,*/
SUM(pl.ProcFee) AS $TotFee,
/*b.TimePeriod, b.MonetaryAmt AS $AnnualMax, ip.monthrenew,*/
ca.Phone AS 'CarrierPh',
IFNULL(ca.CarrierName, 'X - No Insurance') AS Carrier,
(CASE WHEN b.TimePeriod=1 AND ip.MonthRenew<=MONTH(CURDATE()) AND IFNULL(ip.MonthRenew,0)>0 THEN STR_TO_DATE(CONCAT(YEAR(CURDATE()), '-',ip.MonthRenew,'-01'),'%Y-%m-%d')
WHEN b.TimePeriod=1 AND ip.MonthRenew>MONTH(CURDATE()) AND IFNULL(ip.MonthRenew,13)<13 THEN STR_TO_DATE(CONCAT(YEAR(CURDATE())-1, '-',ip.MonthRenew,'-01'),'%Y-%m-%d')
WHEN b.TimePeriod=2 THEN STR_TO_DATE(CONCAT(YEAR(CURDATE()), '-01-01'),'%Y-%m-%d')
WHEN NOT ISNULL(ca.CarrierName) THEN STR_TO_DATE(CONCAT(YEAR(CURDATE()), '-01-01'),'%Y-%m-%d') END
) AS DateRenew,/*when coverage starts*/
COALESCE(MIN(b.MonetaryAmt),0) AS '$Annual Max_',
(CASE WHEN MIN(b.MonetaryAmt) IS NULL THEN '0' ELSE (MIN(b.MonetaryAmt)-IFNULL((SELECT SUM(claimproc.InsPayAmt)
FROM claimproc
WHERE claimproc.Status IN (1, 3, 4)
AND claimproc.PatNum=p.PatNum
AND claimproc.PlanNum=inssub.PlanNum
AND DATE(claimproc.ProcDate) BETWEEN DateRenew AND CURDATE()
),0))END) AS $InsLeft /*AnnualMax-AmtUsed*/
/*,(SELECT SUM(IFNULL(claimproc.InsPayAmt,0))
FROM claimproc
WHERE claimproc.Status IN (1, 3, 4)
AND claimproc.PatNum=p.PatNum
AND claimproc.PlanNum=inssub.PlanNum
AND DATE(claimproc.ProcDate) BETWEEN DateStart AND CURDATE()
) AS $AmtUsed*/
FROM patient p
INNER JOIN appointment a ON a.PatNum=p.PatNum
AND a.AptStatus=1/*Scheduled*/
LEFT JOIN patplan pp ON p.PatNum=pp.PatNum
LEFT JOIN inssub ON inssub.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=inssub.PlanNum
LEFT JOIN carrier ca ON ip.CarrierNum=ca.CarrierNum
LEFT JOIN procedurelog pl ON pl.AptNum=a.AptNum
LEFT JOIN benefit b ON b.PlanNum=inssub.PlanNum
AND b.BenefitType=5 /* limitation */
AND b.TimePeriod IN(1,2)/* service year or calendar year */
AND (b.CovCatNum=0 OR b.CovCatNum=(SELECT CovCatNum FROM covcat WHERE covcat.Description=@GeneralCoverageCategoryName AND covcat.EbenefitCat=1)/*General coverage*/)
AND b.Percent=-1
AND b.QuantityQualifier=0
AND b.Quantity=0
AND b.CodeNum=0
AND b.PatPlanNum=0
LEFT JOIN covcat c ON b.CovCatNum=c.CovCatNum
AND c.EbenefitCat=1 /*General ebenefit cat*/
WHERE (DATE(a.AptDateTime) BETWEEN @FromDate AND @ToDate)
GROUP BY a.AptNum, inssub.PlanNum
ORDER BY Carrier, p.LName,p.FName;
Procedures with key word in note for date range. -
/*404 Procedures with key word in note for date range*/
SET @FromDate= '2009-01-01', @ToDate='2010-07-31'; /*change dates here*/
SELECT procedurelog.ProcDate,procedurelog.ProvNum,
CONCAT(patient.LName,', ',patient.FName) AS 'PatientName',
procedurecode.ProcCode,procedurecode.AbbrDesc,
procedurelog.ToothNum, LEFT(n1.Note, 30) AS 'First 30 characters of Note'
FROM procedurelog,patient,procedurecode,procnote n1
WHERE procedurelog.PatNum = patient.PatNum
AND procedurelog.CodeNum = procedurecode.CodeNum
AND procedurelog.ProcStatus = 2
AND procedurelog.ProcDate BETWEEN @FromDate AND @ToDate
AND procedurelog.ProcNum=n1.ProcNum
AND n1.Note LIKE('%Tooth%') /*change keyword here*/
AND n1.EntryDateTime=(SELECT MAX(n2.EntryDateTime)
FROM procnote n2
WHERE n1.ProcNum = n2.ProcNum)
ORDER BY procedurelog.ProvNum, procedurelog.ProcDate;
Associated recall production: production by appointment with patient name, with count of appointments for a date range, showing sum of production for all procedures in appointments containing a particular procedure code, say D0120. -
/*405 Associated recall production: production by appointment with patient name, with count of appointments for a date range, showing sum of production for all procedures in appointments containing a particular procedure code, say D0120 */
SET @FromDate= '2009-10-01', @ToDate='2009-12-31'; /*change dates here*/
SET @RecallCode='D0120';
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count', a.PatNum, AptDateTime AS AptDateTime,
(SELECT SUM(procedurelog.ProcFee) FROM procedurelog WHERE procedurelog.AptNum=a.AptNum AND procedurelog.ProcStatus=2 GROUP BY a.AptNum) AS $Production
FROM appointment a
INNER JOIN procedurelog pl ON pl.AptNum=a.AptNum AND pl.ProcStatus=2
INNER JOIN procedurecode pc ON pl.CodeNum = pc.CodeNum
INNER JOIN patient p ON p.PatNum=a.PatNum
WHERE AptDateTime BETWEEN @FromDate AND @ToDate+INTERVAL 1 DAY
AND pc.ProcCode=@RecallCode
GROUP BY a.AptNum
ORDER BY AptDateTime, p.LName, p.FName;
Patients with plans with a specific insurance general max. -
/*406 Patients with plans with a specific insurance general max*/
SELECT p.PatNum, inssub.SubscriberID, b.MonetaryAmt AS $AnnualMax,
ca.Phone AS 'CarrierPh', ca.CarrierName AS Carrier
FROM patient p
LEFT JOIN patplan pp ON p.PatNum=pp.PatNum
LEFT JOIN inssub ON inssub.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=inssub.PlanNum
LEFT JOIN carrier ca ON ip.CarrierNum=ca.CarrierNum
LEFT JOIN benefit b ON b.PlanNum=inssub.PlanNum AND b.BenefitType=5 /* limitation */AND b.TimePeriod IN(1,2)/* service year or calendar year */
LEFT JOIN covcat c ON b.CovCatNum=c.CovCatNum AND c.EbenefitCat=1 /*General ebenefit cat*/
WHERE b.MonetaryAmt=1500/*change annual max here*/
GROUP BY p.PatNum, inssub.PlanNum
ORDER BY p.LName,p.FName, ca.CarrierName;
List of all TP procedures with a specified priority, within a user-defined date range. -
/*407 List of all TP procedures with a specified priority,
within a user-defined date range. */
SET @PriorityName = 'Recmend'; /* Change to the name of the priority desired. */
/* This gives a specified date range: */
SET @FromDate = '2009-01-01'; /* Change to the earliest TP date. */
SET @ToDate = '2009-12-31'; /* Change to the latest TP date. */
SELECT PatNum,ProcCode,ProcFee,Surf,ToothNum,DateTP,d.ItemName AS Priority
FROM procedurelog pl
LEFT JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
LEFT JOIN definition d ON d.DefNum=pl.Priority
WHERE pl.ProcStatus=1
AND d.ItemName LIKE @PriorityName
AND DateTP BETWEEN @FromDate AND @ToDate
ORDER BY PatNum ;
Appointment List report with Day of Week added. -
/*408 Appointment List report with Day of Week added */
SET @FromDate='2009-12-03' , @ToDate='2009-12-03';/*Change dates here*/
SELECT Date_Format(a.AptDateTime,'%W') AS 'Day',DATE(a.AptDateTime)AS 'DateApt',
p.PatNum, (YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) AS 'Age',
Date_Format(a.AptDateTime,'%l:%i %p') AS 'TimeApt', FORMAT(LENGTH(a.Pattern)*5,0) AS 'Length', a.ProcDescript
,CONCAT(" ", LEFT(HmPhone,13), "- ", LEFT(WkPhone,13), "- ",LEFT(WirelessPhone,13)) AS 'Phone Hm-Wk-Cell'
FROM appointment a
INNER JOIN patient p ON a.PatNum=p.PatNum /* AND a.AptStatus=1Scheduled*/
WHERE (DATE(a.AptDateTime) BETWEEN @FromDate AND @ToDate)
ORDER BY p.LName,p.FName;
Customers with production exceeding given amount between two dates. -
/*409 Customers with production exceeding given amount between two dates*/
/*Query code written/modified: 05/26/2015*/
SET @FromDate='2015-15-01' , @ToDate='2015-05-22';/*Change dates here*/
SET @SpentAmount=10; /*Change amount here*/
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count', A.*
FROM(
SELECT pl.PatNum, SUM(pl.ProcFee) AS $AmountProduction
FROM procedurelog pl
WHERE pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus=2
GROUP BY pl.PatNum
HAVING SUM(pl.ProcFee)>=@SpentAmount
)A;
Mailing list: Families that have been seen since a given date and have a given account billing type who have zip codes. -
/*411 Mailing list: Families that have been seen since a given date and have a given account billing type who have zip codes*/
SELECT g.LName,g.FName, g.Address, g.Address2, g.City, g.State, g.Zip
FROM patient p
INNER JOIN patient g ON p.Guarantor=g.PatNum
INNER JOIN definition d ON d.DefNum=g.BillingType
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
WHERE p.PatStatus=0
AND d.ItemName LIKE '%Standard Account%'
/*only patients with procedures since the following date*/
AND pl.PatNum=p.PatNum
AND pl.ProcDate >='01-01-2008' AND pl.ProcStatus=2 AND Length(g.Zip)>4
GROUP BY g.PatNum
ORDER BY g.LName,g.FName;
Mailing list for guarantors of active patients. - SEE REPLICATION WARNING for versions before 14.3.1. Also groups by address to prevent mailings to same address with different families.
/*412 mailing list for guarantors of active patients,
also groups by address to prevent mailings to same address with different families*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp SELECT DISTINCT Guarantor FROM patient WHERE PatStatus =0;
SELECT LName, FName, Address, Address2, City, State, Zip FROM patient, tmp
WHERE patient.PatNum=tmp.Guarantor AND Length(ZIP)>4 GROUP BY Address, Address2 ORDER BY LName;
DROP TABLE IF EXISTS tmp;
All referrals in date range, with patient date of first visit, columns may be added or removed. - For Versions 17.1 and greater. Please update your version accordingly
/*413 All referrals in date range, with patient date of first visit*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/16/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2018-01-01' , @ToDate='2018-01-31';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count',
refpats.*
FROM (
SELECT p.PatNum,
p.DateFirstVisit,
CONCAT(rf.LName,', ', rf.FName) AS Referrer,
(CASE WHEN ra.RefType = 1 /*RefFrom*/ THEN 'From' WHen ra.RefType = 0 /*RefTo*/ THEN 'To' ELSE 'Custom' END) AS 'FromTo',
DATE_FORMAT(ra.RefDate,'%m/%d/%Y') AS RefDate
FROM patient p
INNER JOIN refattach ra ON p.PatNum=ra.PatNum
INNER JOIN referral rf ON ra.ReferralNum=rf.ReferralNum
AND ra.RefDate BETWEEN @FromDate AND @ToDate
ORDER BY p.LName, p.FName
)refpats;
Subscribers (not neccesarily patients) with specific insurance group num(s). - Gives mailing addresses for subscribers (active or nonpatient) with a group number that matches one of those in a user-defined list.
/*414 Subscribers (not neccesarily patients) with specific insurance group num(s)*/
/* Gives mailing addresses for subscribers (active or nonpatient) with a
group number that matches one of those in a user-defined list.*/
SELECT i.GroupNum, p.FName, p.LName, p.Address, p.Address2,p.City,p.State,p.Zip
FROM patient p
INNER JOIN inssub ib ON ib.Subscriber=p.PatNum
INNER JOIN insplan i ON i.PlanNum=ib.PlanNum
WHERE i.GroupNum IN ('1234','300523')/* Change group nums here*/
AND (p.PatStatus=0 OR p.PatStatus=1)
ORDER By p.LName;
Sum of insurance income by procedure date for a date range for a given provider. -
/*415 Sum of insurance income by procedure date for a date range for a given provider*/
SET @FromDate='2009-10-01' , @ToDate='2009-10-31';/*change dates here*/
SET @ProviderAbbr='Doc1';/*set provider abbreviation here*/
SELECT provider.Abbr,cp.ProcDate,SUM(cp.InsPayAmt) AS 'InsIncome'
FROM claimproc cp
INNER JOIN provider ON cp.ProvNum=provider.ProvNum/*this is the provider that the payment is associated with*/
AND provider.Abbr=@ProviderAbbr
WHERE (cp.Status=1 OR cp.Status=4)/*received or supplemental*/
AND cp.ProcDate BETWEEN @FromDate AND @ToDate /*DateCP if not counting writeoffs by procdate*/
GROUP BY cp.ProcDate;
Customers with production exceeding some amount (could be zero or any other amount) who were seen between two dates and are between two given ages, 1 year and 17 years in this example. -
/*416 Customers with production exceeding some amount (could be zero or any other amount)
who were seen between two dates and are between two given ages, 1 year and 17 years in this example*/
SET @FromDate='2009-12-01' , @ToDate='2009-12-31';/*Change dates here*/
SET @SpentAmount=1; /*Change amount here*/
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count',pl.PatNum,
(YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) AS 'Age',
SUM(pl.ProcFee) AS $AmountProduction
FROM procedurelog pl
INNER JOIN patient p ON pl.PatNum=p.PatNum
WHERE pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus=2
AND (YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) BETWEEN 1 AND 17
GROUP BY pl.PatNum
HAVING SUM(pl.ProcFee)>=@SpentAmount;
Patients listed who have generated income in a time period (by date of payment). - Insurance and Patient income include limits to patients whose age is at or between given ages.
/*417 Patients listed who have generated income in a time period (by date of payment)
Insurance and Patient income include limits to patients whose age is at or between given ages*/
SET @FromDate='2009-12-01', @ToDate='2009-12-31' ;
SELECT p.PatNum, (YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) AS 'Age',
(SELECT SUM(cp.InsPayAmt) FROM claimproc cp WHERE cp.PatNum=p.PatNum AND (cp.DateCP BETWEEN @FromDate AND
@ToDate) AND (cp.Status=1 OR cp.Status=4)) AS '$InsPayment',
(SELECT SUM(paysplit.SplitAmt) FROM paysplit WHERE paysplit.PatNum=p.PatNum AND paysplit.DatePay
BETWEEN @FromDate AND @ToDate GROUP BY paysplit.PatNum) AS '$PatPayment'
FROM patient p
WHERE
(YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) BETWEEN 1 AND 21
GROUP BY p.PatNum
HAVING ($InsPayment>0 OR $PatPayment>0);
List of Active patients seen in date range with procedure count. -
/*418 List of Active patients seen in date range with procedure count*/
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count', pl.PatNum, COUNT(DISTINCT pl.ProcNum) AS 'Procedures' FROM procedurelog pl
INNER JOIN patient p ON pl.PatNum=p.PatNum
WHERE ProcStatus=2
AND ProcDate>='2008-06-14'
AND ProcDate<='2009-12-31'
AND p.PatStatus=0/*active*/
GROUP BY pl.PatNum
ORDER BY p.LName, p.FName;
Patients seen since date with user defined insurance carrier with fee schedule shown. -
/*419 Patients seen since date with user defined insurance carrier with fee schedule shown*/
Set @Carrier='%Solstice%', @SeenAfterDate='2008-12-15';
SELECT p.PatNum, DATE_FORMAT(MAX(ProcDate),'%m/%d/%Y') AS 'LastVisit', COUNT(pl.ProcNum) AS '# Procs Total', c.CarrierName, fs.Description
FROM carrier c
INNER JOIN insplan ip ON c.CarrierNum=ip.CarrierNum
INNER JOIN inssub ib ON ib.PlanNum=ip.PlanNum
INNER JOIN patplan pp ON pp.InsSubNum=ib.InsSubNum
INNER JOIN patient p ON p.PatNum=pp.PatNum
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
LEFT JOIN feesched fs ON fs.FeeSchedNum=ip.FeeSched
WHERE pl.ProcStatus=2 AND p.PatStatus=0 AND
c.CarrierName Like(@Carrier)
GROUP BY pl.PatNum
HAVING MAX(ProcDate)>@SeenAfterDate
ORDER BY p.LName, p.FName;
Hygiene daily production, completed procedures for a given date range and provider abbreviation. - Defaults to current date can be changed to show treatment planned procedure instead. To use an explicit date range instead of current date, remove comment markings from the beginning and end of the following line and remove the two lines after it.
/*420 Hygiene daily production, completed procedures
for a given date range and provider abbreviation. Defaults to current date
can be changed to show treatment planned procedure instead. */
/* To use an explicit date range instead of current date, remove comment
markings from the beginning and end of the following line and remove the two
lines after it. */
/*SET @FromDate='2010-01-05' , @ToDate='2010-01-05';*/
SET @FromDate=CURDATE();
SET @ToDate=CURDATE();
SELECT CONCAT(patient.LName, ', ',patient.FName, ' ', patient.MiddleI) As Patient,
pl.ProcDate, pv.Abbr,pc.ProcCode, pc.AbbrDesc, pl.ProcFee, pl.ProcStatus
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
INNER JOIN provider pv ON pl.ProvNum=pv.ProvNum
WHERE pl.ProcStatus =2 /* Alter this for the desired Procedure Status. 1=TP, 2=C */
AND (pl.ProcDate BETWEEN @FromDate AND @ToDate)
AND pc.IsHygiene=1
AND pv.Abbr='Hyg1' /* Change this to the desired Provider Abbreviation */
ORDER BY ProcDate,patient.LName, patient.FName ASC;
Production and Income summed by active patient where there was some activity in time range (with adjustments, insurance income and writeoffs by insurance claim received date). -
/*421 Production and Income summed by active patient where there was some activity in time range
(with adjustments, insurance income and writeoffs by insurance claim received date).*/
SET @FromDate='2015-05-01' , @ToDate='2015-05-31';
SELECT p.PatNum,
(SELECT SUM(InsPayAmt) FROM claim c WHERE c.PatNum=p.PatNum AND c.DateReceived BETWEEN @FromDate AND @ToDate) AS '$--InsPay--',
(SELECT SUM(SplitAmt) FROM paysplit WHERE p.PatNum=paysplit.PatNum AND (DatePay BETWEEN @FromDate AND @ToDate)) AS '$--PatientPay--',
(
IFNULL(
(SELECT SUM(InsPayAmt) FROM claim c WHERE c.PatNum=p.PatNum AND c.DateReceived BETWEEN @FromDate AND @ToDate)
,0)+
IFNULL(
(SELECT SUM(SplitAmt) FROM paysplit WHERE p.PatNum=paysplit.PatNum AND (DatePay BETWEEN @FromDate AND @ToDate))
,0)
) AS '$--TotalPay--',
SUM(pl.procfee) AS '$--Production--',
(SELECT SUM(Writeoff) FROM claim c WHERE c.PatNum=p.PatNum AND c.DateReceived BETWEEN @FromDate AND @ToDate) AS '$--WriteOff--',
(SELECT SUM(AdjAmt) FROM adjustment WHERE p.PatNum=adjustment.PatNum AND (adjdate BETWEEN @FromDate AND @ToDate)) AS '$--PatAdj--'
FROM patient p
LEFT JOIN procedurelog pl ON p.PatNum=pl.PatNum AND pl.ProcStatus=2 AND pl.ProcDate BETWEEN @FromDate AND @ToDate
WHERE p.PatStatus=0 /*active patients*/
GROUP BY p.PatNum
HAVING
(SELECT SUM(InsPayAmt) FROM claim c WHERE c.PatNum=p.PatNum AND c.DateReceived BETWEEN @FromDate AND @ToDate) > 0 OR
(SELECT SUM(SplitAmt) FROM paysplit WHERE p.PatNum=paysplit.PatNum AND (DatePay BETWEEN @FromDate AND @ToDate)) >0 OR
SUM(pl.procfee)>0 OR
(SELECT SUM(Writeoff) FROM claim c WHERE c.PatNum=p.PatNum AND c.DateReceived BETWEEN @FromDate AND @ToDate) >0 OR
(SELECT SUM(AdjAmt) FROM adjustment WHERE p.PatNum=adjustment.PatNum AND (adjdate BETWEEN @FromDate AND @ToDate)) >0
ORDER BY p.LName,p.FName;
Count of active patients of (or older than) a given age. - Includes patients without a birthdate as well.
/*422 Count of active patients of or older than a given age */
/*includes patients without a birthdate as well.*/
SET @ThisAgeOrOlder=29;
SELECT (CASE WHEN (YEAR(p.Birthdate))='0001' THEN 'No Birthdate Entered' ELSE (YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) END) AS 'Age', COUNT(DISTINCT p.PatNum) AS 'Patients'
FROM patient p
WHERE (YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) >=@ThisAgeOrOlder
AND p.PatStatus=0
GROUP BY Age
ORDER BY Age DESC;
Active Patient count patients older than 29, completed procs in list. - This counts patients with age > 29, who have completed procedures of a certain code number. Counts matching patients without a birthdate as well.
/*423 Active Patient count patients older than 29, completed procs in list */
/* This counts patients with age > 29, who have completed procedures of a certain code number. Counts matching patients without a birthdate as well. */
/* More codes can be added to the user defined list of codes if desired. */
SELECT (CASE WHEN (YEAR(p.Birthdate))='0001' THEN "No Birthdate Entered" ELSE (YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) END) AS 'Age', COUNT(DISTINCT p.PatNum) AS 'Patients'
FROM patient p
LEFT JOIN procedurelog pl ON p.PatNum=pl.PatNum
LEFT JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
WHERE (YEAR(CURDATE())-YEAR(p.Birthdate)) > 29
AND p.PatStatus=0
AND pl.ProcStatus=2 /* Completed procs (actually seen) */
AND pc.ProcCode in ('D4910', 'D4341', 'D4342', 'D4260', 'D4261')
GROUP BY Age;
Count by age of active patients older than a given age, with completed procedures in user defined list with first visit on or after date. - Counts matching patients without a birthdate as well. More codes can be added to the user defined list of codes if desired. Change the date of @EarliestVisit to the desired date of the earliest first visits to include.
/*424 Count by age of active patients older than a given age, with completed procedures in user defined list with first visit on or after date */
/*Counts matching patients without a birthdate as well. */
/* More codes can be added to the user defined list of codes if desired. Change the date of @EarliestVisit to the desired date of the earliest first visits to include. */
SET @EarliestVisit = '2009-01-01';
SELECT (CASE WHEN (YEAR(p.Birthdate))='0001' THEN "No Birthdate Entered" ELSE (YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) END) AS 'Age', COUNT(DISTINCT p.PatNum) AS 'Patients'
FROM patient p
LEFT JOIN procedurelog pl ON p.PatNum=pl.PatNum
LEFT JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
WHERE (YEAR(CURDATE())-YEAR(p.Birthdate)) > 29
AND p.PatStatus=0
AND pl.ProcStatus=2 /* Completed procs (actually seen) */
AND pc.ProcCode in ('D4910', 'D1110')
AND p.DateFirstVisit <= @EarliestVisit
GROUP BY Age;
Patient Payments for a given patient between two dates with payment type and check number. -
/*425 Patient Payments for a given patient between two dates
with payment type and check number*/
SET @PatNum='13631', @FromDate='2009-01-01' , @ToDate='2009-12-31';
SELECT ps.PatNum, d.ItemName AS 'Payment Type', SplitAmt, CheckNum, DatePay FROM paysplit ps
INNER JOIN payment p ON ps.PayNum=p.PayNum
INNER JOIN definition d ON p.PayType=d.DefNum
WHERE ps.PatNum=@PatNum AND DatePay BETWEEN @FromDate AND @ToDate;
Insurance payments received in one date range for procedures completed in a different date range, with both ranges specified by user. - Uses claim level service date as user may not have entered payments by procedure, so if it is a claim with multiple procedure dates, uses the claim level service date. For the payment date note that this usually but not always matches the payment date, e
/*426 insurance payments received in one date range for procedures completed in a different date range, with both ranges specified by user. Uses claim level service date as user may not have entered payments by procedure, so if it is a claim with multiple procedure dates, uses the claim level service date. For the payment date note that this usually but not always matches the payment date, especially if two payments are made on the same claim, so this won't exactly match the income report, which uses the check date*/
SET @ServiceFromDate='2009-01-01' , @ServiceToDate='2009-12-31';/*claim level service date*/
SET @receivedFromDate='2010-01-01' , @receivedToDate='2010-12-31';/*claim received date*/
SELECT PatNum, DateService, DateReceived, InsPayAmt /*InsPayEst,WriteOff can be easily added*/
FROM claim WHERE
(DateService BETWEEN @ServiceFromDate AND @ServiceToDate) AND
(DateReceived BETWEEN @receivedFromDate AND @receivedToDate);
Sum of insurance income by procedure date for a date range for a given provider. - SEE REPLICATION WARNING for versions before 14.3.1. Also with patient payments summed by payment date CAUTION READ CAREFULLY. Collection (insurance by procedure date, patient payment by pay date).
/*427 Sum of insurance income by procedure date for a date range for a given provider
also with patient payments summed by payment date CAUTION READ CAREFULLY*/
/*Collection (insurance by procedure date, patient payment by pay date)*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @FromDate='2009-10-01' , @ToDate='2009-10-31';/*change dates here*/
SET @ProviderAbbr='Doc1';/*set provider abbreviation here*/
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp
SELECT provider.Abbr,cp.ProcDate AS 'Date',SUM(cp.InsPayAmt) AS 'InsIncome', 0 AS 'PatPayment'
FROM claimproc cp
INNER JOIN provider ON cp.ProvNum=provider.ProvNum/*this is the provider that the payment is associated with*/
AND provider.Abbr=@ProviderAbbr
WHERE (cp.Status=1 OR cp.Status=4)/*received or supplemental*/
AND cp.ProcDate BETWEEN @FromDate AND @ToDate /*DateCP if not counting writeoffs by procdate*/
GROUP BY Date
UNION ALL
SELECT provider.Abbr, paysplit.DatePay AS 'Date',
0 AS 'InsIncome',
SUM(paysplit.SplitAmt) AS 'PatPayment'
FROM
paysplit
INNER JOIN provider ON paysplit.ProvNum=provider.ProvNum/*this is the provider that the payment is associated with*/
AND provider.Abbr=@ProviderAbbr
WHERE paysplit.DatePay BETWEEN @Fromdate AND @ToDate
GROUP BY paysplit.DatePay;
SELECT Abbr, Date,
SUM(InsIncome) AS '$InsIncome(procdate)',
SUM(PatPayment) AS '$PatPayment(paydate)'
FROM tmp GROUP BY Date;
DROP TABLE IF EXISTS tmp;
Return bad addresses for active patients that have ever been seen with last seen date, usually good to go through and call and set to inactive or fix the address. - Less expensive than cold calling or marketing, these are patients you need to contact.
/*428 return bad addresses for active patients that have ever been seen
with last seen date, usually good to go through and call and set to inactive or fix the address
less expensive than cold calling or marketing, these are patients you need to contact*/
SELECT CONCAT(LName,', ', FName) AS 'Patient Name', patient.PatNum AS 'Pat Num',
(SELECT Date_Format(MAX(procdate),'%m/%d/%Y') FROM procedurelog pl WHERE pl.PatNum=patient.PatNum AND pl.procstatus=2) AS 'Last Seen',
(CASE
WHEN LENGTH(Address)<6 THEN 'Bad Address'
WHEN LENGTH(City)<2 THEN 'Bad City'
WHEN LENGTH(State)<2 THEN 'Bad State'
WHEN (NOT (LEFT(ZIP,5) REGEXP '[0-9]{5}')) THEN 'Bad ZIP Code'
END) AS 'Issue',
LEFT(Address, 35) AS Address, LEFT(City, 20) AS City, LEFT(State, 5) AS State, LEFT(Zip, 10) AS ZIP
FROM patient
WHERE PatStatus=0 AND ((NOT (LEFT(ZIP,5) REGEXP '[0-9]{5}'))/*Check first five of zip code*/
OR LENGTH(Address)<6/*change this min length to any value for address*/
OR LENGTH(City)<2/*change this min length to any value for city*/
OR LENGTH(State)<2/*change this min length to any value for state*/)
AND (SELECT COUNT(*) FROM procedurelog pl WHERE pl.PatNum=patient.PatNum AND pl.procstatus=2)>0
ORDER BY LName, FName;
Patients due for a recall (perio or prophy) in a given time period but scheduled after that time period. - Usefull for trying to move back up recall appointments that had been scheduled farther out.
/*429 Patients due for a recall (perio or prophy) in a given time period but scheduled after that time period*/
/*Useful for trying to move back up recall appointments that had been scheduled farther out*/
/*Query code written/modified: 04/12/2018*/
/*change dates below for time period when recall is due*/
SET @FromDate='2017-01-01' , @ToDate='2018-10-31';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count',
recallpats.*
FROM(
SELECT p.PatNum,
rt.Description,
r.DateDue,
a.AptDateTime AS 'AptScheduled'
FROM recall r
INNER JOIN recalltype rt ON r.RecallTypeNum = rt.RecallTypeNum
INNER JOIN patient p ON p.PatNum=r.PatNum
LEFT JOIN appointment a ON a.PatNum=p.PatNum
AND a.AptStatus=1
WHERE p.patstatus = 0
AND (DATE(r.datedue) BETWEEN @FromDate AND @ToDate)
AND (rt.Description LIKE('%perio%') OR rt.Description LIKE('%prophy%'))
AND NOT ISNULL(r.DateDue)
AND DATE(a.AptDateTime)>@ToDate
)recallpats;
Patient (individual not family) balances, less than zero (credits). -
/*430 Patient (individual not family) balances, less than zero (credits)*/
SELECT PatNum, EstBalance AS '$IndivPatientBal' FROM patient p WHERE p.EstBalance<0;
Patient count with ins vs patients without. -
/*431 Patient count with ins vs patients without*/
SELECT (SELECT COUNT( DISTINCT PatNum) FROM patient WHERE HasIns='I' AND PatStatus=0) AS 'ActiveHasIns',(SELECT COUNT( DISTINCT PatNum) FROM patient WHERE HasIns<>'I' AND PatStatus=0) AS 'ActiveNoIns' ;
See which active patients have had a given procedure completed, and what their primary ins carrier is (if any). -
/*432 See which active patients have had a given procedure completed, and what their primary ins carrier is (if any). */
SET @ProcedureCode = 'D0220'; /* Change as desired. */
SELECT p.PatNum, pl.ProvNum, pc.ProcCode, ca.CarrierName FROM procedurelog pl
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
LEFT JOIN patplan pp ON pl.PatNum=pp.PatNum
LEFT JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip ON ip.plannum=ib.plannum
LEFT JOIN carrier ca ON ca.carriernum=ip.carriernum
INNER JOIN patient p ON p.PatNum=pl.PatNum
WHERE pc.ProcCode = @ProcedureCode
AND pl.ProcStatus=2
AND p.PatStatus=0
AND (pp.Ordinal IS NULL OR pp.Ordinal=1)
GROUP BY p.PatNum
ORDER BY LName, FName;
Percentage of patients who have had a particular procedure in a time period relative to the total number of patients seen in that time period. -
/*433 percentage of patients who have had a particular procedure in a time period
relative to the total number of patients seen in that time period*/
SET @FromDate='2009-01-01' , @ToDate='2010-10-31';/*change dates here*/
SET @ProcedureCode = 'D0220'; /* Change as desired. */
SELECT IFNULL((SELECT COUNT(Distinct PatNum) FROM procedurelog pl INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum WHERE pl.ProcStatus=2 AND (pl.ProcDate BETWEEN
@FromDate AND @ToDate) AND pc.ProcCode = @ProcedureCode),0) AS PatientsSeenForCode,
IFNULL((SELECT COUNT(Distinct PatNum) FROM procedurelog pl WHERE pl.ProcStatus=2 AND (pl.ProcDate BETWEEN
@FromDate AND @ToDate)),0) AS PatientsSeen, IFNULL((SELECT COUNT(Distinct PatNum) FROM procedurelog pl INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum WHERE pl.ProcStatus=2 AND (pl.ProcDate BETWEEN
@FromDate AND @ToDate) AND pc.ProcCode = @ProcedureCode),0)/IFNULL((SELECT COUNT(Distinct PatNum) FROM procedurelog pl WHERE pl.ProcStatus=2 AND (pl.ProcDate BETWEEN
@FromDate AND @ToDate)),0) AS PercentSeenForProcedure;
Patients with remaining benefits, patient name, subscriber id, patients remaining 'general' benefits, carrier, carrier phone organized by carrier. - No assumption of calendar year benefits, can be used as the basis for more powerful queries.
/*434 Patients with remaining benefits, patient name, subscriber id, patients remaining 'general' benefits, carrier ,
carrier phone organized by carrier, no assumption of calendar year benefits, can be used as the basis for more powerful queries*/
SELECT LEFT(CONCAT(p.LName, ',' , p.FName),20) AS Patient,
CONCAT(" ", LEFT(HmPhone,13), "- ", LEFT(WkPhone,13), "- ",LEFT(WirelessPhone,13)) AS 'Phone Hm-Wk-Cell',
LEFT(IFNULL(ca.CarrierName, 'X - No Insurance'),25) AS Carrier,
(CASE WHEN b.TimePeriod=1 AND ip.MonthRenew<=MONTH(CURDATE()) AND IFNULL(ip.MonthRenew,0)>0 THEN STR_TO_DATE(CONCAT(YEAR(CURDATE()), '-',ip.MonthRenew,'-01'),'%Y-%m-%d')
WHEN b.TimePeriod=1 AND ip.MonthRenew>MONTH(CURDATE()) AND IFNULL(ip.MonthRenew,13)<13 THEN STR_TO_DATE(CONCAT(YEAR(CURDATE())-1, '-',ip.MonthRenew,'-01'),'%Y-%m-%d')
WHEN b.TimePeriod=2 THEN STR_TO_DATE(CONCAT(YEAR(CURDATE()), '-01-01'),'%Y-%m-%d')
WHEN NOT ISNULL(ca.CarrierName) THEN STR_TO_DATE(CONCAT(YEAR(CURDATE()), '-01-01'),'%Y-%m-%d') END) AS DateRenew/*when coverage starts*/,
IFNULL(b.MonetaryAmt,0)/*AnnualMax*/-IFNULL((SELECT SUM(IFNULL(claimproc.InsPayAmt,0))
FROM claimproc
WHERE claimproc.Status IN (1, 3, 4)
AND claimproc.PatNum=p.PatNum
AND claimproc.PlanNum=inssub.PlanNum
AND DATE(claimproc.ProcDate) BETWEEN DateRenew AND CURDATE()),0)/*AmtUsed*/ As $InsLeft,
IFNULL(b.MonetaryAmt,0) AS $AnnualMax,
IFNULL((SELECT SUM(IFNULL(claimproc.InsPayAmt,0))
FROM claimproc
WHERE claimproc.Status IN (1, 3, 4)
AND claimproc.PatNum=p.PatNum
AND claimproc.PlanNum=inssub.PlanNum
AND DATE(claimproc.ProcDate) BETWEEN DateRenew AND CURDATE()),0) AS $AmtUsed
FROM patient p
LEFT JOIN patplan pp ON p.PatNum=pp.PatNum
LEFT JOIN inssub ON inssub.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=inssub.PlanNum
LEFT JOIN carrier ca ON ip.CarrierNum=ca.CarrierNum
LEFT JOIN benefit b ON b.PlanNum=inssub.PlanNum AND b.BenefitType=5 /* limitation */AND b.TimePeriod IN(1,2)/* service year or calendar year */
LEFT JOIN covcat c ON b.CovCatNum=c.CovCatNum AND c.EbenefitCat=1 /*General ebenefit cat*/
/*the following condition makes non insurance not show*/ WHERE NOT ISNULL(ca.CarrierName)
GROUP BY p.PatNum,inssub.PlanNum
HAVING $InsLeft>0
ORDER BY Carrier, p.LName,p.FName;
Case Acceptance for Date Range. - We only look at work that was TP in the date range, and then see what happened to it as of NOW (today).
/*435 Case Acceptance for Date Range*/
/* we only look at work that was TP in the date range, and then see what happened to it as of NOW (today)*/
SET @FromDate='2010-01-01' , @ToDate='2010-10-31';/*change dates here*/
SELECT
(CASE WHEN ProcStatus=1 THEN 'Still Treatment Planned'
WHEN ProcStatus=2 THEN 'Complete'
WHEN ProcStatus=3 THEN 'Existing Current Provider'
WHEN ProcStatus=4 THEN 'Existing Other Provider'
WHEN ProcStatus=5 THEN 'Referred Out'
WHEN ProcStatus=6 THEN 'Deleted'
WHEN ProcStatus=7 THEN 'Condition' END) AS 'Status',
COUNT(*),SUM(ProcFee) AS '$Total Fees', COUNT(Distinct PatNum) AS 'Unique Patients TPd'
FROM procedurelog pl
WHERE pl.DateTP BETWEEN @FromDate AND @ToDate
GROUP BY ProcStatus
WITH ROLLUP;
Production grouped by carrier and provider for procedures completed in date range where the plan type of the insurance plan upon which there is a claim is flatCopay. -
/*436 production grouped by carrier and provider for procedures completed in date range
where the plan type of the insurance plan upon which there is a claim is flatCopay*/
SET @FromDate='2012-01-01', @ToDate='2015-01-31' ;
/*Adjust above Dates as needed*/
SELECT A.Abbr AS 'Provider',
A.CarrierName,
A.PlanType,
COUNT(DISTINCT A.ProcNum) AS '#Procedures',
SUM(A.Production) AS '$TotProduction'
FROM(
SELECT provider.Abbr,
provider.ProvNum,
carrier.CarrierName,
insplan.PlanType,
procedurelog.ProcNum,
(procedurelog.ProcFee*(procedurelog.UnitQty+procedurelog.BaseUnits)) AS 'Production'
FROM carrier
INNER JOIN insplan ON carrier.CarrierNum=insplan.CarrierNum
AND insplan.PlanType='f'
INNER JOIN claim ON insplan.PlanNum=claim.PlanNum
INNER JOIN claimproc ON claim.ClaimNum=claimproc.ClaimNum
AND claimproc.Status IN(0,1) /*NotReceived,Received*/
INNER JOIN procedurelog ON claimproc.ProcNum=procedurelog.ProcNum
AND (procedurelog.ProcDate BETWEEN @FromDate AND @ToDate)
AND ProcStatus=2
INNER JOIN provider ON procedurelog.ProvNum=provider.ProvNum
GROUP BY CarrierName, provider.ProvNum, procedurelog.ProcNum
) A
GROUP BY CarrierName, ProvNum
ORDER BY A.Abbr,A.CarrierName;
Production grouped by provider for procedures completed in date range where the plan type of the insurance plan upon which there is a claim is flatCopay. -
/*437 production grouped provider for procedures completed in date range
where the plan type of the insurance plan upon which there is a claim is flatCopay*/
SET @FromDate='2009-10-01', @ToDate='2009-12-31' ;
/*Adjust above Dates as needed*/
SELECT provider.Abbr AS 'Provider',
COUNT(DISTINCT procedurelog.ProcNum) AS '#Procedures',
SUM(procedurelog.ProcFee) AS '$TotProduction'
/*SUM(procedurelog.InsPayAmt) as 'InsPaidTotal' */
FROM carrier
INNER JOIN insplan ON carrier.CarrierNum=insplan.CarrierNum AND insplan.PlanType='f'
INNER JOIN claim ON insplan.PlanNum=claim.PlanNum
INNER JOIN claimproc ON claim.ClaimNum=claimproc.ClaimNum
INNER JOIN procedurelog ON claimproc.ProcNum=procedurelog.ProcNum
AND (procedurelog.ProcDate BETWEEN @FromDate AND @ToDate)
AND ProcStatus=2
/*INNER JOIN procedurecode ON procedurelog.CodeNum=procedurecode.CodeNum*/
INNER JOIN provider ON procedurelog.ProvNum=provider.ProvNum
GROUP BY provider.ProvNum
ORDER BY provider.Abbr;
Total production by provider for date range and then production grouped by provider for procedures completed in date range where the plan type of the insurance plan upon which there is a claim is flatCopay. -
/*438 Total production by provider for date range and then production grouped by provider for procedures
completed in date range where the plan type of the insurance plan upon which there is a claim is flatCopay*/
SET @FromDate='2009-10-01', @ToDate='2009-12-31' ;
/*Adjust above Dates as needed*/
SELECT provider.Abbr AS 'Provider',
(SELECT SUM(pl.ProcFee) FROM procedurelog pl
WHERE pl.ProcStatus=2 AND pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProvNum=provider.ProvNum) AS '$AllProduction',
SUM(procedurelog.ProcFee) AS '$MediProduction'
/*SUM(procedurelog.InsPayAmt) as 'InsPaidTotal' */
FROM carrier
INNER JOIN insplan ON carrier.CarrierNum=insplan.CarrierNum AND insplan.PlanType='f'
INNER JOIN claim ON insplan.PlanNum=claim.PlanNum
INNER JOIN claimproc ON claim.ClaimNum=claimproc.ClaimNum
INNER JOIN procedurelog ON claimproc.ProcNum=procedurelog.ProcNum
AND (procedurelog.ProcDate BETWEEN @FromDate AND @ToDate)
AND ProcStatus=2
/*INNER JOIN procedurecode ON procedurelog.CodeNum=procedurecode.CodeNum*/
INNER JOIN provider ON procedurelog.ProvNum=provider.ProvNum
GROUP BY provider.ProvNum
ORDER BY provider.Abbr;
Medical Insurance Only: List of active patients with each insurance plan (not subscribers). - Carrier Names and group names are cutoff for space consideration. Check RAW button to show both PatNum and Patient Name.
/*439 Medical Insurance Only: List of active patients with each insurance plan (not subscribers),
Carrier Names and group names are cutoff for space consideration
Check RAW button to show both PatNum and Patient Name*/
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count',Left(carrier.CarrierName, 15) AS CarrierName, Left(GroupName, 15) AS GroupName,
p.PatNum AS 'Patient Num', CONCAT(p.LName,', ',p.FName,' ',p.MiddleI) AS PatName, ib.SubscriberId
FROM carrier
INNER JOIN insplan ip ON carrier.CarrierNum=ip.CarrierNum
INNER JOIN inssub ib ON ib.PlanNum=ip.PlanNum
INNER JOIN patplan pp ON pp.InsSubNum=ib.InsSubNum
INNER JOIN patient p ON pp.PatNum=p.PatNum
WHERE p.PatStatus=0 AND ip.IsMedical=1
ORDER BY CarrierName, GroupName, p.LName;
Payments for a given patient for a date range with payment type. -
/*440 Payments for a given patient for a date range with payment type.*/
SET @StartDate='2000-01-01';
SET @EndDate='2020-12-31';
SET @PatientNumber=27;
SELECT ps.PatNum, SplitAmt, DatePay, d.ItemName as 'Pay Type' FROM paysplit ps
INNER JOIN payment pm ON pm.PayNum=ps.PayNum
INNER JOIN definition d ON d.DefNum=pm.PayType
WHERE
DatePay BETWEEN @StartDate AND @EndDate AND
ps.PatNum=@PatientNumber;
Patients with checks for a specified carrier in a date range. - Note that you may NOT ADD the check amounts, because it is the check amount, not the payment amount in that column.
/*441 Patients with checks for a specified carrier in a date range... note that you may NOT ADD the check amounts, because it is the check amount, not the payment amount in that column*/
SET @StartDate='2008-01-01';
SET @EndDate='2010-12-31';
SELECT PatNum, SUM(cm.InsPayAmt) AS 'InsPayAmt',CheckAmt,DATE_FORMAT(CheckDate,'%m/%d/%Y') AS 'Check Date', CarrierName, COUNT(cm.ProcNum) AS '#Procedures' FROM claimpayment cp
LEFT JOIN claimproc cm ON cp.ClaimPaymentNum=cm.ClaimPaymentNum
WHERE CheckDate BETWEEN @StartDate AND @EndDate
AND CarrierName LIKE '%ODS%'
GROUP BY cm.ClaimNum, cp.ClaimPaymentNum;
How many days am I open in a date range. -
/*442 how many days am I open in a date range*/
SET @FromDate = '2009-11-26';
SET @ToDate = '2009-11-30';
SELECT COUNT(DISTINCT SchedDate) AS DaysOpen, DATEDIFF(@ToDate, @FromDate)+1 AS Days FROM Schedule
WHERE SchedType=1 AND SchedDate BETWEEN @FromDate AND @ToDate;
List of Patients that have not been seen since a specific date that have insurance benefits remaining. - Includes Insurance Carrier's Name, Patient's Name, Three Phone Numbers, Benefits Remaining, TP Remaining and Last seen date, Patient Address. Assumes everyone has calendar year benefits.
/*443 List of Patients that have not been seen since a specific date that have insurance benefits remaining.
Includes Insurance Carrier's Name, Patient's Name, Three Phone Numbers, Benefits Remaining,
TP Remaining and Last seen date, Patient Address*/
/*Assumes everyone has calendar year benefits*/
SET @FromDate='2013-10-08';
SELECT p.PatNum AS 'Pat#',
p.LName,
p.FName,
p.HmPhone,
p.WkPhone,
p.WirelessPhone,
DATE_FORMAT(lastseen.LastSeen,'%m/%d/%Y')AS LastSeen,
annualmax.AnnualMax '$AnnualMax_',
used.AmtUsed '$AmountUsed_',
annualmax.AnnualMax-COALESCE(used.AmtUsed,0) '$AmtRemaining_',
planned.AmtPlanned '$TreatmentPlan_',
c.CarrierName,
p.address AS 'PatientAddress',
p.city AS 'PatientCity',
p.State,
p.Zip
FROM patient p
INNER JOIN patplan ON p.PatNum=patplan.PatNum
INNER JOIN inssub ON inssub.InsSubNum=patplan.InsSubNum
INNER JOIN insplan ip ON ip.PlanNum=inssub.PlanNum
INNER JOIN carrier c ON c.CarrierNum=ip.CarrierNum
INNER JOIN (
SELECT benefit.PlanNum,
MAX(benefit.MonetaryAmt) AS AnnualMax
FROM benefit
LEFT JOIN covcat ON covcat.CovCatNum = benefit.CovCatNum
WHERE benefit.BenefitType = 5 /* limitation */
AND benefit.TimePeriod = 2 /* calendar year */
AND (covcat.EbenefitCat=1 OR ISNULL(covcat.EbenefitCat))
AND benefit.MonetaryAmt > 0 /* (-1) indicates empty */
GROUP BY benefit.PlanNum
) annualmax ON annualmax.PlanNum=inssub.PlanNum
INNER JOIN (
SELECT patient.PatNum,SUM(pl.ProcFee) AS AmtPlanned
FROM patient
INNER JOIN (
SELECT PatNum,ProcFee FROM procedurelog WHERE ProcStatus=1 /*treatment planned*/ AND ProcFee!=0
) pl ON patient.PatNum=pl.PatNum
WHERE patient.PatStatus=0 /* Patient */
GROUP BY patient.PatNum
) planned ON planned.PatNum=p.PatNum AND planned.AmtPlanned>0
LEFT JOIN (
SELECT patplan.PatPlanNum,
SUM(claimproc.InsPayAmt) AS AmtUsed
FROM claimproc
INNER JOIN inssub ON claimproc.InsSubNum=inssub.InsSubNum
INNER JOIN patplan ON inssub.InsSubNum=patplan.InsSubNum
AND patplan.PatNum=claimproc.PatNum
WHERE claimproc.Status IN (1, 3, 4) -- Rec, Adj, Supp.
AND YEAR(claimproc.ProcDate)=YEAR(CURDATE())
AND claimproc.InsPayAmt!=0
GROUP BY patplan.PatPlanNum
) used ON used.PatPlanNum=patplan.PatPlanNum
INNER JOIN (
SELECT p.PatNum,
MAX(procdate) AS LastSeen
FROM patient p
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
AND pl.ProcStatus=2 /*complete*/
AND p.PatStatus=0 /*active patient*/
GROUP BY pl.PatNum
) lastseen ON lastseen.PatNum=p.PatNum AND lastseen.LastSeen<@FromDate
WHERE PatStatus=0
ORDER BY c.CarrierName;
List of active patients that do not have active insurance plans. -
/*444 List of active patients that do not have active insurance plans.*/
SELECT LName, FName, Patnum
FROM patient
WHERE (patstatus = 0) AND PatNum NOT IN (SELECT DISTINCT PatNum FROM patplan pp
INNER JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
INNER JOIN insplan ip ON ip.PlanNum=ib.PlanNum
WHERE (ip.IsHidden = 0) AND (ib.DateTerm = DATE('0001-01-01')))
ORDER BY LName, FName;
Families with active patients in them where no active patient in the family has been seen in x months whose family balance exceeds 0. - SEE REPLICATION WARNING for versions before 14.3.1.
/*445 Families with active patients in them where no active patient in the family has been seen in x months whose family balance exceeds 0*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @pos=0;
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp
SELECT Guarantor, MAX(procdate) AS 'LastSeen' FROM patient,procedurelog
WHERE procedurelog.PatNum=patient.PatNum
AND procedurelog.procstatus = '2' AND PatStatus=0
GROUP BY Guarantor
HAVING MAX(ProcDate) <= CURDATE()-INTERVAL 183 DAY;
SELECT @pos:=@pos+1 AS 'Cnt', DATE_FORMAT(LastSeen,'%m/%d/%Y') AS 'Last Seen', LName, FName, BalTotal, BalTotal-InsEst AS $InsEstBal, Address, Address2, City, State, Zip FROM patient, tmp
WHERE patient.PatNum=tmp.Guarantor AND Length(ZIP)>4
AND BalTotal>0
ORDER BY LName;
DROP TABLE IF EXISTS tmp;
Procedures of treatment planned or completed status that were treatment planned OR completed in given date range, one specific code. -
/*446 Procedures of treatment planned or completed status that were treatment planned OR completed in given date range, one specific code*/
SET @FromDate='2009-10-01' , @ToDate='2010-03-31';
SELECT PatNum,ProcCode,ProcFee,Surf,ToothNum, DateTP, ProcDate,(CASE WHEN ProcStatus=1 THEN 'TP' WHEN ProcStatus=2 THEN 'Complete' END) AS ProcStatus
FROM procedurelog,procedurecode
WHERE ProcStatus IN (1,2)
AND (DateTP BETWEEN @FromDate AND @ToDate
OR ProcDate BETWEEN @FromDate AND @ToDate)
AND procedurecode.ProcCode='D4341'
AND procedurelog.CodeNum=procedurecode.CodeNum
ORDER BY PatNum;
Patient count with gross production by Zipcode, with at least 1 completed procedure in date range. - Limits to count(zipcodes)>3 as outliers, can be changed to 0 to include all. Like #178 but with date range.
/*447 Patient count with gross production by Zipcode, with at least 1 completed procedure in date range
limits to count(zipcodes)>3 as outliers, can be changed to 0 to include all
like #178 but with date range*/
SET @FromDate='2010-01-01' , @ToDate='2010-03-31';
SELECT LEFT(Zip,5) AS ZipCode, COUNT(DISTINCT p.PatNum) AS 'Patients', SUM(pl.ProcFee)
FROM procedurelog pl
INNER JOIN patient p ON p.PatNum=pl.PatNum
WHERE pl.ProcStatus=2 AND p.PatStatus=0 AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY ZipCode
HAVING patients>3;
Claims received in date range with summary information, fee total,claim fee total, amt paid. -
/*448 claims received in date range with summary information, fee total,claim fee total, amt paid*/
SET @FromDate='2010-03-22', @ToDate='2010-03-22';
/*Adjust above Dates as needed*/
SELECT carrier.CarrierName, c.PatNum, DATE_FORMAT(c.DateService,'%m/%d/%Y') AS 'Service Date', c.ClaimFee,
c.InsPayEst, c.InsPayAmt, c.WriteOff,(c.ClaimFee-c.InsPayAmt-c.Writeoff) AS $Rem, c.DateReceived, c.DedApplied
FROM claim c
LEFT JOIN insplan ip ON ip.PlanNum=c.PlanNum
LEFT JOIN carrier ON carrier.CarrierNum=ip.CarrierNum
WHERE c.DateReceived BETWEEN @FromDate AND @ToDate
AND c.ClaimStatus='R'
ORDER BY CarrierName;
List of active patients (not subscribers) with primary insurance plan listed. - Carrier Names and group names are cutoff for space consideration. Check RAW button to show both PatNum and Patient Name.
/*449 List of active patients (not subscribers) with primary insurance plan listed,
Carrier Names and group names are cutoff for space consideration
Check RAW button to show both PatNum and Patient Name*/
SELECT IFNULL(Left(c.CarrierName, 15), 'None') AS CarrierName, Left(GroupName, 15) AS GroupName,
PlanType, p.PatNum, CONCAT(p.LName,', ',p.FName,' ',p.MiddleI) AS PatName, ib.SubscriberId
FROM patient p
LEFT JOIN patplan pp ON pp.PatNum=p.PatNum
LEFT JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=ib.PlanNum
LEFT JOIN carrier c ON c.CarrierNum=ip.CarrierNum
WHERE p.PatStatus=0 AND (pp.Ordinal=1 OR ISNULL(c.CarrierName))
ORDER BY c.CarrierName, GroupName, p.LName;
Count of referrals received grouped by referral and zipcode. - For Versions 17.1 and greater. Please update your version accordingly
/*450 Count of referrals received grouped by referral and zipcode. */
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/16/2018*/
SELECT B.referralnum,
B.LName,
B.FName,
C.zip,
COUNT(*) AS TotalCount
FROM refattach A, referral B, patient C
WHERE (A.referralnum = B.referralnum) AND (A.PatNum = C.PatNum) AND (A.RefType = 1 /*RefFrom*/)
GROUP BY C.zip, B.referralnum
ORDER BY B.LName, B.FName, C.zip;
Scheduled or completed production with anticipated or actual writeoffs (only for primary insurance , if any) in user defined date range. - Gives net scheduled production for a date range by appointment, useful for setting produciton goals in offices with PPO insurance plans. Anticipated writeoffs shown after primary claim is created.
/*451 Scheduled or completed production with anticipated or actual writeoffs in user defined date range: gives net scheduled production for a date range by appointment, useful for setting production goals in offices with PPO insurance plans*/
/*Query code written/modified: 05/26/2017*/
SET @FromDate='2015-03-16', @ToDate='2017-03-21';
SET @Providers = ''; /*Enter provider abbreviations separated by a pipe ('|' without the quotes). To see all leave blank as ''*/
/*------------------------DO NOT MODIFY BELOW THIS LINE-----------------------------------------*/
SET @Providers=(CASE WHEN @Providers='' THEN '.*' ELSE CONCAT('^',REPLACE(@Providers,'|','$|^'),'$') END);
SELECT ap.AptDateTime,
pl.PatNum,
pv.Abbr,
SUM(pl.ProcFee) AS $Production,
SUM((SELECT SUM(CASE WHEN cp.Status = 1 THEN cp.WriteOff ELSE
(CASE WHEN cp.WriteOffEstOverride = -1 THEN
(CASE WHEN cp.WriteOffEst = -1 THEN 0 ELSE cp.WriteOffEst END)
ELSE cp.WriteOffEstOverride END) END) FROM claimproc cp WHERE cp.ProcNum=pl.ProcNum)) $WriteOffs,
(SUM(pl.ProcFee)-SUM(IFNULL((SELECT
SUM(CASE WHEN cp.Status = 1 THEN cp.WriteOff ELSE
(CASE WHEN cp.WriteOffEstOverride = -1 THEN
(CASE WHEN cp.WriteOffEst = -1 THEN 0 ELSE cp.WriteOffEst END)
ELSE cp.WriteOffEstOverride END) END) FROM claimproc cp WHERE cp.ProcNum=pl.ProcNum),0))) AS $NetProduction
FROM procedurelog pl
INNER JOIN appointment ap ON pl.AptNum=ap.AptNum
AND ap.AptStatus IN(1 /*scheduled apt*/,2 /*complete apt*/,4 /*ASAP appointment*/)
INNER JOIN provider pv ON pl.ProvNum = pv.ProvNum
AND pv.Abbr REGEXP @Providers
WHERE ap.AptDateTime BETWEEN @FromDate AND @ToDate+INTERVAL 1 DAY
GROUP BY ap.AptNum
ORDER BY ap.AptDateTime
Summary Scheduled or completed production with anticipated or actual writeoffs (only for primary insurance , if any) in user defined date range. - Gives net scheduled production for a date range, useful for setting produciton goals in offices with PPO insurance plans. Anticipated writeoffs shown after primary claim is created.
/*452 Summary Scheduled or completed production with anticipated or actual writeoffs (only for primary insurance , if any) in user defined date range: gives net scheduled production for a date range, useful for setting produciton goals in offices with PPO insurance plans*/
SET @FromDate='2010-03-25', @ToDate='2010-03-31';
SELECT SUM(Production) AS $TotalProduction, SUM(Writeoffs) AS $TotalWriteoffs,SUM(NetProduction) AS $NetProduction FROM
(
SELECT ap.AptDateTime,pl.PatNum, SUM(pl.ProcFee) AS Production,
(SELECT SUM(cp.WriteOff) FROM claimproc cp WHERE cp.ProcNum=pl.ProcNum) WriteOffs,
(SUM(pl.ProcFee)-IFNULL((SELECT SUM(cp.WriteOff) FROM claimproc cp WHERE cp.ProcNum=pl.ProcNum),0)) AS NetProduction
FROM procedurelog pl
INNER JOIN appointment ap ON pl.AptNum=ap.AptNum AND (ap.AptStatus=1/*scheduled apt*/ OR ap.AptStatus=2 /*complete apt*/)
WHERE DATE(ap.AptDateTime) BETWEEN @FromDate AND @ToDate
GROUP BY ap.AptNum
) A;
Number and percentage of patients (active and inactive) who have had a particular procedure performed. -
/*453 number and percentage of patients (active and inactive) who have had a particular procedure performed*/
/*Query code written/modified: 06/15/2016*/
SET @ProcCode='D0120';
SELECT
(SELECT COUNT(DISTINCT PatNum)
FROM procedurelog A, procedurecode B
WHERE (A.CodeNum = B.CodeNum) AND (B.ProcCode=@ProcCode) AND (A.procstatus=2))
AS '#PatientsWithProcedure',
(SELECT COUNT(*) FROM patient WHERE PatStatus IN (0,2))
AS 'Total # Inactive and Active Patients',
(FORMAT(100*(SELECT COUNT(DISTINCT PatNum)
FROM procedurelog A, procedurecode B
WHERE (A.CodeNum = B.CodeNum) AND (B.ProcCode=@ProcCode) AND (A.procstatus=2))
/ (SELECT COUNT(*) FROM patient WHERE PatStatus IN (0,2)),2))
AS PatientPercentage;
Count of Procedures and Total Production by Family, ever. - Top 100, remove limit if desired.
/*454 Count of Procedures and Total Production by Family, ever, top 100, remove limit if desired*/
SELECT p.Guarantor, Count(*) AS ProcCount, SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) AS $Production FROM
procedurelog pl INNER JOIN patient p ON p.PatNum=pl.PatNum
WHERE pl.ProcStatus=2
GROUP BY p.Guarantor ORDER BY ProcCount DESC LIMIT 100;
Special Statement grouped by procedure date. - SEE REPLICATION WARNING for versions before 14.3.1. Special Statement shows transactions grouped by procedure date, helps to understand a families account, alternate to going line by line through someones account
/*455 Special Statement grouped by procedure date*/
/*-- Special Statement shows transactions grouped by procedure date, helps to understand a families account, alternate to going line by line through someones account*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @GPatNum='78', @Detail=False /*Set to True or False to show procedure level rows*/;
/*-- Run by putting in Guarantor's Patient Number and setting @Detail to True if you want procedure level detail*/
/*-- it would be very unusual, but you could limit to a given date range if you like, and would NOT bring balance forward*/
SET @FromDate='1900-01-01' , @ToDate='2099-12-31';
/*-- Accounts for payment plans and capitation (HMOs) now too
-- Show transactions by service date, then sum by date*/
DROP TABLE IF EXISTS tmp1, tmp2, tmp3;
Set @Pos=0;/*counter for manipulation later*/
CREATE TABLE tmp1(FName VARCHAR(15),TranType VARCHAR(11),ProcDate DATE,Description VARCHAR(20),PatNum BIGINT,Fee DOUBLE,WriteOff DOUBLE,InsPayAmt DOUBLE,OutIns DOUBLE,Adjust DOUBLE,PatPaid DOUBLE,PatPort DOUBLE,ToBalance DOUBLE,RunningBal DOUBLE);
/*-- insert all completed procedures and any associated insurance claimprocs*/
INSERT INTO tmp1
SELECT p.FName, 'Charge' AS TranType,pl.ProcDate,(CASE WHEN pl.ToothNum<1 THEN pc.ProcCode ELSE CONCAT(pc.ProcCode, '-',pl.ToothNum) END) AS Description,
pl.PatNum, pl.ProcFee*(pl.UnitQty+pl.BaseUnits) Fee,
SUM(cp.Writeoff) AS WriteOff,SUM(cp.InsPayAmt) AS InsPayAmt, 0 AS OutIns, 0 AS Adjust,
IFNULL((SELECT SUM(ps.SplitAmt) FROM paysplit ps WHERE ps.ProcNum=pl.ProcNum AND ps.PayPlanNum=0),0) AS PatPaid,
NULL AS 'PatPort', NULL AS 'ToBalance', NULL AS RunningBal
FROM procedurelog pl
INNER JOIN patient p ON p.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
LEFT JOIN claimproc cp ON cp.ProcNum=pl.ProcNum AND cp.Status IN(1,4, 5, 7) /* received, supplemental, capclaim,capreceived*/
WHERE pl.ProcStatus=2 AND p.Guarantor=@GPatNum /*(SELECT g.Guarantor FROM patient g WHERE g.PatNum=@GPatNum)*/
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY pl.ProcNum
ORDER BY PatNum, ProcDate;
/*-- insurance payments by total*/
INSERT INTO tmp1
SELECT p.FName, 'Other Payments' AS TranType, cp.ProcDate, 'Ins Pay by Total' AS Description, cp.PatNum, 0 AS Fee, SUM(cp.Writeoff) AS Writeoff, SUM(cp.InsPayAmt) AS InsPayAmt,0 AS OutIns, 0 AS Adjust, 0 AS PatPaid, NULL AS 'PatPort', NULL AS ToBalance, NULL AS RunningBal
FROM claimproc cp
INNER JOIN patient p ON cp.PatNum=p.PatNum
WHERE cp.Status IN(1,4) /*rec, suppl*/ AND p.Guarantor=@GPatNum /*(SELECT g.Guarantor FROM patient g WHERE g.PatNum=@GPatNum)*/ AND cp.ProcNum=0
AND cp.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY cp.PatNum, cp.ProcDate;
INSERT INTO tmp1
/*-- Adjustments*/
SELECT FName, 'DaySumAdj' AS TranType, a.ProcDate, 'Adjustments' AS Description, a.PatNum, 0 AS FEE, 0 AS Writeoff, 0 AS InsPayAmt,0 AS OutIns, SUM(AdjAmt) AS Adjust,0 AS 'PatPaid', NULL AS 'PatPort', NULL AS ToBalance, NULL AS RunningBal
FROM adjustment a
INNER JOIN patient p on p.PatNum=a.PatNum
WHERE p.Guarantor=@GPatNum /*(SELECT g.Guarantor FROM patient g WHERE g.PatNum=@GPatNum)*/
AND a.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY a.PatNum, a.ProcDate
UNION ALL
/*-- Remaining Patient Payments*/
SELECT FName, 'DaySumPay' AS TranType, ps.ProcDate, 'Pat Pay by Total' AS Description, p.PatNum, 0 AS FEE, 0 AS Writeoff, 0 AS InsPayAmt,0 AS OutIns, 0 AS Adjust, SUM(SplitAmt) AS PatPaid, NULL AS 'PatPort', NULL AS ToBalance, NULL AS RunningBal
FROM paysplit ps
INNER JOIN patient p on p.PatNum=ps.PatNum
WHERE p.Guarantor=@GPatNum AND ps.ProcNum=0 AND ps.PayPlanNum=0
AND ps.ProcDate BETWEEN @FromDate AND @ToDate
/*(SELECT g.Guarantor FROM patient g WHERE g.PatNum=@GPatNum)*/
GROUP BY ps.PatNum, ps.ProcDate
UNION ALL
/*-- Outstanding Claims*/
SELECT p.FName, 'DayOutIns' AS TranType, cp.ProcDate, 'Day Outstand Ins' AS Description, cp.PatNum, 0 AS Fee, 0 AS Writeoff,0 AS InsPayAmt,(SUM(cp.Writeoff) + SUM(cp.InsPayEst)) AS OutIns, 0 AS Adjust, 0 AS PatPaid, NULL AS 'PatPort', NULL AS ToBalance, NULL AS RunningBal
FROM claimproc cp
INNER JOIN patient p ON cp.PatNum=p.PatNum
WHERE cp.Status IN(0) /*sent*/ AND p.Guarantor=@GPatNum /*(SELECT g.Guarantor FROM patient g WHERE g.PatNum=@GPatNum)*/
AND cp.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY cp.PatNum, cp.ProcDate
UNION ALL
/*Payment Plans*/
SELECT p.FName, 'PPComplete' AS TranType, pp.PayPlanDate as ProcDate, 'Payment Plan' AS Description, p.PatNum, 0 AS Fee, 0 AS Writeoff,0 AS InsPayAmt,0 AS OutIns,-pp.CompletedAmt AS Adjust, 0 AS PatPaid, NULL AS 'PatPort', NULL AS ToBalance, NULL AS RunningBal
FROM payplan pp
INNER JOIN patient p ON pp.PatNum=p.PatNum
WHERE p.Guarantor=@GPatNum
GROUP BY pp.PatNum, pp.PayPlanDate;
/*-- Add totals by date*/
CREATE TABLE tmp2
SELECT * FROM tmp1
UNION ALL
SELECT FName, 'Total' AS TranType, ProcDate, ' Total For Date' AS Description, PatNum, SUM(Fee) AS Fee, SUM(Writeoff) AS Writeoff, SUM(InsPayAmt) AS InsPayAmt, SUM(OutIns) AS OutIns,SUM(Adjust) AS Adjust, SUM(PatPaid) AS PatPaid, NULL AS PatPort, NULL AS ToBalance, NULL AS RunningBal
FROM tmp1 GROUP BY PatNum, ProcDate;
UPDATE tmp2
SET ToBalance=(IFNULL(Fee,0)-IFNULL(Writeoff,0)-IFNULL(InsPayAmt,0)-IFNULL(PatPaid,0)+IFNULL(Adjust,0))
WHERE TranType = 'Total' AND (IFNULL(Fee,0)-IFNULL(Writeoff,0)-IFNULL(InsPayAmt,0)-IFNULL(PatPaid,0)+IFNULL(Adjust,0))<>0;
UPDATE tmp2
SET PatPort=(IFNULL(Fee,0)-IFNULL(Writeoff,0)-IFNULL(InsPayAmt,0)-IFNULL(OutIns,0)) WHERE TranType = 'Total' AND Fee<>0;
DROP TABLE IF EXISTS tmp1;
/*-- Now do running totals, using duplicate table*/
CREATE TABLE tmp1(FName VARCHAR(15),TranType VARCHAR(11),ProcDate DATE,Description VARCHAR(20),PatNum BIGINT,Fee DOUBLE,WriteOff DOUBLE,InsPayAmt DOUBLE,OutIns DOUBLE,Adjust DOUBLE,PatPaid DOUBLE,PatPort DOUBLE,ToBalance DOUBLE,RunningBal DOUBLE);
/*-- insert all completed procedures and any associated insurance claimprocs*/
INSERT INTO tmp1 SELECT * FROM tmp2;
UPDATE tmp2 SET RunningBal=(SELECT SUM(0+IFNULL(tmp1.ToBalance,0)) FROM tmp1 WHERE DATE(tmp1.ProcDate)<=DATE(tmp2.ProcDate) AND tmp1.PatNum=tmp2.PatNum AND tmp1.Description=' Total For Date')
WHERE tmp2.Description=' Total For Date';
/*-- Total by Patient, use fake date to indicate we want it blank later, must be large date to sort to bottom*/
INSERT INTO tmp2
SELECT '' AS FName, 'Total Ind' AS TranType, '3000-01-01' AS ProcDate, CONCAT(' Tot ', FName) AS Description, PatNum,
SUM(Fee) AS Fee, SUM(Writeoff) AS Writeoff,
SUM(InsPayAmt) AS InsPayAmt, SUM(OutIns) AS OutIns,SUM(Adjust) AS Adjust, SUM(PatPaid) AS PatPaid,
SUM(PatPort) AS PatPort, SUM(ToBalance) AS ToBalance, SUM(ToBalance) AS RunningBal
FROM tmp1 WHERE tmp1.Description=' Total For Date'
GROUP BY PatNum;
/*-- add Blank Row after each Patient in Family*/
INSERT INTO tmp2
SELECT '' AS FName, 'Total IndB' AS TranType, '3000-01-01' AS ProcDate, '' AS Description, PatNum,
NULL AS Fee, NULL AS WriteOff,NULL AS InsPayAmt,NULL AS OutIns,NULL AS Adjust,NULL AS PatPaid,NULL AS PatPort,NULL AS ToBalance,NULL AS RunningBal
FROM tmp1 WHERE tmp1.Description=' Total For Date'
GROUP BY PatNum;
/*-- add family total*/
INSERT INTO tmp2
SELECT 'Family' AS FName, 'Total Fam' AS TranType, '3000-01-01' AS ProcDate, ' Total OverAll' AS Description, '999999999999' AS PatNum,
SUM(Fee) AS Fee, SUM(Writeoff) AS Writeoff,
SUM(InsPayAmt) AS InsPayAmt, SUM(OutIns) AS OutIns,SUM(Adjust) AS Adjust, SUM(PatPaid) AS PatPaid,
SUM(PatPort) AS PatPort, SUM(ToBalance) AS ToBalance, SUM(ToBalance) AS RunningBal
FROM tmp1 WHERE tmp1.Description=(' Total For Date');
/*-- now add position record to allow us to eliminate date repetition in detail version*/
CREATE TABLE tmp3
SELECT @pos:=@pos+1 AS RecNum,FName,TranType,ProcDate,Description,PatNum,Fee,WriteOff,InsPayAmt,OutIns,Adjust,PatPaid,PatPort,ToBalance,RunningBal
FROM tmp2
ORDER BY PatNum, ProcDate, TranType;
DROP TABLE IF EXISTS tmp2;
/*-- copy back to temp2, we will need two tables to avoid self reference during update*/
CREATE TABLE tmp2 SELECT * FROM tmp3;
/*-- Now choose which results to display, we add a column 'Detail' to allow a virtual if statement*/
ALTER TABLE tmp3 ADD COLUMN Detail BOOL;
UPDATE tmp3 SET Detail=@Detail;
UPDATE tmp3, tmp2 SET tmp3.ProcDate='3000-01-01' WHERE tmp3.RecNum=tmp2.RecNum+1 AND tmp3.ProcDate=tmp2.ProcDate AND Detail=True;
DELETE FROM tmp3 WHERE TranType NOT LIKE 'Total%' AND Detail=False;
/*-- output results, hiding useless columns, doing some formatting*/
SELECT /*RecNum, */
FName AS Name,
/*TranType,*/
(CASE WHEN ProcDate='3000-01-01' THEN '' ELSE DATE_FORMAT(ProcDate, '%m/%d/%Y') END) AS Date,
Description,
/*PatNum,*/
FORMAT(Fee,2) AS Fee,
FORMAT(WriteOff,2) AS WriteOff,
FORMAT(InsPayAmt,2) AS InsPaid,
FORMAT(OutIns,2) AS OutIns,
FORMAT(Adjust,2) AS Adjust,
FORMAT(PatPaid,2) AS PatPaid,
FORMAT(PatPort,2) AS PatPort,
(CASE WHEN TranType='Total Fam' THEN ' >'
WHEN TranType='Total Ind' THEN ' >'
ELSE FORMAT(ToBalance,2) END) AS ToBalance,
(CASE WHEN TranType='Total Fam' THEN CONCAT('Tot: $', FORMAT((RunningBal),2))
WHEN TranType='Total Ind' THEN FORMAT(IFNULL(RunningBal,0),2)
WHEN ISNULL(ToBalance) THEN NULL
ELSE FORMAT(RunningBal,2) END) AS RunningBal FROM tmp3;
DROP TABLE IF EXISTS tmp1, tmp2, tmp3;
Make list and count of patients with scheduled recalls, and what recall procs are in apts. - Shows first scheduled recall appointment for each patient that has one, also numbers them to give you a count at bottom.
/*456 Make list and count of patients with scheduled recalls, and what recall procs are in apts.*/
/*Shows first scheduled recall appointment for each patient that has one, also numbers them to give you a count at bottom*/
/*Query code written/modified: 10/28/2014*/
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count',A.*
FROM (
SELECT r.PatNum,MIN(a.AptDateTime) AS 'AptDateTime',
(CASE WHEN r.IsDisabled=0 THEN 'Enabled' ELSE 'Disabled' END) AS IsRecDisabled,
GROUP_CONCAT(pc.ProcCode) AS 'Recall Procs in Apt'
FROM appointment a
INNER JOIN procedurelog pl ON a.AptNum=pl.AptNum
INNER JOIN recall r ON r.PatNum=pl.PatNum
INNER JOIN recalltrigger rt ON rt.RecallTypeNum=r.RecallTypeNum AND pl.CodeNum=rt.CodeNum
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
WHERE a.AptDateTime > NOW()
AND (a.AptStatus=1 /*Scheduled */
OR a.AptStatus=4) /* ASAP */
GROUP BY r.PatNum
) A
Active patients that have a completed procedure over a specified date range and a birthdate within aspecified month. - Specify the birthdate month that you are interested in displaying. Includes age. The results are ordered by birthdate month and birthdate day.
/*457 Active patients that have a completed procedure over a specified date range and a birthdate within aspecified month. Specify the birthdate month that you are interested in displaying. Includes age. The results are ordered by birthdate month and birthdate day. */
SET @FromDate = '2008-01-01', @ToDate = CURDATE(); /* Put the date range that you want to search. */
SET @Month = 4; /* Put the numeric representation of the month (like 4 represents April). */
SELECT birthdate,
(CASE WHEN (YEAR(CURDATE())-YEAR(p.Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(p.Birthdate,5))<200
THEN(YEAR(CURDATE())-YEAR(p.Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(p.Birthdate,5)) ELSE 0 END) AS 'Age', PatNum, LName, FName, address, address2, city, state, zip
FROM patient p
WHERE PatNum IN (SELECT PatNum FROM procedurelog
WHERE (procstatus = 2) AND (CAST(MONTH(birthdate) AS DECIMAL) = CAST(@Month AS DECIMAL)) AND
(procdate BETWEEN @FromDate AND @ToDate)) AND PatStatus=0
GROUP BY PatNum
ORDER BY MONTH(birthdate), DAY(birthdate), LName, FName;
Gross production for active patients by zip code. -
/*458 Gross production for active patients by zip code. */
SELECT p.Zip, SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) AS $Production
FROM procedurelog pl
INNER JOIN patient p ON pl.PatNum=p.PatNum
WHERE p.PatStatus=0 AND pl.ProcStatus=2
AND pl.ProcDate>=DATE('2010-01-01')
AND pl.ProcDate<=DATE('2010-04-01')
GROUP BY p.Zip
ORDER BY p.Zip;
Unearned income report with payment type. -
/*459 Unearned income report with payment type*/
SET @FromDate='2010-04-01' , @ToDate='2010-04-30';
SELECT ps.DatePay, p.PatNum, pm.PayType,ps.UnearnedType, ps.SplitAmt
FROM PaySplit ps
INNER JOIN payment pm ON pm.PayNum=ps.PayNum
INNER JOIN patient p ON p.PatNum=ps.PatNum
WHERE ps.DatePay BETWEEN @FromDate AND @ToDate
AND UnearnedType<>0
ORDER BY ps.DatePay,p.LName, p.FName;
Writeoff report for a particular procedure code, by date range, with insurance paid amt. - Listed by procedure, includes all procedures matching code for which there is a received or supplemental claim procedure.
/*460 Writeoff report for a particular procedure code, by date range, with insurance paid amt
listed by procedure, includes all procedures matching code for which there is a received or supplemental claim procedure*/
SET @FromDate='2010-01-01' , @ToDate='2010-03-31';
SELECT cp.PatNum,cp.DateCP,
SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) AS '$Charged',
SUM(cp.InsPayAmt) AS '$InsPayAmt',
SUM(cp.WriteOff) AS '$WriteOff'
FROM procedurelog pl
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
INNER JOIN claimproc cp ON cp.ProcNum=pl.ProcNum
WHERE pc.ProcCode LIKE('D9999%')
AND (cp.DateCP BETWEEN @FromDate AND @ToDate)
AND (cp.Status = 1 OR cp.Status = 4) /*received and supplemental claims*/
GROUP BY pl.ProcNum
ORDER BY cp.DateCP;
Active patients who were seen after a user specified date and (optionally) have a user specified primary carrier. - Displays patient, last seen date, primary carrier name (if insured), hmphone and wireless phone. Also shows count of matching patients.
/*461 Active patients who were seen after a user specified date and (optionally) have a user specified primary carrier
Displays patient, last seen date, primary carrier name (if insured), hmphone and wireless phone. Also shows count of matching patients.*/
SET @FromDate='2000-01-01'; /*Change Dates Here*/
SET @Carrier = '%%'; /* Change to 'NONE' for uninsured, or to the desired carrier name. '%%' for any or no carrier, '%Aetna%' will just show carriers matching name "Aetna". */
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count', A.*
FROM (
SELECT p.PatNum,
LEFT(HmPhone,16) AS HmPhone, LEFT(WirelessPhone,16) AS CellPhone,
DATE_FORMAT(MAX(ProcDate),'%m/%d/%Y') AS 'LastVisit', c.CarrierName
FROM patient p
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
LEFT JOIN patplan pp ON pp.PatNum=p.PatNum AND pp.Ordinal=1
LEFT JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=ib.PlanNum
LEFT JOIN carrier c ON c.CarrierNum=ip.CarrierNum
WHERE (pl.ProcStatus=2) AND (p.PatStatus=0) AND (pl.ProcDate>=@FromDate)
AND ((c.CarrierName LIKE @Carrier) OR (ISNULL(c.CarrierName) AND (@Carrier='%NONE%' OR @Carrier='%%')))
GROUP BY pl.PatNum
ORDER BY p.LName, p.FName
) A;
Production and Income by ref source for date range. - For versions 16.4 and below. SEE REPLICATION WARNING for versions before 14.3.1. KEY POINT: only includes referrals received and income collected during that period, note: duplicates for multiple 'from' referrals in period. Submitted by Steve Gershkowitz.
/*462 Production and Income by ref source for date range, KEY POINT: only includes referrals received and income
collected during that period,whereas other reports may report residual income form referrals before defined date range, also returns TP fee total, note: duplicates for multiple 'from' referrals in period*/
/*Submitted by Steve Gershkowitz, edited by nathan*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
/*For versions 16.4 and below*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate = '2008-09-01', @ToDate = '2008-12-30';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
DROP TABLE IF EXISTS insurance_pay;
CREATE TEMPORARY TABLE insurance_pay(
PatNum MEDIUMINT UNSIGNED NOT NULL,
Payment DOUBLE NOT NULL,
PRIMARY KEY (PatNum));
INSERT INTO insurance_pay
SELECT clm.PatNum, SUM(clm.InsPayAmt) AS InsPaid
FROM claimproc clm
WHERE clm.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY clm.PatNum;
DROP TABLE IF EXISTS planned_proc;
CREATE TEMPORARY TABLE planned_proc
(PatNum MEDIUMINT UNSIGNED NOT NULL,
PlannedFee DOUBLE NOT NULL,
PRIMARY KEY (PatNum));
INSERT INTO planned_proc
SELECT pl.PatNum, SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) AS Planned_Fee
FROM procedurelog pl
WHERE pl.ProcStatus=1 /* TP Planned */
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY pl.PatNum;
DROP TABLE IF EXISTS comp_proc;
CREATE TEMPORARY TABLE comp_proc
(PatNum MEDIUMINT UNSIGNED NOT NULL,
Prod DOUBLE NOT NULL,
PRIMARY KEY (PatNum));
INSERT INTO comp_proc
SELECT pl.PatNum, SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) AS Prod
FROM procedurelog pl
WHERE pl.ProcStatus=2 /* complete */
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY pl.PatNum;
DROP TABLE IF EXISTS var_payments;
CREATE TEMPORARY TABLE var_payments(
PatNum MEDIUMINT UNSIGNED NOT NULL,
PayAmt DOUBLE NOT NULL,
PRIMARY KEY (PatNum));
INSERT INTO var_payments
SELECT pay.PatNum , SUM( pay.PayAmt ) AS Total
FROM payment pay
WHERE pay.PayDate BETWEEN @FromDate AND @ToDate
GROUP BY pay.PatNum;
DROP TABLE IF EXISTS referred;
CREATE TEMPORARY TABLE referred(
PatNum MEDIUMINT UNSIGNED NOT NULL,
RefSource VARCHAR(255)NOT NULL);
INSERT INTO referred
SELECT ra.PatNum,
CASE
WHEN NotPerson=1 /* true */
THEN re.LName
ELSE CONCAT( re.FName, ' ', re.LName )
END AS Source
FROM referral re, refattach ra
WHERE re.ReferralNum = ra.ReferralNum
AND ra.RefDate BETWEEN @FromDate AND @ToDate
AND ra.IsFrom =1 /* true */;
SELECT
ref.RefSource AS Source, COUNT(DISTINCT ref.PatNum) AS HowMany,
COALESCE(SUM(prd.Prod),0) AS "$Production (Gross)",
COALESCE(SUM(ins.Payment),0) AS "$Insurance Collected",
COALESCE(SUM(pay.PayAmt),0) AS "$Cash, CC, Checks, Financing",
COALESCE(COALESCE(SUM(ins.Payment),0) + COALESCE(SUM(payAmt),0)) AS "$Total Collected",
COALESCE(SUM(pln.PlannedFee),0) AS "$Treatment Planned"
FROM referred ref
LEFT OUTER JOIN insurance_pay ins ON ref.PatNum = ins.PatNum
LEFT OUTER JOIN var_payments pay ON ref.PatNum = pay.PatNum
LEFT OUTER JOIN planned_proc pln ON ref.PatNum = pln.PatNum
LEFT OUTER JOIN comp_proc prd ON ref.PatNum = prd.PatNum
GROUP BY ref.RefSource
ORDER BY ref.RefSource;
DROP TABLE IF EXISTS insurance_pay;
DROP TABLE IF EXISTS planned_proc;
DROP TABLE IF EXISTS comp_proc;
DROP TABLE IF EXISTS var_payments;
DROP TABLE IF EXISTS referred;
Income for patients who are younger than a given age, defaults to 21, in a date range. - Uses date PAID as date criteria.
/*463 Income for patients who are younger than a given age, defaults to 21, in a date range. Uses date PAID as date criteria*/
SET @FromDate = '2010-03-01', @ToDate = '2010-03-31', @UnderAge=21, @ShowDetail=True;
SELECT FORMAT(AVG(Age),1) AS AverageAge, SUM(InsPayAmt) AS $TotInsPaid, SUM(PatPaid) AS $TotPatPaid,
SUM(InsPayAmt) + SUM(PatPaid) AS $TotPayments
FROM (
SELECT p.PatNum,
(CASE WHEN (YEAR(CURDATE())-YEAR(p.Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(p.Birthdate,5))<200
THEN(YEAR(CURDATE())-YEAR(p.Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(p.Birthdate,5)) ELSE 0 END) AS 'Age', SUM(cp.InsPayAmt) AS InsPayAmt, SUM(ps.SplitAmt) AS PatPaid
FROM patient p
LEFT JOIN paysplit ps ON ps.PatNum=p.PatNum AND (ps.DatePay BETWEEN @FromDate AND @ToDate)
LEFT JOIN claimproc cp ON p.PatNum=cp.PlanNum AND (cp.DateCP BETWEEN @FromDate AND @ToDate)
GROUP BY p.PatNum
HAVING (SUM(cp.InsPayAmt)>0 OR SUM(ps.SplitAmt)>0)) A
WHERE Age<@UnderAge;
New patients for a time span, with age at time of first visit. - New patient date based on active patients with completed procedure with fee>0.
/*464 New patients for a time span, with age at time of first visit*/
/*(new patient date based on active patients with completed procedure with fee>0)*/
/*Query code written/modified: 03/07/2018*/
SET @FromDate='2018-01-01', @ToDate='2018-01-31';
/*------ DO NOT MODIFY BELOW THIS LINE ------*/
SET @pos=0;
SELECT @pos:=@pos+1 AS NumberOfPatients,
a.PatNum,
a.FirstVisit,
a.AgeAtFirstVisit
FROM (
SELECT p.PatNum,
DATE_FORMAT(MIN(pl.ProcDate),'%m-%d-%Y') AS FirstVisit,
(CASE
WHEN TIMESTAMPDIFF(YEAR,p.Birthdate,MIN(pl.ProcDate)) < 120
THEN TIMESTAMPDIFF(YEAR,p.Birthdate,MIN(pl.ProcDate))
ELSE 0
END) AS 'AgeAtFirstVisit'
FROM patient p
INNER JOIN procedurelog pl
ON pl.PatNum = p.PatNum
AND pl.ProcStatus = 2 /*Complete*/
AND pl.ProcFee > 0 /*Has a fee*/
WHERE p.PatStatus = 0 /*Patient*/
GROUP BY p.PatNum
HAVING MIN(pl.ProcDate) BETWEEN @FromDate AND @ToDate
ORDER BY MIN(pl.ProcDate), p.LName, p.FName
)a;
Outstanding insurance claims for all providers (not including pre-authorizations). - The total is summed by carrier. Optional property to set the number of most recent days to ignore.
/*465 Outstanding insurance claims for all providers (not including pre-authorizations).
The total is summed by carrier. Optional property to set the number of most recent days to ignore.
Created by James Muir on 04/05/2010 for version 7.0. based off of the 'Outstanding Insurance Claims' report.
edited by nathan to also include outstanding payment expected*/
SET @DaysOld = 30; /* Set the number of days to ignore. Use zero to include all claims to present. */
SELECT CA.CarrierNum, CA.CarrierName, CA.Phone, SUM(C.ClaimFee) AS $SumOfFees, SUM(C.InsPayEst) AS $SumOfEstPayments
FROM claim C, insplan I, patient P, carrier CA
WHERE (C.PlanNum = I.PlanNum) AND (C.PatNum = P.PatNum) AND
(CA.CarrierNum = I.CarrierNum) AND (C.ClaimStatus='S') AND
(DATE(C.DateSent) <= DATE_ADD(DATE(NOW()), INTERVAL -@DaysOld DAY)) AND
(C.ClaimType <> 'PreAuth')
GROUP BY CA.CarrierNum
ORDER BY CA.CarrierName, I.PlanNum;
List of procedures over a specified date range where there is no signature associated with the procedure. -
/*466 List of procedures over a specified date range where there is no signature associated with the procedure. Written by James Muir on 04/22/2010 for version 7.0 */
SET @FromDate='2010-04-19' , @ToDate='2010-04-21';
SELECT A.PatNum, A.procdate, C.proccode, C.descript
FROM procedurelog A, procedurecode C
WHERE (A.procnum NOT IN (SELECT DISTINCT B.procnum FROM procnote B WHERE (TRIM(B.signature) <> ''))) AND
(A.procstatus = 2) AND (A.codenum = C.codenum) AND
(DATE(A.procdate) BETWEEN DATE(@FromDate) AND DATE(@ToDate))
ORDER BY A.PatNum, A.procdate;
Insurance Payments received for a specific carrier in a specified date range. -
/*467 Insurance Payments received for a specific carrier in a specified date range.
Written on 04/06/2010 by James Muir for version 7.0. */
SET @CarrierName='%BCBS%';/* Insert a specific carrier, or leave as '%%' for all carriers. */
SET @FromDate='2009-01-01', @ToDate='2011-01-31' ;/*change dates here*/
SELECT c.CarrierName AS 'Carrier', cp.PatNum AS 'Patient',
ROUND(cp.InsPayAmt, 2) AS 'InsPayment', cp.DateCP AS 'PaymentDate'
FROM insplan ip
INNER JOIN carrier c ON c.CarrierNum=ip.CarrierNum
INNER JOIN claimproc cp ON ip.PlanNum=cp.PlanNum
WHERE (DATE(cp.DateCP) BETWEEN DATE(@FromDate) AND DATE(@Todate)) AND
(c.CarrierName LIKE @CarrierName) AND
(cp.Status IN (1, 4))/*payment or supplemental payment*/
ORDER BY c.CarrierName, cp.PatNum, cp.DateCP;
Daily production and income report. - SEE REPLICATION WARNING for versions before 14.3.1. By Service Date instead of payment date: SO IT WILL CHANGE OVER TIME as payments for past procedures are made. Defaults to all providers.
/*468 Daily production and income report (as of version 7.0)
By Service Date instead of payment date: SO IT WILL CHANGE OVER TIME as payments for past procedures are made
Defaults to all providers*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @FromDate='2010-03-01' , @ToDate='2010-03-15';
SET @ProvAbbr='%%';/*Set to a particular provider abbreviation to limit to that provider*/
DROP TABLE IF EXISTS t1;
CREATE TABLE t1(
Date date,
Patient VARCHAR (30),
Description VARCHAR (30),
Prov VARCHAR(10),
$Prod double NOT NULL DEFAULT 0,
$Adjust double NOT NULL DEFAULT 0,
$WritOff double NOT NULL DEFAULT 0,
$TotProd double NOT NULL DEFAULT 0,
$PatIncome double NOT NULL DEFAULT 0,
$InsIncome double NOT NULL DEFAULT 0,
$TotIncome double NOT NULL DEFAULT 0);
/*Prod*/
INSERT INTO t1
SELECT pl.ProcDate AS Date,
CONCAT(p.LName, ', ',p.FName, ' ', p.MiddleI) AS Patient,
pc.AbbrDesc AS Description,
pr.Abbr AS Prov,
pl.ProcFee AS '$Prod',0,0,
pl.ProcFee AS '$TotProd',0,0,0
FROM procedurelog pl
INNER JOIN patient p ON p.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
INNER JOIN provider pr ON pr.ProvNum=pl.ProvNum
WHERE pl.ProcStatus=2 AND pl.ProcDate BETWEEN @FromDate AND @ToDate;
/*Adj*/
INSERT INTO t1
SELECT a.ProcDate AS Date,
CONCAT(p.LName, ', ',p.FName, ' ', p.MiddleI) AS Patient,
d.ItemName AS Description,
pr.Abbr AS Prov,0,
a.AdjAmt AS '$Adjust',0,
a.AdjAmt AS '$TotProd',0,0,0
FROM adjustment a
INNER JOIN patient p ON p.PatNum=a.PatNum
INNER JOIN provider pr ON pr.ProvNum=a.ProvNum
INNER JOIN definition d ON a.AdjType=d.DefNum
WHERE a.ProcDate BETWEEN @FromDate AND @ToDate;
/*PatInc*/
INSERT INTO t1
SELECT ps.ProcDate AS Date,
CONCAT(p.LName, ', ',p.FName, ' ', p.MiddleI) AS Patient,
d.ItemName AS Description,
pr.Abbr AS Prov,0,0,0,0,
ps.SplitAmt AS '$PatIncome',0,
ps.SplitAmt AS '$TotIncome'
FROM paysplit ps
INNER JOIN patient p ON p.PatNum=ps.PatNum
INNER JOIN provider pr ON pr.ProvNum=ps.ProvNum
INNER JOIN payment pa ON ps.PayNum=pa.PayNum
INNER JOIN definition d ON pa.PayType=d.DefNum
WHERE ps.ProcDate BETWEEN @FromDate AND @ToDate;
/*InsIncome, Writeoffs*/
INSERT INTO t1
SELECT cp.ProcDate AS Date,
CONCAT(p.LName, ', ',p.FName, ' ', p.MiddleI) AS Patient,
carrier.CarrierName AS Description,
pr.Abbr AS Prov,0,0,
-SUM(cp.WriteOff),-SUM(cp.WriteOff),0,SUM(cp.InsPayAmt),SUM(cp.InsPayAmt)
FROM claimproc cp
INNER JOIN patient p ON p.PatNum=cp.PatNum
INNER JOIN provider pr ON pr.ProvNum=cp.ProvNum
LEFT JOIN insplan ip ON ip.PlanNum=cp.PlanNum/*insurance plan*/
LEFT JOIN carrier ON carrier.CarrierNum=ip.CarrierNum
WHERE (cp.Status=1 OR cp.Status=4)/* add OR cp.Status=0) if you want to include anticipated writeoffs*/
AND cp.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY cp.ClaimPaymentNum,cp.PatNum;
SELECT * FROM t1 WHERE t1.Prov LIKE(@ProvAbbr) ORDER BY Date, Patient;
DROP TABLE IF EXISTS t1;
Monthly (summed by date) production and income report. - SEE REPLICATION WARNING for versions before 14.3.1. By Service Date instead of payment date: SO IT WILL CHANGE OVER TIME as payments for past procedures are made. Defaults to all providers.
/*469 Monthly (summed by date) production and income report (as of version 7.0)
By Service Date instead of payment date: SO IT WILL CHANGE OVER TIME as payments for past procedures are made
Defaults to all providers*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
/*Query code written/modified: 09/25/14*/
SET @FromDate='2014-09-01' , @ToDate='2014-09-30';
SET @ProvAbbr='%%';/*Set to a particular provider abbreviation to limit to that provider*/
DROP TABLE IF EXISTS t1;
CREATE TABLE t1(
DATE DATE,
Patient VARCHAR (30),
Description VARCHAR (30),
Prov VARCHAR(10),
$Prod DOUBLE NOT NULL DEFAULT 0,
$Adjust DOUBLE NOT NULL DEFAULT 0,
$WritOff DOUBLE NOT NULL DEFAULT 0,
$TotProd DOUBLE NOT NULL DEFAULT 0,
$PatIncome DOUBLE NOT NULL DEFAULT 0,
$InsIncome DOUBLE NOT NULL DEFAULT 0,
$TotIncome DOUBLE NOT NULL DEFAULT 0);
/*Prod*/
INSERT INTO t1
SELECT pl.ProcDate AS DATE,
CONCAT(p.LName, ', ',p.FName, ' ', p.MiddleI) AS Patient,
pc.AbbrDesc AS Description,
pr.Abbr AS Prov,
pl.ProcFee AS '$Prod',0,0,
pl.ProcFee AS '$TotProd',0,0,0
FROM procedurelog pl
INNER JOIN patient p ON p.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
INNER JOIN provider pr ON pr.ProvNum=pl.ProvNum
WHERE pl.ProcStatus=2
AND pl.ProcDate BETWEEN @FromDate AND @ToDate;
/*Adj*/
INSERT INTO t1
SELECT a.ProcDate AS DATE,
CONCAT(p.LName, ', ',p.FName, ' ', p.MiddleI) AS Patient,
d.ItemName AS Description,
pr.Abbr AS Prov,0,
a.AdjAmt AS '$Adjust',0,
a.AdjAmt AS '$TotProd',0,0,0
FROM adjustment a
INNER JOIN patient p ON p.PatNum=a.PatNum
INNER JOIN provider pr ON pr.ProvNum=a.ProvNum
INNER JOIN definition d ON a.AdjType=d.DefNum
WHERE a.ProcDate BETWEEN @FromDate AND @ToDate;
/*PatInc*/
INSERT INTO t1
SELECT ps.ProcDate AS DATE,
CONCAT(p.LName, ', ',p.FName, ' ', p.MiddleI) AS Patient,
d.ItemName AS Description,
pr.Abbr AS Prov,0,0,0,0,
ps.SplitAmt AS '$PatIncome',0,
ps.SplitAmt AS '$TotIncome'
FROM paysplit ps
INNER JOIN patient p ON p.PatNum=ps.PatNum
INNER JOIN provider pr ON pr.ProvNum=ps.ProvNum
INNER JOIN payment pa ON ps.PayNum=pa.PayNum
INNER JOIN definition d ON pa.PayType=d.DefNum
WHERE ps.ProcDate BETWEEN @FromDate AND @ToDate;
/*InsIncome, Writeoffs*/
INSERT INTO t1
SELECT cp.ProcDate AS DATE,
CONCAT(p.LName, ', ',p.FName, ' ', p.MiddleI) AS Patient,
carrier.CarrierName AS Description,
pr.Abbr AS Prov,0,0,
-SUM(cp.WriteOff),-SUM(cp.WriteOff),0,SUM(cp.InsPayAmt),SUM(cp.InsPayAmt)
FROM claimproc cp
INNER JOIN patient p ON p.PatNum=cp.PatNum
INNER JOIN provider pr ON pr.ProvNum=cp.ProvNum
LEFT JOIN insplan ip ON ip.PlanNum=cp.PlanNum/*insurance plan*/
LEFT JOIN carrier ON carrier.CarrierNum=ip.CarrierNum
WHERE (cp.Status=1 OR cp.Status=4)/* add OR cp.Status=0) if you want to include anticipated writeoffs*/
AND cp.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY cp.ProcDate,cp.ClaimPaymentNum,cp.PatNum;
SELECT DATE,
(CASE WHEN @ProvAbbr='%%' THEN 'ALL' ELSE Prov END) AS Prov,
SUM($Prod) $Production,
SUM($Adjust) $Adjust,
SUM($WritOff) $WriteOff,
SUM($TotProd) $TotProd,
SUM($PatIncome) $PatIncome,
SUM($InsIncome) $InsIncome,
SUM($TotIncome) $TotIncome
FROM t1 WHERE t1.Prov LIKE(@ProvAbbr)
GROUP BY DATE ORDER BY DATE;
DROP TABLE IF EXISTS t1;
Return firstname, lastname, email address for all patients that had a specified procedure completed in a given date range. -
/*470 return firstname, lastname, email address for all patients that had a specified procedure completed in a given date range*/
/*Query code written/modified: 05/02/2018*/
SET @FromDate='2018-01-01' , @ToDate='2018-01-31';
SET @Procedures=''; /*Enter items separated by a pipe ('|' without the quotes). For all leave blank as '' */
/* ------------ DO NOT MODIFY BELOW THIS LINE ------------ */
SET @Procedures=(CASE WHEN @Procedures='' THEN '^' ELSE CONCAT('^',REPLACE(@Procedures,'|','$|^'),'$') END);
SELECT p.FName,
p.LName,
p.Email,
GROUP_CONCAT(DISTINCT pc.ProcCode) AS 'Codes'
FROM patient p
INNER JOIN procedurelog pl
ON p.PatNum=pl.PatNum
AND pl.ProcDate BETWEEN @FromDate AND @ToDate -- Date limitation
AND pl.ProcStatus = 2 -- Complete
INNER JOIN procedurecode pc
ON pl.CodeNum= pc.CodeNum
AND pc.ProcCode REGEXP @Procedures -- Code limitation
GROUP BY p.PatNum
ORDER BY p.LName
Return firstname, lastname, email address and patient number for all patients that had a procedure in a list completed in a given date range. -
See Query 470
Treatment planned procedures of active patients with the treatment planned procedures matching a pattern. -
/*472 Treatment planned procedures of active patients with the treatment planned procedures matching a pattern*/
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count', CONCAT(LName, ', ',FName, ' ', MiddleI) AS Patient,
pc.ProcCode AS 'Code', abbrdesc AS 'Description', ToothNum, ProcFee
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
AND ProcStatus=1 AND PatStatus=0
AND (pc.ProcCode LIKE('Z%'))
ORDER BY patient.LName, patient.FName ASC;
Count of patients by Carrier who have procedures completed in date range with procedure count and gross production. -
/*473 Count of patients by Carrier who have procedures
completed in date range with procedure count and gross production*/
SET @FromDate='2010-01-01' , @ToDate='2010-03-31';
/*Adjust above Dates AS needed*/
SELECT carrier.CarrierName, COUNT(DISTINCT claimproc.PatNum) AS 'Patients',
SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) AS '$GrossProduction',
COUNT(pl.ProcNum) AS Procedures
FROM carrier
INNER JOIN insplan ON carrier.CarrierNum=insplan.CarrierNum
INNER JOIN claim ON insplan.PlanNum=claim.PlanNum
INNER JOIN claimproc ON claim.ClaimNum=claimproc.ClaimNum
INNER JOIN procedurelog pl ON claimproc.ProcNum=pl.ProcNum
INNER JOIN procedurecode ON pl.CodeNum=procedurecode.CodeNum
AND (pl.ProcDate BETWEEN @FromDate AND @ToDate)
AND ProcStatus=2
GROUP BY CarrierName
ORDER BY CarrierName;
Count of patients by billing type who have procedures . -
/*474 Count of patients by billing type who have procedures
completed in date range with procedure count and gross production*/
SET @FromDate='2010-01-01' , @ToDate='2010-03-31';
/*Adjust above Dates AS needed*/
SELECT p.BillingType, COUNT(DISTINCT p.PatNum) AS 'Patients',
SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) AS '$GrossProduction',
COUNT(pl.ProcNum) AS Procedures
FROM patient p
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum
INNER JOIN procedurecode ON pl.CodeNum=procedurecode.CodeNum
AND (pl.ProcDate BETWEEN @FromDate AND @ToDate)
AND ProcStatus=2
GROUP BY BillingType
ORDER BY BillingType;
List of patients with billing type and fee who have procedures completed in date range. -
/*475 List of patients with billing type and fee who have procedures
completed in date range*/
SET @FromDate='2010-05-24' , @ToDate='2010-05-24';
/*Adjust above Dates AS needed*/
SELECT p.BillingType, p.PatNum,pc.ProcCode AS 'Code', abbrdesc AS 'Description',
(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) AS '$GrossFee'
FROM patient p
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
AND (pl.ProcDate BETWEEN @FromDate AND @ToDate)
AND ProcStatus=2
ORDER BY p.LName, p.FName;
Version 7.5+ Outstanding insurance claims with date of birth and subscriber ID, by date of service (30 days or more by default) not including PreAuths. -
/*476 Version 7.5+ Outstanding insurance claims with date of birth and subscriber ID, by date of service (30 days or more by default) not including PreAuths*/
SELECT p.PatNum,
CONVERT(DATE_FORMAT(p.BirthDate,'%m/%d/%y'),CHAR)AS 'PatientDOB',
patsub.PatNum AS Subscriber,ins.SubscriberID,CONVERT(DATE_FORMAT(patsub.BirthDate,'%m/%d/%y'),CHAR) AS 'SubscriberDOB',
cl.DateService, ca.CarrierName, ca.Phone FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN patplan pp ON pp.InsSubNum=cl.InsSubNum
INNER JOIN inssub ins ON ins.InsSubNum=pp.InsSubNum
INNER JOIN patient patsub ON patsub.PatNum=ins.Subscriber
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE cl.ClaimStatus='S' AND
DateService<(CURDATE()-INTERVAL 30 DAY) AND
ClaimType<>'PreAuth'
ORDER BY ca.CarrierName,p.LName;
Treatment planned procedures that are not in a scheduled apt or unscheduled list or ASAP appointment. - Limit to active patients with valid zipcode or valid email, this query repeats patient information for each procedure. Change procedure codes by editing the list near the bottom of the query.
/*477 Treatment planned procedures that are not in a scheduled apt or unscheduled list or ASAP appointment.
Limit to active patients with valid zipcode or valid email, this query repeats patient information for each procedure.*/
/*Change procedure codes by editing the list near the bottom of the query.*/
SELECT LName,FName, Address,Address2, State, City, Zip, Email, /*we can comment out the address easily so you can print*/
pc.ProcCode as 'Code', AbbrDesc as 'Description', ToothNum,
pl.DateTP, ap.AptStatus, ProcFee
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
LEFT JOIN appointment ap ON pl.AptNum=ap.AptNum
WHERE (ISNULL(ap.AptNum) OR AptStatus NOT IN(1,2,3,4)) /*1 sched, 3 unsched, 2 complete 4 asap*/
AND ProcStatus=1 /*treatment planned*/ AND PatStatus=0 /*active patient*/
AND ProcCode IN('D3310','D3320','D3330', 'D0120')/*change the procedurecode list here, comma separated in single quotes*/
/*can also use ProcCode LIKE('D2%') to get all D2*** codes*/
AND (LENGTH(patient.Email)>6 OR LENGTH(patient.Zip)>4)/*valid email or zipcode*/
ORDER BY AptStatus, patient.LName, patient.FName ASC;
Patients who have treatment planned procedures that are not in a scheduled apt or unscheduled list or ASAP appointment. - Limit to active patients with valid zipcode or valid email. Change procedure codes by editing the list near the bottom of the query.
/*478 Patients who have treatment planned procedures that are not in a scheduled apt or unscheduled list or ASAP appointment
limit to active patients with valid zipcode or valid email*/
/*change procedure codes by editing the list near the bottom of the query*/
SELECT LName,FName, GROUP_CONCAT(pc.ProcCode) AS ProcCodes, Address,Address2, State, City, Zip, Email
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
LEFT JOIN appointment ap ON pl.AptNum=ap.AptNum
WHERE (ISNULL(ap.AptNum) OR AptStatus NOT IN(1,2,3,4)) /*1 sched, 3 unsched, 2 complete 4 asap*/
AND ProcStatus=1 /*treatment planned*/ AND PatStatus=0 /*active patient*/
AND ProcCode IN('D3310','D3320','D3330', 'D0120')/*change the procedurecode list here, comma separated in single quotes*/
/*can also use ProcCode LIKE('D2%') to get all D2*** codes*/
AND (LENGTH(patient.Email)>6 OR LENGTH(patient.Zip)>4)/*valid email or zipcode*/
GROUP BY patient.PatNum
ORDER BY AptStatus, patient.LName, patient.FName ASC;
Service Notes for patients with appointments scheduled (or ASAP) on a specified day. -
/*479 Service Notes for patients with appointments scheduled (or ASAP) on a specified day. */
SET @FromDate='2010-06-04';
SET @ToDate=@FromDate;
SELECT p.PatNum,pn.Service,ap.AptDateTime FROM patient p
INNER JOIN appointment ap ON p.PatNum=ap.PatNum
INNER JOIN patientnote pn ON p.PatNum=pn.PatNum
WHERE DATE(ap.AptDateTime) >= @FromDate
AND DATE(ap.AptDateTime) <= @ToDate
AND ap.AptStatus IN (1, 4);
Production and income report (as of version 7.0) summed by provider. - Counts insurance writeoffs by ins payment date, so assume that any PPOs are entered as Category Percentage. For all providers.
/*480 Production and income report (as of version 13.1) Summed by provider
counts insurance writeoffs by ins payment date, so assume that any PPOs are entered as Category Percentage
For all providers. Modified 01-23-2013 to account for capitation writeoffs in production amounts.
Modified 5-10-2013 to match the daily/monthly P&I report by Cameron.*/
SET @FromDate='2012-01-01' , @ToDate='2012-03-31';
SELECT @FromDate AS 'DateFrom', @ToDate AS 'DateTo',pv.Abbr,
SUM(CASE WHEN Trans.TranType='Prod' THEN Trans.TranAmount WHEN Trans.TranType='Cap' THEN Trans.Writeoff ELSE 0 END) AS $Production_,
SUM(CASE WHEN Trans.TranType='Adj' THEN Trans.TranAmount ELSE 0 END) AS $Adjustment_,
SUM(CASE WHEN Trans.TranType='Writeoff' THEN Trans.Writeoff ELSE 0 END) AS $Writeoff_,
SUM(CASE WHEN Trans.TranType IN('Prod','Adj') THEN Trans.TranAmount WHEN Trans.TranType IN('Writeoff','Cap') THEN Trans.Writeoff ELSE 0 END) AS $NetProd_,
SUM(CASE WHEN Trans.TranType='PatPay' THEN Trans.TranAmount ELSE 0 END) AS $PatIncome_,
SUM(CASE WHEN Trans.TranType IN('InsPay') THEN Trans.TranAmount ELSE 0 END) AS $InsIncome_,
SUM(CASE WHEN Trans.TranType IN('PatPay','InsPay') THEN Trans.TranAmount ELSE 0 END) AS $TotalIncome_
FROM (
/*Prod*/
SELECT 'Prod' AS TranType,pl.ProvNum,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) AS TranAmount,0 AS Writeoff
FROM procedurelog pl
WHERE pl.ProcStatus=2
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
UNION ALL
/*Adj*/
SELECT 'Adj' AS TranType,a.ProvNum,a.AdjAmt AS TranAmount,0 AS Writeoff
FROM adjustment a
WHERE a.AdjDate BETWEEN @FromDate AND @ToDate
UNION ALL
/*PatInc*/
SELECT 'PatPay' AS TranType,ps.ProvNum,ps.SplitAmt AS TranAmount,0 AS Writeoff
FROM paysplit ps
WHERE ps.IsDiscount=0 AND ps.DatePay BETWEEN @FromDate AND @ToDate
UNION ALL
/*InsIncome*/
SELECT 'InsPay' AS TranType,cp.ProvNum,cp.InsPayAmt AS TranAmount,0
FROM claimproc cp
INNER JOIN claimpayment cpm ON cp.ClaimPaymentNum=cpm.ClaimPaymentNum
WHERE cp.DateCP BETWEEN @FromDate AND @ToDate
AND cp.Status IN(1,4)
UNION ALL
/*Writeoff*/
SELECT 'Writeoff' AS TranType,cp.ProvNum,0 AS TranAmount,-cp.WriteOff AS Writeoff
FROM claimproc cp
WHERE cp.DateCP BETWEEN @FromDate AND @ToDate
AND cp.Status IN(1,4)
UNION ALL
/*Capitation*/
SELECT 'Cap' AS TranType,cp.ProvNum,cp.InsPayAmt AS TranAmount,-cp.Writeoff AS Writeoff
FROM claimproc cp
WHERE cp.Status=7
AND cp.DateCP BETWEEN @FromDate AND @ToDate
) Trans
INNER JOIN provider pv ON pv.ProvNum=Trans.ProvNum
GROUP BY Trans.ProvNum
ORDER BY pv.Abbr;
Calculate current or historical accounts receivable, collectible, outstanding insurance estimates for a single provider. - SEE REPLICATION WARNING for versions before 14.3.1. When compared to an aging report, the ins estimate includes ins FROM accounts with both positive and negative balances, this is like 272 but for a single provider.
/*481 Calculate current or historical accounts receivable, collectible, outstanding insurance estimates for a single provider. When compared to an aging report, the ins estimate includes ins FROM accounts with both positive
and negative balances, this is like 272 but for a single provider, note that these number will not match the account numbers as we are filtering out other providers
and payment plans are ignored*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @AsOf=CURDATE(); /*use this instead to always specific date SET @AsOf='2010-06-15'; */
SET @ProvAbbr='DON'; /*specify provider here, replace VSP-M with DrSmith etc*/
/*first create transaction table*/
DROP TABLE IF EXISTS tmp1, tmp2, tmp3, tmp4;
CREATE TABLE tmp1
(PatNum INT DEFAULT 0,
TranDate DATE DEFAULT '0001-01-01',
TranAmount DOUBLE DEFAULT 0);
/*Get the completed procedure dates and charges for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount
FROM procedurelog pl INNER JOIN provider pr ON pr.ProvNum=pl.ProvNum
WHERE pl.ProcStatus=2 AND pr.Abbr=@ProvAbbr;
/*Paysplits for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount
FROM paysplit ps INNER JOIN provider pr ON pr.ProvNum=ps.ProvNum
WHERE /* ps.PayPlanNum=0 we include even splits attached to payment plans as this is for a particular provider and payment plans do not specify provider*/
pr.Abbr=@ProvAbbr;
/*Get the adjustment dates and amounts for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount
FROM adjustment a INNER JOIN provider pr ON pr.ProvNum=a.ProvNum
WHERE pr.Abbr=@ProvAbbr;
/*Claim payments and capitation writeoffs for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT cp.PatNum PatNum,
cp.DateCp TranDate,-cp.InsPayAmt-cp.Writeoff TranAmount
FROM claimproc cp INNER JOIN provider pr ON pr.ProvNum=cp.ProvNum
WHERE cp.Status IN (1,4,5,7)
AND pr.Abbr=@ProvAbbr;/*received, supplemental, CapClaim or CapComplete*/
/*Payment plan principal for the entire office history on or before the given date
since we are looking for a particular provider only, payment plans are not relevant
but this will possibly give information that will conflict with the full aging report, which includes these amounts
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT pp.PatNum PatNum,
pp.PayPlanDate TranDate,
-pp.CompletedAmt TranAmount
FROM payplan pp INNER JOIN provider pr ON pr.ProvNum=pp.ProvNum
;*/
/*now we need to include the anticipated insurance (sum of payments and writeoffs)
note that if you use PPO type, your anticipated writeoff numbers will have updated to
match your actual writeoff numbers... your best bet is to keep backups or paper copies of your
reports if that change is bothersome */
/*Now Note that as we get these numbers we are summing by family, when really we
are looking for a grand total, this is to make it easier to get the details should we need them
FROM the tmp tables*/
CREATE TABLE tmp3 SELECT p.Guarantor,SUM(cp.InsPayEst) InsPayEst,
(CASE WHEN ISNULL(SUM(cp.Writeoff)) THEN 0 ELSE SUM(cp.WriteOff) END) WriteOff
FROM patient p INNER JOIN claimproc cp ON cp.PatNum=p.PatNum
INNER JOIN provider pr ON pr.ProvNum=cp.ProvNum
WHERE ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR /* still not received and procedure completed before the date*/
(cp.Status IN(1,4) AND cp.DateCP>@AsOf AND cp.ProcDate<=@AsOf)) /*was received after the date of interes and completed before it*/
/*AND p.PatStatus NOT IN(4,3) not archived*/
AND pr.Abbr=@ProvAbbr
GROUP BY p.Guarantor;
CREATE TABLE tmp2
SELECT Guarantor, SUM(TranAmount) AS 'FamBal' FROM patient
INNER JOIN tmp1 ON tmp1.PatNum=Patient.PatNum
WHERE TranDate<=@AsOf
GROUP BY Guarantor;
CREATE TABLE tmp4
SELECT 'AccountsReceivable' AS 'Description', SUM(FamBal) '$Value' FROM tmp2
WHERE FamBal>0
UNION ALL
SELECT 'AccountsPayable' AS 'Description', SUM(FamBal) '$Value' FROM tmp2
WHERE FamBal<0
UNION ALL
SELECT 'TotProviderBalance' AS 'Description', SUM(FamBal) '$Value' FROM tmp2
UNION ALL
SELECT 'TotInsPayEst' AS 'Description', SUM(InsPayEst) '$Value' FROM tmp3
UNION ALL
SELECT 'TotWriteOffEst' AS 'Description', SUM(WriteOff) '$Value' FROM tmp3
UNION ALL
SELECT 'TotPatPortEst' AS 'Description',
(SUM(tmp2.FamBal)-SUM(tmp3.InsPayEst)-SUM(tmp3.WriteOff)) AS '$Value'
FROM tmp2 LEFT JOIN tmp3 ON tmp2.Guarantor=tmp3.Guarantor;
SELECT * FROM tmp4;
DROP TABLE IF EXISTS tmp1, tmp2, tmp3, tmp4;
Family level 'aging' for a single provider. - SEE REPLICATION WARNING for versions before 14.3.1. Note that these number will not match the account numbers as we are filtering out other providers and payment plans are ignored.
/*482 Family level 'aging' for a single provider, note that these number will not match the account numbers as we are filtering out other providers
and payment plans are ignored*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @AsOf=CURDATE(); /*use this instead to always specific date SET @AsOf='2010-06-15'; */
SET @ProvAbbr='VSP-M'; /*specify provider here, replace VSP-M with DrSmith etc*/
/*first create transaction table*/
DROP TABLE IF EXISTS tmp1, tmp2, tmp3;
CREATE TABLE tmp1
(PatNum INT DEFAULT 0,
TranDate DATE DEFAULT '0001-01-01',
TranAmount DOUBLE DEFAULT 0);
/*Get the completed procedure dates and charges for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount
FROM procedurelog pl INNER JOIN provider pr ON pr.ProvNum=pl.ProvNum
WHERE pl.ProcStatus=2 AND pr.Abbr=@ProvAbbr;
/*Paysplits for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount
FROM paysplit ps INNER JOIN provider pr ON pr.ProvNum=ps.ProvNum
WHERE /* ps.PayPlanNum=0 we include even splits attached to payment plans as this is for a particular provider and payment plans do not specify provider*/
pr.Abbr=@ProvAbbr;
/*Get the adjustment dates and amounts for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount
FROM adjustment a INNER JOIN provider pr ON pr.ProvNum=a.ProvNum
WHERE pr.Abbr=@ProvAbbr;
/*Claim payments and capitation writeoffs for the entire office history on or before the given date*/
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT cp.PatNum PatNum,
cp.DateCp TranDate,-cp.InsPayAmt-cp.Writeoff TranAmount
FROM claimproc cp INNER JOIN provider pr ON pr.ProvNum=cp.ProvNum
WHERE cp.Status IN (1,4,5,7)
AND pr.Abbr=@ProvAbbr;/*received, supplemental, CapClaim or CapComplete*/
/*Payment plan principal for the entire office history on or before the given date
since we are looking for a particular provider only, payment plans are not relevant
but this will possibly give information that will conflict with the full aging report, which includes these amounts
INSERT INTO tmp1 (PatNum,TranDate,TranAmount)
SELECT pp.PatNum PatNum,
pp.PayPlanDate TranDate,
-pp.CompletedAmt TranAmount
FROM payplan pp INNER JOIN provider pr ON pr.ProvNum=pp.ProvNum
;*/
/*now we need to include the anticipated insurance (sum of payments and writeoffs)
note that if you use PPO type, your anticipated writeoff numbers will have updated to
match your actual writeoff numbers... your best bet is to keep backups or paper copies of your
reports if that change is bothersome */
/*Now Note that as we get these numbers we are summing by family, when really we
are looking for a grand total, this is to make it easier to get the details should we need them
FROM the tmp tables*/
CREATE TABLE tmp3 SELECT p.Guarantor,SUM(cp.InsPayEst) InsPayEst,
(CASE WHEN ISNULL(SUM(cp.Writeoff)) THEN 0 ELSE SUM(cp.WriteOff) END) WriteOff
FROM patient p INNER JOIN claimproc cp ON cp.PatNum=p.PatNum
INNER JOIN provider pr ON pr.ProvNum=cp.ProvNum
WHERE ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR /* still not received and procedure completed before the date*/
(cp.Status IN(1,4) AND cp.DateCP>@AsOf AND cp.ProcDate<=@AsOf)) /*was received after the date of interes and completed before it*/
/*AND p.PatStatus NOT IN(4,3) not archived*/
AND pr.Abbr=@ProvAbbr
GROUP BY p.Guarantor;
CREATE TABLE tmp2
SELECT Guarantor, SUM(TranAmount) AS 'FamBal' FROM patient
INNER JOIN tmp1 ON tmp1.PatNum=Patient.PatNum
WHERE TranDate<=@AsOf
GROUP BY Guarantor;
SELECT tmp2.Guarantor,tmp2.Guarantor AS 'GuarActNumber', tmp2.FamBal AS $FamBalance, tmp3.InsPayEst AS $FamInsPayEst, tmp3.WriteOff AS $FamWriteOff,
tmp2.FamBal-tmp3.InsPayEst-tmp3.WriteOff AS '$PatPortEst'
FROM tmp2 LEFT JOIN tmp3 ON tmp2.Guarantor=tmp3.Guarantor
WHERE tmp2.FamBal>.005 OR tmp2.FamBal<-.005 ;
DROP TABLE IF EXISTS tmp1, tmp2, tmp3;
Summary of payments by payment type for date range. -
/*483 Summary of payments by payment type for date range.*/
SET @FromDate='2010-01-01' , @ToDate='2010-03-31';
SELECT definition.ItemName AS PaymentType,
SUM(paysplit.SplitAmt) AS $PaymentAmt
FROM payment,definition,paysplit
WHERE paysplit.DatePay BETWEEN @FromDate AND @ToDate
AND payment.PayNum=paysplit.PayNum
AND definition.DefNum=payment.PayType
GROUP BY payment.PayType
UNION
SELECT 'Ins Checks',
SUM(claimproc.InsPayAmt) AS InsAmt
FROM claimproc
WHERE claimproc.DateCP BETWEEN @FromDate AND @ToDate
AND (claimproc.Status=1 OR claimproc.Status=4);
Procedures with received insurance claims in given date range where insurance paid zero. -
/*484 Procedures with received insurance claims in given date range where insurance paid zero*/
SET @FromDate='2009-01-01' , @ToDate='2010-03-31';
SELECT cp.PatNum, cp.ProcDate, pc.ProcCode, pc.AbbrDesc AS 'Procedure',p.Abbr AS 'Provider', pl.ProcFee
FROM claimproc cp
INNER JOIN procedurelog pl ON pl.ProcNum=cp.ProcNum
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
INNER JOIN provider p ON pl.ProvNum=p.ProvNum
INNER JOIN patient pat ON pat.PatNum=cp.PatNum
WHERE inspayamt=0 AND cp.ProcDate BETWEEN @FromDate AND @ToDate
AND cp.InsPayAmt=0 AND (cp.Status=1 OR cp.Status=4)
ORDER BY pat.LName, pat.FName, cp.ProcDate;
Procedure fee production and the production where a given fee schedule is used, summed by provider -
/*485 Procedure fee production and the production where a given fee schedule is used, summed by provider*/
/*Fee schedule in example is for fee schedule named 'Standard'.*/
SET @FromDate='2016-01-01' , @ToDate='2016-01-31';
SELECT p.Abbr AS Provider,
SUM(f.Amount*(pl.UnitQty+pl.BaseUnits)) AS '$SumOtherFeeSched',
SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) AS '$SumFeesCharged',
SUM((f.Amount-pl.Procfee)*(pl.UnitQty+pl.BaseUnits)) AS '$SumFeeDiff'
FROM procedurelog pl
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
INNER JOIN fee f ON pc.CodeNum=f.CodeNum
INNER JOIN feesched fs ON f.FeeSched=fs.FeeSchedNum
AND fs.Description='Standard' /*replace 'Standard' with fee sched name*/
INNER JOIN provider p ON p.ProvNum=pl.ProvNum
WHERE (ProcDate BETWEEN @FromDate AND @ToDate)
GROUP BY p.Abbr;
Count of communication log entries by type for a date range. -
/*486 Count of communication log entries by type for a date range.*/
SET @FromDate='2010-01-01' , @ToDate='2010-01-31';/*or use CURDATE()*/
SELECT d.ItemName,count(*) FROM commlog c
INNER JOIN definition d ON c.CommType=d.DefNum
WHERE DATE(c.CommDateTime) BETWEEN @FromDate AND @ToDate
GROUP BY d.ItemName;
Outstanding insurance claims by Date of Service for a date range not including Preauths with fee total and insurance payment estimate. -
/*487 Outstanding insurance claims by Date of Service for a date range not including Preauths with fee total and insurance payment estimate*/
SET @ServiceFromDate='2009-01-01' , @ServiceToDate='2010-03-31';
SELECT cl.PatNum,cl.DateService,cl.DateSent, cl.ClaimFee, cl.InsPayEst, ca.CarrierName, ca.Phone FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE cl.ClaimStatus='S' AND
(DateService BETWEEN @ServiceFromDate AND @ServiceToDate)
AND ClaimType<>'PreAuth'
ORDER BY cl.DateService;
List of patients (inactive and active) who were last seen in a given date range, who have a patient balance of $50 or less, who have no appointment scheduled with procedures in it. - SEE REPLICATION WARNING for versions before 14.3.1. Returns patient name, balance, family balance, last seen date, address, number of procedures ever completed.
/*488 List of patients (inactive and active) who were last seen in a given date range, who have a patient balance of $50 or less, who have no appointment scheduled with procedures in it. Returns patient name, balance, family balance, last seen date, address, number of procedures ever completed*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @LastSeenFromDate='2006-06-30' , @LastSeenToDate='2010-01-01';
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp SELECT patient.PatNum,patient.LName, patient.FName,
(SELECT COUNT(apl.ProcNum)
FROM appointment a
LEFT JOIN procedurelog apl ON apl.AptNum=a.AptNum
WHERE a.PatNum=patient.PatNum AND a.AptStatus=1 AND DATE(a.AptDateTime)>=CurDate() /*LEFT JOIN appointments*/
) AS SchedProcCount,
DATE_FORMAT(MAX(procedurelog.ProcDate),'%m/%d/%Y') AS 'LastVisit', patient.EstBalance AS '$PatBalance_', g.BalTotal,
patient.Address, patient.Address2, patient.City, patient.State, patient.Zip
FROM patient
INNER JOIN procedurelog ON procedurelog.PatNum=patient.PatNum
INNER JOIN patient g ON patient.Guarantor=g.PatNum
WHERE procedurelog.ProcStatus=2
AND (patient.PatStatus=0 OR patient.PatStatus=1) /*active or inactive patients*/
AND patient.EstBalance<=50 /*limit to $50 or less balance*/
GROUP BY procedurelog.PatNum
ORDER BY patient.LName, patient.FName;
SELECT tmp.LName, tmp.FName, tmp.LastVisit, $PatBalance_, tmp.BalTotal AS $BalTotal_,
tmp.Address, tmp.Address2, tmp.City, tmp.State, tmp.Zip FROM tmp
WHERE (LastVisit>@LastSeenFromDate OR LastVisit<@LastSeenToDate)
AND SchedProcCount=0/* makes sure there are procs in the apt if it is scheduled in the future, those patients are then not included
A temp table has to be used to put the criteria on the subselect query that creates SchedProcCount*/;
DROP TABLE IF EXISTS tmp;
Broken Appointment Count by Clinic (and percentage of broken compared to all completed and broken apts) with totals at bottom. - NOTE: This only includes broken apts where there is a corresponiding adjustment type where it (adj) is on same or previous date as apt where adjustment type description contains string 'broken'.
/*489 Broken Appointment Count by Clinic (and percentage of broken compared to all completed and broken apts) with totals at bottom
NOTE: This only includes broken apts where there is a corresponiding adjustment type where it (adj)
is on same or previouss date as apt where adjustment type description contains string 'broken'*/
SET @AptFromDate='2010-06-25' , @AptToDate='2010-07-05';
SELECT A.Clinic, IFNULL(SUM(Complete),0) AS '#Complete', IFNULL(SUM(Broken),0) AS '#Broken', FORMAT(100*IFNULL(SUM(Broken),0)/(IFNULL(SUM(Broken),0)+IFNULL(SUM(Complete),0)),2) AS '%Broken' FROM (SELECT IFNULL(c.Description,'None') AS Clinic, COUNT(*) AS Complete FROM appointment a
LEFT JOIN clinic c ON c.ClinicNum=a.ClinicNum WHERE a.AptStatus=2 /*Complete*/
AND (DATE(a.AptDateTime) BETWEEN @AptFromDate AND @AptToDate) GROUP BY a.ClinicNum)
A
LEFT JOIN
(SELECT IFNULL(c.Description,'None') AS Clinic, COUNT(*) AS Broken FROM appointment a LEFT JOIN clinic c ON c.ClinicNum=a.ClinicNum WHERE a.AptStatus=5 /*Broken*/
AND (DATE(a.AptDateTime) BETWEEN @AptFromDate AND @AptToDate)
AND
(SELECT COUNT(*) FROM adjustment ad INNER JOIN definition d ON d.DefNum=ad.AdjType
WHERE a.PatNum=ad.PatNum AND ad.AdjDate<=DATE(a.AptDateTime) AND ad.AdjDate>=(DATE(a.AptDateTime)-INTERVAL 1 DAY) AND d.ItemName LIKE('%BROKEN%') >=1) GROUP BY a.ClinicNum)
B ON A.Clinic=B.Clinic GROUP BY A.Clinic WITH ROLLUP;
New patient count by clinic. - Using date of AptDateTime for appointment associated with first completed procedure as criteria for new patient, uses appointment clinic number (also see #104 for a similar query defined slightly differently).
/*490 New patient count by clinic, using date of AptDateTime for appointment associated with first completed procedure as criteria for new patient, uses appointment clinic number (also see #104 for a similar query defined slightly differently). */
SET @FromDate='2011-01-01' , @ToDate='2011-02-28';
(SELECT IFNULL(c.Description,'None') AS 'Clinic', IFNULL(COUNT(DISTINCT B.PatNum),0) AS 'Patients'
FROM (SELECT a.AptDateTime, pl.PatNum, a.ClinicNum, (SELECT MIN(pl2.ProcDate) FROM procedurelog pl2 WHERE pl2.PatNum=pl.PatNum and pl2.ProcStatus=2) AS DateFirstProc
FROM appointment a
INNER JOIN procedurelog pl ON pl.AptNum=a.AptNum
WHERE pl.ProcStatus=2
AND DATE(a.AptDateTime) BETWEEN @FromDate AND @ToDate
GROUP BY pl.PatNum) B
LEFT JOIN clinic c ON B.ClinicNum=c.ClinicNum
WHERE DATE(B.DateFirstProc) BETWEEN @FromDate AND @ToDate
GROUP BY c.Description)
UNION ALL
(SELECT Concat('Total: ', @FromDate, ' to ', @ToDate) AS 'Clinic',
(SELECT COUNT(DISTINCT B.PatNum)
FROM (SELECT pl.PatNum, a.ClinicNum, (SELECT MIN(pl2.ProcDate) FROM procedurelog pl2 WHERE pl2.PatNum=pl.PatNum and pl2.ProcStatus=2) AS DateFirstProc
FROM appointment a
INNER JOIN procedurelog pl ON pl.AptNum=a.AptNum
WHERE pl.ProcStatus=2
AND DATE(a.AptDateTime) BETWEEN @FromDate AND @ToDate
GROUP BY pl.PatNum) B));
Find medical eclaims sent in date range. -
/*491 Find medical eclaims sent in date range */
SET @FromDate='2010-07-01' , @ToDate='2010-07-31';
SELECT c.PatNum, c.DateSent, c.DateService, e.Etype, e.DateTimeTrans, ca.CarrierName FROM etrans e
INNER JOIN claim c on c.ClaimNum=e.ClaimNum
INNER JOIN insplan i ON i.PlanNum=c.PlanNum
INNER JOIN carrier ca ON i.CarrierNum=ca.CarrierNum
INNER JOIN patient p ON c.PatNum=p.PatNum
WHERE i.IsMedical=1 AND
c.DateSent BETWEEN @FromDate AND @ToDate
ORDER BY p.LName, p.FName, c.DateSent DESC;
Active patients who have not had a particular procedure completed in date range. -
/*492 Active patients who have not had a particular procedure(s) completed in date range */
/*Query code written/modified: 12/28/2017*/
SET @FromDate='2017-01-01', @ToDate='2017-12-31';
SET @Codes='D0150|D0140'; /*Enter codes separated by a pipe ('|' without the quotes). For all leave blank as '' */
/*DO NOT MODIFY BELOW THIS LINE*/
SET @Codes=(CASE WHEN @Codes='' THEN '^' ELSE CONCAT('^',REPLACE(@Codes,'|','$|^'),'$') END);
SELECT patient.PatNum AS PatientID, CONCAT(patient.LName, ', ',patient.FName, ' ', patient.MiddleI) AS Patient
FROM patient
LEFT JOIN (
SELECT pl.PatNum, pl.CodeNum FROM procedurelog pl
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
WHERE pl.ProcStatus=2
AND pc.ProcCode REGEXP @Codes
AND (pl.ProcDate BETWEEN @FromDate AND @ToDate)
) procs ON patient.PatNum=procs.PatNum
WHERE ISNULL(procs.CodeNum)
AND patient.PatStatus=0
ORDER BY patient.LName, patient.FName ASC;
Get all fees for all or many fee schedules, takes a lot of manual editing. See Note for instructions - ADVANCED users only. To get your fee schedule names and numbers, run this query : /*Get Fee Schedule Name and Number*/ SELECT FeeSchedNum AS 'FeeNum', Description FROM feesched WHERE IsHidden = 0
/*493 Get all fees for all or many fee schedules, ADVANCED users only. Run this query :
SELECT FeeSchedNum AS 'FeeNum', Description FROM feesched
WHERE IsHidden = 0;
then in the query below replace the numbers where it says: AND fee.FeeSched='53' with the numbers from the above query and replace the names at the end of each line with the corresponding names from your fee schedules.
*/
SELECT pc.ProcCode, /*edit the names and fee schedule numbers to match customers situation*/
(SELECT fee.Amount FROM fee WHERE fee.CodeNum=pc.CodeNum AND fee.FeeSched='53') AS '$ Standard',
(SELECT fee.Amount FROM fee WHERE fee.CodeNum=pc.CodeNum AND fee.FeeSched='316') AS '$ Aetna',
(SELECT fee.Amount FROM fee WHERE fee.CodeNum=pc.CodeNum AND fee.FeeSched='336') AS '$ Anthem Blue',
(SELECT fee.Amount FROM fee WHERE fee.CodeNum=pc.CodeNum AND fee.FeeSched='334') AS '$ DeCare',
(SELECT fee.Amount FROM fee WHERE fee.CodeNum=pc.CodeNum AND fee.FeeSched='238') AS '$ Delta Dental',
(SELECT fee.Amount FROM fee WHERE fee.CodeNum=pc.CodeNum AND fee.FeeSched='337') AS '$ Dentemax',
(SELECT fee.Amount FROM fee WHERE fee.CodeNum=pc.CodeNum AND fee.FeeSched='303') AS '$ First Dental Health',
(SELECT fee.Amount FROM fee WHERE fee.CodeNum=pc.CodeNum AND fee.FeeSched='312') AS '$ Guardian',
(SELECT fee.Amount FROM fee WHERE fee.CodeNum=pc.CodeNum AND fee.FeeSched='305') AS '$ Metlife',
(SELECT fee.Amount FROM fee WHERE fee.CodeNum=pc.CodeNum AND fee.FeeSched='335') AS '$ Principal',
(SELECT fee.Amount FROM fee WHERE fee.CodeNum=pc.CodeNum AND fee.FeeSched='306') AS '$ United Concordia',
(SELECT fee.Amount FROM fee WHERE fee.CodeNum=pc.CodeNum AND fee.FeeSched='239') AS '$ WellPoint',
AbbrDesc,Descript
FROM procedurecode pc
ORDER BY pc.ProcCode;
Percentage and counts of new patients who have had additional work scheduled or completed other than D0* and D1* who were new in given date range. - SEE REPLICATION WARNING for versions before 14.3.1.
/*494 Percentage and counts of new patients who have had additional work scheduled or completed other than D0* and D1*
who were new in given date range*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @FromDate='2010-01-01' , @ToDate='2010-03-31';/*change dates here*/
/*count of patients who have treatment planned or completed procedures that are in another scheduled apt or completed appointment who were FIRST seen in a given date range AND count of total new patients in that date range
this will change over time as the patients may schedule work that had not previously*/
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp(
SELECT PatNum, FirstVisit, /*this third column Future Procs is work scheduled or completed to be after the first apt*/
(SELECT COUNT(*) FROM procedurelog pl
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
INNER JOIN appointment ap ON pl.AptNum=ap.AptNum AND ap.AptStatus IN(1,2,4) /*1 sched 2 complete 4 asap*/
WHERE A.PatNum=pl.PatNum AND DATE(ap.AptDateTime)>A.FirstVisit /*After FirstVisit*/
AND pc.ProcCode NOT LIKE('D1%') AND pc.ProcCode NOT LIKE('D0%')
GROUP BY a.PatNum) AS 'FutureProcs'
FROM (SELECT p.PatNum, DATE(MIN(pl.ProcDate)) AS 'FirstVisit'
FROM patient p
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum AND pl.ProcStatus=2/*complete*/
WHERE PatStatus=0
GROUP BY p.PatNum
HAVING DATE(MIN(pl.ProcDate)) BETWEEN @FromDate AND @ToDate
) A);
SELECT (SELECT COUNT(*) FROM tmp) AS NewPatients,
(SELECT COUNT(*) FROM tmp WHERE FutureProcs>0) AS WorkScheduled,
FORMAT((100*(SELECT COUNT(*) FROM tmp WHERE FutureProcs>0)/(SELECT COUNT(*) FROM tmp)),1) AS '%WorkScheduled';
DROP TABLE IF EXISTS tmp;
List of New patients with count of additional work scheduled or completed other than D0* and D1* who were new in given date range. - This will change over time as the patients may schedule work that had not previously.
/*495 List of New patients with count of additional work scheduled or completed other than D0* and D1*
who were new in given date range*/
SET @FromDate='2010-01-01' , @ToDate='2010-03-31';/*change dates here*/
/*this will change over time as the patients may schedule work that had not previously*/
SELECT PatNum, DateFirstVisit, /*this third column Future Procs is work scheduled or completed to be after the first apt*/
(SELECT COUNT(*) FROM procedurelog pl
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
INNER JOIN appointment ap ON pl.AptNum=ap.AptNum AND ap.AptStatus IN(1,2,4) /*1 sched 2 complete 4 asap*/
WHERE A.PatNum=pl.PatNum AND DATE(ap.AptDateTime)>A.DateFirstVisit /*After FirstVisit*/
AND pc.ProcCode NOT LIKE('D1%') AND pc.ProcCode NOT LIKE('D0%')
GROUP BY a.PatNum) AS 'Procs Sched/Compl'
FROM (SELECT p.PatNum, DATE(MIN(pl.ProcDate)) AS 'DateFirstVisit'
FROM patient p
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum AND pl.ProcStatus=2/*complete*/
WHERE PatStatus=0
GROUP BY p.PatNum
HAVING DATE(MIN(pl.ProcDate)) BETWEEN @FromDate AND @ToDate
) A;
New Patient Report defined by FirstVisit date field, like old new patient report, can be used predictively. - For Versions 17.1 and greater. Please update your version accordingly
/*496 New Patient Report defined by FirstVisit date field, like old new patient report, can be used predictively*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/16/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2018-01-01' , @ToDate='2018-01-31';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count',
newpats.*
FROM (
SELECT p.PatNum, DateFirstVisit,
(
SELECT SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits))
FROM procedurelog pl
WHERE p.PatNum=pl.PatNum
AND DATE(pl.ProcDate)=DATE(p.DateFirstVisit)
AND pl.ProcStatus=2 /*Completed*/
) AS '$VisitCharged',
(
SELECT CONCAT(r.LName, ',', r.FName) AS RefFName
FROM referral r
LEFT JOIN refattach ra ON r.ReferralNum=ra.ReferralNum
WHERE p.PatNum=ra.PatNum
AND ra.RefType = 1 /*RefFrom*/
GROUP BY ra.PatNum
) AS 'Referral Name'
FROM patient p
WHERE
DATE(p.DateFirstVisit) BETWEEN @FromDate AND @ToDate
ORDER BY DateFirstVisit, p.LName
)newpats;
Insurance Preauths received where procedures is complete and was completed in given date range. - Shows Patient's name, procedure code, procedure fee, date recieved and date completed, ins pay estimate, carrier name, ordered by procedure date descending.
/*497 Insurance Preauths received where procedures is complete and was completed in given date range, shows Patient's name, procedure code, procedure fee, date recieved and date completed, ins pay estimate, carrier name, ordered by procedure date descending*/
SET @FromDate='2000-10-01' , @ToDate='2020-03-31';
SELECT pl.PatNum,ProcCode,ProcFee,c.DateReceived, pl.ProcDate, cp.InsPayEst, ca.CarrierName
FROM procedurelog pl
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
INNER JOIN claimproc cp ON cp.ProcNum=pl.ProcNum
INNER JOIN claim c on c.ClaimNum=cp.ClaimNum
INNER JOIN insplan i ON i.PlanNum=c.PlanNum
INNER JOIN carrier ca ON i.CarrierNum=ca.CarrierNum
WHERE pl.ProcStatus=2/*complete*/
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
AND c.ClaimStatus='R' /*received*/
AND c.ClaimType='PreAuth'
ORDER BY pl.ProcDate DESC;
Production and Income by procedure, for a service date range, summed by patient and service date. - SEE REPLICATION WARNING for versions before 14.3.1. Only works if you put patient payment splits by procedure.
/*498 Production and Income by procedure, for a service date range, summed by patient and service date
only works if you put patient payment splits by procedure*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @ServiceFromDate='2010-06-01' , @ServiceToDate='2010-06-03';
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp /*for speed, otherwise join size too large*/
SELECT pl.PatNum,pl.ProcDate,pl.ProcNum,
pr.Abbr, (pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) AS 'VisitFee',
(SELECT SUM(ps.SplitAmt) FROM paysplit ps WHERE ps.ProcNum>0 AND ps.ProcNum=pl.ProcNum) AS 'PatPaid',
(SELECT SUM(cp.InsPayAmt) FROM claimproc cp WHERE cp.ProcNum>0 AND cp.ProcNum=pl.ProcNum) AS 'InsPaid'
FROM procedurelog pl
INNER JOIN provider pr ON pr.ProvNum=pl.ProvNum
WHERE pl.ProcStatus=2 AND pl.ProcDate BETWEEN @ServiceFromDate AND @ServiceToDate
/*AND pr.Abbr LIKE('%03%')*/;
SELECT tmp.PatNum, tmp.ProcDate,tmp.Abbr,
SUM(VisitFee) AS $VisitFee,
SUM(PatPaid) AS $PatientPaid_,
SUM(InsPaid) AS $InsurancePaid_,
IFNULL(SUM(VisitFee),0)-IFNULL(SUM(PatPaid),0)-IFNULL(SUM(InsPaid),0) AS $RemainingBal_
FROM tmp
INNER JOIN patient p ON tmp.PatNum=p.PatNum
GROUP BY PatNum, ProcDate
ORDER BY LName, ProcDate;
DROP TABLE IF EXISTS tmp;
Production and Income for a service date range, summed by provider. - SEE REPLICATION WARNING for versions before 14.3.1. Only works if you put patient payment splits by procedure.
/*499 Production and Income for a service date range, summed by provider
only works if you put patient payment splits by procedure*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @ServiceFromDate='2017-08-01' , @ServiceToDate='2017-08-31';
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp /*for speed, otherwise join size too large*/
SELECT pl.PatNum,
pl.ProcDate,
pl.ProcNum,
pr.Abbr AS 'Prov',
(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) AS 'VisitFee',
(
SELECT SUM(ps.SplitAmt)
FROM paysplit ps
WHERE ps.ProcNum>0
AND ps.ProcNum=pl.ProcNum
) AS 'PatPaid',
(
SELECT SUM(cp.InsPayAmt)
FROM claimproc cp
WHERE cp.ProcNum>0
AND cp.ProcNum=pl.ProcNum
) AS 'InsPaid'
FROM procedurelog pl
INNER JOIN provider pr ON pr.ProvNum=pl.ProvNum
WHERE pl.ProcStatus=2
AND pl.ProcDate BETWEEN @ServiceFromDate AND @ServiceToDate
/* AND pr.Abbr LIKE('%03%')/*optional, could be a list, use IN('D1234', 'D2345')*/;
SELECT Prov,
SUM(VisitFee) AS $VisitFee,
SUM(PatPaid) AS $PatientPaid_,
SUM(InsPaid) AS $InsurancePaid_,
IFNULL(SUM(VisitFee),0)-IFNULL(SUM(PatPaid),0)-IFNULL(SUM(InsPaid),0) AS $RemainingBal_
FROM tmp
INNER JOIN patient p ON tmp.PatNum=p.PatNum
GROUP BY Prov
ORDER BY Prov;
DROP TABLE IF EXISTS tmp;
Patients with 'referred from' source in given date range (determined by date of 1st visit -- not referral attach date). - For versions 16.4 and below. SEE REPLICATION WARNING for versions before 14.3.1. Sums of: fees for procs completed on day of 1st visit. Payments from that patient on day of 1st visit. Claim amts paid for procs completed on day of 1st visit.
/*500 Patients with 'referred from' source in given date range
(determined by date of 1st visit -- not referral attach date), sums of:
fees for procs completed on day of 1st visit.
payments from that patient on day of 1st visit.
claim amts paid for procs completed on day of 1st visit. (calculated by claim procedure level procedure date)
fees for treatment planned procedures planned within one week of 1st visit*/
/*This query is unusual and should be understood before the data is used*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
/*For versions 16.4 and below*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2009-10-01' , @ToDate='2009-10-31';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp
SELECT A.PatNum, DATE(MIN(pl.ProcDate)) AS DateFV
FROM procedurelog pl
INNER JOIN (/*patients seen in date range*/SELECT pl.PatNum
FROM procedurelog pl
WHERE pl.ProcDate BETWEEN @FromDate AND @ToDate AND pl.ProcStatus=2/*complete*/) A ON
A.PatNum=pl.PatNum
WHERE pl.ProcStatus=2/*complete*/
GROUP BY pl.PatNum
HAVING DATE(MIN(pl.ProcDate)) BETWEEN @FromDate AND @ToDate;
SELECT tmp.DateFV, tmp.PatNum,(SELECT CONCAT(r.LName, ',', r.FName) AS RefFName FROM referral r
LEFT JOIN refattach ra ON r.ReferralNum=ra.ReferralNum WHERE tmp.PatNum=ra.PatNum
AND ra.IsFrom='1' GROUP BY ra.PatNum) AS 'Referral Name',
(SELECT SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) FROM procedurelog pl WHERE pl.PatNum=tmp.PatNum AND pl.ProcStatus=2 AND DATE(pl.ProcDate)=tmp.DateFV) AS '$1VisFees',
(SELECT SUM(SplitAmt) FROM paysplit WHERE tmp.PatNum=paysplit.PatNum AND (DatePay=tmp.DateFV)) AS '$1VisPatPay',
(SELECT SUM(InsPayAmt) FROM claimproc cp WHERE cp.PatNum=tmp.PatNum AND cp.ProcDate=tmp.DateFV) AS '$1VisInsPay',
(SELECT SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) FROM procedurelog pl WHERE pl.PatNum=tmp.PatNum AND (pl.ProcStatus=2 OR pl.ProcStatus=1) AND DATE(pl.DateTP)<=(tmp.DateFV +INTERVAL 7 DAY)) AS '$1WeekTP'
FROM tmp;
DROP TABLE IF EXISTS tmp;
Count of patients from each 'referred from' source in given date range (determined by date of 1st visit -- not referral attach date). - For versions 16.4 and below. SEE REPLICATION WARNING for versions before 14.3.1. With sums of: Fees for procs completed on day of 1st visit. Payments from that patient on day of 1st visit. Claim amts paid for procs completed on day of 1st visit.
/*501 Count of patients from each 'referred from' source in given date range
(determined by date of 1st visit -- not referral attach date), with sums of:
fees for procs completed on day of 1st visit.
payments from that patient on day of 1st visit.
claim amts paid for procs completed on day of 1st visit. (calculated by claim procedure level procedure date)
fees for treatment planned procedures planned within one week of 1st visit*/
/*This query is unusual and should be understood before the data is used*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
/*For versions 16.4 and below*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2009-10-01' , @ToDate='2009-10-31';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp
SELECT A.PatNum, DATE(MIN(pl.ProcDate)) AS DateFV
FROM procedurelog pl
INNER JOIN (/*patients seen in date range*/SELECT pl.PatNum
FROM procedurelog pl
WHERE pl.ProcDate BETWEEN @FromDate AND @ToDate AND pl.ProcStatus=2/*complete*/) A ON
A.PatNum=pl.PatNum
WHERE pl.ProcStatus=2/*complete*/
GROUP BY pl.PatNum
HAVING DATE(MIN(pl.ProcDate)) BETWEEN @FromDate AND @ToDate;
SELECT B.ReferraLName, COUNT(*) '#Pats',
SUM(B.1VisFees) '$1VisFees',
SUM(B.1VisPatPay) '$1VisPatPay',
SUM(B.1VisInsPay) '$1VisInsPay',
SUM(B.1WeekTP) '$1WeekTP',
SUM(B.1VisPatPay)+ SUM(B.1VisInsPay) '$1VisTotPay'
FROM (
SELECT tmp.DateFV, tmp.PatNum,(SELECT CONCAT(r.LName, ',', r.FName) AS RefName FROM referral r
LEFT JOIN refattach ra ON r.ReferralNum=ra.ReferralNum WHERE tmp.PatNum=ra.PatNum
AND ra.IsFrom='1' GROUP BY ra.PatNum) AS 'ReferraLName',
(SELECT SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) FROM procedurelog pl WHERE pl.PatNum=tmp.PatNum AND pl.ProcStatus=2 AND DATE(pl.ProcDate)=tmp.DateFV) AS '1VisFees',
(SELECT SUM(SplitAmt) FROM paysplit WHERE tmp.PatNum=paysplit.PatNum AND (DatePay=tmp.DateFV)) AS '1VisPatPay',
(SELECT SUM(InsPayAmt) FROM claimproc cp WHERE cp.PatNum=tmp.PatNum AND cp.ProcDate=tmp.DateFV) AS '1VisInsPay',
(SELECT SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) FROM procedurelog pl WHERE pl.PatNum=tmp.PatNum AND (pl.ProcStatus=2 OR pl.ProcStatus=1) AND DATE(pl.DateTP)<=(tmp.DateFV +INTERVAL 7 DAY)) AS '1WeekTP'
FROM tmp) B
GROUP BY B.ReferraLName;
DROP TABLE IF EXISTS tmp;
Daily procedures report with amount paid to date for each procedure by treating provider. - As of 7.2 only works if you split patient payments to procedures. For all providers, leave variable like: @Provider='%%'.
/*502 Daily procedures report with amount paid to date for each procedure by treating provider. As of 7.2 only works if you split patient payments to procedures. For all providers, leave variable like: @Provider='%%'.*/
SET @FromDate='2012-11-01',@ToDate='2013-02-12',@Provider='%DOC%';
SELECT p.PatNum,pc.ProcCode,pr.Abbr AS Prov,pl.ProcDate,pl.ToothNum,
pc.AbbrDesc,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) AS ProcFee,
SUM(COALESCE(A.InsPayEst,0)) AS $InsPayEst_,
SUM(COALESCE(A.InsPayAmt,0)) AS $InsPayAmt_,
SUM(COALESCE(B.SplitAmt,0)) AS $PatPayAmt_,
SUM(COALESCE(B.SplitAmt,0))+SUM(COALESCE(A.InsPayAmt,0)) AS $TotalPaid_
FROM patient p
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum
AND pl.ProcStatus=2
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
INNER JOIN provider pr ON pr.ProvNum=pl.ProvNum AND pr.Abbr LIKE @Provider
LEFT JOIN (
SELECT cp.ProcNum,SUM(cp.InsPayEst) AS InsPayEst,SUM(cp.InsPayAmt) AS InsPayAmt
FROM claimproc cp
WHERE cp.Status IN(6,0,1,4)
GROUP BY cp.ProcNum
) A ON A.ProcNum=pl.ProcNum
LEFT JOIN (
SELECT ps.ProcNum,SUM(ps.SplitAmt) AS SplitAmt
FROM paysplit ps
GROUP BY ps.ProcNum
) B ON B.ProcNum=pl.ProcNum
GROUP BY pl.ProcNum
ORDER BY pl.ProcDate,p.LName,p.FName;
Mailing Information for patients without insurance, lists guarantors, valid addresses. -
/*503 Mailing Information for patients without insurance, lists guarantors, valid addresses.*/
SELECT g.LName, g.FName,
g.Address, g.Address2, g.City, g.State, g.Zip
FROM patient p
INNER JOIN patient g ON p.Guarantor=g.PatNum
WHERE p.HasIns != 'I'
AND p.PatStatus=0 /*patient*/
AND length(g.ZIP)>4 AND length(g.Address>5)
GROUP BY g.PatNum
ORDER BY g.LName, g.FName;
Appointments on schedule with no attached procedures. -
/*504 Appointments on schedule with no attached procedures. */
SELECT ap.PatNum, AptDateTime,AptStatus FROM appointment ap
LEFT JOIN procedurelog pl ON pl.AptNum=ap.AptNum
WHERE pl.ProcNum IS NULL
AND (ap.AptStatus=1 OR ap.AptStatus=4)
GROUP BY ap.AptNum
ORDER BY ap.AptDateTime;
Balances of patients with appointments on a given date. -
/*505 Balances of patients with appointments on a given date*/
SET @AptDate='2010-08-03';
SELECT appointment.AptDateTime,patient.LName,patient.FName,patient.EstBalance AS PatBal, g.BalTotal
FROM appointment
INNER JOIN patient ON appointment.PatNum=patient.PatNum
INNER JOIN patient g ON patient.Guarantor=g.PatNum
AND DATE(appointment.AptDateTime)=@AptDate
AND AptStatus != 6
AND AptStatus != 3;
New Decay from first exam to second exam in time period. - SEE REPLICATION WARNING for versions before 14.3.1.
/*506 New Decay from first exam to second exam in time period*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @FromDate='2008-08-31' , @ToDate='2010-08-31', @pos=0;
/*visit=comp exam, or periodic or limited exam
decay=look for completed or TP D2* that were TP on same date as a D0* was completed
Report the following numbers,
1.Patients seen in date range (D0* completed)
2.Patients with decay on first visit in date range
3.Patients seen more than once in date range
4.Patients seen >1 with decay in first visit
5.patients seen >1 with new decay in second visit
6.patients seen >1 with no new decay in second visit
7.patients seen >1 with decay in first and second visit
8.patients seen >1 with no decay in first visit but new decay in second visit
9.patients seen >1 with decay in first visit but no new decay in second visit
10. Number of third or more visits discarded*/
DROP TABLE IF EXISTS A;
DROP TABLE IF EXISTS B;
CREATE TABLE A
SELECT pl.PatNum, @pos:=@pos+1 AS RecNum,
DATE(pl.ProcDate) DateProc,
(SELECT COUNT(*) FROM procedurelog pl2 INNER JOIN procedurecode pc2 ON pl2.CodeNum=pc2.CodeNum
WHERE pc2.ProcCode LIKE('D2%')/*decay*/
AND pl2.ProcStatus IN(1,2,7)/*TP, complete or condition*/
AND DATE(pl2.DateTP)=DATE(pl.ProcDate) AND pl.PatNum=pl2.PatNum) NewDecay
FROM procedurelog pl
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
WHERE pc.ProcCode IN ('D0120', 'D0140', 'D0150')/*seen for exam in date range*/
AND pl.ProcStatus=2 AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY pl.PatNum, pl.ProcDate
ORDER BY pl.PatNum,pl.ProcDate ASC;
/*mark first and second appointments, mark third appointments for for non-use*/
CREATE TABLE B
SELECT A.PatNum, A.DateProc,A.NewDecay, IF(A.RecNum=1,1,IF(A.PatNum=(SELECT A1.PatNum FROM A A1 WHERE A1.RecNum=A.RecNum-1), IF(A.PatNum=(SELECT A1.PatNum FROM A A1 WHERE A1.RecNum=A.RecNum-2) AND A.RecNum<>2, 3,2),1)) AptNum
FROM A;
SELECT '1.Patients seen in date range (D0* completed)' AS Metric,
COUNT(DISTINCT PatNum) VALUE FROM B
UNION
SELECT '2.Patients with decay on first visit in date range' AS Metric,
COUNT(DISTINCT PatNum) VALUE FROM B WHERE NewDecay>0 AND AptNum=1
UNION
SELECT '3.Patients seen more than once in date range' AS Metric,
COUNT(DISTINCT PatNum) VALUE FROM B WHERE AptNum=2
UNION
SELECT '4.Patients seen >1 with decay in first visit' AS Metric,
COUNT(DISTINCT PatNum) VALUE FROM B WHERE AptNum=1 AND (SELECT COUNT(*) FROM B B1 WHERE B.PatNum=B1.PatNum AND B1.AptNum=2)=1 AND B.NewDecay>0
UNION
SELECT '5.patients seen >1 with new decay in second visit' AS Metric,
COUNT(DISTINCT PatNum) VALUE FROM B WHERE AptNum=2 AND B.NewDecay>0
UNION
SELECT '6.patients seen >1 with no new decay in second visit' AS Metric,
COUNT(DISTINCT PatNum) VALUE FROM B WHERE AptNum=2 AND B.NewDecay=0
UNION
SELECT '7.patients seen >1 with decay in first and second visit' AS Metric,
COUNT(DISTINCT PatNum) VALUE FROM B WHERE AptNum=1 AND (SELECT COUNT(*) FROM B B1 WHERE B.PatNum=B1.PatNum AND B1.AptNum=2 AND B1.NewDecay>0)=1 AND B.NewDecay>0
UNION
SELECT '8.patients seen >1 with no decay in first visit but new decay in second visit' AS Metric,
COUNT(DISTINCT PatNum) VALUE FROM B WHERE AptNum=1 AND (SELECT COUNT(*) FROM B B1 WHERE B.PatNum=B1.PatNum AND B1.AptNum=2 AND B1.NewDecay>0)=1 AND B.NewDecay=0
UNION
SELECT '9.patients seen >1 with decay in first visit but no new decay in second visit' AS Metric,
COUNT(DISTINCT PatNum) VALUE FROM B WHERE AptNum=1 AND (SELECT COUNT(*) FROM B B1 WHERE B.PatNum=B1.PatNum AND B1.AptNum=2 AND B1.NewDecay=0)=1 AND B.NewDecay>0
UNION
SELECT '10. Number of third or more visits discarded' AS Metric,
COUNT(*) VALUE FROM B WHERE AptNum>2;
DROP TABLE IF EXISTS A;
DROP TABLE IF EXISTS B;
Family Activity - production, num of complete appts, payments. - SEE REPLICATION WARNING for versions before 14.3.1. Families with activity (complete appts or received payments) within specified date range.
/*507 Family Activity - production, num of complete appts, payments. Families with activity (complete appts or received payments) within specified date range. */
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @FromDate='2010-01-01';
SET @ToDate='2010-06-01';
DROP TABLE IF EXISTS tmpproc, tmpapt, tmppatpay, tmpinspay;
CREATE TABLE tmpproc
SELECT p.Guarantor, SUM(pl.ProcFee) AS Production, COUNT(pl.ProcNum) AS ProcCountCompl FROM procedurelog pl
INNER JOIN patient p ON pl.PatNum=p.PatNum
INNER JOIN patient g ON p.Guarantor=g.PatNum
WHERE pl.ProcStatus = 2 /* Complete procs. */
AND ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY p.Guarantor;
CREATE TABLE tmpapt
SELECT p.Guarantor, COUNT(ap.AptNum) AS NumFamApts, SUM(CHAR_LENGTH(ap.Pattern)*5) AS FamAptMinutes
FROM appointment ap
INNER JOIN patient p ON ap.PatNum=p.PatNum
WHERE ap.AptStatus = 2 /* Complete apts */
AND AptDateTime BETWEEN @FromDate AND @ToDate+INTERVAL 1 DAY
GROUP BY p.Guarantor;
CREATE TABLE tmppatpay
SELECT p.Guarantor, SUM(ps.SplitAmt) AS PatIncome
FROM paysplit ps
INNER JOIN patient p ON ps.PatNum=p.PatNum
AND DatePay BETWEEN @FromDate AND @ToDate
GROUP BY p.Guarantor;
CREATE TABLE tmpinspay
SELECT p.Guarantor, SUM(cp.InsPayAmt) AS InsIncome
FROM claimproc cp
INNER JOIN patient p ON cp.PatNum=p.PatNum
WHERE cp.Status=1 /* Received claimproc */
AND cp.InsPayAmt > 0.005 /* Paid On */
AND DateEntry BETWEEN @FromDate AND @ToDate
GROUP BY p.Guarantor;
SELECT CONCAT(g.FName, " ", g.LName) AS "Guarantor Name",
tmpproc.ProcCountCompl AS "Family Procedures",
tmpapt.NumFamApts AS "Family Appointments", ROUND(tmpapt.FamAptMinutes/10,0) AS "Family 10 Min Units",
tmpproc.Production AS "$Family Production",
tmppatpay.PatIncome AS "$Family Patient Income",
tmpinspay.InsIncome AS "$Family Insurance Income"
FROM patient g
LEFT JOIN tmpproc ON g.PatNum=tmpproc.Guarantor
LEFT JOIN tmpapt ON g.PatNum=tmpapt.Guarantor
LEFT JOIN tmppatpay ON g.PatNum=tmppatpay.Guarantor
LEFT JOIN tmpinspay ON g.PatNum=tmpinspay.Guarantor
WHERE tmpapt.NumFamApts > 0
OR tmppatpay.PatIncome > 0.005
OR tmpinspay.InsIncome > 0.005;
DROP TABLE IF EXISTS tmpproc, tmpapt, tmppaypay, tmpinspay;
Active patients who have a specific code in treatment plan, with addresses. - Like 304 with date range.
/*508 Active patients who have a specific code in treatment plan, with addresses
like 304 with date range*/
/*Query code written/modified: 08/26/2016*/
SET @FromDate='2010-01-01';
SET @ToDate='2010-06-01';
SET @pos=0;
SELECT @pos:=@pos+1 AS COUNT, A.*
FROM (
SELECT pc.ProcCode,
p.LName,
p.FName,
p.Address,
p.Address2,
p.City,
p.State,
p.Zip
FROM patient p
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum
AND pl.ProcStatus=1 /*treatment planned*/
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
WHERE DATE(pl.DateTP) BETWEEN @FromDate AND @ToDate
AND pc.ProcCode IN('D0120') /* NOTE: put as many procedurecodes as you like, in single quotes separated by commas*/
)A;
Aging listed by Aging, so 90+ grouped, then 60-90 etc with phone numbers. -
/*510 Aging listed by Aging, so 90+ grouped, then 60-90 etc with phone numbers*/
SELECT CONCAT(LEFT(patient.LName, 15), ',',LEFT(patient.FName,15)) As 'Guarantor',
LEFT(CONCAT(HmPhone, " - ", WkPhone, " - ",WirelessPhone),50) AS 'Hm-Wk-Cell Phone numbers',BalTotal AS '$Fam-',
Bal_0_30 AS '$0-30-',
Bal_31_60 AS '$31-60-',
Bal_61_90 AS '$61-90-',
BalOver90 AS '$+90-',
InsEst AS '$InsEst-' FROM Patient
WHERE Bal_0_30>0 OR Bal_31_60>0 OR Bal_61_90>0 OR BalOver90>0
ORDER BY IF(BalOver90,0,1),
IF(Bal_61_90,0,1),
IF(Bal_31_60,0,1),
IF(Bal_0_30,0,1),
LName, FName;
Monthly production and income report,with scheduled column, scheduled writeoffs are estimated writeoffs counts insurance writeoffs by procedure date (PPO) - SEE REPLICATION WARNING for versions before 14.3.1. Only counts writeoffs for completed work if a claim has been created, but counts estimated writeoffs for scheduled work For all providers, date range must all be in same month
/*511 Monthly production and income report,with scheduled column, scheduled writeoffs are estimated writeoffs counts insurance writeoffs by procedure date (PPO), Only counts writeoffs for completed work if a claim has been created, but counts estimated writeoffs for scheduled work
For all providers, date range must all be in same month*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS t1,t2;
SET @FromDate='2010-10-01' , @ToDate='2010-10-31';
CREATE TABLE t1(
DAY INT NOT NULL,
DATE DATE,
DAYOFWEEK VARCHAR(10),
$Production DOUBLE NOT NULL DEFAULT 0,
$WriteOffs DOUBLE NOT NULL DEFAULT 0,
$SchedProd DOUBLE NOT NULL DEFAULT 0,
$SchdWrtOff DOUBLE NOT NULL DEFAULT 0,
$Adjustments DOUBLE NOT NULL DEFAULT 0,
$TotProduction DOUBLE NOT NULL DEFAULT 0,
$PatIncome DOUBLE NOT NULL DEFAULT 0,
$InsIncome DOUBLE NOT NULL DEFAULT 0,
$TotIncome DOUBLE NOT NULL DEFAULT 0);
/*Load Days of month*/
INSERT INTO t1(DAY)
VALUES (1),(2),(3),(4),(5),(6),(7),(8),(9),(10),(11),(12),(13),(14),(15),(16),(17),(18),(19),(20),(21),(22),(23),(24),(25),(26),(27),(28),(29),(30),(31);
DELETE FROM t1 WHERE DAY>DAY(LAST_DAY(@FromDate));
UPDATE t1 SET DATE=STR_TO_DATE(CONCAT(MONTH(@FromDate), '/', DAY, '/', YEAR(@FromDate)),'%c/%e/%Y');
UPDATE t1 SET DAYOFWEEK=DATE_FORMAT(DATE, '%W');
/*Prod*/
CREATE TABLE t2
SELECT DAYOFMONTH(pl.ProcDate) AS 'Day',
SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) AS 'Production'
FROM procedurelog pl WHERE pl.ProcStatus=2 AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY DAYOFMONTH(pl.ProcDate);
UPDATE t1,t2 SET t1.$Production=t2.Production WHERE t1.Day=t2.Day;
DROP TABLE IF EXISTS t2;
/*Sched Prod and writeoffs*/
CREATE TABLE t2
SELECT DAYOFMONTH(ap.AptDateTime) AS 'Day',
SUM(pl.procfee) AS 'SchedProd',
SUM(IF((cp.WriteOffEstOverride=-1),IF((cp.WriteOffEst=-1),0,cp.WriteOffEst), cp.WriteOffEstOverride)) AS 'SchdWrtOff'
FROM appointment ap
INNER JOIN procedurelog pl ON pl.AptNum=ap.AptNum
LEFT JOIN claimproc cp ON cp.ProcNum=pl.ProcNum
WHERE pl.ProcStatus=1 AND ap.AptStatus=1
AND ap.AptDateTime BETWEEN @FromDate AND @ToDate+INTERVAL 1 DAY
AND (ISNULL(cp.Status) OR cp.Status=6 /*estimate*/)
GROUP BY DAYOFMONTH(ap.AptDateTime);
UPDATE t1,t2 SET t1.$SchedProd=t2.SchedProd , t1.$SchdWrtOff=-t2.SchdWrtOff WHERE t1.Day=t2.Day;
DROP TABLE IF EXISTS t2;
/*Adj*/
CREATE TABLE t2
SELECT DAYOFMONTH(a.AdjDate) AS 'Day',
SUM(a.AdjAmt) AS 'Adjustments' FROM adjustment a
WHERE a.AdjDate BETWEEN @FromDate AND @ToDate
GROUP BY DAYOFMONTH(a.AdjDate);
UPDATE t1,t2 SET t1.$Adjustments=t2.Adjustments WHERE t1.Day=t2.Day;
DROP TABLE IF EXISTS t2;
/*PatInc*/
CREATE TABLE t2
SELECT DAYOFMONTH(pp.DatePay) AS 'Day',
SUM(pp.SplitAmt) AS 'PatIncome' FROM paysplit pp
WHERE pp.DatePay BETWEEN @FromDate AND @ToDate
GROUP BY DAYOFMONTH(pp.DatePay);
UPDATE t1,t2 SET t1.$PatIncome=t2.PatIncome WHERE t1.Day=t2.Day;
DROP TABLE IF EXISTS t2;
/*Writeoffs*/
CREATE TABLE t2
SELECT DAYOFMONTH(cp.ProcDate) AS 'Day',
SUM(cp.WriteOff) AS 'WriteOffs'
FROM claimproc cp
WHERE (cp.Status=1 OR cp.Status=4 OR cp.Status=0)
AND (cp.ProcDate BETWEEN @FromDate AND @ToDate /*vs DateCP if not counting writeoffs by procdate*/)
GROUP BY DAYOFMONTH(cp.ProcDate);
UPDATE t1,t2 SET
t1.$WriteOffs=-t2.WriteOffs
WHERE t1.Day=t2.Day;
DROP TABLE IF EXISTS t2;
/*InsIncome*/
CREATE TABLE t2
SELECT DAYOFMONTH(cpay.CheckDate) AS 'Day',
SUM(cp.InsPayAmt) AS 'InsIncome'
FROM claimproc cp
INNER JOIN claimpayment cpay ON cpay.ClaimPaymentNum=cp.ClaimPaymentNum
WHERE cpay.CheckDate BETWEEN @FromDate AND @ToDate AND
cp.Status IN(1,4)
GROUP BY DAYOFMONTH(cpay.CheckDate);
UPDATE t1,t2 SET t1.$InsIncome=t2.InsIncome
WHERE t1.Day=t2.Day;
UPDATE t1 SET
$TotProduction=$Production+$Adjustments+$WriteOffs+$SchedProd+$SchdWrtOff,
$TotIncome=$InsIncome+$PatIncome ;
DROP TABLE IF EXISTS t2;
ALTER TABLE t1 DROP DAY;
SELECT * FROM t1;
DROP TABLE IF EXISTS t1;
Patients on unscheduled list with all phone numbers. -
/*512 Patients on unscheduled list with all phone numbers*/
SELECT a.PatNum, a.AptDateTime, a.UnschedStatus, a.ProvNum, a.ProcDescript, a.Note, p.WirelessPhone, p.HmPhone, p.WkPhone
FROM appointment a
INNER JOIN patient p ON a.PatNum=p.PatNum
WHERE a.AptStatus=3;
Recall Reminders Sent in a specified date range. - Shows patient, reminder description, and date/time the reminder was sent. These are commlog entries of 'Recall' type, so if any don't belong they should probably be changed to Misc or some other type, so they will not be counted as reminders.
/*513 Recall Reminders Sent in a specified date range. Shows patient, reminder description, and date/time the reminder was sent. These are commlog entries of 'Recall' type, so if any don't belong they should probably be changed to Misc or some other type, so they will not be counted as reminders.*/
SET @pos=0, @FromDate='2010-10-01' , @ToDate='2010-10-01';
SELECT @pos:=@pos+1 AS 'Count', commlog.PatNum, Note, CommDateTime AS ReminderSent FROM commlog
INNER JOIN definition ON commlog.CommType=definition.DefNum
INNER JOIN patient ON commlog.PatNum=patient.PatNum
WHERE ItemName Like 'Recall' AND NOTE LIKE ('%%')
AND DATE(CommDateTime) BETWEEN @FromDate AND @ToDate
ORDER BY patient.LName, patient.FName;
Somewhat like 325 shows work treatment planned in a date range but that is also in a SAVED treatment plan and not scheduled. -
/*515 Somewhat like 325 shows work treatment planned in a date range but that is also in a SAVED treatment plan and not scheduled */
SET @pos=0, @FromDate='2006-07-21' , @ToDate='2011-07-21';
SELECT * FROM (
SELECT @pos:=@pos+1 as 'Count', pa.PatNum, /* tp.Heading, */
pc.ProcCode as 'Code', abbrdesc as 'Description', ToothNum, CONVERT(DATE_FORMAT(pl.DateTP,'%m-%d-%Y'),CHAR) AS 'DateTP',
pr.Abbr, ProcFee, IF(pl.AptNum, IF(pl.ProcStatus=2, 'Complete', IF(pl.Procstatus=1, 'Scheduled', 'Other')), IF(pl.ProcStatus=2, 'Complete','TP')) AS 'Status'
FROM patient pa
INNER JOIN procedurelog pl ON pa.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
INNER JOIN provider pr ON pl.ProvNum=pr.ProvNum
INNER JOIN proctp ptp ON ptp.ProcNumOrig=pl.ProcNum
INNER JOIN treatplan tp ON tp.TreatPlanNum=ptp.TreatPlanNum
WHERE pl.ProcStatus IN(1,2) AND
(pl.DateTP BETWEEN @FromDate AND @ToDate)
ORDER BY pl.DateTP,pa.LName, pa.FName ASC) AS A
WHERE A.Status='TP';
List of patients seen in date range with provider that did procedures where the patient has capitation insurance. -
/*516 list of patients seen in date range with provider that did procedures where the patient has capitation insurance*/
/*Change dates as needed in first line of query */
SET @pos=0, @StartDate='2010-05-01' , @EndDate='2010-12-01';
SELECT @pos:=@pos+1 AS 'PatCount', COUNT(pl.ProcNum) AS Procs, pa.PatNum, pr.Abbr AS Provider, pa.CarrierName
FROM
(SELECT p.PatNum, ca.CarrierName FROM patient p INNER JOIN patplan pp ON pp.PatNum=p.PatNum
INNER JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
INNER JOIN insplan ip ON ip.PlanNum=ib.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=ip.CarrierNum
WHERE ip.PlanType='c') AS pa
INNER JOIN procedurelog pl ON pa.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
INNER JOIN provider pr ON pl.ProvNum=pr.ProvNum
WHERE pl.ProcStatus=2 AND (pl.ProcDate BETWEEN @StartDate AND @EndDate)
GROUP BY pa.PatNum, pr.Abbr, pa.CarrierName;
Recall info for patients with any insurance carrier, and specific date range, with date of last visit. - Change dates as needed in first line of query.
/*517 Recall info for patients with any insurance carrier, and specific date range, with date of last visit*/
/*Change dates as needed in first line of query */
SET @pos=0, @StartDate='2011-01-01' , @EndDate='2013-04-01';
SELECT @pos:=@pos+1 AS 'Count',p.LName, p.FName, r.DateDue, d.ItemName AS 'RecallStatus',rt.Description AS 'Type',
(SELECT CONVERT(DATE_FORMAT(MAX(ProcDate),'%m/%d/%Y'), CHAR) FROM patient INNER JOIN procedurelog
ON procedurelog.PatNum=patient.PatNum WHERE procedurelog.ProcStatus=2 AND patient.PatStatus=0 AND p.PatNum=patient.PatNum
GROUP BY procedurelog.PatNum) AS 'LastVisit(any)', c.CarrierName
FROM patient p
INNER JOIN recall r ON p.PatNum=r.PatNum
LEFT JOIN definition d ON r.RecallStatus=d.DefNum
INNER JOIN patplan pp ON pp.PatNum=p.PatNum
INNER JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
INNER JOIN insplan ip ON ip.PlanNum=ib.PlanNum
INNER JOIN carrier c ON c.CarrierNum=ip.CarrierNum
INNER JOIN recalltype rt ON rt.RecallTypeNum=r.RecallTypeNum
WHERE (DateDue BETWEEN @StartDate AND @EndDate)
ORDER BY p.LName, p.FName;
Patients who have been seeen in date range who have double insurance. -
/*518 Patients who have been seeen in date range who have double insurance*/
SET @pos=0, @StartDate='2010-07-01' , @EndDate='2010-12-31';
SELECT @pos:=@pos+1 AS 'Count',p.LName, p.FName, p.PatNum AS PatNumber, MAX(pl.ProcDate) AS 'LastSeenDate'
FROM patient p
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum AND pl.ProcStatus=2
INNER JOIN patplan pp ON pp.PatNum=p.PatNum AND pp.Ordinal=2
GROUP BY p.PatNum
ORDER BY p.LName, p.FName;
New Patients in given date range who do not have a scheduled appointment. -
/*519 New Patients in given date range who do not have a scheduled appointment*/
SET @FromDate='2010-01-01' , @ToDate='2010-12-31';
SELECT CONCAT(p.LName, ', ',p.FName, ' ', p.MiddleI) As PatName, p.PatNum AS 'PatNumber', MIN(pl.ProcDate) AS 'DateFirstSeen'
FROM patient p
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum AND pl.ProcStatus=2 /*complete*/
LEFT JOIN appointment a ON p.PatNum=a.PatNum AND a.AptStatus=1 /*sched*/
WHERE ISNULL(a.AptNum)
GROUP BY p.PatNum, a.AptNum
HAVING MIN(pl.ProcDate) BETWEEN @FromDate AND @ToDate
ORDER BY p.LName, p.FName;
Show procedures completed in a date range for patients who have a given fee schedule attached to their primary insurance, in this example Delta. -
/*520 Show procedures completed in a date range for patients who have a given fee schedule attached to their primary insurance, in this example Delta*/
SET @FromDate='2010-01-01' , @ToDate='2010-12-31';
SELECT CONCAT(patient.LName, ', ',patient.FName, ' ', patient.MiddleI) As Patient, pl.ProcDate,
pv.Abbr,pc.ProcCode, pc.AbbrDesc, ToothNum, pl.ProcFee
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
INNER JOIN provider pv ON pl.ProvNum=pv.ProvNum
INNER JOIN patplan pp ON pp.PatNum=patient.PatNum AND pp.Ordinal=1
INNER JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
INNER JOIN insplan ip ON ib.PlanNum=ip.PlanNum
INNER JOIN feesched fs ON fs.FeeSchedNum=ip.FeeSched
WHERE pl.ProcStatus = '2' AND (pl.ProcDate >=@FromDate
AND pl.ProcDate <= @ToDate) AND
(pc.ProcCode LIKE '%D1110%' OR pc.ProcCode LIKE '%D0110%' OR pc.ProcCode LIKE '%D1234%')
AND fs.Description LIKE('%delta%')
ORDER BY ProcDate,patient.LName, patient.FName ASC;
Simple sum of patient payments and sum of insurance payments for a given time span. -
/*521 Simple sum of patient payments and sum of insurance payments for a given time span.*/
SET @Fromdate='2010-01-01', @Todate='2010-12-31';
SELECT 'PatientPayment' AS PaymentType,
SUM(paysplit.SplitAmt) AS PaymentAmt
FROM paysplit
WHERE paysplit.DatePay BETWEEN @Fromdate AND @Todate
UNION
SELECT 'Ins Checks' as PaymentType, SUM(claimproc.InsPayAmt) AS PaymentAmt
FROM claimproc
WHERE claimproc.DateCP BETWEEN @Fromdate AND @Todate
AND (claimproc.Status=1 OR claimproc.Status=4);
Guarantors of patients who have been seen in a date range for one or more of a given list of procedure codes with list of patient First Names. - SEE REPLICATION WARNING for versions before 14.3.1.
/*522 Guarantors of patients who have been seen in a date range for one or more of a given list of procedure codes with list of patient First Names.*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS tmp;
CREATE TABLE tmp SELECT DISTINCT p.PatNum, p.Guarantor, g.LName, g.FName, g.Address, g.Address2, g.City, g.State, g.Zip FROM patient p
INNER JOIN patient g ON g.PatNum=p.Guarantor WHERE p.PatStatus=0;
SET @pos=0, @FromDate='2010-01-01' , @ToDate='2010-12-31';
SELECT @pos:=@pos+1 as 'Count', tmp.LName, tmp.FName, GROUP_CONCAT(DISTINCT(patient.FName)) AS PatFNames, tmp.Address, tmp.Address2, tmp.City, tmp.State, tmp.Zip FROM patient
INNER JOIN tmp ON patient.PatNum=tmp.PatNum
INNER JOIN procedurelog ON procedurelog.PatNum=patient.PatNum
INNER JOIN procedurecode pc ON procedurelog.CodeNum=pc.CodeNum
WHERE procedurelog.ProcStatus=2
AND ProcDate BETWEEN @FromDate AND @ToDate
AND Length(tmp.Zip)>4
AND ProcCode IN('D1110', 'D1120')
GROUP BY tmp.Guarantor
ORDER BY LName;
DROP TABLE IF EXISTS tmp;
Guarantors of families in which none of the patients have been seen after a given date. -
/*523 Guarantors of families in which none of the patients have been seen after a given date. */
SELECT g.LName, g.FName, g.Address, g.Address2, g.City, g.State, g.Zip, MAX(pl.ProcDate) AS 'DateLastSeen'
FROM patient p
INNER JOIN patient g ON g.PatNum=p.Guarantor
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum
AND pl.procstatus = '2'
GROUP BY g.PatNum
HAVING MAX(pl.ProcDate) < '2010-06-15';
Gross production and income by provider. - SEE REPLICATION WARNING for versions before 14.3.1. Today, MTD, YTD.
/*524 Gross production and income by provider, Today, MTD, YTD*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @AsOf=CURDATE(); /*use this instead to show any day SET @AsOf='2009-05-20'; */
/*first create transaction table*/
DROP TABLE IF EXISTS tmp1;
CREATE TABLE tmp1
(TranType VARCHAR(10), PatNum INT DEFAULT 0,
TranDate DATE DEFAULT '0001-01-01',
TranAmount DOUBLE DEFAULT 0, ProvNum INT DEFAULT 0);
/*Get the completed procedure dates and charges for the entire office history on or before the given date*/
INSERT INTO tmp1 (TranType,PatNum,TranDate,TranAmount,ProvNum)
SELECT 'Fee' AS TranType, pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount, pl.ProvNum
FROM procedurelog pl
WHERE pl.ProcStatus=2 AND YEAR(pl.ProcDate)=YEAR(@AsOf);
/*Paysplits for the entire office history on or before the given date*/
INSERT INTO tmp1 (TranType,PatNum,TranDate,TranAmount,ProvNum)
SELECT 'Pay' AS TranType,ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount, ps.ProvNum
FROM paysplit ps
WHERE YEAR(ps.ProcDate)=YEAR(@AsOf);
/*Claim payments, XXXlimit to ones with a check*/
INSERT INTO tmp1 (TranType,PatNum,TranDate,TranAmount,ProvNum)
SELECT 'InsPay' AS TranType,cp.PatNum PatNum,
cp.DateCp TranDate,-cp.InsPayAmt TranAmount, cp.ProvNum
FROM claimproc cp
WHERE cp.Status IN (1,4,5,7) AND cp.ClaimPaymentNum>0/*received, supplemental, CapClaim or CapComplete*/
AND YEAR(cp.DateCp)=YEAR(@AsOf);
SELECT p.Abbr,
FORMAT((SELECT SUM(TranAmount) FROM tmp1 WHERE TranType='Fee' AND TranDate=@AsOf AND tmp1.ProvNum=p.ProvNum),2) AS '$TodayGrossProd',
FORMAT((SELECT SUM(-TranAmount) FROM tmp1 WHERE TranType IN('Pay','InsPay') AND TranDate=@AsOf AND tmp1.ProvNum=p.ProvNum),2) AS '$TodayIncome',
FORMAT((SELECT SUM(TranAmount) FROM tmp1 WHERE TranType='Fee'
AND MONTH(TranDate)=MONTH(@AsOf) AND YEAR(TranDate)=YEAR(@AsOf) AND TranDate<=@AsOf AND tmp1.ProvNum=p.ProvNum),2) AS '$MTDGrossProd',
FORMAT((SELECT SUM(-TranAmount) FROM tmp1 WHERE TranType IN('Pay','InsPay')
AND MONTH(TranDate)=MONTH(@AsOf) AND YEAR(TranDate)=YEAR(@AsOf) AND TranDate<=@AsOf AND tmp1.ProvNum=p.ProvNum),2) AS '$MTDIncome',
FORMAT((SELECT SUM(TranAmount) FROM tmp1 WHERE TranType='Fee'
AND YEAR(TranDate)=YEAR(@AsOf) AND TranDate<=@AsOf AND tmp1.ProvNum=p.ProvNum),2) AS '$YTDGrossProd',
FORMAT((SELECT SUM(-TranAmount) FROM tmp1 WHERE TranType IN('Pay','InsPay')
AND YEAR(TranDate)=YEAR(@AsOf) AND TranDate<=@AsOf AND tmp1.ProvNum=p.ProvNum),2) AS '$YTDIncome'
FROM provider p WHERE p.IsHidden=False
GROUP BY ProvNum;
DROP TABLE IF EXISTS tmp1;
All recall appointments in date range with status. -
/*525 All recall appointments in date range with status.*/
SET @FromDate='2015-01-01' , @ToDate='2016-12-21'; /*set dates here, includes these and all between*/
SELECT p.FName,
p.LName,
p.WirelessPhone,
p.HmPhone,
p.WkPhone,
a.AptDateTime,
a.AptStatus,
MIN(r.DateDue) AS DateDue,
SUBSTRING_INDEX(GROUP_CONCAT(DISTINCT rty.Description,':',r.DateDue ORDER BY r.DateDue SEPARATOR '|' ),':',1) AS Description
FROM appointment a
INNER JOIN patient p ON a.PatNum=p.PatNum
INNER JOIN recall r ON r.PatNum=p.PatNum
INNER JOIN recalltype rty ON rty.RecallTypeNum=r.RecallTypeNum
INNER JOIN recalltrigger rtr ON rtr.RecallTypeNum=r.RecallTypeNum
INNER JOIN procedurelog pl ON pl.CodeNum=rtr.CodeNum
AND pl.ProcStatus IN(1,2) /*TP or Completed proc*/
AND pl.AptNum=a.AptNum
WHERE a.AptDateTime BETWEEN @FromDate AND @ToDate+INTERVAL 1 DAY
GROUP BY a.AptNum
ORDER BY a.AptDateTime
Procedure level payment report for those who link patient payments to procedures. -
/*526 Procedure level payment report for those who link patient payments to procedures.*/
SET @StartDate= '2010-12-01'; /*includes start date in result set*/
SET @EndDate= '2010-12-31'; /*includes end date in result set*/
SELECT pl.ProcDate, pl.PatNum, pc.ProcCode, pl.ProcFee*(pl.UnitQty+pl.BaseUnits) AS $GrossProd, /* SUM(cp.WriteOff), also I would add adjustments*/ SUM(cp.InsPayAmt) AS $InsPaidAmt, SUM(ps.SplitAmt) AS $PatPaidAmt
FROM procedurelog pl
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
LEFT JOIN claimproc cp ON cp.ProcNum=pl.ProcNum AND cp.Status IN (1,4,5,7)/*received, supplemental, CapClaim or CapComplete*/
LEFT JOIN paysplit ps ON ps.ProcNum=pl.ProcNum
WHERE pl.ProcDate BETWEEN @StartDate AND @EndDate AND pl.ProcStatus=2 /*completed procedures only*/
GROUP BY pl.ProcNum;
List all patients with carrier and employer. -
/*527 List all patients with carrier and employer.*/
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count',
pats.*
FROM (
SELECT p.PatNum,
pp.Ordinal AS PlanOrder,
c.CarrierName,
e.EmpName
FROM patient p
INNER JOIN patplan pp ON pp.PatNum=p.PatNum
INNER JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
INNER JOIN insplan ip ON ib.PlanNum=ip.PlanNum
INNER JOIN carrier c ON c.CarrierNum=ip.CarrierNum
LEFT JOIN employer e ON ip.EmployerNum=e.EmployerNum
ORDER BY p.LName, p.FName, pp.Ordinal
)pats;
All active patients list with clinic and email. -
/*528 All active patients list with clinic and email.*/
SELECT p.LName, p.FName, p.Email,c.Description
FROM patient p
LEFT JOIN clinic c ON c.ClinicNum=p.ClinicNum
WHERE p.PatStatus=0;
Patient count with and without insurance. -
/*529 Patient count with and without insurance.*/
SELECT HasIns, COUNT(HasIns) FROM patient WHERE PatStatus=0 GROUP BY HasIns;
Patient count by Gender. -
/*530 Patient count by Gender.*/
SELECT Gender, COUNT(Gender) FROM patient WHERE PatStatus=0 GROUP BY Gender;
Sum of adjustments by type for a given provider and date range. -
/*532 Sum of adjustments by type for a given provider and date range.*/
SET @Start='2010-01-01' , @End='2010-12-31', @ProvAbbr='DOC';
/*Adjust above Dates as needed*/
SELECT AdjType, SUM(AdjAmt), Count(AdjNum) AS AdjCount FROM adjustment a
INNER JOIN provider p ON p.ProvNum=a.ProvNum
WHERE AdjDate >=@Start
AND AdjDate <=@End
AND p.Abbr=@ProvAbbr
GROUP BY AdjType
ORDER BY SUM(AdjAmt);
List non zero, non-general deductibles. - Useful for finding patients with potentially erroneous benefit information.
/*533 List non zero, non-general deductibles. Useful for finding patients with potentially erroneous benefit information.*/
SELECT pp.PatNum,b.MonetaryAmt, b.CovCatNum FROM benefit b
INNER JOIN insplan ip ON ip.PlanNum=b.PlanNum
INNER JOIN inssub ib ON ib.PlanNum=ip.PlanNum
INNER JOIN patplan pp on pp.InsSubNum=ib.InsSubNum
WHERE
b.BenefitType=2 AND b.MonetaryAmt>0 AND b.CovCatNum<>9 AND b.CovCatNum<>0;
Unscheduled appt list, with phone numbers, last seen date, and how long since last seen. - SEE REPLICATION WARNING for versions before 14.3.1. Only includes patients on unscheduled list who have no scheduled appointments.
/*534 Unscheduled appt list, with phone numbers, last seen date, and how long since last seen. Only includes patients on unscheduled list who have no scheduled appointments. */
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
DROP TABLE IF EXISTS tmp1, tmp2, tmp3;
SET @pos=0;
CREATE TABLE tmp1 SELECT DISTINCT PatNum FROM appointment WHERE AptStatus=1; /* Patients with scheduled appointments. */
CREATE TABLE tmp2 SELECT PatNum, MAX(AptDateTime) AS 'AptDateTime' FROM appointment WHERE AptStatus=2 GROUP BY PatNum; /* Gives last seen for patients who have completed appointments. */
CREATE TABLE tmp3 SELECT DISTINCT PatNum FROM appointment WHERE AptStatus=3; /* Patients on Unscheduled List */
SELECT @pos:=@pos+1 as numberofpatients, p.PatNum, p.HmPhone, tmp2.AptDateTime AS LastApt,
(TO_DAYS(curdate()) - TO_DAYS(tmp2.AptDateTime)) AS 'DaysSince'
FROM patient p
LEFT JOIN tmp1 ON p.PatNum=tmp1.PatNum
LEFT JOIN tmp2 ON p.PatNum=tmp2.PatNum
INNER JOIN tmp3 ON p.PatNum=tmp3.PatNum /* Include only patients who are on unscheduled list.*/
WHERE tmp1.PatNum IS NULL /* Exclude all patients with scheduled appointments. */
AND (tmp2.AptDateTime) GROUP BY tmp2.PatNum
ORDER BY p.LName, p.FName ASC;
DROP TABLE IF EXISTS tmp1, tmp2, tmp3;
Returns all treatment planned procedures for active patients without a scheduled OR planned apt. - With phone nums where the procedures were treatment planned in a given date range.
/*535 Returns all treatment planned procedures for active patients without a scheduled OR planned apt. With phone nums where the procedures were treatment planned in a given date range.*/
SET @FromDate='2009-10-01' , @ToDate='2010-12-31';
SELECT CONCAT(LName, ', ',FName, ' ', MiddleI) AS Patient, hmphone, wkphone, wirelessphone, SUM(ProcFee) AS '$FeeSum', Concat(Address, ' ', Address2) AS Address, City, State, Zip FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum AND ProcStatus=1
LEFT JOIN appointment ap ON patient.PatNum=ap.PatNum AND (ap.AptStatus=1 OR ap.AptStatus=6 )
WHERE ap.AptNum IS NULL AND patient.PatStatus=0
AND pl.DateTP Between @FromDate AND @ToDate
GROUP BY patient.PatNum
ORDER BY patient.LName, patient.FName ASC;
Insurance aging report. - Outstanding insurance aged by date sent 0 to 30, 30 to 60, 60 to 90 etc.
/*536 Insurance aging report per patient. Outstanding insurance aged by date sent */
/*Query code written/modifed 04/24/2018*/
SELECT
PatNum,
FORMAT(SUM(a.Ins0to30),2) AS $Ins0to30_ ,
FORMAT(SUM(a.Ins30to60),2) AS $Ins30to60_,
FORMAT(SUM(a.Ins60to90),2) AS $Ins60to90_,
FORMAT(SUM(a.InsOver90),2) AS $InsOver90_,
FORMAT(SUM(a.InsPayEst),2) AS $Total_
FROM (
/*divide insurance estimates into aging buckets per claim*/
SELECT
claim.ClaimNum,
claim.PatNum,
claim.InsPayEst,
claim.DateSent,
IF((TO_DAYS(CURDATE())-TO_DAYS(claim.DateSent))> 90,InsPayEst,0) AS 'InsOver90',
IF((TO_DAYS(CURDATE())-TO_DAYS(claim.DateSent))> 60,IF((TO_DAYS(CURDATE())-TO_DAYS(claim.DateSent))<= 90, InsPayEst,0),0) AS 'Ins60to90',
IF((TO_DAYS(CURDATE())-TO_DAYS(claim.DateSent))> 30,IF((TO_DAYS(CURDATE())-TO_DAYS(claim.DateSent))<= 60, InsPayEst,0),0) AS 'Ins30to60',
IF((TO_DAYS(CURDATE())-TO_DAYS(claim.DateSent))<= 30,InsPayEst,0) AS 'Ins0to30'
FROM claim
WHERE ClaimStatus='S' -- limit to sent claims
AND claim.ClaimType != 'PreAuth' -- exclude pre-auths
) a
GROUP BY A.PatNum;
Unscheduled List with phone numbers added. -
/*537 Unscheduled List with phone numbers added.*/
SELECT CONCAT(p.LName, ', ', p.FName) AS Name, DATE(a.AptDateTime) AS Date, a.UnschedStatus, a.ProvNum, a.ProcDescript,
LEFT(CONCAT(HmPhone, " - ", WkPhone, " - ",WirelessPhone),50) AS 'Hm-Wk-Cell Phone numbers',
a.Note FROM Appointment a
INNER JOIN patient p ON p.PatNum=a.PatNum
WHERE AptStatus=3 /*Unsched*/;
Time Card summary for all Employees. -
/*538 Time Card summary for all Employees.*/
SET @FromDate='2011-02-01' , @ToDate='2011-02-15';
SELECT e.FName,e.LName,
FORMAT(SUM(TIME_TO_SEC(IF((TIME_TO_SEC(TimeDisplayed2)>0 AND c.ClockStatus IN(0,1)), TIMEDIFF(TimeDisplayed2, TimeDisplayed1),0)))/3600,2) AS RawHours,
FORMAT(
(IFNULL((SELECT SUM(TIME_TO_SEC(ta.RegHours)) FROM timeadjust ta WHERE ta.EmployeeNum=e.EmployeeNum AND DATE(ta.TimeEntry) BETWEEN @FromDate AND @ToDate),0) /*adj reg hours*/ +
IFNULL((SELECT SUM(TIME_TO_SEC(ta.OTimeHours)) FROM timeadjust ta WHERE ta.EmployeeNum=e.EmployeeNum AND DATE(ta.TimeEntry) BETWEEN @FromDate AND @ToDate),0) /*adj OT hours*/ +
SUM(TIME_TO_SEC(IF(c.ClockStatus IN(0,1),IF(c.AdjustIsOverRidden, c.Adjust, c.AdjustAuto),0))))/3600
,2) AS AdHours,
FORMAT(SUM(TIME_TO_SEC(IF((TIME_TO_SEC(c.TimeDisplayed2)>0 AND c.ClockStatus=2), TIMEDIFF(c.TimeDisplayed2, c.TimeDisplayed1),0)))/3600,2) AS BreakTot,
FORMAT((SUM(TIME_TO_SEC(IF((TIME_TO_SEC(c.TimeDisplayed2)>0 AND c.ClockStatus=2), TIMEDIFF(c.TimeDisplayed2, c.TimeDisplayed1),0)))+
SUM(TIME_TO_SEC(IF(c.ClockStatus IN(0,1),IF(c.AdjustIsOverRidden, c.Adjust, c.AdjustAuto),0))) /*minus (+) adjustments*/
)/3600,2) AS BreakAdj,
FORMAT((IFNULL((SELECT SUM(TIME_TO_SEC(ta.OTimeHours)) FROM timeadjust ta WHERE ta.EmployeeNum =e.EmployeeNum AND DATE(ta.TimeEntry) BETWEEN @FromDate AND @ToDate),0) /*adj OT hours*/ +
SUM(TIME_TO_SEC(IF(c.ClockStatus IN(0,1) AND c.OTimeHours<>'-01:00:00', (c.OTimeHours),0)))+
SUM(TIME_TO_SEC(IF(c.ClockStatus IN(0,1),c.OTimeAuto,0))))/3600,2) AS OverTime,
FORMAT((IFNULL((SELECT SUM(TIME_TO_SEC(ta.RegHours)) FROM timeadjust ta WHERE ta.EmployeeNum =e.EmployeeNum AND DATE(ta.TimeEntry) BETWEEN @FromDate AND @ToDate),0) /*adj reg hours*/ +
SUM(TIME_TO_SEC(IF((TIME_TO_SEC(c.TimeDisplayed2)>0 AND c.ClockStatus IN(0,1)), TIMEDIFF(c.TimeDisplayed2, c.TimeDisplayed1),0)))+
SUM(TIME_TO_SEC(IF(c.ClockStatus IN(0,1),IF(c.AdjustIsOverRidden, c.Adjust, c.AdjustAuto),0)))- /*minus (+) adjustments*/
SUM(TIME_TO_SEC(IF(c.ClockStatus IN(0,1) AND c.OTimeHours<>'-01:00:00', c.OTimeHours,0)))- /*minus Overtime*/
SUM(TIME_TO_SEC(IF(c.ClockStatus IN(0,1) , c.OTimeAuto,0))))/3600,2) AS RegHours /*minus Overtime Auto*/
FROM employee e
INNER JOIN clockEvent c ON c.EmployeeNum=e.EmployeeNum
WHERE (DATE(c.TimeDisplayed1) BETWEEN @FromDate AND @ToDate)
GROUP BY c.EmployeeNum
ORDER BY LName, FName;
Find deposit date and check info by checknum. -
/*539 Find deposit date and check info by checknum.*/
SELECT * FROM claimpayment cp
INNER JOIN deposit d ON d.DepositNum=cp.DepositNum
WHERE cp.CheckNum LIKE('%79838693%');
Insurance info for patients with apts in date range. -
/*540 insurance info for patients with apts in date range*/
SET @FromDate='2011-10-28' , @ToDate='2011-11-02';
SELECT
p.LName,
p.FName,
p.PatNum AS PatID,
a.AptDateTime,
IFNULL(c.CarrierName, '') PriCarrier,
IFNULL(ins.SubscriberID, '') PriSubID,
IFNULL(c.Phone,'') PriCarPhone,
IFNULL(c2.CarrierName, '') SecCarrier,
IFNULL(ins2.SubscriberID, '') SecSubID,
IFNULL(c2.Phone,'') SecCarPhone,
p.addrnote
FROM patient p
INNER JOIN appointment a
ON p.PatNum = a.PatNum
LEFT JOIN patplan pp
ON pp.PatNum = p.PatNum
AND pp.Ordinal = 1 -- Primary
LEFT JOIN inssub ins
ON ins.InsSubNum = pp.InsSubNum
LEFT JOIN insplan ip
ON ip.PlanNum = ins.PlanNum
LEFT JOIN carrier c
ON c.CarrierNum = ip.CarrierNum
LEFT JOIN patplan pp2
ON pp2.PatNum = p.PatNum
AND pp2.Ordinal = 2 -- Secondary
LEFT JOIN inssub ins2
ON ins2.InsSubNum = pp2.InsSubNum
LEFT JOIN insplan ip2
ON ip2.PlanNum = ins2.PlanNum
LEFT JOIN carrier c2
ON c2.CarrierNum = ip2.CarrierNum
WHERE a.aptdatetime BETWEEN @FromDate AND @ToDate + INTERVAL 1 DAY;
Claims of status 'Sent' by Date of Service with PatNum, Amount billed insurance, Amount billed patient and Date sent. - Edit Dates to change date of service range.
/*541 Claims of status 'Sent' by Date of Service with PatNum, Amount billed insurance, Amount billed patient and Date sent.
Edit Dates to change date of service range.*/
SET @FromDate='2009-01-01' , @ToDate='2011-01-31';
SELECT cl.PatNum, p.PatNum AS 'RawPatNum',cl.DateService,cl.DateSent,
ca.CarrierName, ca.Phone, cl.ClaimFee,
(SELECT SUM(ProcFee)-SUM(cp.WriteOff) FROM procedurelog pl INNER JOIN claimproc cp ON pl.ProcNum=cp.ProcNum WHERE cp.ClaimNum=cl.ClaimNum) AS '$PatBilled'
FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE
cl.ClaimType<>'PreAuth' AND (cl.ClaimStatus='S') AND
(DateService BETWEEN @FromDate AND @ToDate)
ORDER BY ca.CarrierName,p.LName;
Finds procedures in a date range where the writeoff does not match the writeoffest, or the writeoffestoverride. - Edit Dates to change date of insurance payment range.
/*542 Finds procedures in a date range where the writeoff does not match the writeoffest, or the writeoffestoverride.*/
/* Edit Dates to change date of insurance payment range.*/
SET @FromDate='2009-01-01' , @ToDate='2012-01-31';
SELECT c.PatNum,c.ProcDate,c.DateCP,pc.ProcCode, p.ProcFee, c.CodeSent,
IF(c.Status=4,'Sup','Rec') AS Status,
IF(WriteOffEst=-1,0,WriteOffEst) AS WOffEst,
IF(WriteOffEstOverride=-1,0,WriteOffEstOverride) AS WOEstOver,
WriteOff
FROM claimproc c
INNER JOIN procedurelog p ON c.ProcNum=p.ProcNum
INNER JOIN procedurecode pc ON pc.CodeNum=p.CodeNum
WHERE IF(WriteOffEstOverride=-1,IF(WriteOffEst=-1,0,WriteOffEst),WriteOffEstOverride)<>c.WriteOff
AND c.DateCP BETWEEN @FromDate AND @ToDate
AND c.Status IN (1,4)
ORDER BY c.DateCP DESC;
Find procedures in a date range where the writeoffestoverride has been used. - Edit Dates to change date of insurance payment range.
/*543 Find procedures in a date range where the writeoffestoverride has been used.*/
/* Edit Dates to change date of insurance payment range.*/
SET @FromDate='2009-01-01' , @ToDate='2012-01-31';
SELECT c.PatNum,c.ProcDate,c.DateCP,pc.ProcCode, p.ProcFee, c.CodeSent,
IF(c.Status=4,'Sup','Rec') AS Status,
IF(WriteOffEst=-1,0,WriteOffEst) AS WOffEst,
IF(WriteOffEstOverride=-1,0,WriteOffEstOverride) AS WOEstOver,
WriteOff
FROM claimproc c
INNER JOIN procedurelog p ON c.ProcNum=p.ProcNum
INNER JOIN procedurecode pc ON pc.CodeNum=p.CodeNum
WHERE WriteOffEstOverride<>-1
AND c.DateCP BETWEEN @FromDate AND @ToDate
AND c.Status IN (1,4)
ORDER BY c.DateCP DESC;
Finds procedures in a date range where the writeoff is greater than writeoffest or the writeoffestoverride, also includes remarks. - Edit Dates to change date of insurance payment range.
/*544 Finds procedures in a date range where the writeoff is greater than writeoffest or the writeoffestoverride, also includes remarks.*/
/* Edit Dates to change date of insurance payment range.*/
SET @FromDate='2009-01-01' , @ToDate='2012-01-31';
SELECT c.PatNum,c.ProcDate,c.DateCP,pc.ProcCode, p.ProcFee, c.CodeSent,
IF(c.Status=4,'Sup','Rec') AS Status,
IF(WriteOffEst=-1,0,WriteOffEst) AS WOffEst,
IF(WriteOffEstOverride=-1,0,WriteOffEstOverride) AS WOEstOver,
WriteOff,c.Remarks
FROM claimproc c
INNER JOIN procedurelog p ON c.ProcNum=p.ProcNum
INNER JOIN procedurecode pc ON pc.CodeNum=p.CodeNum
WHERE IF(WriteOffEstOverride=-1,IF(WriteOffEst=-1,0,WriteOffEst),WriteOffEstOverride)<c.WriteOff
AND c.DateCP BETWEEN @FromDate AND @ToDate
AND c.Status IN (1,4)
ORDER BY c.DateCP DESC;
Monthly uninsured and insured new patients over a period. - See #106 for a count of uninsured and insured over date range.
/*545 Monthly uninsured and insured new patients over a period.*/
/*See #106 for a count of uninsured and insured over date range.*/
SET @FromDate='2005-01-01', @ToDate='2011-03-31';
SELECT YEAR(DateFirstVisit) AS Year, MONTH(DateFirstVisit) AS Month, SUM(IF(ISNULL(pp.PatNum),0,1)) AS 'Insured Count', SUM(IF(ISNULL(pp.PatNum),1,0)) AS 'Uninsured Count'
FROM patient p
LEFT JOIN patplan pp ON pp.PatNum=p.PatNum AND pp.Ordinal=1
WHERE p.DateFirstVisit BETWEEN @FromDate AND @ToDate
GROUP BY Year DESC, Month DESC;
New Patient Production in a time period, where the patient was new in time span and procedures were completed in time span. -
/*546 New Patient Production in a time period, where the patient was new in time span and procedures were completed in time span.*/
SET @FromDate='2010-01-01', @ToDate='2010-12-31';
SET @pos=0;
SELECT @pos:=@pos+1 AS numberofpatients, pl.PatNum, A.DateFirstVisit, SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) AS $GrossProd
FROM procedurelog pl
INNER JOIN
(SELECT pl2.PatNum, MIN(pl2.ProcDate) AS 'DateFirstVisit' FROM procedurelog pl2 WHERE pl2.ProcStatus=2 GROUP BY pl2.PatNum)
A ON A.PatNum=pl.PatNum
WHERE pl.ProcStatus=2 /*complete*/ AND (pl.ProcDate BETWEEN @FromDate AND @ToDate)
AND (DATE(A.DateFirstVisit) BETWEEN @FromDate AND @ToDate)
GROUP BY pl.PatNum
ORDER BY DateFirstVisit;
Lists ALL active patients and referral source. - For Versions 17.1 and greater. Please update your version accordingly
/*547 Lists ALL active patients and From referral sources.*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/16/2018*/
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT p.LName,
p.FName,
r.LName AS FromLName,
r.FName AS FromFName
FROM patient p
LEFT JOIN refattach ra ON ra.PatNum=p.PatNum
AND ra.RefType = 1 /*RefFrom*/
LEFT JOIN referral r ON r.ReferralNum=ra.ReferralNum
WHERE PatStatus=0/*active Patients*/
ORDER BY p.LName, p.FName;
Guarantors in collections with positive balances. - Includes address, balance, employer, date of birth and date last seen in family, where last seen date more than 120 Days ago.
/*548 Guarantors in collections with positive balances. Includes address, balance, employer, date of birth and date last seen in family, where last seen date more than 120 Days ago*/
SELECT * FROM (
SELECT
g.FName, g.LName,
'Bozart' AS 'Company',
g.Address, g.Address2, g.City, g.State, g.Zip,
g.BirthDate,
g.SSN, e.EmpName, g.PatNum AS 'ClientRefNum',
(SELECT MAX(pl.ProcDate)
FROM procedurelog pl
INNER JOIN patient p ON p.PatNum=pl.PatNum
WHERE pl.ProcStatus=2 AND p.Guarantor=g.PatNum) AS 'DateLastSeen',
g.BalTotal
FROM patient g
INNER JOIN definition d ON d.DefNum=g.BillingType
LEFT JOIN employer e ON g.EmployerNum=e.EmployerNum
WHERE g.Guarantor=g.PatNum AND
d.ItemName LIKE ('%collection%') AND
BalTotal>0.001
)A WHERE DateLastSeen<(CurDate()-INTERVAL 120 Day)
ORDER BY LName, FName;
Search for Check by Check Number, includes deposit date. -
/*549 Search for Check by Check Number, includes deposit date*/
SET @Check='%123%';
SELECT patient.PatNum,
CONCAT(patient.LName,', ',patient.FName,' ',patient.MiddleI) AS Name,
claimpayment.CheckDate,
carrier.CarrierName,claimpayment.CheckNum,
claimproc.ClaimNum,SUM(claimproc.InsPayAmt ) AS $ChkAmt, deposit.DateDeposit
FROM claimpayment
INNER JOIN claimproc ON claimproc.ClaimPaymentNum = claimpayment.ClaimPaymentNum
INNER JOIN insplan ON claimproc.PlanNum = insplan.PlanNum
INNER JOIN patient ON claimproc.PatNum = patient.PatNum
INNER JOIN carrier ON carrier.CarrierNum = insplan.CarrierNum
LEFT JOIN deposit ON claimpayment.DepositNum=deposit.DepositNum
WHERE claimpayment.CheckNum LIKE(@Check)
GROUP BY claimproc.ClaimNum ORDER By CarrierName;
Possible duplicate patients with identical first and last name with birthdate and preferred name listed. -
/*550 Possible duplicate patients with identical first and last name with birthdate and preferred name listed.*/
SELECT p.PatNum AS PatNumber, p.LName, p.FName, p.Preferred, p.BirthDate, A.DupCount FROM
patient p
INNER JOIN
(SELECT LName, FName, PatStatus, COUNT(*) AS DupCount FROM patient WHERE PatStatus<>4 GROUP BY LName, FName HAVING COUNT(*)>1) A
ON A.LName=p.LName AND A.FName=p.FName
WHERE p.PatStatus<>4;
Very Likely duplicate patients with identical first name, last name, birthdate and preferred name. -
/*551 Very Likely duplicate patients with identical first name, last name, birthdate and preferred name.*/
SELECT p.PatNum AS PatNumber, p.LName, p.FName, p.Preferred, p.BirthDate, A.DupCount FROM
patient p
INNER JOIN
(SELECT LName, FName, Preferred, BirthDate, COUNT(*) AS DupCount FROM patient WHERE PatStatus<>4 GROUP BY LName, FName, Preferred, Birthdate HAVING COUNT(*)>1) A
ON A.LName=p.LName AND
A.FName=p.FName AND
A.Preferred=p.Preferred AND
A.BirthDate=p.BirthDate
WHERE p.PatStatus<>4;
List of all providers who saw patients in a date range. - With date of first and last procedure completion in date range.
/*552 List of all providers who saw patients in a date range. With date of first and last procedure completion in date range.*/
SET @FromDate='2000-01-01', @ToDate='2020-12-31';
SELECT pr.LName, pr.FName, MIN(ProcDate) AS DateFirst, MAX(ProcDate) AS DateLast
FROM procedurelog pl INNER JOIN provider pr ON pl.ProvNum=pr.ProvNum
WHERE ProcStatus=2 /*complete*/ AND
ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY pr.ProvNum;
Payments to accounts of defined billing type in date range. - Put billing type, e.g. Standard Account, in place of billingtypehere.
/*553 Payments to accounts of defined billing type in date range.*/
/*Put billing type, e.g. Standard Account, in place of billingtypehere.*/
SET @FromDate='2011-01-01', @ToDate='2011-03-31';
SELECT p.PatNum, ItemName, SplitAmt,FORMAT(SplitAmt/7.5, 2) AS $eCW, DatePay
FROM patient p
INNER JOIN paysplit ps ON p.PatNum=ps.PatNum
INNER JOIN definition d ON p.BillingType=d.DefNum
WHERE ItemName LIKE('%billingtypehere%')AND DatePay BETWEEN @FromDate AND @ToDate
ORDER BY p.LName,FName;
Shows patients with missing teeth. -
/*554 Shows patients with missing teeth.*/
/*Query code written/modified on: 08/09/2018*/
SELECT
p.PatNum AS 'Pat Num',
CONCAT( -- Build a name string like OD's default
TRIM(p.LName),
',',
(CASE WHEN LENGTH(TRIM(p.Preferred)) > 0 THEN CONCAT(' \'', TRIM(p.Preferred),'\'') ELSE '' END), -- Display preferred if we have one
' ',
TRIM(p.FName),
(CASE WHEN LENGTH(TRIM(p.MiddleI)) > 0 THEN CONCAT(' ', TRIM(p.MiddleI)) ELSE '' END) -- Display middle initial if we have one
) AS 'PatientName',
GROUP_CONCAT(ti.ToothNum) AS 'Teeth'
FROM patient p
INNER JOIN toothinitial ti
ON p.PatNum = ti.PatNum
AND ti.ToothNum NOT IN (1,16,17,32) -- Wisdoms
AND ti.InitialType = 0 -- Missing
GROUP BY p.PatNum
ORDER BY p.LName, p.FName;
Active Patients referred in date range with ref source and phone numbers. - For Versions 17.1 and greater. Please update your version accordingly. Sorted by ref source, then patient LName.
/*555 Active Patients referred in date range with ref source and phone numbers. Sorted by ref source, then patient LName.*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/16/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2018-01-01', @ToDate='2018-03-31';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT p.LName, p.FName, LEFT(CONCAT(p.HmPhone, " - ", p.WkPhone, " - ",p.WirelessPhone),50) AS 'Hm-Wk-Cell Phone numbers',
r.LName AS FromLName,
r.FName AS FromFName,
ra.RefDate
FROM patient p
LEFT JOIN refattach ra ON ra.PatNum=p.PatNum
AND ra.RefType = 1 /*RefFrom*/
LEFT JOIN referral r ON r.ReferralNum=ra.ReferralNum
WHERE PatStatus=0/*active Patients*/
AND ra.RefDate BETWEEN @FromDate AND @ToDate
ORDER BY r.LName ASC, r.FName ASC, p.LName ASC, p.FName ASC, ra.RefDate ASC;
Average Daily Production by provider. -
/*556 Average Daily Production by provider. Will show $0 for ave if there were 0 days worked*/
/*Query code written/modified: 11/13/2014*/
SET @FromDate='2014-10-01', @ToDate='2014-10-31';
SELECT *, $GrossProd+$Adjustments-$Writeoffs $NetProd,
$GrossProd/DaysWorked $AveGrossPr,
($GrossProd+$Adjustments-$Writeoffs)/DaysWorked $AveNetPr
FROM (
SELECT pr.Abbr,
pr.LName,
pr.FName,
COALESCE(( SELECT COUNT(DISTINCT pl.ProcDate)
FROM procedurelog pl
WHERE pl.ProvNum=pr.ProvNum
AND pl.ProcStatus=2
AND (pl.ProcDate BETWEEN @FromDate AND @ToDate)
),0) DaysWorked,
COALESCE(( SELECT SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits))-IFNULL(SUM(cp.WriteOff),0)
FROM procedurelog pl
LEFT JOIN claimproc cp ON pl.ProcNum=cp.ProcNum
AND cp.Status='7'
WHERE pl.ProvNum=pr.ProvNum
AND pl.ProcStatus=2
AND (pl.ProcDate BETWEEN @FromDate AND @ToDate)
),0) $GrossProd,
COALESCE(( SELECT SUM(cp.WriteOff)
FROM claimproc cp
WHERE cp.Status IN(1,4) /*received, supplemental*/
AND cp.ProvNum=pr.ProvNum
AND (cp.DateCP BETWEEN @FromDate AND @ToDate)
),0) $Writeoffs,
COALESCE(( SELECT SUM(a.AdjAmt)
FROM adjustment a
WHERE a.ProvNum=pr.ProvNum
AND (a.AdjDate BETWEEN @FromDate AND @ToDate)
),0) $Adjustments
FROM provider pr
) A;
Patients addresses, seen or to be seen in given date range, who have insurance. -
/*557 Patients addresses, seen or to be seen in given date range, who have insurance.*/
SET @FromDate='2011-03-01', @ToDate='2011-03-31';
SELECT g.LName, g.FName, g.Address, g.Address2, g.City, g.State, g.Zip FROM
appointment a
INNER JOIN patient p ON p.PatNum=a.PatNum
INNER JOIN patient g ON p.Guarantor=g.PatNum
WHERE (DATE(a.AptDateTime) BETWEEN @FromDate AND @ToDate) AND
a.AptStatus IN (1,2,4) AND p.HasIns='I'
GROUP BY g.PatNum ORDER BY g.LName;
Ins income by provider for date range. -
/*558 Ins income by provider for date range.*/
SET @Start='2007-01-01' , @Before='2011-01-01';
/*Adjust above Dates as needed*/
SELECT cp.ProvNum, CarrierName, SUM(InsPayAmt) AS $Income
FROM claimpayment c
INNER JOIN claimproc cp ON cp.ClaimPaymentNum=c.ClaimPaymentNum
WHERE CheckDate >= @Start
AND CheckDate < @Before
GROUP BY ProvNum,CarrierName
ORDER by Provnum, CarrierName;
Procedures with a given string in the notes. -
/*559 Procedures with a given string in the notes.*/
SET @StartDate='2011-03-01', @EndDate='2011-03-31';
SELECT pl.PatNum, pl.PatNum AS 'Pat_Num',pc.ProcCode,pl.ToothNum,pl.ProcFee AS $ProcFee,pn.note
FROM procedurelog pl
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
INNER JOIN patient p ON p.PatNum=pl.PatNum
INNER JOIN procnote pn ON pn.ProcNum=pl.ProcNum
WHERE pl.ProcDate BETWEEN @StartDate AND @EndDate AND pl.ProcStatus=2 /*completed procedures only*/
AND pn.Note LIKE('%tooth%') /*change keyword/phrase here*/
AND pn.EntryDateTime=(SELECT MAX(n2.EntryDateTime)
FROM procnote n2
WHERE pn.ProcNum = n2.ProcNum) /*this looks at only the latest note, the one you see without turning on audit*/
GROUP BY pl.ProcNum
ORDER BY pl.ProcDate DESC, p.LName, p.FName;
Outstanding insurance claims by Date of Service for a date range not including Preauths. - With fee total and subscriber information.
/*560 Outstanding insurance claims by Date of Service for a date range not including Preauths. With fee total and subscriber information*/
SET @ServiceFromDate='2008-01-01' , @ServiceToDate='2011-03-31';
SELECT LEFT(ca.CarrierName,15) AS Carrier, ca.Phone,cl.PatNum,p.BirthDate, isb.SubScriberID, ps.BirthDate AS DateSuBir, cl.DateService /*,cl.DateSent*/, cl.ClaimFee FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN inssub isb ON cl.InsSubNum=isb.InsSubNum
INNER JOIN insplan i ON i.PlanNum=isb.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
INNER JOIN patient ps ON ps.PatNum=isb.Subscriber
WHERE cl.ClaimStatus='S' AND
(DateService BETWEEN @ServiceFromDate AND @ServiceToDate)
AND ClaimType<>'PreAuth'
ORDER BY cl.DateService;
List fees and procedures on fee schedules where the fee is higher that the standard fee (or whatever fee schedule name you specify) - Useful for finding errors or fees that you should raise to match PPO fees
/*561 List fees and procedures on fee schedules where the fee is higher that the standard fee (or whatever fee schedule name you specify) Useful for finding errors or fees that you should raise to match PPO fees*/
SET @FeeSchedName='Standard';
SELECT A.Amount AS StandardFee, B.Amount AS OtherFee, B.FeeSched, B.CodeNum, C.ProcCode FROM Fee A
INNER JOIN Fee B ON A.CodeNum=B.CodeNum
LEFT OUTER JOIN ProcedureCode C ON B.CodeNum=C.CodeNum
WHERE (A.Feesched=(select feeschednum from feesched where (description= @FeeSchedName) and (ishidden = 0) limit 1)) AND (A.Amount < B.Amount)
ORDER BY B.FeeSched, C.ProcCode;
Aging report for patients that are insurance subscribers, with subscriber ID numbers. -
/*577 Aging report for patients that are insurance subscribers, with subscriber ID numbers. */
SELECT DISTINCTROW SubscriberID, CONCAT(LName,', ',FName,' ',MiddleI) AS Patient
,Bal_0_30,Bal_31_60,Bal_61_90,BalOver90
,BalTotal,InsEst,BalTotal-InsEst AS $pat
FROM patient
INNER JOIN inssub ins ON patient.PatNum=ins.Subscriber
WHERE (patstatus != 2)
AND (Bal_0_30 > '.005' OR Bal_31_60 > '.005' OR Bal_61_90 > '.005' OR BalOver90 > '.005'
OR BalTotal < '-.005')
ORDER BY LName,FName;
Claims of status 'Sent' or 'Recieved' limited by Sent Date with Patient Name, Amount billed insurance, Amount billed patient and Date sent - Edit Dates to change date of claim last sent range
/*578 Claims of status 'Sent' or 'Recieved' limited by Sent Date with Patient Name, Amount billed insurance, Amount billed patient and Date sent
Edit Dates to change date of claim last sent range*/
SET @SentFromDate='2011-03-23' , @SentToDate='2011-05-06';
SELECT cl.PatNum, /*p.PatNum AS 'RawPatNum',*/cl.DateService,cl.DateSent, cl.ClaimStatus As 'Rec',
LEFT(ca.CarrierName,12) AS Carrier, ca.Phone, cl.ClaimFee, cl.InsPayEst, cl.InsPayAmt,
(SELECT SUM(ProcFee)-SUM(cp.WriteOff) FROM procedurelog pl INNER JOIN claimproc cp ON pl.ProcNum=cp.ProcNum WHERE cp.ClaimNum=cl.ClaimNum) AS '$PatBilled',
(SELECT SUM(ProcFee)-SUM(cp.WriteOff) FROM procedurelog pl INNER JOIN claimproc cp ON pl.ProcNum=cp.ProcNum WHERE cp.ClaimNum=cl.ClaimNum)-
(CASE WHEN cl.ClaimStatus='R' THEN cl.InsPayAmt ELSE cl.InsPayEst END) AS $PatPortion
FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE
cl.ClaimType<>'PreAuth' AND (cl.ClaimStatus='R' OR cl.ClaimStatus='S') AND
(DateSent BETWEEN @SentFromDate AND @SentToDate)
ORDER BY ca.CarrierName,p.LName;
Claims of status 'Sent' or 'Received' limited by Service Date with Patient Name, Amount billed insurance, Amount billed patient and Date sent - Edit Dates to change service range.
/*579 Claims of status 'Sent' or 'Received' limited by Service Date with Patient Name, Amount billed insurance, Amount billed patient and Date sent
Edit Dates to change service range*/
SET @ServiceFromDate='2011-03-23' , @ServiceToDate='2011-05-06';
SELECT cl.PatNum, /*p.PatNum AS 'RawPatNum',*/cl.DateService,cl.DateSent, cl.ClaimStatus As 'Rec',
LEFT(ca.CarrierName,12) AS Carrier, ca.Phone, cl.ClaimFee, cl.InsPayEst, cl.InsPayAmt,
(SELECT SUM(ProcFee)-SUM(cp.WriteOff) FROM procedurelog pl INNER JOIN claimproc cp ON pl.ProcNum=cp.ProcNum WHERE cp.ClaimNum=cl.ClaimNum) AS '$PatBilled',
(SELECT SUM(ProcFee)-SUM(cp.WriteOff) FROM procedurelog pl INNER JOIN claimproc cp ON pl.ProcNum=cp.ProcNum WHERE cp.ClaimNum=cl.ClaimNum)-
(CASE WHEN cl.ClaimStatus='R' THEN cl.InsPayAmt ELSE cl.InsPayEst END) AS $PatPortion
FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE
cl.ClaimType<>'PreAuth' AND (cl.ClaimStatus='R' OR cl.ClaimStatus='S') AND
(DateService BETWEEN @ServiceFromDate AND @ServiceToDate)
ORDER BY ca.CarrierName,p.LName;
Daily procedures report with writeoff column and fee-writeoff column and claim procedure status. - Does not show description or clinic can be limited by provider.
/*580 Daily procedures report with writeoff column and fee-writeoff column and claim procedure status, does not show description or clinic
can be limited by provider*/
SET @ProvAbbr='DrZora'; /*Put provider abbreviation in single quotes*/
SET @FromDate= '2011-08-01', @ToDate='2011-08-31'; /*change dates here*/
SELECT pl.ProcDate,pa.PatNum, ProcCode,
pl.ToothNum,pr.Abbr,pl.ProcFee AS $Fee, -SUM(claimproc.WriteOff) AS '$Writeoff', pl.ProcFee-SUM(claimproc.WriteOff) AS '$Fee-Writeoff',
GROUP_CONCAT(CASE WHEN claimproc.Status=0 THEN 'Sent'
WHEN claimproc.Status=1 THEN 'Received'
WHEN claimproc.Status=4 THEN 'Supplemental'
WHEN claimproc.Status=5 THEN 'Estimate'
ELSE 'Capitation' END) AS Status
FROM patient pa,procedurecode pc, provider pr, procedurelog pl
LEFT JOIN claimproc ON pl.ProcNum=claimproc.ProcNum AND claimproc.Status IN (1,0,4,5,6,7,8)
WHERE pl.ProcStatus = '2'
AND pl.CodeNum=pc.CodeNum
AND pa.PatNum=pl.PatNum
AND pr.ProvNum=pl.ProvNum
AND pl.ProcDate >=@FromDate
AND pl.ProcDate <=@ToDate
AND pr.Abbr = @ProvAbbr
GROUP BY pl.ProcNum
ORDER BY pl.ProcDate,pa.LName, pa.FName;
List of Patients with balance over 90 days AND Billing Type is "Bad Debt-Sent to collections" - Includes Patients Name, Patient Address, Phone Numbers, SSN, DOB, Patnum, Last Date of Service, Date of Last Payment, Last Amount Paid, Balance Due Amount.
/*590 List of Patients with balance over 90 days AND Billing Type is "Bad Debt-Sent to collections". Includes Patients Name, Patient Address, Phone Numbers, SSN, DOB, Patnum, Last Date of Service, Date of Last Payment, Last Amount Paid, Balance Due Amount*/
SELECT p.LName, p.FName, p.PatNum AS 'PatNo.',p.HmPhone,p.WkPhone,p.WirelessPhone AS Wireless, p.SSN, p.BirthDate,
(SELECT MAX(pl.ProcDate)
FROM procedurelog pl
INNER JOIN patient p2 ON p2.PatNum=pl.PatNum
WHERE pl.ProcStatus=2 AND p2.Guarantor=p.PatNum) AS 'DateLastSeen',
(SELECT MAX(ps.DatePay)
FROM paysplit ps
INNER JOIN patient p2 ON p2.PatNum=ps.PatNum
WHERE p2.Guarantor=p.PatNum) AS 'DateLastPaid',
(SELECT SUM(ps.SplitAmt) FROM paysplit ps
INNER JOIN patient p3 ON p3.PatNum=ps.PatNum
WHERE p3.Guarantor=p.PatNum AND ps.DatePay=
(SELECT MAX(ps.DatePay)
FROM paysplit ps
INNER JOIN patient p2 ON p2.PatNum=ps.PatNum
WHERE p2.Guarantor=p.PatNum)) AS $AmtLastPaid,
p.Address, p.Address2, p.City,p.State, p.ZIP,p.BalTotal
FROM patient p
INNER JOIN definition d ON p.BillingType=d.DefNum
WHERE ItemName LIKE('%Sent to Collections%') AND
p.BalTotal>.005 AND p.BalOver90>.005
Provider summed report: gross production, patient income, insurance income, hours worked (by provider time checked in appointments) for a given date range. - Change dates below, both the start and end dates are included in the results.
/*591 Provider summed report: gross production, patient income, insurance income, hours worked (by provider time checked in appointments) for a given date range, change dates below, both the start and end dates are included in the results*/
SET @FromDate='2011-09-07' , @ToDate='2011-09-13'; /*dates include start and end*/
SELECT pr.Abbr, IFNULL(SUM(CHAR_LENGTH(REPLACE(ap.Pattern, '/',''))*5/60),0) AS HrsWorked,
(SELECT SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) FROM procedurelog pl WHERE pl.ProvNum=pr.ProvNum AND pl.ProcStatus=2 AND (pl.ProcDate BETWEEN @FromDate AND @ToDate)) $RawProduction,
IFNULL((SELECT SUM(ps.SplitAmt) FROM paysplit ps WHERE ps.ProvNum=pr.ProvNum AND (ps.DatePay BETWEEN @FromDate AND @ToDate)),0) AS $PatPay,
IFNULL((SELECT SUM(cp.InsPayAmt) FROM claimpayment cy
INNER JOIN claimproc cp ON cp.ClaimPaymentNum=cy.ClaimPaymentNum /*this join isn't needed for the date or amount, it is included to make sure there was a check made*/ WHERE cp.ProvNum=pr.ProvNum AND (cy.CheckDate BETWEEN @FromDate AND @ToDate)),0) AS $InsPay
FROM provider pr
LEFT JOIN appointment ap ON pr.ProvNum=ap.ProvNum AND ap.AptStatus=2 AND (DATE(ap.AptDateTime) BETWEEN @FromDate and @ToDate)
GROUP BY pr.ProvNum;
New patients in last 30 days with no follow-up appointment. Shows Primary Provider, Patient Name, $ TP Amount, homephone number and First visit date. - Could also show one provider seen on date of first visit.
/*592 New patients in last 30 days with no follow-up appointment. Shows Primary Provider, Patient Name, $ TP Amount, homephone number and First visit date, could also show one provider seen on date of first visit*/
SET @FromDate=CURDATE()-INTERVAL 30 DAY, @ToDate=CURDATE(); /*you can also put dates in in this exact format '2011-01-25'*/
SELECT * FROM
(SELECT /*A.ProvNum,*/pr.Abbr, p.PatNum, p.HmPhone, A.FirstVisit,
FORMAT(IFNULL((SELECT SUM(pl2.ProcFee) FROM procedurelog pl2 WHERE pl2.PatNum=p.PatNum AND pl2.ProcStatus=1/*tp*/),0),2) AS $TreatmentPlan,
IFNULL((SELECT DATE_FORMAT(MIN(ap.AptDateTime),'%m-%d-%Y') FROM appointment ap WHERE ap.PatNum=p.PatNum AND DATE(ap.AptDateTime)>DATE(A.FirstVisit) AND ap.AptStatus IN ('1','2')),'NONE') AS NextVisit
FROM
(SELECT pl.PatNum,pl.ProvNum, MIN(pl.ProcDate) AS FirstVisit
FROM procedurelog pl
WHERE pl.ProcStatus=2
GROUP BY pl.PatNum)A
INNER JOIN patient p ON p.PatNum=A.PatNum
INNER JOIN provider pr ON pr.ProvNum=p.PriProv
WHERE (A.FirstVisit BETWEEN @FromDate AND @ToDate)
GROUP BY p.PatNum
ORDER BY pr.Abbr)B
WHERE NextVisit='NONE';
Aging and balance summed by primary provider of guarantor. - Note: one would likely see a skew toward the default practice provider, this would be correted over time as you fix the priprov of the guarantors.
/*593 Aging and balance summed by primary provider of guarantor
Note 1: one would likely see a skew toward the default practice provider, this would be correted over time as you fix the priprov of the guarantors. Note 2: you could add a seperate column for sum of payables (neg balances) and sum of receivables (positive balances) for each provider as well because a credit of 400 and a debt of 400 are not the same as a pure 0 account.
There would be no additional charge */
SELECT PriProv, SUM(Bal_0_30), SUM(Bal_31_60), SUM(Bal_61_90),
SUM(BalOver90), SUM(InsEst), SUM(BalTotal),
(SUM(BalTotal) -SUM(InsEst)) AS $PatPortion
FROM patient p
GROUP BY PriProv;
Guarantors of families in which none of the active patients have been seen on or after a given date, where no member of the family has listed insurance carrier(s) -
/*594 Guarantors of families in which none of the active patients have been seen on or after a given date,
where no member of the family has listed insurance carrier(s) */
SET @BeforeDate='2011-06-13';
SELECT A.*
FROM
(
SELECT g.PatNum,g.LName, g.FName, g.Address, g.Address2, g.City, g.State, g.Zip, MAX(pl.ProcDate) AS 'DateLastSeen'
FROM patient p
INNER JOIN patient g ON g.PatNum=p.Guarantor
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum
WHERE pl.ProcStatus=2 AND p.PatStatus=0
GROUP BY g.PatNum
HAVING MAX(pl.ProcDate) < @BeforeDate
)A WHERE (SELECT COUNT(*) FROM patplan pp
INNER JOIN patient p2 ON p2.PatNum=pp.PatNum
INNER JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
INNER JOIN insplan ip ON ip.PlanNum=ib.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=ip.CarrierNum AND (ca.CarrierName ='Dentical' OR ca.CarrierName='Delta Dental Healthy Family')
WHERE p2.Guarantor=A.PatNum)=0
ORDER BY A.LName, A.FName;
New patients in date range with exam type (edit if needed), insured flag, dollars treatment planned, amount paid at first visit, and date of subsequent visit scheduled or complete, also returns a provnum for one of the procedures and the username that set - Edit as needed.
/*595 New patients in date range with exam type (edit if needed), insured flag, dollars treatment planned, amount paid at first visit, and date of subsequent visit scheduled or complete, also returns a provnum for one of the procedures and the username that set complete specified procedure on the date of first visit (edit as needed)*/
SET @FromDate='2010-01-01', @ToDate='2010-01-05';
SELECT A.ProvNum,p.LName, p.FName, A.FirstVisit,
(CASE WHEN GROUP_CONCAT(pc.ProcCode) LIKE('%D0150%') THEN 'D0150'
WHEN GROUP_CONCAT(pc.ProcCode) LIKE('%D0140%') THEN 'D0140'
WHEN GROUP_CONCAT(pc.ProcCode) LIKE('%D0120%') THEN 'D0120'
WHEN GROUP_CONCAT(pc.ProcCode) LIKE('%D0160%') THEN 'D0160'
WHEN GROUP_CONCAT(pc.ProcCode) LIKE('%D0170%') THEN 'D0170'
WHEN GROUP_CONCAT(pc.ProcCode) LIKE('%D0180%') THEN 'D0180'
ELSE 'NONE' END) AS 'ExamType',
IFNULL( (SELECT UserOD.UserName FROM securitylog sl INNER JOIN UserOD ON sl.UserNum=UserOD.UserNum WHERE DATE(sl.LogDateTime)=DATE(A.FirstVisit) AND sl.PatNum=p.PatNum AND sl.PermType=23 /*completing procedure*/
AND LogText LIKE('%D0210%')),'NONE') AS UserName,
(CASE WHEN p.HasIns='I' THEN 'INS' ELSE 'NO INS' END) AS 'Insured',
(SELECT SUM(pl2.ProcFee) FROM procedurelog pl2 WHERE pl2.PatNum=p.PatNum AND pl2.ProcStatus=1/*tp*/) AS $TreatmentPlan,
(SELECT SUM(ps.SplitAmt) FROM paysplit ps WHERE ps.PatNum=p.PatNum AND ps.DatePay=MIN(pl.ProcDate)) AS $PayFirstVisit,
IFNULL((SELECT DATE_FORMAT(MIN(ap.AptDateTime),'%m-%d-%Y') FROM appointment ap WHERE ap.PatNum=p.PatNum AND DATE(ap.AptDateTime)>DATE(A.FirstVisit) AND ap.AptStatus IN ('1','2')),'NONE') AS NextVisit
FROM
(SELECT pl.PatNum,pl.ProvNum, MIN(pl.ProcDate) AS FirstVisit
FROM procedurelog pl
WHERE pl.ProcStatus=2
GROUP BY pl.PatNum)A
INNER JOIN patient p ON p.PatNum=A.PatNum
INNER JOIN procedurelog pl ON pl.PatNum = p.PatNum AND pl.ProcDate=A.FirstVisit
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
WHERE pl.ProcStatus=2 AND (A.FirstVisit BETWEEN @FromDate AND @ToDate)
GROUP BY p.PatNum
ORDER BY A.FirstVisit;
Patient count by Billing Type of patients that have had a particular procedure completed in a given date range. - Edit date range at top.
/*596 Patient count by Billing Type of patients that have had a particular procedure completed in a given date range
edit date range at top*/
SET @FromDate='2011-01-01', @ToDate='2011-12-31';
SELECT d.ItemName AS 'Billing Type', COUNT(DISTINCT p.PatNum)
FROM procedurelog pl
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
INNER JOIN patient p ON p.PatNum=pl.PatNum
INNER JOIN definition d ON p.BillingType=d.DefNum
WHERE pc.ProcCode='D0220' and pl.ProcStatus=2 /*complete*/ AND
(pl.ProcDate BETWEEN @FromDate AND @ToDate)
GROUP BY d.ItemName;
Procedures completed in a given date range with given provider, carrier (so must be in a claim) and that are in a list of D Codes. - Edit date range at top.
/*597 Procedures completed in a given date range with given provider, carrier (so must be in a claim) and that are in a list of D Codes
edit date range at top*/
SET @FromDate='2011-01-01', @ToDate='2011-12-31';
SET @ProvAbbr='DrAbbot' /*put exact provider abbr here in single quotes*/;
SET @CarrierString='%delta%'/*put carrier string match in single quotes and %, like '%blue%' */;
SELECT pl.ProcDate, pl.PatNum,pc.ProcCode, cp.WriteOff AS $WriteOff, CarrierName,pr.Abbr As ProvAbbr
FROM procedurelog pl
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
INNER JOIN patient p ON p.PatNum=pl.PatNum
INNER JOIN claimproc cp ON cp.ProcNum=pl.ProcNum
INNER JOIN insplan ip ON cp.PlanNum = ip.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum = ip.CarrierNum
INNER JOIN provider pr ON pr.ProvNum=pl.ProvNum
WHERE pc.ProcCode IN('D0230', 'D1203', 'D1204', 'D1110', 'D1120', 'D0150', 'D0120', 'D0140', 'D0330', 'D0274', 'D0272', 'D0210', 'D0220') and pl.ProcStatus=2 /*complete*/ AND
(pl.ProcDate BETWEEN @FromDate AND @ToDate) AND CarrierName LIKE(@CarrierString) AND pr.Abbr=@ProvAbbr;
Count of Hygiene Appointments and Distinct Hygiene Patients scheduled in future Date Range. - Only a count.
/*598 Count of Hygiene Appointments and Distinct Hygiene Patients scheduled in future Date Range, only a count*/
/*defined as appointments with one or more hygiene procedures
there are other tables joined here to allow for easy additional information*/
SET @FromDate='2011-10-27' , @ToDate='2020-09-03';
SELECT 'Hyg Apt Count' AS 'Item', COUNT(DISTINCT a.AptNum) AS 'Count' FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
INNER JOIN provider pv ON pl.ProvNum=pv.ProvNum
INNER JOIN appointment a ON pl.AptNum = a.AptNum
WHERE a.AptStatus=1 AND a.AptDateTime BETWEEN @FromDate AND @ToDate AND pc.IsHygiene=1
UNION ALL
SELECT 'Hyg Patient Count' AS 'Item', COUNT(DISTINCT a.PatNum) AS 'Count' FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
INNER JOIN provider pv ON pl.ProvNum=pv.ProvNum
INNER JOIN appointment a ON pl.AptNum = a.AptNum
WHERE a.AptStatus=1 AND a.AptDateTime BETWEEN @FromDate AND @ToDate AND pc.IsHygiene=1
Duplicate Procedures in Date Range. - Edit date range at top.
/*599 Duplicate Procedures in Date Range*/
SET @FromDate='2009-01-01', @ToDate='2011-12-31';
SELECT pl.PatNum,pl.PatNum as 'Pat Num',pc.ProcCode, pl.ToothNum, COUNT(*), pl.ProvNum, DATE(MIN(pl.ProcDate)) AS DateFirst, DATE(MAX(pl.ProcDate)) AS DateLast
FROM procedurelog pl
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
INNER JOIN patient p ON p.PatNum=pl.PatNum
WHERE pc.ProcCode='D8090' and pl.ProcStatus=2 /*complete*/ AND
(pl.ProcDate BETWEEN @FromDate AND @ToDate)
GROUP BY pl.PatNum, pc.ProcCode, pl.ToothNum
HAVING COUNT(*)>1;
New Patients in date range with referral source, current treatment planned production, scheduled production, production completed. - For Versions 17.1 and greater. Please update your version accordingly. All amounts gross production, that is no writeoffs or adjustments considered, base units not considered.
/*600 New Patients in date range with referral source, current treatment planned production, scheduled production, production completed (all amounts gross production, that is no writeoffs or adjustments considered, base units not considered)*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/16/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2018-01-01' , @ToDate='2018-01-31';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SET @pos=0;
SELECT @pos:=@pos+1 AS '#',
C.*
FROM (
SELECT A.DateFirstVisit,
p.PatNum,
r.LName AS RefLName,
r.FName AS RefFName,
A.SumComplete AS '$Complete' ,
B.TreatPlan AS '$TreatPlan',
B.TPSched AS '$TPSched'
FROM patient p
INNER JOIN (
SELECT pl.PatNum,
MIN(pl.ProcDate) AS DateFirstVisit,
SUM(pl.ProcFee) AS SumComplete
FROM procedurelog pl
WHERE pl.ProcStatus=2
GROUP BY pl.PatNum
HAVING MIN(pl.ProcDate) BETWEEN @FromDate AND @ToDate
)A ON A.PatNum=p.PatNum
LEFT JOIN (
SELECT pl2.PatNum,
SUM(pl2.ProcFee) AS TreatPlan,
(
SELECT SUM(pl3.ProcFee)
FROM procedurelog pl3
INNER JOIN appointment ap ON ap.AptNum=pl3.AptNum
WHERE pl3.ProcStatus=1
AND ap.AptStatus=1
AND pl2.PatNum=pl3.PatNum
GROUP BY pl3.PatNum
) AS TPSched
FROM procedurelog pl2
WHERE pl2.ProcStatus=1 /*TP*/
GROUP BY pl2.PatNum
)B ON A.PatNum=B.PatNum
LEFT JOIN refattach ra ON p.PatNum=ra.PatNum
LEFT JOIN referral r ON r.ReferralNum=ra.ReferralNum
AND ra.RefType = 1 /*RefFrom*/
ORDER BY DateFirstVisit, p.LName, p.FName
)C;
List of patients who have had their first and last visits in a date range and don't have any other scheduled appts in the future. -
/*601 List of patients who have had their first and last visits in a date range and don't have any other scheduled appts in the future*/
SET @pos=0, @FromDate='2011-01-01' , @ToDate='2011-12-31';
SELECT p.PatNum, A.DateFirstVisit, B.DateLastVisit /*, C.DateNextApt*/
FROM patient p
INNER JOIN (
SELECT PatNum, MIN(pl.ProcDate) AS DateFirstVisit
FROM procedurelog pl
WHERE pl.ProcStatus=2
GROUP BY pl.PatNum
HAVING MIN(pl.ProcDate) BETWEEN @FromDate AND @ToDate
)A
ON p.PatNum=A.PatNum
INNER JOIN (
SELECT PatNum, MAX(pl.ProcDate) AS DateLastVisit
FROM procedurelog pl
WHERE pl.ProcStatus=2
GROUP BY pl.PatNum
HAVING MIN(pl.ProcDate) BETWEEN @FromDate AND @ToDate
)B
ON p.PatNum=B.PatNum
LEFT JOIN (
SELECT ap.PatNum,MIN(DATE(ap.AptDateTime)) AS DateNextApt
FROM appointment ap
WHERE DATE(ap.AptDateTime)>=CURDATE()
AND ap.AptStatus IN(1,3,4) /*sched, unsched list,ASAP list*/
GROUP BY ap.PatNum
) C
ON p.PatNum=C.PatNum
WHERE ISNULL(DateNextApt);
Patient income (payments made by patient not insurance company) in date range, sorted highest to lowest with age and remaining Treatment Planned total. - SEE REPLICATION WARNING for versions before 14.3.1.
/*602 Patient income (payments made by patient not insurance company) in date range, sorted highest to lowest with birthdate and remaining Treatment Planned total*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @FromDate='2011-01-01' , @ToDate='2011-12-31';
SELECT PatNum, (CASE WHEN (YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5))<120
THEN (YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) ELSE 'NONE' END)
AS 'Age', (SELECT SUM(SplitAmt)
FROM paysplit WHERE paysplit.PatNum=patient.PatNum AND paysplit.DatePay BETWEEN @FromDate AND @ToDate) AS '$PatientPayments',
(SELECT SUM(ProcFee) FROM procedurelog WHERE procedurelog.ProcStatus=1 AND
procedurelog.PatNum=patient.PatNum) AS '$Treatment Planned' FROM
patient ORDER BY $PatientPayments DESC, LName, FName;
/*BROKEN FIX, look up number, sophie at dr mallete, main problem is we are pulling payments based on criteria that then do not include other insurance carriers for which payments were made in date range, may be fixed now, look to other fields that first one*/
/* Production, Income and New Patient Count summed by carrier, for primary insurance only (with patient income, with adjustments and writeoffs, writeoffs by ProcDate)
NOTE: InsPay is insurance payments received in date range, InsProcPay is all payment received at any time for procs completed during date range.
new patients are patient who were new in date range, but production and income is for all patients seen in date range for specified carrier(s)*/
/*more complex of a query than it apears, be ready to get dizzy if you are editing*/
SET @FromDate='2011-06-15' , @ToDate='2011-09-30';
/*1. sums payments by procedures and writeoffs by procedure, this level needed to prevent duplication of patient payments when summing by patient*/
/*2. sum by patient to get the patient payments, also rolling up the proc level payments and proclevel production,
if we do this above we get duplicate patient payment rows if any patient has had more than one procedure done in time span*/
/*3. now we can finally roll up to carrier level, also adding the insurance checks this is a carrier level query,
if we include them above, we get duplicates*/
DROP TABLE IF EXISTS tmp1;
CREATE TABLE tmp1 AS
SELECT C.CarrierName,
(SELECT SUM(CheckAmt) FROM claimpayment cpa WHERE (cpa.CheckDate BETWEEN @FromDate AND @ToDate) AND cpa.CarrierName=C.CarrierName) AS '$InsPay',
SUM(C.$InsProcPay) AS '$InsProcPay',SUM(C.$WriteOff) AS '$WriteOff', SUM($PatientPay) AS '$PatientPay', SUM($PatAdj) AS '$PatAdjust', SUM($Production) AS '$Production',
SUM(C.IsNew) AS NewPatients
FROM (
SELECT B.CarrierName, B.CarrierNum,SUM(B.$InsProcPay) AS $InsProcPay,SUM(B.$WriteOff) AS $WriteOff,
IF((SELECT MIN(pl.ProcDate) FROM procedurelog pl WHERE pl.ProcStatus=2 AND pl.PatNum=B.PatNum) BETWEEN @FromDate AND @ToDate,1,0) AS IsNew,
(SELECT SUM(PayAmt) FROM payment WHERE B.PatNum=payment.PatNum AND (paydate BETWEEN @FromDate AND @ToDate)) AS '$PatientPay',
(SELECT SUM(AdjAmt) FROM adjustment WHERE B.PatNum=adjustment.PatNum AND (adjdate BETWEEN @FromDate AND @ToDate)) AS '$PatAdj',
B.$Production
FROM (
SELECT A.CarrierName, A.CarrierNum,A.PatNum,A.ProcNum,
(SELECT SUM(InsPayAmt) FROM claimproc cpr WHERE cpr.ProcNum=A.ProcNum) AS '$InsProcPay',
(SELECT SUM(Writeoff) FROM claimproc cpr WHERE cpr.ProcNum=A.ProcNum) AS '$WriteOff',
A.ProcFee AS '$Production'
FROM
(/* returns all rows of procedures completed in date range for which the patient has primary insurance currently */
SELECT carrier.carriernum, carrier.CarrierName, pl.ProcNum, p.PatNum, pl.procfee AS procfee
FROM carrier
INNER JOIN insplan ip ON carrier.CarrierNum=ip.CarrierNum
INNER JOIN inssub ib ON ip.PlanNum=ib.PlanNum
INNER JOIN patplan pp ON ib.InsSubNum=pp.InsSubNum AND Ordinal=1
INNER JOIN patient p ON pp.PatNum=p.PatNum
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum AND (pl.ProcDate BETWEEN @FromDate AND @ToDate) AND pl.ProcStatus=2
) A
) B GROUP BY B.PatNum
) C
GROUP BY C.CarrierName
ORDER BY C.CarrierName;
SELECT * FROM tmp1
UNION ALL
SELECT cpa.CarrierName, SUM(CheckAmt) AS '$InsPay',0,0,0,0,0,0 FROM claimpayment cpa WHERE (cpa.CheckDate BETWEEN @FromDate AND @ToDate) AND cpa.CarrierName NOT IN(SELECT DISTINCT CarrierName FROM tmp1);
DROP TABLE IF EXISTS tmp1;
Guarantor Names and Addresses of families with active patients that are not 'new families'. - Specifically where patients in family were seen in date range, like the last three years, where at least one family member was seen in that date range excluding a second date range, that is, families that are active but not new.
/*603 Guarantor Names and Addresses of families with active patients that are not 'new families'. Specifically where patients in family were seen in date range, like the last three years, where at least one family member was seen in that date range excluding a second date range, that is, families that are active but not new*/
SET @FromDate='2008-11-15' , @ToDate='2011-12-01'; /*Usually last three years, returns families that were last seen in this date range*/
SET @NewFromDate='2010-12-01' , @NewToDate='2011-12-01'; /*Usually last year, excludes families where all members as described above were also first seen in this second period, that is, new familes. Entire 'new family' period must be within above 'patient' period*/
SELECT /*COUNT(*), count of family members*/ /*IF(SUM(NewPat)=SUM(LastVisit), 'New', 'Old') AS 'NewOld', indicator if you just want one list*/ A.LName,A.FName, A.Address,A.Address2,A.City,A.State,A.ZIP FROM
(SELECT p.PatNum, g.PatNum AS GPatNum,g.LName, g.FName, g.Address,g.Address2,g.City,g.State,g.ZIP,IF((SELECT MIN(pl.ProcDate) FROM procedurelog pl WHERE pl.ProcStatus=2 AND pl.PatNum=p.PatNum) BETWEEN @NewFromDate AND @NewToDate,1,0) NewPat, IF((SELECT MAX(pl.ProcDate) FROM procedurelog pl WHERE pl.ProcStatus=2 AND pl.PatNum=p.PatNum) BETWEEN @FromDate AND @ToDate,1,0) LastVisit
FROM patient p
INNER JOIN patient g ON g.PatNum=p.Guarantor WHERE p.PatStatus=0)A
GROUP BY A.GPatNum HAVING SUM(NewPat)<>SUM(LastVisit) ORDER BY A.LName;
List of New Families, specifically families where not all of the member patients of those member patients who have been seen in a given period (the active patient period, like three years) were first seen in a second given period (like the last year) -
/*604 List of New Families, specifically families where not all of the member patients of those member patients who have been seen in a given period (the active patient period, like three years) were first seen in a second given period (like the last year)*/
SET @FromDate='2008-11-15' , @ToDate='2011-12-01'; /*Usually last three years, returns families that were last seen in this date range*/
SET @NewFromDate='2010-12-01' , @NewToDate='2011-12-01'; /*Usually last year, excludes families where all members as described above were also first seen in this second period, that is, new familes. Entire 'new family' period must be within above 'patient' period*/
SELECT /*COUNT(*), count of family members*/ /*IF(SUM(NewPat)=SUM(LastVisit), 'New', 'Old') AS 'NewOld', indicator if you just want one list*/ A.LName,A.FName, A.Address,A.Address2,A.City,A.State,A.ZIP FROM
(SELECT p.PatNum, g.PatNum AS GPatNum,g.LName, g.FName, g.Address,g.Address2,g.City,g.State,g.ZIP,IF((SELECT MIN(pl.ProcDate) FROM procedurelog pl WHERE pl.ProcStatus=2 AND pl.PatNum=p.PatNum) BETWEEN @NewFromDate AND @NewToDate,1,0) NewPat, IF((SELECT MAX(pl.ProcDate) FROM procedurelog pl WHERE pl.ProcStatus=2 AND pl.PatNum=p.PatNum) BETWEEN @FromDate AND @ToDate,1,0) LastVisit
FROM patient p
INNER JOIN patient g ON g.PatNum=p.Guarantor WHERE p.PatStatus=0)A
GROUP BY A.GPatNum HAVING SUM(NewPat)=SUM(LastVisit) ORDER BY A.LName;
Procedures completed in date range by other than the Primary Provider - Edit date range.
/*605 Procedures completed in date range by other than the Primary Provider*/
SET @FromDate='2008-11-15' , @ToDate='2011-12-01';
SELECT pr2.Abbr AS 'PriProv', pr1.Abbr AS 'TreatProv', ProcDate, pc.ProcCode,pc.Descript,pl.ProcFee AS '$GrossFee'
FROM procedurelog pl
INNER JOIN provider pr1 ON pl.ProvNum=pr1.ProvNum
INNER JOIN patient p ON p.PatNum=pl.PatNum
INNER JOIN provider pr2 ON pr2.ProvNum=p.PriProv
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
WHERE pl.ProcDate BETWEEN @FromDate AND @ToDate AND pr1.ProvNum<>pr2.ProvNum AND pl.ProcStatus=2
ORDER BY pr2.Abbr, pr1.Abbr, p.LName, p.FName;
Patient visits with no (or zero length) procedure notes or group clinical notes. - Edit date range at top.
/*606 patient visits with no (or zero length) procedure notes or group clinical notes*/
SET @FromDate='2011-07-11' , @ToDate='2011-07-11';/*Set date range here, can be edited to run for current date automatically*/
SELECT pa.PatNum, pa.BirthDate, pa.PatNum AS 'PatIDNum',
pl.ProcDate AS DateApt, GROUP_CONCAT(pc.ProcCode) AS ProcedureCodes, pr.Abbr AS Provider
/*,GROUP_CONCAT(pn.Note SEPARATOR ''),GROUP_CONCAT(pn2.Note SEPARATOR ''),LENGTH(GROUP_CONCAT(pn.Note SEPARATOR '')),LENGTH(GROUP_CONCAT(pn2.Note SEPARATOR ''))*/
FROM procedurelog pl
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
INNER JOIN patient pa ON pa.PatNum=pl.PatNum
INNER JOIN provider pr ON pr.ProvNum=pl.ProvNum
LEFT JOIN procnote pn ON pn.ProcNum=pl.ProcNum AND pn.EntryDateTime=(SELECT MAX(n2.EntryDateTime) FROM procnote n2 WHERE pn.ProcNum = n2.ProcNum) /*this looks at only the latest note, the one you see without turning on audit*/
LEFT JOIN procgroupitem pgi ON pgi.ProcNum=pl.ProcNum
LEFT JOIN procnote pn2 ON pn2.ProcNum=pgi.GroupNum AND pn2.EntryDateTime=(SELECT MAX(n3.EntryDateTime) FROM procnote n3 WHERE pn2.ProcNum = n3.ProcNum) /*this looks at only the latest group note, the one you see without turning on audit*/
WHERE pl.ProcDate BETWEEN @FromDate AND @ToDate AND (pl.ProcStatus=2 OR (pl.ProcStatus=3 AND pc.ProcCode='~GRP~'))
GROUP BY pl.PatNum,pl.ProcDate
HAVING (ISNULL(GROUP_CONCAT(pn.Note SEPARATOR '')) OR LENGTH(GROUP_CONCAT(pn.Note SEPARATOR ''))<1) /*both conditions needed as options, could be a zero length note, must also consider the commas in the group concat*/
AND (ISNULL(GROUP_CONCAT(pn2.Note SEPARATOR '')) OR LENGTH(GROUP_CONCAT(pn2.Note SEPARATOR ''))<1) /*this is for the group note*/ ORDER BY pr.abbr,DateApt;
Active (status) patients with no scheduled apt who have not been in for a time period with the date of their last completed apt. Also shows phone numbers and whether there is pending treatment. - From @daysIntervalStart days ago to @daysIntervalEnd days ago, change the interval currently 365 days: 1 year.
/*607 Active (status) patients with no scheduled apt who have not been in for a time period with the date of their last completed apt. Also shows phone numbers and whether there is pending treatment - (From @daysIntervalStart days ago to @daysIntervalEnd days ago, change the interval currently 365 days: 1 year)*/
SET @ProviderAbbr='' /*put a drs abbreviation between the single quotes to filter, leave as '' to return all*/;
SET @pos=0, @daysIntervalStart=365/*<<<Just normally change this one*/, @daysIntervalEnd=0;
SELECT @pos:=@pos+1 as numberofpatients,A.* FROM
(SELECT patient.PatNum, patient.HmPhone, patient.WkPhone, patient.WirelessPhone, tmp2.AptDateTime AS LastApt,
(TO_DAYS(CURDATE()) - TO_DAYS(tmp2.AptDateTime)) AS 'DaysSince',(CASE WHEN (SELECT COUNT(*) FROM procedurelog pl WHERE pl.ProcStatus=1 /*TP*/ AND pl.PatNum=patient.PatNum)>0 THEN 'Yes' ELSE 'No' END) AS 'TreatmentPending?' ,(SELECT provider.Abbr FROM provider WHERE patient.PriProv=provider.ProvNum) AS Provider
FROM patient
LEFT JOIN (SELECT DISTINCT PatNum FROM appointment WHERE AptStatus=1)/*patients with scheduled appointments*/ tmp1 ON patient.PatNum=tmp1.PatNum
LEFT JOIN (SELECT PatNum, MAX(AptDateTime) AS 'AptDateTime' FROM appointment WHERE AptStatus=2 GROUP BY PatNum) tmp2 ON patient.PatNum=tmp2.PatNum
WHERE tmp1.PatNum IS NULL
AND ((TO_DAYS(CURDATE()) - TO_DAYS(tmp2.AptDateTime)) BETWEEN @daysIntervalEnd AND @daysIntervalStart)
AND patient.PatStatus=0 AND
(CASE WHEN @ProviderAbbr='' THEN '' ELSE (SELECT provider.Abbr FROM provider WHERE patient.PriProv=provider.ProvNum) END)=@ProviderAbbr
GROUP BY tmp2.PatNum
ORDER BY (SELECT provider.Abbr FROM provider WHERE patient.PriProv=provider.ProvNum), patient.LName, patient.FName ASC)A;
Line Item Accounting: Procedures by date range with associated payments and providers, ONLY for clinics splitting patient payments to procedures. - Edit date range at top.
/*608 Line Item Accounting: Procedures by date range with associated payments and providers, ONLY for clinics splitting patient payments to procedures*/
SET @FromDate='2011-11-10' , @ToDate='2011-12-01';/*Set date range here, can be edited to run for current date automatically*/
SELECT *, A.$GrossProd+A.$AllAdj-A.$InsProcPay-A.$PatProcPay AS $Remain FROM
(SELECT pl.ProcDate, LEFT(CONCAT(pa.LName,', ',pa.FName,' ',pa.MiddleI),20) AS Patient, pc.ProcCode, pc.AbbrDesc, pr.Abbr AS Provider,
IFNULL(pl.ProcFee*(pl.UnitQty+pl.BaseUnits),0) AS '$GrossProd',
IFNULL((SELECT SUM(InsPayAmt) FROM claimproc cpr WHERE cpr.ProcNum=pl.ProcNum),0) AS '$InsProcPay',
(SELECT GROUP_CONCAT(DISTINCT pr2.Abbr) FROM claimproc cpr INNER JOIN provider pr2 ON pr2.ProvNum=cpr.ProvNum WHERE cpr.ProcNum=pl.ProcNum) AS 'Ins$Prov',
IFNULL((SELECT SUM(Writeoff) FROM claimproc cpr WHERE cpr.ProcNum=pl.ProcNum),0) + IFNULL((SELECT SUM(AdjAmt) FROM adjustment a WHERE a.ProcNum=pl.ProcNum),0) AS '$AllAdj',
IFNULL((SELECT SUM(SplitAmt) FROM paysplit ps WHERE ps.ProcNum=pl.ProcNum),0) AS '$PatProcPay',
(SELECT GROUP_CONCAT(DISTINCT pr2.Abbr) FROM paysplit ps INNER JOIN provider pr2 ON pr2.ProvNum=ps.ProvNum WHERE ps.ProcNum=pl.ProcNum) AS 'Pat$Prov'
FROM procedurelog pl
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
INNER JOIN patient pa ON pa.PatNum=pl.PatNum
INNER JOIN provider pr ON pr.ProvNum=pl.ProvNum
WHERE pl.ProcDate BETWEEN @FromDate AND @ToDate AND pl.ProcStatus=2
ORDER BY pl.ProcDate, pl.PatNum,pr.Abbr, pc.ProcCode) A
Patients with appointment AND birthday in given time span, with Age, Birthdate, Name, Phone and AptDateTime. - Edit date range at top.
/*609 Patients with appointment AND birthday in given time span, with Age, Birthdate, Name, Phone and AptDateTime*/
SET @FromDate='2011-06-10' , @ToDate='2011-12-01';/*Set date range here*/
SELECT p.LName, p.FName, LEFT(CONCAT(p.HmPhone, " - ", p.WkPhone, " - ",p.WirelessPhone),50) AS 'Hm-Wk-Cell Phone numbers',
(YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) AS 'Age',
p.BirthDate, a.AptDateTime
/*p.Address, p.Address2, p.City, p.State, p.ZIP,p.Email*/
FROM patient p
INNER JOIN appointment a ON a.PatNum=p.PatNum
WHERE ((p.BirthDate + INTERVAL ((YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5))-1) YEAR) BETWEEN @FromDate AND @ToDate OR
(p.BirthDate + INTERVAL (YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) YEAR) BETWEEN @FromDate AND @ToDate OR (p.BirthDate + INTERVAL ((YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5))+1) YEAR) BETWEEN @FromDate AND @ToDate)
AND DATE(a.AptDateTime) BETWEEN @FromDate AND @ToDate
ORDER BY DAY(BirthDate),p.LName, p.FName;
Claim information for specified claim level treating provider , claim level clinic and date range. - NOTES: the reason why we say 'claim level' is because each procedure and each payment (claim proc) can be associate with a provider that may or may not be different from the claim level treating provider. Same is true of clinic. Option is also included
/*610 Claim information for specified claim level treating provider <optional>, claim level clinic <optional> and date range*/
SET @FromDate='2011-11-01' , @ToDate='2011-11-31';/*change date here */
SET @Clinic=''/*if you want to limit by clinic, put clinic name in single quotes, like 'MyClinic'*/;
SET @ProvAbbr=''/*if you want to limit by provider, put provider abbreviation in single quotes, like 'DrSmith'*/;
/* NOTES: the reason why we say 'claim level' is because each procedure and each payment (claim proc) can be associate with a provider that may or may not be different from the claim level treating provider. Same is true of clinic. Option is also included to show sum of patient payments associated with procedures in claim, this is usually $0, and will be unless patient payments are split to procedures. There really are too many fields here, export to print. Includes Reason Underpaid and Claim Note*/
SELECT cl.PatNum, clinic.Description AS 'Clinic',pr.Abbr AS 'TreatProv', cl.DateService, cl.DateReceived, cl.PlanNum,IFNULL(SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)),0) AS $ChargeFee, cl.ClaimFee, cl.InsPayEst,cl.InsPayAmt, IFNULL((SELECT SUM(SplitAmt) FROM paysplit ps WHERE ps.ProcNum=pl.ProcNum),0) AS '$PatProcPay',ReasonUnderPaid, cl.ClaimNote
FROM claim cl
LEFT JOIN claimproc cp ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN procedurelog pl ON cp.ProcNum=pl.ProcNum
LEFT JOIN clinic ON clinic.ClinicNum=cl.ClinicNum
INNER JOIN provider pr ON cl.ProvTreat=pr.ProvNum
WHERE (cl.DateService BETWEEN @FromDate AND @ToDate)
AND (clinic.Description=@Clinic OR @Clinic='')/*allows user to not put in a clinic if desired and the query will still work*/
AND (pr.Abbr=@ProvAbbr OR @ProvAbbr='')
GROUP BY cl.ClaimNum;
Production and Income for a particular patient (with adjustments, insurance income by inspay date, writeoffs and balance). - By more narrow date range if desired, as is will return all income and production for patient.
/*611 Production and Income for a particular patient (with adjustments, insurance income by inspay date, writeoffs and balance)
By more narrow date range if desired, as is will return all income and production for patient*/
SET @PatNum='78', @FROMDate='' , @ToDate='2020-10-10'; /*change dates here if desired, zero length FromDate gives no lower limit*/
SELECT * FROM
(SELECT p.PatNum,
(SELECT SUM(InsPayAmt) FROM claim c WHERE c.PatNum=p.PatNum AND c.DateReceived BETWEEN @FROMDate AND @ToDate) AS '$InsProcPay',
(SELECT SUM(Writeoff) FROM claim c WHERE c.PatNum=p.PatNum AND c.DateReceived BETWEEN @FROMDate AND @ToDate) AS '$PPODiscount',
(SELECT SUM(SplitAmt) FROM paysplit WHERE p.PatNum=paysplit.PatNum AND (DatePay BETWEEN @FROMDate AND @ToDate)) AS '$PatientPay',
(SELECT SUM(AdjAmt) FROM adjustment WHERE p.PatNum=adjustment.PatNum AND (adjdate BETWEEN @FROMDate AND @ToDate)) AS '$PatAdj',
SUM(pl.procfee) AS '$Production',
EstBalance AS $PatBalance
FROM patient p
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum AND pl.ProcStatus=2
WHERE p.PatNum=@PatNum AND pl.ProcDate BETWEEN @FROMDate AND @ToDate
GROUP BY p.PatNum)A;
Production and Income for a particular family (with adjustments, insurance income by inspay date, writeoffs and balance), also shows for every member of family and whole family. - By more narrow date range if desired, as is will return all income and production for patient.
/*612 Production and Income for a particular family (with adjustments, insurance income by inspay date, writeoffs and balance), also shows for every member of family and whole family
By more narrow date range if desired, as is will return all income and production for patient*/
SET @PatNum='78', @FROMDate='' , @ToDate='2020-10-10';
SELECT A.PatNum,
A.InsProcPay $InsProcPay,
A.PPODiscount $PPODiscount,
A.PatientPay $PatientPay,
A.PatAdj $PatAdj,
A.Production $Production,
A.EstBalance AS $PatBalance
FROM
(SELECT p.PatNum,
(SELECT SUM(InsPayAmt) FROM claim c WHERE c.PatNum=p.PatNum AND c.DateReceived BETWEEN @FROMDate AND @ToDate) AS 'InsProcPay',
(SELECT SUM(Writeoff) FROM claim c WHERE c.PatNum=p.PatNum AND c.DateReceived BETWEEN @FROMDate AND @ToDate) AS 'PPODiscount',
(SELECT SUM(SplitAmt) FROM paysplit WHERE p.PatNum=paysplit.PatNum AND (DatePay BETWEEN @FROMDate AND @ToDate)) AS 'PatientPay',
(SELECT SUM(AdjAmt) FROM adjustment WHERE p.PatNum=adjustment.PatNum AND (adjdate BETWEEN @FROMDate AND @ToDate)) AS 'PatAdj',
SUM(pl.procfee) AS 'Production',
p.EstBalance,g.BalTotal
FROM patient p
INNER JOIN patient g ON g.PatNum=p.Guarantor
INNER JOIN procedurelog pl ON p.PatNum=pl.PatNum AND pl.ProcStatus=2
WHERE g.PatNum=(SELECT patient.Guarantor FROM patient WHERE patient.PatNum=@PatNum) AND pl.ProcDate BETWEEN @FROMDate AND @ToDate
GROUP BY p.PatNum)A;
Unsigned Consent Forms in date range. - Edit date range at top.
/*613 Unsigned Consent Forms in Date range*/
SET @StartDate='2013-01-01', @EndDate='2013-01-31';
SELECT sh.PatNum,sh.Description,sh.DateTimeSheet
FROM sheet sh
INNER JOIN sheetfield sf ON sf.SheetNum=sh.SheetNum AND sf.FieldType=9 /*SigBox*/
WHERE SheetType=6 /*Consent*/
AND DateTimeSheet BETWEEN @StartDate AND @EndDate
AND sf.FieldValue=''/*no signature*/;
List all PPO insured patients with name, home and wireless phone number. -
/*614 List all PPO insured patients with name, home and wireless phone number*/
SET @pos=0;
SELECT @pos:=@pos+1 AS Count, A.* FROM
(
SELECT DISTINCTROW FName, LName, HmPhone,WirelessPhone, 'PPO' AS PlanType, carrier.CarrierName
FROM carrier
INNER JOIN insplan ip ON carrier.CarrierNum=ip.CarrierNum
INNER JOIN inssub ib ON ip.PlanNum=ib.PlanNum
INNER JOIN patplan pp ON ib.InsSubNum=pp.InsSubNum /*AND Ordinal=1 use for primary only*/
INNER JOIN patient p ON pp.PatNum=p.PatNum
WHERE ip.PlanType='p'
ORDER BY p.LName,p.FName
) A;
Unscheduled list with sum of fees for appointment and amount insurance remaining before appointment. - Assumes everyone has calendar year benefits.
/*615 Unscheduled list with sum of fees for appointment and amount insurance remaining before appointment*/
/*Assumes everyone has calendar year benefits*/
SELECT a.PatNum,p.PatStatus, a.AptDateTime, d.ItemName AS Status,a.ProvNum, a.ProcDescript, (SELECT SUM(pl.ProcFee) FROM procedurelog pl WHERE pl.AptNum=a.AptNum) AS $AptFee,
/*t.AnnualMax AS "$AnnualMax", optional*/
/*tempused.AmtUsed AS "$AmountUsed", optional*/
(CASE WHEN ISNULL(tempused.AmtUsed) THEN (t.AnnualMax) ELSE (t.AnnualMax-tempused.AmtUsed) END)
AS $AmtRemain, a.Note
/*CONCAT(" ", LEFT(HmPhone,13), "- ", LEFT(WkPhone,13), "- ",LEFT(WirelessPhone,13)) AS 'Phone Hm-Wk-Cell',
LEFT(CarrierName,15) AS 'Carrier (abbr)',
tempLastSeen.LastSeen, t.carriername*/
FROM appointment a
INNER JOIN patient p ON p.Patnum=a.PatNum
LEFT JOIN definition d ON a.UnschedStatus=d.DefNum
LEFT JOIN(
SELECT benefit.PlanNum, benefit.MonetaryAmt AS AnnualMax, p.PatNum, c.CarrierName,
p.HmPhone, p.WkPhone,p.WirelessPhone, p.FName, p.MiddleI, p.LName, patplan.PatPlanNum, p.address, p.zip, p.city, p.state
FROM benefit
LEFT JOIN covcat ON covcat.CovCatNum = benefit.CovCatNum AND benefit.BenefitType = 5 /* limitation */
/*AND benefit.TimePeriod = 2 include this line to exclude non calendar year benefits*/
AND benefit.MonetaryAmt <> 0
INNER JOIN inssub ON benefit.PlanNum=inssub.PlanNum
INNER JOIN patplan on inssub.InsSubNum=patplan.InsSubNum
INNER JOIN insplan ip ON ip.PlanNum=inssub.PlanNum AND ORDINAL=1
INNER JOIN carrier c ON c.CarrierNum=ip.CarrierNum
INNER JOIN patient p ON p.PatNum=patplan.PatNum AND p.PatStatus=0
WHERE benefit.BenefitType = 5 AND (covcat.EbenefitCat=1 OR ISNULL(covcat.EbenefitCat)) AND benefit.CoverageLevel=1 /*AND benefit.TimePeriod = 2 include this line to exclude non calendar year benefits*/
AND benefit.MonetaryAmt > 0
ORDER BY benefit.PlanNum
) t ON a.PatNum=t.PatNum
LEFT JOIN(
SELECT patient.PatNum, SUM(procedurelog.ProcFee) AS AmtPlanned
FROM procedurelog
INNER JOIN patient ON patient.PatNum =procedurelog.PatNum
WHERE procedurelog.ProcStatus = 1 /*treatment planned*/
GROUP BY patient.PatNum
) tempplanned ON tempplanned.PatNum=t.PatNum
LEFT JOIN(
SELECT patplan.PatPlanNum,
SUM(IFNULL(claimproc.InsPayAmt,0)) AS AmtUsed
FROM claimproc
LEFT JOIN inssub ON claimproc.PlanNum = inssub.PlanNum
LEFT JOIN patplan ON patplan.PatNum = claimproc.PatNum
AND patplan.InsSubNum=inssub.InsSubNum
WHERE claimproc.Status IN (1, 3, 4)
AND claimproc.ProcDate BETWEEN makedate(year(CURDATE()), 1)
AND makedate(year(CURDATE())+1, 1) /*current calendar year*/
GROUP BY patplan.PatPlanNum
)tempused ON tempused.PatPlanNum=t.PatPlanNum
WHERE a.AptStatus=3/*unsched list*/ AND p.PatStatus=0
ORDER BY d.ItemName, a.AptDateTime,p.LName, p.FName ;
Claim information for specified claim level treating provider , claim level clinic and date range splitting insurance payments by procedurecode type into two groups: xrays (or whatever) and other. - Edit date range at top.
/*616 Claim information for specified claim level treating provider <optional>, claim level clinic <optional> and date range splitting insurance payments by procedurecode type into two groups: xrays (or whatever) and other*/
SET @FromDate='2011-11-01' , @ToDate='2011-11-31';/*change date here */
SET @Clinic=''/*if you want to limit by clinic, put clinic name in single quotes, like 'MyClinic'*/;
SET @ProvAbbr=''/*if you want to limit by provider, put provider abbreviation in single quotes, like 'DrSmith'*/;
/* NOTES: the reason why we say 'claim level' is because each procedure and each payment (claim proc) can be associate with a provider that may or may not be different from the claim level treating provider. Same is true of clinic. Option is also included to show sum of patient payments associated with procedures in claim, this is usually $0, and will be unless patient payments are split to procedures. There really are too many fields here, export to print. Includes Reason Underpaid and Claim Note*/
SELECT cl.PatNum, clinic.Description AS 'Clinic',pr.Abbr AS 'TreatProv', cl.DateService, cl.DateReceived, cl.PlanNum,IFNULL(SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)),0) AS $ChargeFee, cl.ClaimFee, cl.InsPayEst,cl.InsPayAmt-SUM(CASE WHEN pc.ProcCode IN('D0220','D0230','D0272','D0274','D0330') THEN cp.InsPayAmt ELSE 0 END) AS InsPayOther, SUM(CASE WHEN pc.ProcCode IN('D0220','D0230','D0272','D0274','D0330') THEN cp.InsPayAmt ELSE 0 END) AS InsPayXrays, IFNULL((SELECT SUM(SplitAmt) FROM paysplit ps WHERE ps.ProcNum=pl.ProcNum),0) AS '$PatProcPay',ReasonUnderPaid, cl.ClaimNote
FROM claim cl
LEFT JOIN claimproc cp ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN procedurelog pl ON cp.ProcNum=pl.ProcNum
LEFT JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
LEFT JOIN clinic ON clinic.ClinicNum=cl.ClinicNum
INNER JOIN provider pr ON cl.ProvTreat=pr.ProvNum
WHERE (cl.DateService BETWEEN @FromDate AND @ToDate)
AND (clinic.Description=@Clinic OR @Clinic='')/*allows user to not put in a clinic if desired and the query will still work*/
AND (pr.Abbr=@ProvAbbr OR @ProvAbbr='')
GROUP BY cl.ClaimNum;
Active patients with missing teeth, also shows age, the missing teeth and the last seen date and next appointment if any. -
/*618 active patients with missing teeth, also shows age, the missing teeth and the last seen date and next appointment if any*/
SELECT p.PatNum,
IF(IFNULL(FLOOR(DATEDIFF(CURDATE(),p.BirthDate)/365.2425),0)>200,'Bad Birthdate',IFNULL(FLOOR(DATEDIFF(CURDATE(),p.BirthDate)/365.2425),0)) AS Age,
/*(IFNULL(FLOOR(DATEDIFF(CURDATE(),p.BirthDate)/365.2425),0)>200,'Bad Birthdate') AS Age,*/
GROUP_CONCAT(T.ToothNum ORDER BY CAST(ToothNum AS SIGNED) ASC) AS MissingTeeth, B.DateLastVisit, A.DateNextSchedApt FROM
(SELECT tinit.PatNum,ToothNum FROM toothinitial tinit WHERE InitialType IN (0,1) /*missing OR hidden*/ AND ToothNum REGEXP('[0-9]')/*numeric, thus adult teeth missing*/) T
INNER JOIN patient p ON p.PatNum=T.PatNum
LEFT JOIN
(SELECT appointment.PatNum, MIN(DATE(AptDateTime)) AS DateNextSchedApt FROM appointment WHERE AptDateTime>=CURDATE() AND AptStatus=1 GROUP BY appointment.PatNum)
A
ON A.PatNum=p.PatNum
LEFT JOIN
(SELECT PatNum, MAX(pl.ProcDate) AS DateLastVisit
FROM procedurelog pl
WHERE pl.ProcStatus=2
GROUP BY pl.PatNum HAVING MIN(pl.ProcDate) BETWEEN @FromDate AND @ToDate)
B
ON p.PatNum=B.PatNum
WHERE p.PatStatus=0 /*active*/
GROUP BY p.PatNum
ORDER BY p.LName, p.FName, p.PatNum;
Patient name,three Patient Fields and appointment status associated with appointments of all statuses where the AptDateTime is in a given date range. - Edit date range at top.
/*620 Patient name,three Patient Fields and appointment status associated with appointments of all statuses where the AptDateTime is in a given date range*/
SET @FromDate='2011-11-01' , @ToDate='2011-11-31';/*change dates here, replace with CURDATE() to auto pick todays date*/
SELECT a.PatNum,
(SELECT MAX(FieldValue) FROM patfield WHERE patfield.PatNum=a.PatNum AND FieldName='Procedure 1 Outcome') AS 'P1 Outcome',
(SELECT MAX(FieldValue) FROM patfield WHERE patfield.PatNum=a.PatNum AND FieldName='Procedure 2 Outcome') AS 'P2 Outcome',
(SELECT MAX(FieldValue) FROM patfield WHERE patfield.PatNum=a.PatNum AND FieldName='Procedure 3 Outcome') AS 'P3 Outcome',
a.AptDateTime AS 'Date',
a.AptStatus
FROM appointment a
WHERE DATE(a.AptDateTime) BETWEEN @FromDate AND @ToDate;
Patient schedule list for next day with a patient field def (each office edit to show your field(s)), apt length, age with years and months and appointment status. -
/*621 Patient schedule list for next day with a patient field def (each office edit to show your field(s)), apt length, age with years and months and apt status */
SET @FromDate=CURDATE()+ INTERVAL 1 DAY , @ToDate=CURDATE()+ INTERVAL 1 DAY;/*No dates to change, runs for tomorrow, put date in like '2011-01-30' instead of CURDATE()+ INTERVAL 1 DAY if you would like*/
SELECT
DATE_FORMAT(DATE(a.AptDateTime), '%W') AS 'Day',
a.AptDateTime AS 'Date',
TIME_FORMAT(AptDateTime,'%H:%i') AS 'Time',
CHAR_LENGTH(a.Pattern)*5 AS 'Length',
a.PatNum,IF(IFNULL(FLOOR(DATEDIFF(CURDATE(),BirthDate)/365.2425),0)>200,'Bad Birthdate',CONCAT(
IFNULL(FLOOR(DATEDIFF(CURDATE(),BirthDate)/365.2425),0),
' years, ',
IFNULL(FLOOR((DATEDIFF(CURDATE(),BirthDate)/365.2425 - FLOOR(DATEDIFF(CURDATE(),BirthDate)/365.2425))* 12),0),
' months'))
Age,
(SELECT MAX(FieldValue) FROM patfield WHERE patfield.PatNum=a.PatNum AND FieldName='Special Needs') AS 'SN',
d.ItemName AS 'ConfStatus', a.AptStatus
FROM appointment a
INNER JOIN patient p ON a.PatNum=p.PatNum
LEFT JOIN definition d ON a.Confirmed=d.DefNum
WHERE DATE(a.AptDateTime) BETWEEN @FromDate AND @ToDate
AND a.AptStatus=1;
Writeoff report showing tooth level info, by date range, with insurance paid amt listed by procedure, includes all procedures matching code for which there is a received or supplemental claim procedure. - Edit date range at top.
/*622 Writeoff report showing tooth level info, by date range, with insurance paid amt
listed by procedure, includes all procedures matching code for which there is a received or supplemental claim procedure*/
SET @FromDate='2010-01-01' , @ToDate='2010-03-31';
SELECT cp.PatNum,cp.DateCP,
SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) AS '$Charged',
SUM(cp.InsPayAmt) AS '$InsPayAmt',
SUM(cp.WriteOff) AS '$WriteOff',
SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits))-SUM(cp.WriteOff) AS 'TrueProduction'
FROM procedurelog pl
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
INNER JOIN claimproc cp ON cp.ProcNum=pl.ProcNum
WHERE pc.ProcCode LIKE('D9999%')
AND (cp.DateCP BETWEEN @FromDate AND @ToDate)
AND (cp.Status = 1 OR cp.Status = 4) /*received and supplemental claims*/
GROUP BY pl.ProcNum
ORDER BY cp.DateCP;
List all patients with insurance adjustments to benefits, could be edited to limit by date range. - Edit date range at top.
/*623 List all patients with insurance adjustments to benefits, could be edited to limit by date range*/
SELECT p.PatNum, InsPayAmt, DedApplied, ProcDate FROM claimproc cp INNER JOIN patient p ON p.PatNum=cp.PatNum WHERE ProcNum=0 AND ProvNum='' AND (InsPayAmt>0 OR DedApplied>0) ORDER BY p.LName, p.FName;
Percent of appointments by insurance carrier, add the medicaid percentages for a time period to determine EHR eligibility (this query works for current Open Dental users as well as post conversion and trial conversions: if there was no claim for a particu - Adjust dates at top as needed.
/*625 Percent of appointments by insurance carrier, add the medicaid percentages for a time period to determine EHR eligibility (this query works for current Open Dental users as well as post conversion and trial conversions: if there was no claim for a particular procedure, assumes if patient has insurance currently that the patient had it at time of appointment): Count and % of appointments (or dates where procedures were completed) by carrier over given period, adds up to more or less than 100% because there can be more than one carrier per patient and because non insurance patients are not on the list (although their appointments are part of the denominator for the % appointments) */
SET @FromDate='2010-01-01' , @ToDate='2010-03-31';
/*Adjust above Dates AS needed*/
SELECT A.CarrierName,COUNT(DISTINCT A.PatNum) AS 'Patients',
COUNT(DISTINCT A.ProcDate,A.PatNum) AS Appointments, FORMAT((COUNT(DISTINCT A.ProcDate,A.PatNum)/(SELECT COUNT(DISTINCT pl2.ProcDate,pl2.PatNum) FROM procedurelog pl2 WHERE (pl2.ProcDate BETWEEN @FromDate AND @ToDate) AND pl2.ProcStatus=2))*100,1) AS '% of visits'
FROM
/*where claims may or may not exist but insurance currently does*/
(SELECT ca.CarrierName, pl.PatNum, pl.ProcDate
FROM carrier ca
INNER JOIN insplan ip ON ca.CarrierNum=ip.CarrierNum
INNER JOIN inssub isu ON isu.PlanNum=ip.PlanNum
INNER JOIN patplan pp ON pp.InsSubNum=isu.InsSubNum
INNER JOIN procedurelog pl ON pp.PatNum=pl.PatNum
AND (pl.ProcDate BETWEEN @FromDate AND @ToDate)
AND pl.ProcStatus=2
UNION/*where claims exist but insurance plan may no longer be attached to patient, UNION discards duplicates*/
SELECT
ca.CarrierName, pl.PatNum, pl.ProcDate
FROM carrier ca
INNER JOIN insplan ip ON ca.CarrierNum=ip.CarrierNum
INNER JOIN claim cl ON ip.PlanNum=cl.PlanNum
INNER JOIN claimproc cp ON cl.ClaimNum=cp.ClaimNum
INNER JOIN procedurelog pl ON cp.ProcNum=pl.ProcNum
AND (pl.ProcDate BETWEEN @FromDate AND @ToDate)
AND pl.ProcStatus=2)
A
GROUP BY A.CarrierName
ORDER BY A.CarrierName;
Summary claim information summed by date and clinic, with sums of claim fees, insurance estimates, insurance payments and including counts of claims and patients. - Edit date range at top.
/*626 Summary claim information summed by date and clinic, with sums of claim fees, insurance estimates, insurance payments and including counts of claims and patients*/
SET @FromDate='2012-01-01' , @ToDate='2012-01-31';/*change date here */
/* note that the same procedure may be sent to multiple Carriers, inflating the $ClaimFees */
SELECT cl.DateService, DATE_FORMAT(cl.DateService,'%W') AS WeekDay, clinic.Description AS 'Clinic', COUNT(DISTINCT cl.PatNum) AS Patients, COUNT(DISTINCT cl.ClaimNum) AS Claims, SUM(cl.ClaimFee) AS $ClaimFees_,
SUM(InsPayEst) AS '$InsPayEst_', SUM(cl.InsPayAmt) AS '$InsPaid_'
FROM claim cl
LEFT JOIN clinic ON clinic.ClinicNum=cl.ClinicNum
WHERE cl.ClaimType<>'PreAuth' AND
cl.DateService BETWEEN @FromDate AND @ToDate
GROUP BY cl.DateService, cl.ClinicNum
ORDER BY cl.DateService, cl.ClinicNum;
Net Production (with PPO writeoffs removed by procedure date, other adjustments not considered) and Income by referral source for date range. KEY POINT: only includes referral froms and income collected during that period, whereas some other reports may s - For Versions 17.1 and greater. Please update your version accordingly. See 1270 for patient breakdown.
/*627 Net Production (with PPO writeoffs removed by procedure date, other adjustments not considered) and Income by referral source for date range, KEY POINT: only includes referrals received and income
collected during that period,whereas some other reports may report residual income form referrals before defined date range, also returns TP fee total, note: duplicates for multiple 'from' referrals in period*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/16/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate = '2018-01-01', @ToDate = '2018-01-31';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT ref.Source,
COUNT(DISTINCT ref.PatNum) AS HowMany,
COALESCE(SUM(prd.Prod),0) AS "$Prod (Gross-Writeoffs)",
COALESCE(SUM(ins.Payment),0) AS "$Insurance Collected",
COALESCE(SUM(pay.PayAmt),0) AS "$Cash, CC, Checks, Financing",
COALESCE(COALESCE(SUM(ins.Payment),0) + COALESCE(SUM(payAmt),0)) AS "$Total Collected",
COALESCE(SUM(pln.PlannedFee),0) AS "$Treatment Planned"
FROM (
SELECT ra.PatNum,
(CASE
WHEN NotPerson=1 /* true */
THEN re.LName
ELSE CONCAT(re.FName, ' ', re.LName)
END) AS Source
FROM referral re, refattach ra
WHERE re.ReferralNum = ra.ReferralNum
AND ra.RefDate BETWEEN @FromDate AND @ToDate
AND ra.RefType = 1 /*RefFrom*/
) ref
LEFT OUTER JOIN (
SELECT cp.PatNum,
SUM(cp.InsPayAmt) AS Payment
FROM claimproc cp
WHERE cp.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY cp.PatNum
) ins ON ref.PatNum = ins.PatNum
LEFT OUTER JOIN (
SELECT pay.PatNum ,
SUM(pay.PayAmt) AS PayAmt
FROM payment pay
WHERE pay.PayDate BETWEEN @FromDate AND @ToDate
GROUP BY pay.PatNum
) pay ON ref.PatNum = pay.PatNum
LEFT OUTER JOIN (
SELECT pl.PatNum,
SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) PlannedFee
FROM procedurelog pl
WHERE pl.ProcStatus=1 /* TP Planned */
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY pl.PatNum
) pln ON ref.PatNum = pln.PatNum
LEFT OUTER JOIN (
SELECT pl.PatNum,
SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) - (IFNULL((SELECT SUM(cp.WriteOff)
FROM claimproc cp
WHERE cp.ProcNum=pl.ProcNum),0)) AS Prod
FROM procedurelog pl
WHERE pl.ProcStatus=2 /* complete */
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY pl.PatNum
) prd ON ref.PatNum = prd.PatNum
GROUP BY ref.Source
ORDER BY ref.Source;
Patients that have an appointment scheduled in a date range, who also have an outstanding insurance claim - Edit date range at top.
/*628 Patients that have an appointment scheduled in a date range, who also have an outstanding insurance claim*/
SET @FromDate = '2011-08-01', @ToDate = '2011-12-31';
SELECT p.PatNum, ib.SubscriberID, ip.GroupNum, p.BirthDate,ca.CarrierName,ca.Phone, cl.ClaimFee,
cl.InsPayEst, cl.DateService, cl.DateSent,COUNT(a.AptNum) AS '#'
FROM patient p
INNER JOIN appointment a ON a.PatNum=p.PatNum AND a.AptDateTime BETWEEN @FromDate AND @ToDate AND a.AptStatus=1/*planned*/
INNER JOIN claim cl ON p.PatNum=cl.PatNum
INNER JOIN inssub ib ON ib.InsSubNum=cl.InsSubNum
INNER JOIN insplan ip ON ip.PlanNum=ib.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=ip.CarrierNum
WHERE (cl.ClaimStatus='S') AND (cl.ClaimType in ('P','S'))
GROUP BY p.PatNum, ib.SubscriberID, ip.GroupNum, p.BirthDate,ca.CarrierName,ca.Phone, cl.ClaimFee,cl.InsPayEst, cl.DateService, cl.DateSent
ORDER BY ca.CarrierName, p.LName, p.FName, cl.DateService;
Email list (and some other fields, editable) of active patients (not subscribers) whose carrier matches a given insurance carrier string. - Change the 'Delta' to any carrier name string.
/*629 Email list (and some other fields, editable) of active patients (not subscribers) whose carrier matches a given insurance carrier string, (change the Delta to any carrier name string)*/
SELECT IFNULL(Left(c.CarrierName, 15), 'None') AS CarrierName, p.PatNum, p.Email, Left(GroupName, 15) AS GroupName,
PlanType, ib.SubscriberId
FROM patient p
LEFT JOIN patplan pp ON pp.PatNum=p.PatNum
LEFT JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=ib.PlanNum
LEFT JOIN carrier c ON c.CarrierNum=ip.CarrierNum
WHERE p.PatStatus=0 AND c.CarrierName LIKE('%Delta%')
ORDER BY c.CarrierName, GroupName, p.LName;
Active Patient count by age and gender. -
/*630 Active Patient count by age and gender*/
SELECT (YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) AS 'Age', p.Gender,COUNT(DISTINCT p.PatNum) AS 'Patients'
FROM patient p
WHERE p.PatStatus=0
GROUP BY Age, Gender ORDER BY Age, Gender ASC;
List of patients who have had a broken appointment but never completed any procedures. -
/*631 List of patients who have had a broken appointment but never completed any procedures*/
/*Query code written/modified: 11/29/2016*/
SELECT p.FName, p.LName, p.PatStatus,
DATE(MAX(a.AptDateTime)) AS DateApt, MAX(adj.AdjDate) AS DateAdj,
MAX(CASE WHEN pc1.CodeNum IS NOT NULL THEN pl1.ProcDate END) AS DateBrokenProc, p.HmPhone, p.WkPhone,
p.WirelessPhone AS 'Wireless'
FROM patient p
LEFT JOIN appointment a ON a.PatNum=p.PatNum AND a.AptStatus=5/*broken*/
LEFT JOIN
(
SELECT ad.AdjDate, ad.PatNum FROM adjustment ad INNER JOIN definition d ON d.DefNum=ad.AdjType WHERE d.ItemName LIKE('%BROKEN%')
) adj ON adj.PatNum=p.PatNum
LEFT JOIN procedurelog pl1 ON pl1.PatNum=p.PatNum
AND pl1.ProcStatus=2
LEFT JOIN procedurecode pc1 ON pc1.CodeNum=pl1.CodeNum
AND pc1.ProcCode IN ('D9986','D9987')
/*no completed procedures*/
WHERE NOT EXISTS(SELECT pl.PatNum FROM procedurelog pl
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
AND pc.ProcCode NOT IN ('D9986','D9987')
WHERE pl.PatNum=p.PatNum AND pl.ProcStatus=2)
AND p.PatStatus=0 /*active patients*/
GROUP BY p.PatNum
HAVING NOT(ISNULL(MAX(a.AptDateTime))
AND ISNULL(MAX(adj.AdjDate))
AND ISNULL(MAX(CASE WHEN pc1.CodeNum IS NOT NULL THEN pl1.ProcDate END)))/*must have a broken apt or broken apt adjustment or broken apt procedure*/
ORDER BY DateApt, LName, FName DESC;
List of all appointments for active patients, with provider and carrier. -
/*632 List of all appointments for active patients, with provider and carrier*/
SELECT a.AptDateTime, p.FName, p.LName, pr.Abbr, c.CarrierName
FROM patient p
INNER JOIN appointment a ON p.PatNum=a.PatNum
INNER JOIN provider pr ON a.ProvNum=pr.ProvNum
LEFT JOIN patplan pp ON pp.PatNum=p.PatNum AND pp.Ordinal=1 /*primary*/
LEFT JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=ib.PlanNum
LEFT JOIN carrier c ON c.CarrierNum=ip.CarrierNum
WHERE p.PatStatus=0
ORDER BY FName, LName, AptDateTime, pr.Abbr;
Procedure Notes for date range including group notes. -
/*633 procnotes for date range including group notes*/
SET @FromDate='2012-01-01', @ToDate='2012-01-31';
SELECT ProcDate, LEFT(CONCAT(tmp1.LName,', ',tmp1.FName),25) AS PatName,
ToothNum AS 'T#', Surf, ProcCode, AbbrDesc,
(CASE WHEN NOT ISNULL(tmp1.NoteEntered) THEN (SELECT pn.Note FROM procnote pn WHERE tmp1.ProcNum=pn.ProcNum AND pn.EntryDateTime=tmp1.NoteEntered) Else 'None' END) AS 'Note'
FROM
(
SELECT MAX(procnote.EntryDateTime) AS 'NoteEntered', procedurelog.ProcDate, provider.LName AS `Dr`,patient.PatNum,patient.LName,patient.FName,procedurelog.ToothNum,
procedurelog.Surf,procedurelog.ProcNum, procedurecode.ProcCode,procedurecode.AbbrDesc
FROM procedurelog
INNER JOIN procedurecode ON procedurelog.CodeNum=procedurecode.CodeNum
INNER JOIN provider ON provider.ProvNum=procedurelog.ProvNum
INNER JOIN patient ON patient.PatNum=procedurelog.PatNum
LEFT JOIN procnote ON procnote.ProcNum=procedurelog.ProcNum
WHERE procedurelog.ProcDate BETWEEN @FromDate AND @ToDate
AND (procedurelog.ProcStatus = '2' /*complete*/ OR procedurelog.ProcStatus = '3' /*EC for group notes*/)
GROUP BY procedurelog.ProcNum
) tmp1
Order BY LName ASC, ProcCode ASC
Families with credit balances, Name, Balance and Address. - For accurate balances, run aging under Tools>Aging prior to running this report.
/*634 Families with Credit balances, Name, balance and address. For accurate balances, run aging under Tools>Aging prior to running this report.*/
SELECT Guarantor, BalTotal,Address, Address2, City, State, Zip FROM patient
WHERE Guarantor=PatNum AND BalTotal<0
Patients listed with address and carrier who have not been seen since some date in the past, also includes patient status (normally you would engage the active patient limitation that is commented out instead of showing status) and allows carrier exclusio - In this example excludes carriers with medicaid in the name
/*635 Patients listed with address and carrier who have not been seen since some date in the past, also includes patient status (normally you would engage the active patient limitation that is commented out instead of showing status) and allows carrier exclusion, (in this example excludes carriers with medicaid in the name)*/
/*New*/ Set @NotCarrier='%medicaid%', @NotSeenAfterDate='2009-12-31', @pos=0;
SELECT @pos:=@pos+1 as numberofpatients, A.* FROM( SELECT p.LName,p.FName,p.PatStatus,p.Address,p.Address2,p.City,p.State,p.Zip,p.PatNum,
DATE_FORMAT(MAX(ProcDate),'%m/%d/%Y') AS 'LastVisit', c.CarrierName
FROM carrier c
INNER JOIN insplan ip ON c.CarrierNum=ip.CarrierNum
INNER JOIN inssub ib ON ib.PlanNum=ip.PlanNum
INNER JOIN patplan pp ON ib.InsSubNum=pp.InsSubNum
INNER JOIN patient p ON pp.PatNum=p.PatNum
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
WHERE pl.ProcStatus=2 AND /*p.PatStatus=0 AND*/
c.CarrierName NOT LIKE(@NotCarrier)
GROUP BY pl.PatNum, c.CarrierName
HAVING MAX(ProcDate)<@NotSeenAfterDate
ORDER BY p.LName, p.FName) A;
Payments made by given insurance carrier on procedures completed by given provider summed by patient. -
/*636 Payments made by given insurance carrier on procedures completed by given provider summed by patient*/
Set @Carrier='%medicaid of texas%', @provAbbr='mcguire';
SELECT p.PatNum,(SELECT SUM(claimproc.InsPayAmt) FROM claimproc WHERE claimproc.InsSubNum=ib.InsSubNum) AS InsPayAmt, c.CarrierName
FROM carrier c
INNER JOIN insplan ip ON c.CarrierNum=ip.CarrierNum
INNER JOIN inssub ib ON ib.PlanNum=ip.PlanNum
INNER JOIN patplan pp ON ib.InsSubNum=pp.InsSubNum
INNER JOIN patient p ON pp.PatNum=p.PatNum
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
INNER JOIN provider pr ON pr.ProvNum=pl.ProvNum
WHERE pl.ProcStatus=2 AND
c.CarrierName LIKE(@Carrier) AND pr.Abbr=@provAbbr
GROUP BY pl.PatNum
ORDER BY p.LName, p.FName;
Patients who have had a given procedure code completed with counts for that code in a given date range. - Edit date range at top.
/*637 Patients who have had a given procedure code completed with counts for that code in a given date range*/
SET @FromDate='2012-01-01', @ToDate='2012-01-31', @CodeNum='D8670';
SELECT pl.PatNum,COUNT(*) AS ProcedureCount
FROM procedurelog pl
INNER JOIN patient ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
WHERE pc.ProcCode=@CodeNum
AND pl.ProcDate BETWEEN @FromDate AND @ToDate AND
pl.ProcStatus=2 /*complete*/
GROUP BY pl.PatNum
ORDER BY patient.LName,patient.FName ASC;
Summary claim information summed by date and clinic, with sums of claim fees, insurance estimates, insurance payments, outstanding claim fees, writeoffs, count of claims and count of patients. - Edit date range at top.
/*638 Summary claim information summed by date and clinic, with sums of claim fees, insurance estimates, insurance payments, outstanding claim fees, writeoffs, count of claims and coun of patients*/
SET @FromDate='2012-01-01' , @ToDate='2012-03-31', @Clinic='%%', @Provider='%%';/*change date here */
/* note that the same procedure may be sent to multiple Carriers, inflating the $ClaimFees */
SELECT cl.DateService, DATE_FORMAT(cl.DateService,'%W') AS WeekDay, clinic.Description AS 'Clinic', COUNT(DISTINCT cl.PatNum) AS Patients, COUNT(DISTINCT cl.ClaimNum) AS Claims, SUM(cl.ClaimFee) AS $ClaimFees_, SUM(cl.InsPayAmt) AS '$InsPaid_', SUM(CASE WHEN cl.ClaimStatus='S' THEN ClaimFee ELSE 0 END) AS $OutClaimFees, SUM(cl.WriteOff) AS '$WriteOff'
FROM claim cl
LEFT JOIN clinic ON clinic.ClinicNum=cl.ClinicNum
INNER JOIN provider pv ON cl.ProvTreat=pv.ProvNum AND pv.Abbr LIKE @Provider
WHERE cl.ClaimType<>'PreAuth' AND
cl.DateService BETWEEN @FromDate AND @ToDate
AND clinic.Description LIKE @Clinic
GROUP BY cl.DateService, cl.ClinicNum
ORDER BY cl.DateService, cl.ClinicNum;
Received insurance claims FROM a particular carrier showing estimated vs paid amounts. - Edit date range at top.
/*639 Received insurance claims FROM a particular carrier showing estimated vs paid amounts*/
SET @Carrier='%Blue Cross%';
SET @FromDate='2012-01-01' , @ToDate='2012-03-31';
SELECT cl.PatNum,cl.DateSent, cl.DateReceived, ca.CarrierName, ca.Phone, cl.ClaimStatus, cl.InsPayEst,InsPayAmt FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE cl.ClaimStatus='R' AND ca.CarrierName LIKE @Carrier AND
cl.DateReceived BETWEEN @FromDate AND @ToDate
ORDER BY ca.CarrierName,p.LName;
Providers production per hour, includes gross, adjustments, writeoffs, net production and hours workedin given period for all providers. - Edit date range at top.
/*640 Providers production per hour, includes gross, adjustments, writeoffs, net production and hours workedin given period for all providers*/
SET @FromDate = '2012-01-01', @ToDate = '2012-01-31';
SELECT Abbr,
COALESCE(Hours,0) AS Hours,
COALESCE(GrossProd,0) AS $GrossProd_,
COALESCE(Adjust,0) AS $Adjust_,
COALESCE(WriteOff,0) AS $WriteOff_,
COALESCE(GrossProd,0)+COALESCE(Adjust,0)-COALESCE(Writeoff,0) AS $NetProd_,
COALESCE(GrossProd,0)/COALESCE(Hours,0) AS $GrossPerHr_,
(COALESCE(GrossProd,0)+COALESCE(Adjust,0)-COALESCE(Writeoff,0))/COALESCE(Hours,0) AS $NetPerHr_
FROM (
SELECT p.Abbr,
SUM(HOUR(TIMEDIFF(s.StopTime, s.StartTime))) AS Hours,
(
SELECT SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits))
FROM procedurelog pl
WHERE pl.ProvNum=p.ProvNum
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus=2 /*complete*/
) GrossProd,
(
SELECT SUM(adj.AdjAmt)
FROM adjustment adj
WHERE adj.ProvNum=p.ProvNum
AND adj.AdjDate BETWEEN @FromDate AND @ToDate
) AS Adjust,
(
SELECT SUM(cp.Writeoff)
FROM procedurelog pl
INNER JOIN claimproc cp ON cp.ProcNum=pl.ProcNum
AND cp.Status IN (1,4,0)/*received, supplemental,sent(anticipated)*/
WHERE pl.ProvNum=p.ProvNum
AND pl.ProcDate BETWEEN @FromDate AND @ToDate AND pl.ProcStatus=2 /*complete*/
) WriteOff
FROM provider p
LEFT JOIN schedule s ON p.ProvNum=s.ProvNum
AND (s.SchedDate BETWEEN @FromDate AND @ToDate)
AND s.SchedType = 1 /* Provider */
WHERE p.IsHidden=FALSE
GROUP BY p.ProvNum
) A
WHERE (Hours<>0 OR GrossProd<>0 OR Adjust <>0 OR WriteOff<>0);
Patients with same first and last names with no birthdate on record. -
/*641 Patients with same first and last names with no birthdate on record.*/
SELECT p.* FROM (SELECT COUNT(*) AS count, LName, FName
FROM patient
WHERE PatStatus<>4 AND YEAR(Birthdate)=1
GROUP BY LName, FName
HAVING count>1) A
LEFT JOIN patient p ON p.LName=A.LName AND p.FName=A.FName
WHERE p.PatStatus<>4 AND YEAR(p.Birthdate)=1
ORDER BY p.LName, p.FName;
Patients with same first name, last name, and birthdate. -
/*642 Patients with same first name, last name, and birthdate.*/
SELECT p.* FROM (SELECT COUNT(*) AS count, LName, FName, Birthdate
FROM patient
WHERE PatStatus<>4 AND YEAR(Birthdate)>1
GROUP BY LName, FName, Birthdate
HAVING count>1) A
LEFT JOIN patient p ON p.LName=A.LName AND p.FName=A.FName AND p.Birthdate=A.Birthdate
WHERE p.PatStatus<>4
ORDER BY p.LName, p.FName;
All patients with their status and current medications. - A patient will show once for each medication.
/*643 All patients with their status and current medications.
A patient will show once for each medication.*/
SELECT p.PatNum,p.PatStatus,m.MedName AS Medication
FROM medicationpat mp
INNER JOIN patient p ON p.PatNum=mp.PatNum
INNER JOIN medication m ON m.MedicationNum=mp.MedicationNum
ORDER BY p.LName,p.FName;
Patients whose recall date scheduled is before the recall due date. - Shows patient,recall type description,due date, and scheduled date.
/*644 Patients whose recall date scheduled is before the recall due date.
Shows patient,recall type description,due date, and scheduled date.*/
SELECT r.PatNum,rt.Description,r.DateDue,r.DateScheduled
FROM recall r
INNER JOIN recalltype rt ON rt.RecallTypeNum=r.RecallTypeNum
WHERE r.DateScheduled!='0001-01-01'
AND r.DateScheduled<r.DateDue
ORDER BY r.DateDue, r.DateScheduled;
List of procedures treatment planned in date range with appoinment date and time if scheduled. -
/*645 List of procedures treatment planned in date range with appoinment date and time if scheduled*/
SET @pos=0, @FromDate='2012-01-14', @ToDate='2012-02-29';
SELECT @pos:=@pos+1 AS 'Count',A.*
FROM (
SELECT pa.PatNum,pc.ProcCode AS Code,pc.AbbrDesc AS Description,pl.ToothNum AS 'Tooth#',DATE_FORMAT(pl.DateTP,'%m-%d-%Y') AS DateTP,
pr.Abbr AS Provider,pl.ProcFee AS $ProcFee_,(CASE WHEN DATE(a.AptDateTime)>=CURDATE() THEN a.AptDateTime ELSE 'No Apt' END) AS Appointment
FROM patient pa
INNER JOIN procedurelog pl ON pa.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
INNER JOIN provider pr ON pl.ProvNum=pr.ProvNum
LEFT JOIN appointment a ON a.AptNum=pl.AptNum AND a.AptStatus IN (1,2) /*sched or complete*/
WHERE ProcStatus=1 /* AND pr.Abbr IN ('DR01')*/
AND pl.DateTP BETWEEN @FromDate AND @ToDate AND pc.IsHygiene=0 AND pc.ProcCode<>'ZClin'
ORDER BY DateTP,pa.LName, pa.FName ASC
) A;
Treatment planned work sitting in completed appointments, normally not possible, helpful for some eCW installations. -
/*646 Treatment planned work sitting in completed appointments, normally not possible, helpful for some eCW installations.*/
SET @pos=0, @FromDate='2000-01-31' , @ToDate='2020-01-31'; /*change date range if desired, wide open as default*/
SELECT @pos:=@pos+1 AS 'Count', A.*
FROM (
SELECT pa.PatNum,pc.ProcCode AS Code,pc.AbbrDesc AS Description,pl.ToothNum AS 'Tooth#',
ap.AptDateTime,DATE_FORMAT(pl.DateTP,'%m-%d-%Y') AS DateTP,pr.Abbr AS Provider
FROM patient pa
INNER JOIN procedurelog pl ON pa.PatNum=pl.PatNum AND pl.ProcStatus=1 /*Tp work*/
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
INNER JOIN provider pr ON pl.ProvNum=pr.ProvNum
INNER JOIN appointment ap ON ap.AptNum=pl.AptNum AND ap.AptStatus=2 /*complete apts*/
WHERE pl.ProcStatus IN (1,2)
AND (DATE(ap.AptDateTime) BETWEEN @FromDate AND @ToDate)
ORDER BY DATE(ap.AptDateTime),pa.LName,pa.FName ASC
) A;
Outstanding Medicaid Claims by Date of Service with PatNum, amount billed to insurance, and date sent. - Edit Interval number if you want to change minimum time outstanding.
/*647 Outstanding Medicaid Claims by Date of Service with PatNum, amount billed to insurance, and date sent.
Edit Interval number if you want to change minimum time outstanding.*/
SET @DaysOld=(CURDATE()-INTERVAL 30 DAY) /*change interval here*/;
SELECT ca.CarrierName,ca.Phone,cl.ClaimType,cl.PatNum,p.PatNum AS RawPatNum,cl.DateService,cl.DateSent,cl.ClaimFee AS $ClaimFee_
FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE cl.ClaimStatus='S'
AND cl.DateService<@DaysOld
AND ca.CarrierName LIKE '%medicaid%'
ORDER BY ca.CarrierName,p.LName;
New patients with carrier in date range, includes anticipated and no show patients. -
/*648 New patients with carrier in date range, includes anticipated and no show patients.*/
SET @FromDate='2011-01-01';
SET @ToDate='2011-05-01';
SELECT p.FName,p.LName,p.DateFirstVisit,IFNULL(ca.CarrierName,'NONE') AS CarrierName
FROM patient p
LEFT JOIN patplan pp ON pp.PatNum=p.PatNum AND pp.Ordinal=1
LEFT JOIN inssub ins ON ins.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=ins.PlanNum
LEFT JOIN carrier ca ON ca.CarrierNum=ip.CarrierNum
WHERE p.DateFirstVisit BETWEEN @FromDate AND @ToDate
AND p.patstatus=0
ORDER BY CarrierName,p.DateFirstVisit;
Summary statistics by provider. - See query details for explaination of columns.
/*649 Summary statistics by provider. See query details for explaination of columns.*/
SET @FromDate='2012-03-01' , @ToDate='2012-03-31';/*<--Change Date Here*/
/*1.Prov - Provider
2.Patcount - Count of Patients seen in date range
3.NetPat - patients with completed procedures in date range who have never been seen before
4.$Diagnosis - Sum of fees of completed or treatment planned procedures that were first TP in given date range
5.$InsIncome - Sum of insurance payments recieved in date range
6.$PatIncome - Patient payments made in date range
7.$NetProd - Sum of fees of completed procedures completed in date range MINUS Writeoffs (by procedure date) MINUS Adjustments (by adjustment date)
8.Recalls - Count of recalls, measure by counting completed D0120 periodic exams in date range*/
SELECT pv.Abbr,COALESCE(PatCount.Count,0) AS PatCount,COALESCE(NewPat.Count,0) AS NewPat,
COALESCE(Recalls.Count,0) AS Recalls,COALESCE(Diagnosed.Amount,0) AS $Diagnosed_,
COALESCE(Prod.Amount,0) AS $Production_,COALESCE(Adjust.Amount,0) AS $Adjust_,
COALESCE(Writeoff.Amount,0) AS $Writeoff_,COALESCE(InsPay.Amount,0) AS $InsPay_,
COALESCE(PatPay.Amount,0) AS $PatPay_
FROM provider pv
LEFT JOIN (
SELECT pl.ProvNum,COUNT(DISTINCT(pl.PatNum)) AS 'Count'
FROM procedurelog pl
WHERE pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY pl.ProvNum
) PatCount ON PatCount.ProvNum=pv.ProvNum
LEFT JOIN (
SELECT pl.ProvNum,COUNT(DISTINCT(A.PatNum)) AS 'Count'
FROM (
SELECT pl.PatNum,MIN(pl.ProcDate) AS FirstVisit
FROM procedurelog pl
WHERE pl.ProcStatus=2
GROUP BY pl.PatNum
) A
INNER JOIN procedurelog pl ON pl.PatNum=A.PatNum
AND pl.ProcDate=A.FirstVisit
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY pl.ProvNum
) NewPat ON NewPat.ProvNum=pv.ProvNum
LEFT JOIN (
/*recalls in this case are defined as D0120*/
SELECT pl.ProvNum,COUNT(*) AS 'Count'
FROM procedurelog pl
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum AND pc.ProcCode='D0120'
WHERE pl.ProcStatus=2
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY pl.ProvNum
) Recalls ON Recalls.ProvNum=pv.ProvNum
LEFT JOIN (
SELECT pl.ProvNum,SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) AS Amount
FROM procedurelog pl
WHERE pl.DateTP BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus IN(1,2)/*TP,Complete*/
GROUP BY pl.ProvNum
) Diagnosed ON Diagnosed.ProvNum=pv.ProvNum
LEFT JOIN (
SELECT cp.ProvNum,SUM(cp.InsPayAmt) AS Amount
FROM claimproc cp
WHERE cp.Status IN(1,4)/*received, supplemental*/
AND cp.DateCp BETWEEN @FromDate AND @ToDate
GROUP BY cp.ProvNum
) InsPay ON InsPay.ProvNum=pv.ProvNum
LEFT JOIN (
SELECT ps.ProvNum,SUM(ps.SplitAmt) AS Amount
FROM paysplit ps
WHERE ps.DatePay BETWEEN @FromDate AND @ToDate
GROUP BY ps.ProvNum
) PatPay ON PatPay.ProvNum=pv.ProvNum
LEFT JOIN (
SELECT pl.ProvNum,SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) AS Amount
FROM procedurelog pl
WHERE pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus=2
GROUP BY pl.ProvNum
) Prod ON Prod.ProvNum=pv.ProvNum
LEFT JOIN (
SELECT cp.ProvNum,SUM(cp.Writeoff) AS Amount
FROM claimproc cp
WHERE cp.Status IN (0,1,4)/*not received, received, supplemental*/
AND cp.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY cp.ProvNum
) Writeoff ON Writeoff.ProvNum=pv.ProvNum
LEFT JOIN (
SELECT a.ProvNum,SUM(a.AdjAmt) AS Amount
FROM adjustment a
WHERE a.AdjDate BETWEEN @FromDate AND @ToDate
GROUP BY a.ProvNum
) Adjust ON Adjust.ProvNum=pv.ProvNum
ORDER BY pv.Abbr;
Record of sent claims (shows each time sent or resent) for one patient. - Will not show claims that were 'undone' from Manage Module send claims window.
/*650 Record of sent claims (shows each time sent or resent) for one patient. Will not show claims that were 'undone' from Manage Module send claims window.*/
SET @PatNum=816;/*<--Set PatNum here*/
SELECT p.LName,p.FName,c.CarrierName,e.DateTimeTrans
FROM etrans e
INNER JOIN patient p ON p.PatNum=e.PatNum
LEFT JOIN carrier c ON e.CarrierNum=c.CarrierNum
WHERE e.PatNum=@PatNum;
Treatment Planned or Completed procedures that were treatment planned in a specific date range. - The provider attached to the procedure as well as the providers and secondary providers (hygienists) that saw the patient (by appointment) on the date that the procedure was treatment planned is also listed.
/*651 Treatment Planned or Completed procedures that were treatment planned in a specific date range.*/
SET @FromDate='2011-03-14' , @ToDate='2012-03-14';
/*-------------------- Do not modify under this line --------------------*/
/*Additional information: The provider attached to the procedure as well as the providers and secondary providers (hygienists) that saw the patient (by appointment) on the date that the procedure was treatment planned is also listed. In some offices this would inidcate who treatment planned the procedure (more complex version of 144) there are too many columns used to print well, you must choose some columns to eliminate or export to print*/
#
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count', a.*
FROM (
SELECT
pa.PatNum,
pc.ProcCode AS 'Code',
abbrdesc AS 'Description',
ToothNum,
DATE_FORMAT(pl.DateTP,'%m-%d-%Y') AS 'DateTP',
IF((pl.ProcStatus=2), pl.ProcDate, NULL) AS DateCompleted,
pr.Abbr AS 'Provider',
ProcFee,
IF((pl.AptNum=0), "Unattached", "Attached") AS HasApt,
pl.ProcStatus,
(
SELECT GROUP_CONCAT(DISTINCT(pr.Abbr))
FROM appointment a
LEFT JOIN provider pr
ON pr.ProvNum=a.ProvNum
WHERE a.PatNum=pa.PatNum
AND DATE(a.AptDateTime)=pl.DateTP
) AS TPProv,
(
SELECT GROUP_CONCAT(DISTINCT(pr.Abbr))
FROM appointment a
LEFT JOIN provider pr
ON pr.ProvNum=a.ProvHyg
WHERE a.PatNum=pa.PatNum
AND DATE(a.AptDateTime)=pl.DateTP
) AS TPHyg
FROM patient pa
INNER JOIN procedurelog pl
ON pa.PatNum=pl.PatNum
INNER JOIN procedurecode pc
ON pl.CodeNum= pc.CodeNum
INNER JOIN provider pr
ON pl.ProvNum=pr.ProvNum
WHERE ProcStatus IN(1,2)
AND (DateTP BETWEEN @FromDate AND @ToDate)
ORDER BY DateTP,pa.LName, pa.FName
) a;
Numbered list of all referrals that are not marked as 'not person' for a given date range. - For Versions 17.1 and greater. Please update your version accordingly. Much like 27 but adds provider of both referred patient and ref source if the source is a patient. Note that it is too wide to print, so usually this one is exported or used as a mail
/*652 Numbered list of all referrals that are not marked as 'not person' for a given date range. Much like 27 but adds provider of both referred patient and ref source if the source is a patient. Note that it is too wide to print, so usually this one is exported or used as a mail merge list.*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/16/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2018-01-01',@ToDate='2018-01-14';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count',
A.*
FROM (
SELECT DATE(refattach.RefDate) AS DateRef,
patient.PriProv,
prov2.Abbr AS RefSourceProv,
patient.PatNum,
patient.LName,
patient.FName,
patient.MiddleI,
patient.Preferred,
patient.Salutation,
patient.Address,
patient.Address2,
patient.City,
patient.State,
patient.Zip ,
referral.LName AS RefLName,
referral.FName AS RefFName,
referral.MName AS RefMName,
referral.Title AS RefTitle,
referral.Address AS RefAddress,
referral.Address2 AS RefAddress2,
referral.City AS RefCity,
referral.ST AS RefST,
referral.Zip AS RefZip,
referral.Specialty
FROM patient
INNER JOIN refattach ON patient.PatNum=refattach.PatNum
INNER JOIN referral ON referral.ReferralNum=refattach.ReferralNum
LEFT JOIN patient p2 ON referral.PatNum=p2.PatNum
LEFT JOIN provider prov2 ON prov2.ProvNum=p2.PriProv
WHERE refattach.RefType = 1 /*RefFrom*/
AND refattach.RefDate BETWEEN @FromDate AND @ToDate
AND referral.NotPerson=0 /*False*/
ORDER BY Specialty,RefLName,RefFName
) A;
Count of patients from each referral source, the amount of treatment planned work for those patients, the amount of that treatment planned work that is in a scheduled appointment, and the amount of completed work for those patients. - For Versions 17.1 and greater. Please update your version accordingly. Change date range for date of first visit.
/*653 Count of patients from each referral source, the amount of treatment planned work for those patients, the amount of that treatment planned work that is in a scheduled appointment, and the amount of completed work for those patients. Change date range for date of first visit.*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/16/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2017-01-01',@ToDate='2018-03-14';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT r.LName AS RefLName, r.FName AS RefFName,
COUNT(DISTINCT p.PatNum) AS '#NewPat',
SUM(IF(pl.ProcStatus=1, pl.ProcFee*(pl.UnitQty+pl.BaseUnits), 0)) AS $TreatPlan_,
SUM(IF(pl.ProcStatus=1 AND pl.AptNum>0, pl.ProcFee*(pl.UnitQty+pl.BaseUnits), 0)) AS $Scheduled_,
SUM(IF(pl.ProcStatus=2, pl.ProcFee*(pl.UnitQty+pl.BaseUnits), 0)) AS $Completed_
FROM procedurelog pl
INNER JOIN patient p ON p.PatNum=pl.PatNum
INNER JOIN refattach ra ON ra.PatNum=p.PatNum
AND ra.RefType = 1 /*RefFrom*/
INNER JOIN referral r ON r.ReferralNum=ra.ReferralNum
WHERE p.DateFirstVisit BETWEEN @FromDate AND @ToDate
GROUP BY r.ReferralNum;
List of patients with mailing information seen in date range that have not been seen since and are not scheduled. - With patient status and zipcode.
/*654 List of patients with mailing information seen in date range that have not been seen since and are not scheduled.
With patient status and zipcode. limitations: export as CSV and then use MSWord mail merge wizard*/
SET @FromDate='2012-04-01', @ToDate='2016-08-01';
SELECT p.FName, p.LName, CONCAT(p.Address, ' Return service requested') AS Address,
p.Address2, p.City, p.State, p.Zip, p.PatStatus
FROM patient p
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
INNER JOIN appointment ap ON ap.PatNum=p.PatNum
WHERE p.PatStatus IN (0,2) /*comma delimited list Patient: 0, NonPatient: 1, Inactive: 2, Archived: 3, Deleted: 4, Deceased: 5, Prospective: 6*/
/* comment out the line below line if you want no limitation or add the word NOT if you are trying to exclude certain zip codes, like LEFT(p.ZipCode,5) NOT IN ('...*/
/*AND LEFT(p.Zip,5) IN ('12345','45678')*/
AND pl.ProcStatus=2
AND LENGTH(p.Zip>4)
GROUP BY p.PatNum
HAVING MAX(pl.ProcDate) BETWEEN @FromDate AND @ToDate
AND MAX(ap.AptDateTime) <= MAX(pl.ProcDate);
Count of patients seen by each clinic for the date range set. - Count is based on the number of distinct patients that had procedures completed in each clinic in the date range. Note 'No Clinic' as the clinic description means there are procs that do not have a valid clinic assigned.
/*655 Count of patients seen by each clinic for the date range set. Count is based on the number of distinct patients that had procedures completed in each clinic in the date range. Note 'No Clinic' as the clinic description means there are procs that do not have a valid clinic assigned.*/
SET @StartDate='2010-11-01',@EndDate='2012-05-31';
SELECT COALESCE(cl.Description,'No Clinic') AS Clinic,COUNT(DISTINCT pl.PatNum) AS 'Count'
FROM procedurelog pl
LEFT JOIN clinic cl ON cl.ClinicNum=pl.ClinicNum
WHERE pl.ProcStatus=2
AND pl.ProcDate BETWEEN @StartDate AND @EndDate
GROUP BY pl.ClinicNum;
Verification list for appointments on given date with carrier phone and procedures in apt. - Abbreviates to first 15 chars of carrier to save space. Like 281 but with apt time.
/*656 Verification list for appointments on given date with carrier phone and procedures in apt. Abbreviates to first 15 chars of carrier to save space. Like 281 but with apt time.*/
SET @Date='2012-05-18';/*set this date*/
SELECT p.PatNum,c.Phone,a.AptDateTime,
COALESCE(GROUP_CONCAT(pc.AbbrDesc),'None') AS ProceduresInApt,
COALESCE(LEFT(CarrierName,15),'No Ins') AS 'Carrier (abbr)'
FROM appointment a
INNER JOIN patient p ON a.PatNum=p.PatNum
LEFT JOIN patplan pp ON p.PatNum=pp.PatNum
LEFT JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum AND pp.Ordinal=1
LEFT JOIN insplan ip ON ip.PlanNum=ib.PlanNum
LEFT JOIN carrier c ON c.CarrierNum=ip.CarrierNum
LEFT JOIN procedurelog pl ON pl.AptNum=a.AptNum
LEFT JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
WHERE DATE(a.AptDateTime)=@Date
GROUP BY p.PatNum
ORDER BY p.LName,p.FName;
Gross Production and total income for a date range with sum of AR, summed by guarantor's billing type. -
/*657 Gross Production and total income for a date range with sum of AR, summed by guarantor's billing type.*/
SET @FromDate='2012-03-01',@ToDate='2012-03-31';
SELECT trans.*,(SELECT SUM(CASE WHEN g.BalTotal>0.005 THEN g.BalTotal ELSE 0 END) FROM patient g WHERE g.BillingType=trans.BillingType) AS $AcctsRec_Total_
FROM
(
SELECT g.BillingType,SUM(CASE WHEN TranType='Fee' THEN TranAmount ELSE 0 END) AS $GrossProduct_,
SUM(CASE WHEN TranType IN('Pay', 'InsPay') THEN TranAmount ELSE 0 END) AS $TotalPayments
FROM
/*transaction table*/
(
/*Get the completed procedure dates and charges for the entire office history on or before the given date*/
SELECT 'Fee' AS TranType, pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2 AND pl.ProcDate BETWEEN @FromDate AND @ToDate
/*Paysplits for the entire office history on or before the given date*/
UNION ALL
SELECT 'Pay' AS TranType,ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount
FROM paysplit ps
WHERE ps.ProcDate BETWEEN @FromDate AND @ToDate
/*Get the adjustment dates and amounts for the entire office history on or before the given date*/
UNION ALL
SELECT 'Adj' AS TranType, a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount
FROM adjustment a WHERE a.AdjDate BETWEEN @FromDate AND @ToDate
/*Claim payments for the entire office history on or before the given date*/
UNION ALL
SELECT 'InsPay' AS TranType,cp.PatNum PatNum,
cp.DateCp TranDate,-cp.InsPayAmt TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4)/*received, supplemental*/ AND cp.DateCp BETWEEN @FromDate AND @ToDate
/*Claim payments the entire office history on or before the given date*/
UNION ALL
SELECT 'Writeoff' AS TranType,cp.PatNum PatNum,
cp.DateCp TranDate,-cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4)/*received, supplemental*/ AND cp.DateCp BETWEEN @FromDate AND @ToDate
) RawPatTrans
INNER JOIN patient ON patient.PatNum=RawPatTrans.PatNum
INNER JOIN patient g ON patient.Guarantor=g.PatNum
WHERE TranAmount<>0
GROUP BY g.BillingType
) trans;
Treatment plan for a patient with the total amount of the treatment planned procedures. - Change the @PatNum to the patient number you would like to view.
/*658 Treatment plan for a patient with the total amount of the treatment planned procedures.*/
/*Change the @PatNum to the patient number you would like to view.*/
SET @PatNum='816';
SELECT pl.ToothNum AS Tth, pl.Surf, pc.ProcCode AS Code, pc.Descript AS Description
FROM procedurelog pl
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
WHERE pl.PatNum=@PatNum AND pl.ProcStatus=1
UNION ALL
SELECT NULL, NULL, NULL, ' ' AS Description
UNION ALL
SELECT NULL, NULL, 'Treatment Total' AS Code, CONCAT('$', SUM(A.ProcFee))
FROM
(SELECT pl.ProcFee
FROM procedurelog pl
WHERE pl.PatNum=@PatNum AND pl.ProcStatus=1) A
UNION ALL
SELECT NULL, NULL, NULL, ' ' AS Description
UNION ALL
SELECT NULL, NULL, NULL, 'Please understand that this is AN ESTIMATE ONLY. While we try to' AS Description
UNION ALL
SELECT NULL, NULL, NULL, 'anticipate all treatment which may be required, there are cases where' AS Description
UNION ALL
SELECT NULL, NULL, NULL, 'the extent of a dental problem cannot be fully understood until' AS Description
UNION ALL
SELECT NULL, NULL, NULL, 'treatment has begun. Unforeseen changes in treatment can result in' AS Description
UNION ALL
SELECT NULL, NULL, NULL, 'additional cost and we will inform you of any changes at the time of' AS Description
UNION ALL
SELECT NULL, NULL, NULL, 'the visit. If you have dental insurance, please be aware that your' AS Description
UNION ALL
SELECT NULL, NULL, NULL, 'coverage may be different if you have not already met your deductible,' AS Description
UNION ALL
SELECT NULL, NULL, NULL, 'or your yearly maximum has been reached.' AS Description
UNION ALL
SELECT NULL, NULL, NULL, ' ' AS Description
UNION ALL
SELECT NULL, NULL, NULL, 'I have received a copy of the above treatment estimate and acknowledge' AS Description
UNION ALL
SELECT NULL, NULL, NULL, 'that I am financially responsible for the estimated patient portion of' AS Description
UNION ALL
SELECT NULL, NULL, NULL, 'the charges at each visit. I understand the risks, benefits, costs,' AS Description
UNION ALL
SELECT NULL, NULL, NULL, 'and alternatives to care.' AS Description
UNION ALL
SELECT NULL, NULL, NULL, ' ' AS Description
UNION ALL
SELECT NULL, NULL, NULL, ' ' AS Description
UNION ALL
SELECT NULL, NULL, NULL, 'Signature ______________________________________________________' AS Description
UNION ALL
SELECT NULL, NULL, NULL, ' ' AS Description
UNION ALL
SELECT NULL, NULL, NULL, ' ' AS Description
UNION ALL
SELECT NULL, NULL, NULL, 'Date ______________________________' AS Description;
List of patients seen on a given day and count of cleaning, non-cleaning, and total appointments scheduled or completed after that day. - At the bottom of the query, percentages of patients seen on a given day with those appointments. Set date of original appointment to variable @DateDone at the top of the query.
/*659 List of patients seen on a given day and count of cleaning, non-cleaning, and total appointments scheduled or completed after that day. At the bottom of the query, percentages of patients seen on a given day with those appointments. Set date of original appointment to variable @DateDone at the top of the query. */
SET @DateDone='2012-05-31';
SET @TotalSeen=(
SELECT COUNT(p.PatNum)
FROM patient p
INNER JOIN appointment a1 ON a1.PatNum=p.PatNum AND DATE(a1.AptDateTime)=@DateDone
WHERE a1.AptStatus=2
);
SELECT D.PatNum, D.TotalCleaning, (D.TotalSched-D.TotalCleaning) AS TotalNonClean, D.TotalSched FROM
(SELECT B.PatNum, COALESCE(C.TotalCleaning, 0) AS TotalCleaning, B.TotalSched
FROM
(SELECT A.PatNum, SUM(IF(a2.AptStatus=1 OR a2.AptStatus=2, 1, 0)) AS TotalSched FROM (SELECT p.PatNum
FROM patient p
LEFT JOIN appointment a1 ON a1.PatNum=p.PatNum AND DATE(a1.AptDateTime)=@DateDone
WHERE a1.AptStatus=2) A
LEFT JOIN appointment a2 ON A.PatNum=a2.PatNum AND DATE(a2.AptDateTime)>@DateDone
GROUP BY A.PatNum) B
LEFT JOIN (SELECT B.PatNum, COUNT(DISTINCT(B.AptNum)) AS TotalCleaning FROM (SELECT A.PatNum, a2.AptNum FROM (SELECT p.PatNum, a1.AptNum
FROM patient p
LEFT JOIN appointment a1 ON a1.PatNum=p.PatNum AND DATE(a1.AptDateTime)=@DateDone
WHERE a1.AptStatus=2) A
LEFT JOIN appointment a2 ON A.PatNum=a2.PatNum AND DATE(a2.AptDateTime)>@DateDone
LEFT JOIN procedurelog pl ON pl.AptNum=a2.AptNum
LEFT JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
WHERE pc.ProcCode IN('D1110', 'D1120', 'D4910', 'D4341', 'D4342') AND a2.AptStatus IN (1,2)) B
GROUP BY B.PatNum) C ON C.PatNum=B.PatNum) D
UNION ALL
SELECT '%OfToday' AS PatNum, (FORMAT((SUM(IF(E.TotalCleaning=0, 0, 1))/@TotalSeen)*100, 2)) AS TotalCleaning,
(FORMAT((SUM(IF(E.TotalNonClean=0, 0, 1))/@TotalSeen)*100, 2)) AS TotalNonClean,
(FORMAT((SUM(IF(E.TotalSched=0, 0, 1))/@TotalSeen)*100, 2)) AS TotalSched FROM
(SELECT D.PatNum, D.TotalCleaning, (D.TotalSched-D.TotalCleaning) AS TotalNonClean, D.TotalSched FROM
(SELECT B.PatNum, COALESCE(C.TotalCleaning, 0) AS TotalCleaning, B.TotalSched
FROM
(SELECT A.PatNum, SUM(IF(a2.AptStatus=1 OR a2.AptStatus=2, 1, 0)) AS TotalSched FROM (SELECT p.PatNum
FROM patient p
LEFT JOIN appointment a1 ON a1.PatNum=p.PatNum AND DATE(a1.AptDateTime)=@DateDone
WHERE a1.AptStatus=2) A
LEFT JOIN appointment a2 ON A.PatNum=a2.PatNum AND DATE(a2.AptDateTime)>@DateDone
GROUP BY A.PatNum) B
LEFT JOIN (SELECT B.PatNum, COUNT(DISTINCT(B.AptNum)) AS TotalCleaning FROM (SELECT A.PatNum, a2.AptNum FROM (SELECT p.PatNum, a1.AptNum
FROM patient p
LEFT JOIN appointment a1 ON a1.PatNum=p.PatNum AND DATE(a1.AptDateTime)=@DateDone
WHERE a1.AptStatus=2) A
LEFT JOIN appointment a2 ON A.PatNum=a2.PatNum AND DATE(a2.AptDateTime)>@DateDone
LEFT JOIN procedurelog pl ON pl.AptNum=a2.AptNum
LEFT JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
WHERE pc.ProcCode IN('D1110', 'D1120', 'D4910', 'D4341', 'D4342') AND a2.AptStatus IN (1,2)) B
GROUP BY B.PatNum) C ON C.PatNum=B.PatNum) D) E;
Treatment acceptance (scheduled or complete in an appointment). -
/*660 Treatment acceptance (scheduled or complete in an appointment).*/
/*Will show over 100% if the number of treatment planned procedures that were scheduled is greater than the number that is still unscheduled.*/
/*Query code written/modified: 06/12/2015*/
SET @StartDate='2012-05-01' , @EndDate='2015-05-31';
SELECT 'TP and Scheduled (apt complete or still scheduled)' AS ProcCondition,SUM(pl.ProcFee) AS $TotalFees_
FROM procedurelog pl
INNER JOIN appointment ap ON pl.AptNum=ap.AptNum
AND DATE(pl.DateTP) BETWEEN @StartDate AND @EndDate
AND AptStatus IN (1,2)
UNION ALL
SELECT 'TP and Unscheduled' AS ProcCondition, SUM(pl.ProcFee) AS $TotalFees_
FROM procedurelog pl
LEFT JOIN appointment ap ON pl.AptNum=ap.AptNum
WHERE (ISNULL(ap.aptnum) OR AptStatus=6 OR AptStatus=3)
AND DATE(pl.DateTP) BETWEEN @StartDate AND @EndDate
UNION ALL
SELECT 'Percent (TP & Sched/TP & Unsched)' AS ProcCondition,
100*((
SELECT SUM(pl2.ProcFee)
FROM procedurelog pl2
INNER JOIN appointment ap2 ON pl2.AptNum=ap2.AptNum
AND DATE(pl2.DateTP) BETWEEN @StartDate AND @EndDate
AND ap2.AptStatus IN (1,2)
)/SUM(pl.ProcFee)
) AS $TotalFees_
FROM procedurelog pl
LEFT JOIN appointment ap ON pl.AptNum=ap.AptNum
WHERE (ISNULL(ap.aptnum) OR ap.AptStatus=6 OR ap.AptStatus=3)
AND DATE(pl.DateTP) BETWEEN @StartDate AND @EndDate;
Count of active patients grouped by primary carrier whose date of first visit is before the EndDate. -
/*661 Count of active patients grouped by primary carrier whose date of first visit is before the EndDate.*/
SET @EndDate='2012-12-31';
/*Adjust above Date AS needed*/
SELECT carrier.CarrierName,COUNT(DISTINCT patient.PatNum) AS Patients
FROM patient
LEFT JOIN patplan ON patient.PatNum=patplan.PatNum AND patplan.Ordinal=1
LEFT JOIN inssub ON inssub.InsSubNum=patplan.InsSubNum
LEFT JOIN insplan ON insplan.PlanNum=inssub.PlanNum
LEFT JOIN carrier ON carrier.CarrierNum=insplan.CarrierNum
WHERE patient.PatStatus=0
AND patient.DateFirstVisit BETWEEN '1900-01-01' AND @EndDate
GROUP BY CarrierName
ORDER BY CarrierName;
Count of active patients grouped by primary carrier whose date of first visit is before the EndDate or who have never had any work completed. - Similar to #661 except includes active patients who have never had any work completed.
/*662 Count of active patients grouped by primary carrier whose date of first visit is before the EndDate or who have never had any work completed. Similar to #661 except includes active patients who have never had any work completed.*/
SET @EndDate='2012-06-31';
/*Adjust above date as needed*/
SELECT carrier.CarrierName,COUNT(DISTINCT patient.PatNum) AS Patients
FROM patient
LEFT JOIN patplan ON patient.PatNum=patplan.PatNum AND patplan.Ordinal=1
LEFT JOIN inssub ON inssub.InsSubNum=patplan.InsSubNum
LEFT JOIN insplan ON insplan.PlanNum=inssub.PlanNum
LEFT JOIN carrier ON carrier.CarrierNum=insplan.CarrierNum
WHERE patient.PatStatus=0
AND patient.DateFirstVisit<@EndDate
GROUP BY CarrierName
ORDER BY CarrierName;
Special aging for families with any balance that subtracts writeoff estimates from aged balances. - Includes 91-120 day column as well as >120 day column. A/R for version before 14.3
/*663 Special aging for families with any balance that subtracts writeoff estimates from aged balances. Includes 91-120 day column as well as >120 day column.*/
SET @AsOf='2013-07-01';
/*Our internal aging report has a column named '-INS EST' that we subtract from the family balance to give an estimated patient portion. The '-INS EST' column is the amount insurance is expected to pay plus the estimated writeoff amount. This query instead takes the writeoff amount and subtracts it from the aged family balance based on the procedure date. So instead of subtracting it out of the 'TOTAL' column, it is subtracted from each of the aged columns, which are then summed to equal the 'TOTAL' column. The '-INS EST' column is now just the estimated insurance payment amount. If compared to our internal aging report, the '=PATIENT' column should not change. The 'TOTAL' column is the amount an office might actually expect to receive from their outstanding production, provided the estimated writeoffs are correct. This does inclued negative balances.*/
SELECT E.Guarantor AS GUARANTOR,
E.0to30 AS '0-30 DAYS',E.31to60 AS '31-60 DAYS',
E.61to90 AS '61-90 DAYS',E.91to120 AS '91-120 DAYS',
E.Over120 AS '>120 DAYS',E.Total AS TOTAL,
E.InsEst AS '-INS EST',E.PatEst AS '=PATIENT'
FROM (
SELECT 0 AS ItemOrder,CONCAT(D.LName,', ',D.FName) AS Guarantor,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60 THEN D.FamCharges0to30
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30-D.FamCredits END)
,2),2) AS 0to30,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90 THEN D.FamCharges31to60
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60-D.FamCredits END)
,2),2) AS 31to60,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<=D.FamChargesOver120+D.FamCharges91to120 THEN D.FamCharges61to90
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90-D.FamCredits END)
,2),2) AS 61to90,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<=D.FamChargesOver120 THEN D.FamCharges91to120
WHEN D.FamChargesOver120+D.FamCharges91to120<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120-D.FamCredits END)
,2),2) AS 91to120,
FORMAT(ROUND(
(CASE WHEN D.FamCredits>=D.FamChargesOver120 THEN 0
ELSE D.FamChargesOver120-D.FamCredits END)
,2),2) AS Over120,
FORMAT(ROUND(D.FamBal,2),2) AS Total,
FORMAT(ROUND(COALESCE(D.FamInsEst,0),2),2) AS InsEst,
FORMAT(ROUND(D.FamBal-COALESCE(D.FamInsEst,0),2),2) AS PatEst
FROM (
/*Get the family level charges, credits, and ins estimates*/
SELECT g.PatNum,g.LName,g.FName,SUM(B.PatBal)-SUM(COALESCE(WO.WOEst,0)) AS FamBal,
SUM(B.Charges0to30)-SUM(COALESCE(WO.WOEst0to30,0)) AS FamCharges0to30,
SUM(B.Charges31to60)-SUM(COALESCE(WO.WOEst31to60,0)) AS FamCharges31to60,
SUM(B.Charges61to90)-SUM(COALESCE(WO.WOEst61to90,0)) AS FamCharges61to90,
SUM(B.Charges91to120)-SUM(COALESCE(WO.WOEst91to120,0)) AS FamCharges91to120,
SUM(B.ChargesOver120)-SUM(COALESCE(WO.WOEstOver120,0)) AS FamChargesOver120,
SUM(B.Credits) AS FamCredits,SUM(COALESCE(InsPay.InsPayEst,0)) AS FamInsEst
FROM (
/*Get Patient level charges and credits*/
SELECT RawPatTrans.PatNum,SUM(RawPatTrans.TranAmount) AS PatBal,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<=@AsOf AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 30 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges0to30,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 30 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 60 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges31to60,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 60 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges61to90,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 90 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 120 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges91to120,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 120 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS ChargesOver120,
-(SUM(CASE WHEN (RawPatTrans.TranAmount<0 AND RawPatTrans.TranDate<=@AsOf) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Credits
FROM (
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum AS PatNum,pl.ProcDate AS TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) AS TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum AS PatNum,ps.DatePay AS TranDate,-ps.SplitAmt AS TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum AS PatNum,a.AdjDate AS TranDate,a.AdjAmt AS TranAmount
FROM adjustment a
WHERE a.AdjAmt!=0
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum AS PatNum,cp.DateCp AS TranDate,-cp.InsPayAmt-cp.Writeoff AS TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4,5,7)/*received,supplemental,CapClaim, or CapComplete*/
UNION ALL
/*Payment plan principal for the entire office history on or before the given date*/
SELECT 'PayPlan' AS TranType,pp.PatNum AS PatNum,pp.PayPlanDate AS TranDate,-pp.CompletedAmt AS TranAmount
FROM payplan pp
WHERE pp.CompletedAmt!=0
) RawPatTrans
WHERE TranDate<=@AsOf
GROUP BY RawPatTrans.PatNum
) B
LEFT JOIN (
/*Get patient level InsPayEst from unreceived claims.*/
SELECT cp.PatNum,SUM(cp.InsPayEst) AS InsPayEst
FROM claimproc cp
WHERE cp.PatNum!=0
AND ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR (cp.Status=1 AND cp.DateCP>@AsOf))
AND cp.ProcDate<=@ASOf
GROUP BY cp.PatNum
) InsPay ON InsPay.PatNum=B.PatNum
LEFT JOIN (
/*Get patient level InsPayEst from unreceived claims.*/
SELECT cp.PatNum,SUM(cp.Writeoff) AS WOEst,
SUM(CASE WHEN (cp.ProcDate<=@AsOf AND cp.ProcDate>=(@AsOf-INTERVAL 30 DAY)) THEN cp.Writeoff ELSE 0 END) AS WOEst0to30,
SUM(CASE WHEN (cp.ProcDate<(@AsOf-INTERVAL 30 DAY) AND cp.ProcDate>=(@AsOf-INTERVAL 60 DAY)) THEN cp.Writeoff ELSE 0 END) AS WOEst31to60,
SUM(CASE WHEN (cp.ProcDate<(@AsOf-INTERVAL 60 DAY) AND cp.ProcDate>=(@AsOf-INTERVAL 90 DAY)) THEN cp.Writeoff ELSE 0 END) AS WOEst61to90,
SUM(CASE WHEN (cp.ProcDate<(@AsOf-INTERVAL 90 DAY) AND cp.ProcDate>=(@AsOf-INTERVAL 120 DAY)) THEN cp.Writeoff ELSE 0 END) AS WOEst91to120,
SUM(CASE WHEN cp.ProcDate<(@AsOf-INTERVAL 120 DAY) THEN cp.Writeoff ELSE 0 END) AS WOEstOver120
FROM claimproc cp
WHERE cp.PatNum!=0
AND ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR (cp.Status=1 AND cp.DateCP>@AsOf))
AND cp.ProcDate<=@ASOf
GROUP BY cp.PatNum
) WO ON WO.PatNum=B.PatNum
INNER JOIN patient p ON p.PatNum=B.PatNum
INNER JOIN patient g ON g.PatNum=p.Guarantor
GROUP BY g.PatNum
) D
WHERE ABS(D.FamBal)>0.005
UNION ALL
SELECT 1 AS ItemOrder,'--------------------------------','---------------','---------------','---------------','---------------','---------------','---------------','---------------','---------------'
UNION ALL
SELECT 2 AS ItemOrder,'TOTALS:' AS Guarantor,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60 THEN D.FamCharges0to30
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30-D.FamCredits END))
,2),2) AS 0to30,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90 THEN D.FamCharges31to60
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60-D.FamCredits END))
,2),2) AS 31to60,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<=D.FamChargesOver120+D.FamCharges91to120 THEN D.FamCharges61to90
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90-D.FamCredits END))
,2),2) AS 61to90,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<=D.FamChargesOver120 THEN D.FamCharges91to120
WHEN D.FamChargesOver120+D.FamCharges91to120<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120-D.FamCredits END))
,2),2) AS 91to120,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits>=D.FamChargesOver120 THEN 0
ELSE D.FamChargesOver120-D.FamCredits END))
,2),2) AS Over120,
FORMAT(ROUND(SUM(D.FamBal),2),2) AS Total,
FORMAT(ROUND(SUM(COALESCE(D.FamInsEst,0)),2),2) AS InsEst,
FORMAT(ROUND(SUM(D.FamBal-COALESCE(D.FamInsEst,0)),2),2) AS PatEst
FROM (
/*Get the family level charges, credits, and ins estimates*/
SELECT g.PatNum,g.LName,g.FName,SUM(B.PatBal)-SUM(COALESCE(WO.WOEst,0)) AS FamBal,
SUM(B.Charges0to30)-SUM(COALESCE(WO.WOEst0to30,0)) AS FamCharges0to30,
SUM(B.Charges31to60)-SUM(COALESCE(WO.WOEst31to60,0)) AS FamCharges31to60,
SUM(B.Charges61to90)-SUM(COALESCE(WO.WOEst61to90,0)) AS FamCharges61to90,
SUM(B.Charges91to120)-SUM(COALESCE(WO.WOEst91to120,0)) AS FamCharges91to120,
SUM(B.ChargesOver120)-SUM(COALESCE(WO.WOEstOver120,0)) AS FamChargesOver120,
SUM(B.Credits) AS FamCredits,SUM(COALESCE(InsPay.InsPayEst,0)) AS FamInsEst
FROM (
/*Get Patient level charges and credits*/
SELECT RawPatTrans.PatNum,SUM(RawPatTrans.TranAmount) AS PatBal,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<=@AsOf AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 30 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges0to30,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 30 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 60 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges31to60,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 60 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges61to90,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 90 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 120 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges91to120,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 120 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS ChargesOver120,
-(SUM(CASE WHEN (RawPatTrans.TranAmount<0 AND RawPatTrans.TranDate<=@AsOf) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Credits
FROM (
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum AS PatNum,pl.ProcDate AS TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) AS TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum AS PatNum,ps.DatePay AS TranDate,-ps.SplitAmt AS TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum AS PatNum,a.AdjDate AS TranDate,a.AdjAmt AS TranAmount
FROM adjustment a
WHERE a.AdjAmt!=0
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum AS PatNum,cp.DateCp AS TranDate,-cp.InsPayAmt-cp.Writeoff AS TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4,5,7)/*received,supplemental,CapClaim, or CapComplete*/
UNION ALL
/*Payment plan principal for the entire office history on or before the given date*/
SELECT 'PayPlan' AS TranType,pp.PatNum AS PatNum,pp.PayPlanDate AS TranDate,-pp.CompletedAmt AS TranAmount
FROM payplan pp
WHERE pp.CompletedAmt!=0
) RawPatTrans
WHERE TranDate<=@AsOf
GROUP BY RawPatTrans.PatNum
) B
LEFT JOIN (
/*Get patient level InsPayEst from unreceived claims.*/
SELECT cp.PatNum,SUM(cp.InsPayEst) AS InsPayEst
FROM claimproc cp
WHERE cp.PatNum!=0
AND ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR (cp.Status=1 AND cp.DateCP>@AsOf))
AND cp.ProcDate<=@ASOf
GROUP BY cp.PatNum
) InsPay ON InsPay.PatNum=B.PatNum
LEFT JOIN (
/*Get patient level InsPayEst from unreceived claims.*/
SELECT cp.PatNum,SUM(cp.Writeoff) AS WOEst,
SUM(CASE WHEN (cp.ProcDate<=@AsOf AND cp.ProcDate>=(@AsOf-INTERVAL 30 DAY)) THEN cp.Writeoff ELSE 0 END) AS WOEst0to30,
SUM(CASE WHEN (cp.ProcDate<(@AsOf-INTERVAL 30 DAY) AND cp.ProcDate>=(@AsOf-INTERVAL 60 DAY)) THEN cp.Writeoff ELSE 0 END) AS WOEst31to60,
SUM(CASE WHEN (cp.ProcDate<(@AsOf-INTERVAL 60 DAY) AND cp.ProcDate>=(@AsOf-INTERVAL 90 DAY)) THEN cp.Writeoff ELSE 0 END) AS WOEst61to90,
SUM(CASE WHEN (cp.ProcDate<(@AsOf-INTERVAL 90 DAY) AND cp.ProcDate>=(@AsOf-INTERVAL 120 DAY)) THEN cp.Writeoff ELSE 0 END) AS WOEst91to120,
SUM(CASE WHEN cp.ProcDate<(@AsOf-INTERVAL 120 DAY) THEN cp.Writeoff ELSE 0 END) AS WOEstOver120
FROM claimproc cp
WHERE cp.PatNum!=0
AND ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR (cp.Status=1 AND cp.DateCP>@AsOf))
AND cp.ProcDate<=@ASOf
GROUP BY cp.PatNum
) WO ON WO.PatNum=B.PatNum
INNER JOIN patient p ON p.PatNum=B.PatNum
INNER JOIN patient g ON g.PatNum=p.Guarantor
GROUP BY g.PatNum
) D
WHERE ABS(D.FamBal)>0.005
) E
ORDER BY E.ItemOrder,E.Guarantor;
Net and gross production per patient for each provider over a user defined time period, writeoffs by procedure date. -
/*664 Net and gross production per patient for each provider over a user defined time period, writeoffs by procedure date*/
SET @FromDate='2012-05-01', @ToDate='2012-05-31';
SELECT *, $GrossProd+$Writeoffs+$Adjustments $NetProd, $GrossProd/PatCount $AveGrossPr,($GrossProd+$Writeoffs+$Adjustments)/PatCount $AveNetPr FROM (
SELECT pr.Abbr, pr.LName, pr.FName,
(SELECT COUNT(DISTINCT pl.PatNum) FROM procedurelog pl WHERE pl.ProvNum=pr.ProvNum AND pl.ProcStatus=2 AND (pl.ProcDate BETWEEN @FromDate AND @ToDate)) PatCount,
(SELECT SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) FROM procedurelog pl WHERE pl.ProvNum=pr.ProvNum AND pl.ProcStatus=2 AND (pl.ProcDate BETWEEN @FromDate AND @ToDate)) $GrossProd,
(SELECT SUM(-cp.WriteOff) FROM claimproc cp WHERE cp.Status IN(0,1,4,5,7) /*received, not received, supplemental, CapClaim or CapComplete*/ AND cp.ProvNum=pr.ProvNum AND (cp.ProcDate BETWEEN @FromDate AND @ToDate)) $Writeoffs,
(SELECT SUM(a.AdjAmt) FROM adjustment a WHERE a.ProvNum=pr.ProvNum AND (a.AdjDate BETWEEN @FromDate AND @ToDate)) $Adjustments
FROM provider pr) A;
New patients for a time span, with age at time of first visit, Dr First Seen, and Chart number. - New patient date based on first completed procedure with a fee >0.
/*665 New patients for a time span, with age at time of first visit, Dr First Seen, and Chart number. (new patient date based on first completed procedure date with fee>0)*/
/*Query code written/modified: 05/14/2016*/
SET @FromDate='2016-04-01', @ToDate='2016-04-30';
SET @pos=0;
SELECT @pos:=@pos+1 AS numberofpatients, A.*
FROM (
SELECT p.PatNum, p.ChartNumber,
(SELECT MIN(prov.ABBR) FROM appointment ap2 INNER JOIN provider prov ON prov.ProvNum=ap2.ProvNum WHERE ap2.AptStatus=2 AND ap2.PatNum=p.PatNum AND ap2.AptDateTime=
(SELECT MIN(appointment.AptDateTime) FROM appointment WHERE appointment.PatNum=p.PatNum AND appointment.AptStatus=2)) AS FirstDoc,
DATE_FORMAT(MIN(procedurelog.ProcDate),'%m-%d-%Y') AS FirstVisit,
(CASE WHEN (YEAR(MIN(procedurelog.ProcDate))-YEAR(p.Birthdate)) - (RIGHT(MIN(procedurelog.ProcDate),5)<RIGHT(p.Birthdate,5))<200
THEN(YEAR(MIN(procedurelog.ProcDate))-YEAR(p.Birthdate)) - (RIGHT(MIN(procedurelog.ProcDate),5)<RIGHT(p.Birthdate,5)) ELSE 0 END) AS 'Age at First Visit'
FROM patient p
INNER JOIN procedurelog ON procedurelog.PatNum = p.PatNum
INNER JOIN procedurecode pc ON pc.CodeNum=procedurelog.CodeNum
AND pc.ProcCode NOT IN ('D9986','D9987')
WHERE procedurelog.ProcStatus=2
AND procedurelog.ProcFee > 0
GROUP BY p.PatNum
HAVING MIN(procedurelog.ProcDate) BETWEEN @FromDate AND @ToDate
ORDER BY MIN(procedurelog.ProcDate)
)A;
Daily procedures report without fee. -
/*667 Daily procedures report without fee */
SET @FromDate= '2012-06-01', @ToDate='2012-07-31'; /*change dates here*/
SELECT pl.ProcDate, CONCAT(pa.LName,', ',pa.FName,' ',pa.MiddleI) AS PatName,pr.Abbr, ProcCode,
pl.ToothNum,pc.Descript
FROM patient pa,procedurecode pc, provider pr, procedurelog pl
WHERE pl.ProcStatus = '2'
AND pl.CodeNum=pc.CodeNum
AND pa.PatNum=pl.PatNum
AND pr.ProvNum=pl.ProvNum
AND pl.ProcDate >=@FromDate
AND pl.ProcDate <=@ToDate
GROUP BY pl.ProcNum
ORDER BY pl.ProcDate,PatName
Aging for families with a positive balance, includes extra 90-180 and Over 180 column, no over 90 column. - Export to Excel or OpenOffice to view properly. A/R for version before 14.3
/*668 Aging for families with a positive balance, includes extra 90-180 and Over 180 column, no over 90 column
export to Excel or OpenOffice to view properly*/
SET @AsOf='2012-07-31';
/*transaction table*/
SELECT b.PatNum, b.LName, b.FName,
B.FamBal AS $FamBal,
LEAST((B.FamBal), B.0to30Trans) AS $0to30Bal,
IF(B.FamBal-B.0to30Trans<=0,0,LEAST((B.FamBal-B.0to30Trans), B.30to60Trans)) AS $30to60Bal,
IF(B.FamBal-B.0to30Trans-B.30to60Trans<=0,0,LEAST((B.FamBal-B.0to30Trans-B.30to60Trans), B.60to90Trans)) AS $60to90Bal,
IF(B.FamBal-B.0to30Trans-B.30to60Trans-B.60to90Trans<=0,0,LEAST((B.FamBal-B.0to30Trans-B.30to60Trans-B.60to90Trans), B.90to180Trans)) AS $90to180Bal,
IF(B.FamBal-B.0to30Trans-B.30to60Trans-B.60to90Trans-B.90to180Trans<=0,0,LEAST((B.FamBal-B.0to30Trans-B.30to60Trans-B.60to90Trans-B.90to180Trans), B.Over180Trans)) AS $Over180Bal
FROM
(
SELECT g.PatNum, g.LName, g.FName, SUM(RawPatTrans.TranAmount) AS FamBal,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 30 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS 0to30Trans,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 30 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 60 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS 30to60Trans,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 60 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS 60to90Trans,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 90 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 180 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS 90to180Trans,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 180 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Over180Trans
FROM
(
/*Get the completed procedure dates and charges for the entire office history on or before the given date*/
SELECT 'Fee' AS TranType, pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2
/*Paysplits for the entire office history on or before the given date*/
UNION ALL
SELECT 'Pay' AS TranType,ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
/*Get the adjustment dates and amounts for the entire office history on or before the given date*/
UNION ALL
SELECT 'Adj' AS TranType, a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount
FROM adjustment a
/*Claim payments for the entire office history on or before the given date*/
UNION ALL
SELECT 'InsPay' AS TranType,cp.PatNum PatNum,
cp.DateCp TranDate,-cp.InsPayAmt TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4)/*received, supplemental*/
/*Claim payments the entire office history on or before the given date*/
UNION ALL
SELECT 'Writeoff' AS TranType,cp.PatNum PatNum,
cp.DateCp TranDate,-cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4)/*received, supplemental*/
/*Claim capitation payments and capitation writeoffs for the entire office history on or before the given date*/
UNION ALL
SELECT 'Capitat' AS TranType,cp.PatNum PatNum,
cp.DateCp TranDate,-cp.InsPayAmt-cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.Status IN (5,7)/* CapClaim or CapComplete*/
/*Payment plan principal for the entire office history on or before the given date*/
UNION ALL
SELECT 'PayPlan' AS TranType,pp.PatNum PatNum,
pp.PayPlanDate TranDate,
-pp.CompletedAmt TranAmount
FROM payplan pp
)
RawPatTrans
INNER JOIN patient ON patient.PatNum=RawPatTrans.PatNum
INNER JOIN patient g ON patient.Guarantor = g.PatNum
WHERE TranAmount<> 0 AND TranDate<=@AsOf
GROUP BY g.PatNum
)B WHERE B.FamBal>0.001 GROUP BY B.PatNum ORDER BY B.LName, B.FName
;
Number of visits by billing type for date range. -
/*669 Number of visits by billing type for date range*/
SELECT billingtype, COUNT(DISTINCT patient.PatNum,procedurelog.ProcDate) AS VisitCount
FROM patient, procedurelog
WHERE procedurelog.PatNum = patient.PatNum AND
patient.PatStatus = '0' AND
procedurelog.ProcDate > '2012-01-01' AND
procedurelog.ProcDate < '2012-12-31' AND
procedurelog.ProcStatus=2
GROUP BY BillingType
Patients with service year benefits, with carrier, service month and service month filter. - Edit service year renewal month filter at top.
/*670 Patients with service year benefits, with carrier, service month and service month filter*/
/*Edit service year renewal month filter here:*/
SET @ServiceMonth=2;
SELECT p.PatNum, c.CarrierName, ip.MonthRenew, COUNT(*) AS 'NumServYearBens'
FROM carrier c
INNER JOIN insplan ip ON c.CarrierNum=ip.CarrierNum
INNER JOIN inssub ib ON ib.PlanNum=ip.PlanNum
INNER JOIN patplan pp ON ib.InsSubNum=pp.InsSubNum
INNER JOIN patient p ON pp.PatNum=p.PatNum
INNER JOIN benefit b ON ip.PlanNum=b.PlanNum
WHERE p.PatStatus=0 AND
b.TimePeriod=1
AND ip.MonthRenew=@ServiceMonth
GROUP BY p.PatNum, c.CarrierName
ORDER BY p.LName, p.FName, c.CarrierName;
Outstanding secondary insurance claims that are on hold, by date of service. -
/*671 Outstanding secondary insurance claims that are on hold by Date of Service*/
SELECT cl.PatNum,cl.DateService,cl.DateSent, ca.CarrierName, ca.Phone FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE cl.ClaimStatus='H' AND
DateService<(CURDATE()-INTERVAL 30 DAY) AND
ClaimType='S'
ORDER BY ca.CarrierName,p.LName;
Accounts Receivable with writeoffs considered. - With Guarantor, Gross Accounts, Writeoff, Net Accounts, InsEst, PatientEst.
/*672 Accounts Receivable with writeoffs considered
With Guarantor, Gross Accounts, Writeoff, Net Accounts, InsEst, PatientEst*/
SET @AsOf='2012-07-31';
/*transaction table*/
SELECT b.PatNum,
B.FamBal AS $GrossAcctBal,
B.WriteOffEst AS $WriteOffEst,
B.FamBal-B.WriteOffEst AS $NetAcctBal,
B.InsPayEst AS $InsPayEst,
B.FamBal-B.WriteOffEst-InsPayEst AS $PatientEst
FROM
(
SELECT g.PatNum, g.LName, g.FName, SUM(RawPatTrans.TranAmount) AS FamBal,
(SELECT SUM(InsPayEst) FROM claim WHERE claim.PatNum=patient.PatNum AND (claim.ClaimStatus='W' OR claim.ClaimStatus='S')AND claim.ClaimType<>'PreAuth') AS 'InsPayEst',
(SELECT SUM(WriteOff) FROM claim WHERE claim.PatNum=patient.PatNum AND (claim.ClaimStatus='W' OR claim.ClaimStatus='S')AND claim.ClaimType<>'PreAuth') AS 'WriteOffEst'
FROM
(
/*Get the completed procedure dates and charges for the entire office history on or before the given date*/
SELECT 'Fee' AS TranType, pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2
/*Paysplits for the entire office history on or before the given date*/
UNION ALL
SELECT 'Pay' AS TranType,ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
/*Get the adjustment dates and amounts for the entire office history on or before the given date*/
UNION ALL
SELECT 'Adj' AS TranType, a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount
FROM adjustment a
/*Claim payments for the entire office history on or before the given date*/
UNION ALL
SELECT 'InsPay' AS TranType,cp.PatNum PatNum,
cp.DateCp TranDate,-cp.InsPayAmt TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4)/*received, supplemental*/
/*Claim payments the entire office history on or before the given date*/
UNION ALL
SELECT 'Writeoff' AS TranType,cp.PatNum PatNum,
cp.DateCp TranDate,-cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4)/*received, supplemental*/
/*Claim capitation payments and capitation writeoffs for the entire office history on or before the given date*/
UNION ALL
SELECT 'Capitat' AS TranType,cp.PatNum PatNum,
cp.DateCp TranDate,-cp.InsPayAmt-cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.Status IN (5,7)/* CapClaim or CapComplete*/
/*Payment plan principal for the entire office history on or before the given date*/
UNION ALL
SELECT 'PayPlan' AS TranType,pp.PatNum PatNum,
pp.PayPlanDate TranDate,
-pp.CompletedAmt TranAmount
FROM payplan pp
)
RawPatTrans
INNER JOIN patient ON patient.PatNum=RawPatTrans.PatNum
INNER JOIN patient g ON patient.Guarantor = g.PatNum
WHERE TranAmount<> 0 AND TranDate<=@AsOf
GROUP BY g.PatNum
)B WHERE B.FamBal>0.001 GROUP BY B.PatNum ORDER BY B.LName, B.FName
;
Outstanding insurance claims by Date of Service, not including Preauths for varying days since service ranges. - @StartDaysPast=30, @EndDaysPast=700 will give you 30 or more days since service, up to 700 days old.
/*673 Outstanding insurance claims by Date of Service not including Preauths for varying days since service ranges*/
SET @StartDaysPast=30, @EndDaysPast=500; /*30 and 730 will give you 30 or more days since service*/
SELECT cl.PatNum,cl.DateService,cl.DateSent, ca.CarrierName, ca.Phone FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
WHERE cl.ClaimStatus='S' AND
DateService<(CURDATE()-INTERVAL @StartDaysPast DAY) AND DateService>(CURDATE()-INTERVAL @EndDaysPast DAY)
AND ClaimType<>'PreAuth'
ORDER BY ca.CarrierName,p.LName;
Replication customers: Finds appointments that are in the same operatory on the same date with overlapping time. - SPECIAL USE.
/*674 SPECIAL USE Replication customers- Finds appointments that are in the same operatory on the same date with overlapping time.*/
SET @FromDate=DATE(CURDATE()),@ToDate=DATE(CURDATE()+INTERVAL 180 DAY);/*Default: From current date to current date + 180 days*/
SELECT A.AptNum, A.StartTime, A.EndTime, a2.AptNum, a2.AptDateTime, op.OpName
FROM
(SELECT a1.AptNum, a1.AptDateTime AS StartTime, DATE_ADD(a1.AptDateTime,INTERVAL (CHAR_LENGTH(a1.Pattern)*5) MINUTE) AS EndTime, a1.Op
FROM appointment a1
WHERE DATE(a1.AptDateTime) BETWEEN @FromDate AND @ToDate AND a1.AptStatus IN(1,4)/*Scheduled or ASAP*/) A
INNER JOIN appointment a2 ON A.Op=a2.Op AND A.AptNum<>a2.AptNum
INNER JOIN operatory op ON op.OperatoryNum=a2.Op
WHERE a2.AptDateTime BETWEEN A.StartTime AND A.EndTime AND a2.AptStatus IN(1,4);
Production, Writeoffs, Adjustments, Net Production, Ins Payments, Patient Payments and Total Payments by fee schedule in a date range. - Edit date range at top.
/*675 Production, Writeoffs, Adjustments, Net Production, Ins Payments, Patient Payments and Total Payments by fee schedule in a date range*/
SET @FromDate='2012-07-01',@ToDate='2012-07-31';
SELECT A.FeeSchedule, /*A.PatNum,*/ A.$Production_,A.$Adjustment_,A.$Writeoff_,(A.$Production_+A.$Adjustment_-A.$Writeoff_) AS $NetProd_,A.$InsPay_,A.$PatPay_,A.$TotPay_
FROM
(
SELECT /*GROUP_CONCAT(RawTable.PatNum) AS PatNum,*/(CASE WHEN (fs1.Description IS NULL AND fs2.Description IS NULL) THEN fs3.Description
WHEN (fs1.Description IS NULL AND fs2.Description IS NOT NULL) THEN fs2.Description
WHEN (fs1.Description IS NOT NULL) THEN fs1.Description ELSE NULL END) AS FeeSchedule,
SUM(CASE WHEN (RawTable.TranType='Fee') THEN RawTable.TranAmount ELSE 0 END) AS $Production_,
SUM(CASE WHEN (RawTable.TranType='Adj') THEN RawTable.TranAmount ELSE 0 END) AS $Adjustment_,
SUM(CASE WHEN (RawTable.TranType='Writeoff') THEN RawTable.TranAmount ELSE 0 END) AS $Writeoff_,
SUM(CASE WHEN (RawTable.TranType='InsPay') THEN RawTable.TranAmount ELSE 0 END) AS $InsPay_,
SUM(CASE WHEN (RawTable.TranType='Pay') THEN RawTable.TranAmount ELSE 0 END) AS $PatPay_,
SUM(CASE WHEN (RawTable.TranType='Pay' OR RawTable.TranType='InsPay') THEN RawTable.TranAmount ELSE 0 END) AS $TotPay_
FROM
(
/*Get the completed procedure dates and charges for the entire office history on or before the given date*/
SELECT 'Fee' AS TranType,pl.PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2
/*Paysplits for the entire office history on or before the given date*/
UNION ALL
SELECT 'Pay' AS TranType,ps.PatNum,ps.ProcDate TranDate,ps.SplitAmt TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
/*Get the adjustment dates and amounts for the entire office history on or before the given date*/
UNION ALL
SELECT 'Adj' AS TranType, a.PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount
FROM adjustment a
/*Claim payments for the entire office history on or before the given date*/
UNION ALL
SELECT 'InsPay' AS TranType,cp.PatNum,cp.DateCp TranDate,cp.InsPayAmt TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4)/*received, supplemental*/
/*Claim writeoffs for the entire office history on or before the given date*/
UNION ALL
SELECT 'Writeoff' AS TranType,cp.PatNum,cp.DateCp TranDate,cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4)/*received, supplemental*/
) RawTable
INNER JOIN patient p ON p.PatNum=RawTable.PatNum
INNER JOIN provider pv ON p.PriProv=pv.ProvNum
INNER JOIN feesched fs3 ON fs3.FeeSchedNum=pv.FeeSched
LEFT JOIN feesched fs2 ON fs2.FeeSchedNum=p.FeeSched
LEFT JOIN patplan pp ON pp.PatNum=p.PatNum AND pp.Ordinal=1
LEFT JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=ib.PlanNum
LEFT JOIN feesched fs1 ON ip.FeeSched=fs1.FeeSchedNum
WHERE RawTable.TranDate BETWEEN @FromDate AND @ToDate
GROUP BY FeeSchedule) A
ORDER BY FeeSchedule;
List of patients due for recall (of type prophy or perio) in date range with no scheduled apt. - Edit date range at top.
/*676 List of patients due for recall (of type prophy or perio) in date range with no scheduled apt*/
/*Query code written/modified: 08/26/2014*/
SET @FromDate='2005-10-01' , @ToDate='2014-12-31';
SET @pos=0;
SELECT @pos:=@pos+1 AS 'Count', A.*
FROM (
SELECT rt.description,r.DateDue, p.PatNum /*, p.Address, p.Address2, p.City, p.State, p.ZIP*/ FROM recall r
INNER JOIN recalltype rt ON r.recalltypenum = rt.recalltypenum
INNER JOIN patient p ON p.PatNum=r.PatNum
LEFT JOIN appointment a ON a.PatNum=p.PatNum AND a.AptStatus=1
WHERE p.patstatus = 0 AND (DATE(r.DateDue) BETWEEN @FromDate AND @ToDate)
AND (rt.Description LIKE('%perio%') OR rt.Description LIKE('%prophy%')) AND NOT ISNULL(r.DateDue)
AND ISNULL(a.AptNum)/*no sched apt*/
ORDER BY p.LName, p.FName, rt.description, r.DateDue
) A;
Active Patients with insurance having a given Copay Fee Schedule. -
/*677 Active Patients with insurance having a given Copay Fee Schedule*/
SELECT carrier.CarrierName, p.PatNum, feesched.Description AS 'FeeSchedule'
FROM carrier
INNER JOIN insplan ip ON carrier.CarrierNum=ip.CarrierNum
INNER JOIN inssub iss ON ip.PlanNum=iss.PlanNum
INNER JOIN patplan pp ON iss.InsSubNum=pp.InsSubNum
INNER JOIN patient p ON pp.PatNum=p.PatNum
INNER JOIN feesched ON ip.CopayFeeSched=feesched.FeeSchedNum
WHERE p.PatStatus=0 AND feesched.Description LIKE ('%Standard%')
ORDER BY CarrierName;
Aging for one Clinic. - Run Aging first from tools menu, usually customize for each clinic.
/*678 Aging for one Clinic, run Aging first from tools menu, usually customize for each clinic*/
SET @ClinicName='Clinic 1';
SELECT LEFT(CONCAT(PatNum,'-',LName,', ',FName,' ',MiddleI),25) AS Guarantor
,Bal_0_30,Bal_31_60,Bal_61_90,BalOver90
,BalTotal AS $BalanceTotal_,InsEst AS $InsurEst_,BalTotal-InsEst AS '$PatientEst_' /*, ClinicNum*/
FROM patient
INNER JOIN clinic ON clinic.ClinicNum=patient.ClinicNum
WHERE (patstatus != 2)
AND (
Bal_0_30 > '.005' OR Bal_31_60 > '.005' OR Bal_61_90 > '.005' OR BalOver90 > '.005'
/*OR BalTotal < '-.005' Credits*/
) AND clinic.Description=@ClinicName
ORDER BY LName,FName;
Patients listed with address and carrier who have not been seen since some date in the past, but who have a current or future date in their insurance plan(see #635 to remove this exclusion) -
/*679 Patients listed with address and carrier who have not been seen since some date in the past,
but who have a current or future <Effective To> date in their insurance plan(see #635 to remove this exclusion)
also includes patient status (normally you would engage the active patient limitation that
is commented out instead of showing status) and allows carrier exclusion, (in this example excludes carriers with medicaid in the name)*/
Set @NotCarrier='%medicaid%', @NotSeenAfterDate='2011-12-31', @pos=0;
SELECT @pos:=@pos+1 as numberofpatients, A.* FROM( SELECT p.LName,p.FName,p.PatStatus,p.Address,p.Address2,p.City,p.State,p.Zip,p.PatNum,
DATE_FORMAT(MAX(ProcDate),'%m/%d/%Y') AS 'LastVisit', c.CarrierName, DateTerm
FROM carrier c
INNER JOIN insplan ip ON c.CarrierNum=ip.CarrierNum
INNER JOIN inssub ib ON ib.PlanNum=ip.PlanNum
INNER JOIN patplan pp ON ib.InsSubNum=pp.InsSubNum
INNER JOIN patient p ON pp.PatNum=p.PatNum
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
WHERE pl.ProcStatus=2 AND /*p.PatStatus=0 AND*/
c.CarrierName NOT LIKE(@NotCarrier) AND (ib.DateTerm)>=CURDATE()
GROUP BY pl.PatNum, c.CarrierName
HAVING MAX(ProcDate)<@NotSeenAfterDate
ORDER BY p.LName, p.FName) A;
Treatment planned procedures for patients with specified billing type. -
/*680 Treatment planned procedures for patients with specified billing type*/
SET @BillingType='Medicaid';/*<------Set billing type here------*/
SELECT p.PatNum,p.Birthdate,p.HmPhone,p.Address,p.Address2,p.City,p.State,p.Zip,pl.DateTP,pc.ProcCode,pc.Descript AS Description,pl.ProcFee AS $ProcFee_,a.AptDateTime AS ApptDateTime
FROM patient p
INNER JOIN definition d ON d.DefNum=p.BillingType AND d.ItemName=@BillingType
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum AND pl.ProcStatus=1
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
LEFT JOIN appointment a ON a.AptNum=pl.AptNum
ORDER BY p.LName,p.FName,ApptDateTime,DateTP;
Treatment planned procedures that are not scheduled that were treatment planned in a user defined date range with patient, codes, description, fees and billing code. -
/*681 Treatment planned procedures that are not scheduled that were treatment planned in a user defined date range with patient, codes, description, fees and billing code. */
SET @FromDate='2012-07-09';
SET @ToDate='2012-07-23';
SELECT CONCAT(LName, ', ',FName, ' ', MiddleI) As Patient,
pc.ProcCode as 'Code', abbrdesc as 'Description', ToothNum,
DATE_FORMAT(pl.ProcDate,'%m-%d-%Y') AS 'Date', ap.AptStatus, ProcFee, BillingType
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
LEFT JOIN appointment ap ON pl.AptNum=ap.AptNum
WHERE (isnull(ap.aptnum) OR AptStatus=6 OR AptStatus=3)
AND ProcStatus=1 AND PatStatus=0
AND Date(ProcDate) BETWEEN @FromDate AND @ToDate
ORDER BY aptstatus, patient.LName, patient.FName ASC;
Aging for families with a positive balance, includes extra 90-180, 180-360 and over 360 column, no over 90 column. - Export to Excel or OpenOffice to view properly. A/R for version before 14.3
/*682 Aging for families with a positive balance, includes extra 90-180, 180-360 and over 360 column, no over 90 column
export to Excel or OpenOffice to view properly*/
SET @AsOf='2012-07-31';
/*transaction table*/
SELECT b.PatNum AS 'Pat Num', b.LName, b.FName,
b.FamBal AS $FamBal,
LEAST((b.FamBal), b.0to30Trans) AS $0to30Bal,
IF(b.FamBal-b.0to30Trans<=0,0,LEAST((b.FamBal-b.0to30Trans), b.30to60Trans)) AS $30to60Bal,
IF(b.FamBal-b.0to30Trans-b.30to60Trans<=0,0,LEAST((b.FamBal-b.0to30Trans-b.30to60Trans), b.60to90Trans)) AS $60to90Bal,
IF(b.FamBal-b.0to30Trans-b.30to60Trans-b.60to90Trans<=0,0,LEAST((b.FamBal-b.0to30Trans-b.30to60Trans-b.60to90Trans), b.90to180Trans)) AS $90to180Bal,
IF(b.FamBal-b.0to30Trans-b.30to60Trans-b.60to90Trans-b.90to180Trans<=0,0,LEAST((b.FamBal-b.0to30Trans-b.30to60Trans-b.60to90Trans-b.90to180Trans), b.180to360Trans)) AS $180to360Bal,
IF(b.FamBal-b.0to30Trans-b.30to60Trans-b.60to90Trans-b.90to180Trans-b.180to360Trans<=0,0,LEAST((b.FamBal-b.0to30Trans-b.30to60Trans-b.60to90Trans-b.90to180Trans-b.180to360Trans), b.Over360Trans)) AS $Over360Bal
FROM
(
SELECT g.PatNum, g.LName, g.FName, SUM(RawPatTrans.TranAmount) AS FamBal,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 30 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS 0to30Trans,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 30 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 60 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS 30to60Trans,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 60 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS 60to90Trans,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 90 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 180 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS 90to180Trans,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 180 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 360 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS 180to360Trans,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 360 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Over360Trans
FROM
(
/*Get the completed procedure dates and charges for the entire office history on or before the given date*/
SELECT 'Fee' AS TranType, pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2
/*Paysplits for the entire office history on or before the given date*/
UNION ALL
SELECT 'Pay' AS TranType,ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
/*Get the adjustment dates and amounts for the entire office history on or before the given date*/
UNION ALL
SELECT 'Adj' AS TranType, a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount
FROM adjustment a
/*Claim payments for the entire office history on or before the given date*/
UNION ALL
SELECT 'InsPay' AS TranType,cp.PatNum PatNum,
cp.DateCp TranDate,-cp.InsPayAmt TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4)/*received, supplemental*/
/*Claim payments the entire office history on or before the given date*/
UNION ALL
SELECT 'Writeoff' AS TranType,cp.PatNum PatNum,
cp.DateCp TranDate,-cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4)/*received, supplemental*/
/*Claim capitation payments and capitation writeoffs for the entire office history on or before the given date*/
UNION ALL
SELECT 'Capitat' AS TranType,cp.PatNum PatNum,
cp.DateCp TranDate,-cp.InsPayAmt-cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.Status IN (5,7)/* CapClaim or CapComplete*/
/*Payment plan principal for the entire office history on or before the given date*/
UNION ALL
SELECT 'PayPlan' AS TranType,pp.PatNum PatNum,
pp.PayPlanDate TranDate,
-pp.CompletedAmt TranAmount
FROM payplan pp
)
RawPatTrans
INNER JOIN patient ON patient.PatNum=RawPatTrans.PatNum
INNER JOIN patient g ON patient.Guarantor = g.PatNum
WHERE TranAmount<> 0 AND TranDate<=@AsOf
GROUP BY g.PatNum
)b WHERE b.FamBal>0.001 GROUP BY b.PatNum ORDER BY b.LName, b.FName
;
Clinic filtered Aging for families with a positive balance, includes extra 90-180, 180-360 and over 360 column, no over 90 column - Export to Excel or OpenOffice to view properly. A/R for version before 14.3
/*683 Clinic filtered Aging for families with a positive balance, includes extra 90-180, 180-360 and over 360 column, no over 90 column
export to Excel or OpenOffice to view properly*/
SET @AsOf='2012-07-31';
/*transaction table*/
SELECT b.PatNum AS 'Pat Num', b.LName, b.FName,b.Description AS 'Clinic',
B.FamBal AS $FamBal,
LEAST((B.FamBal), B.0to30Trans) AS $0to30Bal,
IF(B.FamBal-B.0to30Trans<=0,0,LEAST((B.FamBal-B.0to30Trans), B.30to60Trans)) AS $30to60Bal,
IF(B.FamBal-B.0to30Trans-B.30to60Trans<=0,0,LEAST((B.FamBal-B.0to30Trans-B.30to60Trans), B.60to90Trans)) AS $60to90Bal,
IF(B.FamBal-B.0to30Trans-B.30to60Trans-B.60to90Trans<=0,0,LEAST((B.FamBal-B.0to30Trans-B.30to60Trans-B.60to90Trans), B.90to180Trans)) AS $90to180Bal,
IF(B.FamBal-B.0to30Trans-B.30to60Trans-B.60to90Trans-B.90to180Trans<=0,0,LEAST((B.FamBal-B.0to30Trans-B.30to60Trans-B.60to90Trans-B.90to180Trans), B.180to360Trans)) AS $180to360Bal,
IF(B.FamBal-B.0to30Trans-B.30to60Trans-B.60to90Trans-B.90to180Trans-B.180to360Trans<=0,0,LEAST((B.FamBal-B.0to30Trans-B.30to60Trans-B.60to90Trans-B.90to180Trans-B.180to360Trans), B.Over360Trans)) AS $Over360Bal
FROM
(
SELECT g.PatNum, g.LName, g.FName, SUM(RawPatTrans.TranAmount) AS FamBal,c.Description,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 30 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS 0to30Trans,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 30 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 60 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS 30to60Trans,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 60 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS 60to90Trans,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 90 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 180 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS 90to180Trans,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 180 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 360 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS 180to360Trans,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 360 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Over360Trans
FROM
(
/*Get the completed procedure dates and charges for the entire office history on or before the given date*/
SELECT 'Fee' AS TranType, pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2
/*Paysplits for the entire office history on or before the given date*/
UNION ALL
SELECT 'Pay' AS TranType,ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
/*Get the adjustment dates and amounts for the entire office history on or before the given date*/
UNION ALL
SELECT 'Adj' AS TranType, a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount
FROM adjustment a
/*Claim payments for the entire office history on or before the given date*/
UNION ALL
SELECT 'InsPay' AS TranType,cp.PatNum PatNum,
cp.DateCp TranDate,-cp.InsPayAmt TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4)/*received, supplemental*/
/*Claim payments the entire office history on or before the given date*/
UNION ALL
SELECT 'Writeoff' AS TranType,cp.PatNum PatNum,
cp.DateCp TranDate,-cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4)/*received, supplemental*/
/*Claim capitation payments and capitation writeoffs for the entire office history on or before the given date*/
UNION ALL
SELECT 'Capitat' AS TranType,cp.PatNum PatNum,
cp.DateCp TranDate,-cp.InsPayAmt-cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.Status IN (5,7)/* CapClaim or CapComplete*/
/*Payment plan principal for the entire office history on or before the given date*/
UNION ALL
SELECT 'PayPlan' AS TranType,pp.PatNum PatNum,
pp.PayPlanDate TranDate,
-pp.CompletedAmt TranAmount
FROM payplan pp
)
RawPatTrans
INNER JOIN patient ON patient.PatNum=RawPatTrans.PatNum
INNER JOIN patient g ON patient.Guarantor = g.PatNum
INNER JOIN clinic c ON g.ClinicNum=c.ClinicNum
WHERE TranAmount<> 0 AND TranDate<=@AsOf /*AND ((c.Description LIKE('C%')) OR (c.Description='Test'))*/
GROUP BY g.PatNum
)B WHERE B.FamBal>0.001 GROUP BY B.PatNum ORDER BY B.LName, B.FName
;
List of patients (active) who have had a broken appointment with count, date of most recent, counted both ways (by adjustments and broken appointments) -
/*684 List of patients (active) who have had a broken appointment with count, date of most recent, counted both ways (by adjustments and broken appointments)*/
SELECT p.FName, p.LName, p.PatStatus, MIN(a2.AptDateTime) 'NextApt', MAX(adj.AdjDate) AS DateBrkAdj, DATE(MAX(a.AptDateTime)) AS DateBrkApt,
COUNT(DISTINCT adj.AdjNum) AS 'BrkApts (by BrkAdj)',COUNT(DISTINCT a.AptNum) AS 'BrkApts (still there)' FROM patient p
LEFT JOIN appointment a ON a.PatNum=p.PatNum AND a.AptStatus=5/*Broken*/
LEFT JOIN appointment a2 ON a2.PatNum=p.PatNum AND a2.AptStatus=1 /*Scheduled*/
LEFT JOIN
(
SELECT ad.AdjDate, ad.AdjNum, ad.PatNum FROM adjustment ad INNER JOIN definition d ON d.DefNum=ad.AdjType WHERE d.ItemName LIKE('%BROKEN%')
) adj ON adj.PatNum=p.PatNum
WHERE p.PatStatus=0 /*active patients*/
GROUP BY p.PatNum
HAVING NOT(ISNULL(MAX(a.AptDateTime)) AND ISNULL(MAX(adj.AdjDate)))/*must have a broken apt or broken apt adjustment*/
ORDER BY NextApt DESC,DateBrkAdj DESC, LName DESC, FName DESC;
Count of active patients by insurance plan type including no insurance -
/*685 Count of active patients by insurance plan type including no insurance*/
SELECT 'Cash Patients' AS InsType,
COUNT(p.PatNum) AS PatientCount
FROM patient p
WHERE p.PatStatus='0' /*Active*/
AND HasIns=''
UNION ALL
SELECT
(CASE WHEN ip.PlanType='c' THEN 'Capitation'
WHEN ip.PlanType='p' THEN 'PPO Percentage'
WHEN ip.PlanType='' THEN 'Category Percentage'
WHEN ip.PlanType='f' THEN 'Medicaid/Flat Copay'
ELSE 'Unknown'
END) AS InsType,
COUNT(DISTINCT p.PatNum) AS PatientCount
FROM patient p
INNER JOIN patplan pp ON pp.PatNum=p.PatNum
AND pp.Ordinal=1 /*primary insurance*/
INNER JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
INNER JOIN insplan ip ON ip.PlanNum=ib.PlanNum
WHERE p.PatStatus=0 /*Active patients*/
GROUP BY ip.PlanType;
Outstanding Insurance Claims (not preauths, only with assigned benefits) with patient, date sent, plan number, claimfee and ins estimate -
/*686 Outstanding Insurance Claims (not preauths, only with assigned benefits) with patient, date sent, plan number, claimfee and ins estimate*/
SELECT cl.PatNum,cl.DateSent, ca.CarrierName,i.plannum, cl.claimfee, cl.inspayest
FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
INNER JOIN inssub ib ON ib.InsSubNum=cl.InsSubNum AND ib.AssignBen=1
WHERE cl.ClaimStatus='S'
GROUP BY cl.ClaimNum
ORDER BY ca.CarrierName,p.LName;
Daily Payments Report, broken down like built in report -
/*687 Daily Payments Report, broken down like built in report*/
SET @StartDate='2012-10-01', @EndDate='2012-10-31';
(SELECT 'Insurance Check' AS PaymentType,cp.PatNum,c.CarrierName,cp.DateCP AS DatePay,cpy.CheckNum,FORMAT(SUM(cp.InsPayAmt),2) AS PaymentAmt
FROM claimproc cp
INNER JOIN claimpayment cpy ON cpy.ClaimPaymentNum=cp.ClaimPaymentNum
INNER JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
INNER JOIN insplan ip ON ip.PlanNum=cl.PlanNum
INNER JOIN carrier c ON c.CarrierNum=ip.CarrierNum
WHERE cp.DateCP BETWEEN @StartDate AND @EndDate
AND (cp.Status=1 OR cp.Status=4)
GROUP BY cp.PatNum, cp.DateCP)
UNION ALL
(SELECT CONCAT('Patient Payment - ',d.ItemName) AS PaymentType,ps.PatNum,null AS CarrierName,ps.DatePay,pm.CheckNum,FORMAT(SUM(ps.SplitAmt),2) AS PaymentAmt
FROM payment pm
INNER JOIN definition d ON d.DefNum=pm.PayType
INNER JOIN paysplit ps ON ps.PayNum=pm.PayNum
WHERE ps.DatePay BETWEEN @StartDate AND @EndDate
GROUP BY pm.PayType,ps.PatNum,ps.DatePay)
ORDER BY PaymentType,DatePay,CarrierName;
Primary insurance info and provider seen for patients seen in date range. - Each line is a provider on a given date for a particular patient.
/*688 Primary insurance info and provider seen for patients seen in date range.
Each line is a provider on a given date for a particular patient. There may be multiple lines per patient for the same day if they were seen by multiple providers. Only includes primary insurance information. */
SET @FromDate='2012-01-01', @ToDate='2012-03-01';
SELECT FName, LName, BirthDate, CarrierName, SubscriberID, Provider, DateSeen FROM
(SELECT p.FName, p.LName, p.BirthDate, ca.CarrierName, iss.SubscriberID, pv.Abbr AS Provider, pl.ProcDate AS DateSeen FROM procedurelog pl
INNER JOIN patient p ON p.PatNum=pl.PatNum
INNER JOIN patplan pp ON pp.PatNum=p.PatNum AND Ordinal=1
INNER JOIN inssub iss ON iss.InsSubNum=pp.InsSubNum
INNER JOIN insplan ip ON ip.PlanNum=iss.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=ip.CarrierNum
INNER JOIN provider pv ON pl.ProvNum=pv.ProvNum
WHERE pl.ProcDate BETWEEN @FromDate AND @ToDate AND pl.ProcStatus=2
GROUP BY pl.PatNum, pl.ProcDate, pl.ProvNum ) A
New patient count by treating provider for date range -
/*689 New patient count by treating provider for date range*/
SET @FromDate='2013-08-01' , @ToDate='2013-09-20'; /*dates include start and end*/
SELECT Abbr,COUNT(*)
FROM
(
SELECT A.PatNum, pr.Abbr, COUNT(*) FROM
(
SELECT p.PatNum, DATE(MIN(pl.ProcDate)) AS DateFirstVisit
FROM patient p
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
WHERE pl.procstatus=2
GROUP BY p.PatNum HAVING DateFirstVisit BETWEEN @FromDate AND @ToDate
) A
INNER JOIN procedurelog pl ON pl.PatNum=A.PatNum AND pl.ProcDate=A.DateFirstVisit
INNER JOIN provider pr ON pl.ProvNum=pr.ProvNum
GROUP BY A.PatNum, pr.Abbr
) B
GROUP BY B.Abbr;
Mailing list of guarantors of patients with a particular insplan requires group number. - Returns the guarantors of all patients with plan, not the subscriber, also if you drop the plan it goes off the list
/*690 Mailing list of guarantors of patients with a particular insplan requires group number, returns the guarantors of all
patients with plan, not the subscriber, also if you drop the plan it goes off the list*/
SET @GroupNum='%6%';
SELECT DISTINCTROW gu.LName, gu.FName, gu.Address,
gu.Address2, gu.City, gu.zip, ca.CarrierName, ip.GroupNum
FROM patient p
INNER JOIN patplan pp ON pp.PatNum=p.PatNum
INNER JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
INNER JOIN insplan ip ON ip.PlanNum=ib.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=ip.CarrierNum
INNER JOIN patient gu ON p.Guarantor=gu.PatNum
WHERE ip.GroupNum LIKE(@GroupNum)
ORDER BY ca.CarrierName, gu.LName;
All Open Insurance Claims (used for Trojan Professional Services) -
/*691 All Open Insurance Claims (used for Trojan Professional Services) */
SELECT ca.CarrierName, ca.Phone,
(CASE WHEN pp.Ordinal=1 THEN 'Primary' WHEN pp.Ordinal=2 THEN 'Secondary' ELSE 'Other' END) AS Type,
p.LName, p.FName, cl.DateService, cl.DateSent, cl.ClaimFee, p.BirthDate,
psub.LName AS 'InsSub_LName',
psub.FName AS 'InsSub_FName',
psub.BirthDate AS 'InsSub_BirthDate',
psub.SSN AS 'InsSub_SSN',
iss.SubscriberID AS 'SubscriberID',
i.GroupName,
i.GroupNum,
e.EmpName,
cl.ClaimIdentifier,
(CASE WHEN etrans.etype=1 THEN 'P' ELSE 'E' END) AS 'EClaimIndic'
FROM claim cl
INNER JOIN patient p ON p.PatNum=cl.PatNum
INNER JOIN inssub iss ON iss.InsSubNum=cl.InsSubNum
INNER JOIN patplan pp ON pp.PatNum=p.PatNum AND pp.InsSubNum=cl.InsSubNum
INNER JOIN patient psub ON psub.PatNum=iss.Subscriber
INNER JOIN insplan i ON i.PlanNum=cl.PlanNum
INNER JOIN carrier ca ON ca.CarrierNum=i.CarrierNum
LEFT JOIN employer e ON e.EmployerNum=i.EmployerNum
LEFT JOIN etrans ON etrans.ClaimNum=cl.ClaimNum
WHERE cl.ClaimStatus='S'
GROUP BY cl.ClaimNum
ORDER BY ca.CarrierName,p.LName;
Gross production for work performed in given date range for patients referred from given referral source. - For Versions 17.1 and greater. Please update your version accordingly
/*692 Gross production for work performed in given date range for patients referred from given referral source.*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 04/16/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2018-01-01',@ToDate='2018-01-31';
SET @RefLName='%%',@RefFName='%%'; /*Change referral source here or leave %% for all*/
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT p.PatNum,
r.LName AS RefLName,
r.FName AS RefFName,
SUM(pl.ProcFee) AS $GrossProd_
FROM patient p
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
AND pl.ProcStatus=2
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
INNER JOIN refattach ra ON p.PatNum=ra.PatNum
INNER JOIN referral r ON r.ReferralNum=ra.ReferralNum
AND ra.RefType = 1 /*RefFrom*/
AND r.FName LIKE @RefFName
AND r.LName LIKE @RefLName
GROUP BY p.PatNum
ORDER BY p.LName,p.FName;
Guarantors of patients who have had a procedure in given list completed in a user defined date range -
/*693 Guarantors of patients who have had a procedure in given list completed in a user defined date range*/
@StartDate='2011-06-01';
@EndDate='2012-11-19';
SELECT Guarantor, PatNum
FROM patient
WHERE PatNum IN
(
SELECT procedurelog.PatNum
FROM procedurelog
INNER JOIN procedurecode
ON procedurelog.CodeNum=procedurecode.CodeNum
WHERE procedurelog.ProcStatus=2
AND procedurecode.ProcCode IN ('D1110','D1120','D4910')
AND procedurelog.ProcDate BETWEEN @StartDate and @EndDate
);
Today's patients with balance,years since pano, isrecall?, #of siblings (non patients under 19 in family), # in family, email, wireless phone -
/*694 Today's patients with balance,years since pano, isrecall?, #of siblings (non patients under 19 in family), # in family, email, wireless phone*/
SELECT p.PatNum, /* a.AptNum, */
IFNULL(FORMAT(DATEDIFF(CurDate(),(SELECT MIN(pano.ProcDate) FROM procedurelog pano
INNER JOIN procedurecode panocode ON pano.CodeNum=panocode.CodeNum
WHERE panocode.ProcCode='D0330' AND pano.ProcStatus=2 AND pano.PatNum=p.PatNum))/365,1),'None') AS 'YrsPano',
(CASE WHEN ((SELECT COUNT(*) FROM procedurelog pl2
INNER JOIN recall r2 ON r2.PatNum=pl2.PatNum
INNER JOIN recalltrigger rt2 ON rt2.RecallTypeNum=r2.RecallTypeNum AND pl2.CodeNum=rt2.CodeNum
WHERE pl2.AptNum=a.AptNum)>0) THEN 'Yes' ELSE 'No' END) AS 'RecallApt',
(SELECT count(*) FROM patient sib WHERE sib.Guarantor=p.Guarantor AND (DATEDIFF(CurDate(),(sib.Birthdate))/365<19) AND sib.PatStatus NOT IN (0,3,4,5)) AS '#Sib',
(SELECT count(*) FROM patient fam WHERE fam.Guarantor=p.Guarantor AND fam.PatStatus NOT IN (3,4,5)) AS '#Family', Format(g.BalTotal,2) as '$BalTotal_',
p.Email, p.WirelessPhone
FROM patient p
INNER JOIN appointment a on a.PatNum=p.PatNum
INNER JOIN patient g ON p.Guarantor=g.PatNum
WHERE DATE(a.AptDateTime)=CurDate();
Shows all patients that had account activity on the date set, their previous balance, ending balance as of date set, every procedure completed on date set,adj,writeoffs,payments on date set, totals, MTD totals, YTD totals and A/R as of date set. - A/R for version before 14.3
/*696 'Ending Balance' is the balance on the date set to variable @Date
Shows all patients that had account activity on the date set, their previous balance, ending balance as of date set,
every procedure completed on date set,adj,writeoffs,payments on date set,
totals, MTD totals, YTD totals and A/R as of date set.*/
SET @Date='2013-02-05';/*<----SET DATE HERE---*/
SELECT CONCAT('Day Sheet For: ',DATE_FORMAT(@Date,'%m/%d/%Y')) AS 'ID - Name','' AS Dr,'' AS Description,
'' AS TxArea,null AS Charge,null AS Adjust,null AS Writeoff,null AS Payment,null AS Bal
UNION ALL
SELECT '' AS 'ID - Name','' AS Dr,'' AS Description,'' AS TxArea,null AS Charge,null AS Adjust,null AS Writeoff,null AS Payment,null AS BalA
UNION ALL
SELECT LEFT((CASE WHEN AllTrans.ItemOrder=0 THEN CONCAT(AllTrans.PatNum,' - ',AllTrans.LName,', ',AllTrans.FName) ELSE '' END),30) AS 'ID - Name',pv.Abbr AS Dr,
LEFT(AllTrans.Description,35) AS Description,AllTrans.TxArea,FORMAT(AllTrans.Charge,2) AS Charge,FORMAT(AllTrans.Adjust,2) AS Adjust,FORMAT(-AllTrans.Writeoff,2) AS Writeoff,
FORMAT(-AllTrans.Payment,2) AS Payment,FORMAT(AllTrans.Bal,2) AS Bal
FROM (
SELECT 1 AS ItemOrder,p.PatNum,p.LName,p.FName,A.ProvNum,
(CASE WHEN A.TranType='Fee' THEN CONCAT(pc.ProcCode,' - ',pc.Descript)
WHEN A.TranType IN('Pay','Adj') THEN CONCAT(A.TranType,' - ',d.ItemName)
WHEN A.TranType='Writeoff' THEN CONCAT(A.TranType,' - ',c.CarrierName)
ELSE 'Payment Plan' END) AS Description,
(CASE WHEN A.TranType='Fee' AND (pc.TreatArea IN(4,5,6)) THEN A.Surf
WHEN A.TranType='Fee' AND pc.TreatArea=1 THEN CONCAT(A.ToothNum, ", ", A.Surf)
WHEN A.TranType='Fee' AND pc.TreatArea=2 THEN A.ToothNum
WHEN A.TranType='Fee' AND pc.TreatArea=7 THEN A.ToothRange
WHEN A.TranType='Fee' AND pc.TreatArea NOT IN(1,2,4,5,6,7) THEN 'Mouth'
ELSE '' END) AS TxArea,
(CASE WHEN A.TranType='Fee' THEN A.TranAmount ELSE null END) AS Charge,
(CASE WHEN A.TranType='Adj' THEN A.TranAmount ELSE null END) AS Adjust,
null AS Writeoff,
(CASE WHEN A.TranType='Pay' THEN A.TranAmount ELSE null END) AS Payment,
null AS Bal
FROM (
/*transaction table*/
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount,pl.ProvNum ProvNum,pl.CodeNum Code,pl.Surf Surf,pl.ToothNum ToothNum,pl.ToothRange ToothRange
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount,ps.ProvNum ProvNum,p.PayType Code,null,null,null
FROM paysplit ps
LEFT JOIN payment p ON p.PayNum=ps.PayNum
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
AND ps.SplitAmt<>0
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount,a.ProvNum ProvNum,a.AdjType Code,null,null,null
FROM adjustment a
WHERE a.AdjAmt<>0
) A
INNER JOIN patient p ON p.PatNum=A.PatNum
LEFT JOIN procedurecode pc ON pc.CodeNum=A.Code
LEFT JOIN definition d ON d.DefNum=A.Code
LEFT JOIN carrier c ON c.CarrierNum=A.Code
WHERE A.TranDate=@Date
UNION ALL
(
SELECT 1 AS ItemOrder,p.PatNum,p.LName,p.FName,A.ProvNum,
CONCAT(A.TranType,' - ',c.CarrierName) AS Description,
'' AS TxArea,null AS Charge,null AS Adjust,
SUM(CASE WHEN A.TranType='Writeoff' THEN A.TranAmount ELSE null END) AS Writeoff,
SUM(CASE WHEN A.TranType='InsPay' THEN A.TranAmount ELSE null END) AS Payment,
null AS Bal
FROM (
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum PatNum,cp.DateCp TranDate,-cp.InsPayAmt TranAmount,cp.ProvNum ProvNum,ip.CarrierNum Code
FROM claimproc cp
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
WHERE cp.Status IN (1,4)/*received, supplemental*/
AND cp.InsPayAmt<>0
UNION ALL
/*Claim writeoffs for the entire office history*/
SELECT 'Writeoff' AS TranType,cp.PatNum PatNum,cp.DateCp TranDate,-cp.Writeoff TranAmount,cp.ProvNum ProvNum,ip.CarrierNum Code
FROM claimproc cp
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
WHERE cp.Status IN (1,4)/*received, supplemental*/
AND cp.Writeoff<>0
) A
INNER JOIN patient p ON p.PatNum=A.PatNum
LEFT JOIN carrier c ON c.CarrierNum=A.Code
WHERE A.TranDate=@Date
GROUP BY p.PatNum,A.TranType
)
UNION ALL
(
SELECT 0 AS ItemOrder,C.PatNum,p.LName,p.FName,'' AS Dr,'Previous Balance' AS Description,'' AS TxArea,null AS Charge,null AS Adjust,
null AS Writeoff,null AS Payment,
(CASE WHEN ABS(C.PrevBal)>0.01 THEN C.PrevBal ELSE 0 END) AS Bal
FROM (
SELECT B.PatNum,SUM(CASE WHEN (B.TranDate<@Date) THEN B.TranAmount ELSE 0 END) AS PrevBal,MAX(B.TranDate) AS DateLast
FROM (
/*transaction table*/
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount,pl.ProvNum ProvNum,pl.CodeNum Code,pl.Surf Surf,pl.ToothNum ToothNum,pl.ToothRange ToothRange
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount,ps.ProvNum ProvNum,p.PayType Code,null,null,null
FROM paysplit ps
LEFT JOIN payment p ON p.PayNum=ps.PayNum
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
AND ps.SplitAmt<>0
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum PatNum,cp.DateCp TranDate,-cp.InsPayAmt TranAmount,cp.ProvNum ProvNum,ip.CarrierNum Code,null,null,null
FROM claimproc cp
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
WHERE cp.Status IN (1,4)/*received, supplemental*/
AND cp.InsPayAmt<>0
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount,a.ProvNum ProvNum,a.AdjType Code,null,null,null
FROM adjustment a
WHERE a.AdjAmt<>0
UNION ALL
/*Claim writeoffs for the entire office history*/
SELECT 'Writeoff' AS TranType,cp.PatNum PatNum,cp.DateCp TranDate,-cp.Writeoff TranAmount,cp.ProvNum ProvNum,ip.CarrierNum Code,null,null,null
FROM claimproc cp
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
WHERE cp.Status IN (1,4)/*received, supplemental*/
AND cp.Writeoff<>0
) B
WHERE B.TranDate<=@Date
GROUP BY B.PatNum
HAVING DateLast=@Date
) C
INNER JOIN patient p ON p.PatNum=C.PatNum
)
UNION ALL
(
SELECT 2 AS ItemOrder,C.PatNum,p.LName,p.FName,'' AS Dr,'Ending Balance' AS Description,'' AS TxArea,null AS Charge,null AS Adjust,
null AS Writeoff,null AS Payment,
(CASE WHEN ABS(C.CurBal)>0.01 THEN C.CurBal ELSE 0 END) AS Bal
FROM (
SELECT B.PatNum,SUM(CASE WHEN (B.TranDate<=@Date) THEN B.TranAmount ELSE 0 END) AS CurBal,MAX(B.TranDate) AS DateLast
FROM (
/*transaction table*/
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount,pl.ProvNum ProvNum,pl.CodeNum Code,pl.Surf Surf,pl.ToothNum ToothNum,pl.ToothRange ToothRange
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount,ps.ProvNum ProvNum,p.PayType Code,null,null,null
FROM paysplit ps
LEFT JOIN payment p ON p.PayNum=ps.PayNum
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
AND ps.SplitAmt<>0
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum PatNum,cp.DateCp TranDate,-cp.InsPayAmt TranAmount,cp.ProvNum ProvNum,ip.CarrierNum Code,null,null,null
FROM claimproc cp
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
WHERE cp.Status IN (1,4)/*received, supplemental*/
AND cp.InsPayAmt<>0
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount,a.ProvNum ProvNum,a.AdjType Code,null,null,null
FROM adjustment a
WHERE a.AdjAmt<>0
UNION ALL
/*Claim writeoffs for the entire office history*/
SELECT 'Writeoff' AS TranType,cp.PatNum PatNum,cp.DateCp TranDate,-cp.Writeoff TranAmount,cp.ProvNum ProvNum,ip.CarrierNum Code,null,null,null
FROM claimproc cp
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
WHERE cp.Status IN (1,4)/*received, supplemental*/
AND cp.Writeoff<>0
) B
WHERE B.TranDate<=@Date
GROUP BY B.PatNum
HAVING DateLast=@Date
) C
INNER JOIN patient p ON p.PatNum=C.PatNum
)
UNION ALL
(
SELECT 3 AS ItemOrder,C.PatNum,p.LName,p.FName,'' AS Dr,'' AS Description,'' AS TxArea,null AS Charge,null AS Adjust,
null AS Writeoff,null AS Payment,null AS Bal
FROM (
SELECT B.PatNum,MAX(B.TranDate) AS DateLast
FROM (
/*transaction table*/
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount,pl.ProvNum ProvNum,pl.CodeNum Code,pl.Surf Surf,pl.ToothNum ToothNum,pl.ToothRange ToothRange
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount,ps.ProvNum ProvNum,p.PayType Code,null,null,null
FROM paysplit ps
LEFT JOIN payment p ON p.PayNum=ps.PayNum
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
AND ps.SplitAmt<>0
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum PatNum,cp.DateCp TranDate,-cp.InsPayAmt TranAmount,cp.ProvNum ProvNum,ip.CarrierNum Code,null,null,null
FROM claimproc cp
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
WHERE cp.Status IN (1,4)/*received, supplemental*/
AND cp.InsPayAmt<>0
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount,a.ProvNum ProvNum,a.AdjType Code,null,null,null
FROM adjustment a
WHERE a.AdjAmt<>0
UNION ALL
/*Claim writeoffs for the entire office history*/
SELECT 'Writeoff' AS TranType,cp.PatNum PatNum,cp.DateCp TranDate,-cp.Writeoff TranAmount,cp.ProvNum ProvNum,ip.CarrierNum Code,null,null,null
FROM claimproc cp
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
WHERE cp.Status IN (1,4)/*received, supplemental*/
AND cp.Writeoff<>0
) B
WHERE B.TranDate<=@Date
GROUP BY B.PatNum
HAVING DateLast=@Date
) C
INNER JOIN patient p ON p.PatNum=C.PatNum
)
ORDER BY LName,FName,ItemOrder,Description
) AllTrans
LEFT JOIN provider pv ON pv.ProvNum=AllTrans.ProvNum
UNION ALL
SELECT '','','','--------','-----------','-----------','-----------','-----------',''
UNION ALL
SELECT '','','','Totals:' AS TxArea,
FORMAT((CASE WHEN ABS(B.Charge)>0.01 THEN B.Charge ELSE 0 END),2) AS Charge,
FORMAT((CASE WHEN ABS(B.Adjust)>0.01 THEN B.Adjust ELSE 0 END),2) AS Adjust,
FORMAT((CASE WHEN ABS(B.Writeoff)>0.01 THEN B.Writeoff ELSE 0 END),2) AS Writeoff,
FORMAT((CASE WHEN ABS(B.Payment)>0.01 THEN B.Payment ELSE 0 END),2) AS Payment,
null AS Bal
FROM
(
SELECT SUM(CASE WHEN A.TranType='Fee' THEN A.TranAmount ELSE 0 END) AS Charge,
SUM(CASE WHEN A.TranType='Adj' THEN A.TranAmount ELSE 0 END) AS Adjust,
-SUM(CASE WHEN A.TranType='Writeoff' THEN A.TranAmount ELSE 0 END) AS Writeoff,
-SUM(CASE WHEN A.TranType IN('Pay','InsPay') THEN A.TranAmount ELSE 0 END) AS Payment
FROM (
/*transaction table*/
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount,pl.ProvNum ProvNum,pl.CodeNum Code,pl.Surf Surf,pl.ToothNum ToothNum,pl.ToothRange ToothRange
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount,ps.ProvNum ProvNum,p.PayType Code,null,null,null
FROM paysplit ps
LEFT JOIN payment p ON p.PayNum=ps.PayNum
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum PatNum,cp.DateCp TranDate,-cp.InsPayAmt TranAmount,cp.ProvNum ProvNum,ip.CarrierNum Code,null,null,null
FROM claimproc cp
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
WHERE cp.Status IN (1,4)/*received, supplemental*/
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount,a.ProvNum ProvNum,a.AdjType Code,null,null,null
FROM adjustment a
UNION ALL
/*Claim writeoffs for the entire office history*/
SELECT 'Writeoff' AS TranType,cp.PatNum PatNum,cp.DateCp TranDate,-cp.Writeoff TranAmount,cp.ProvNum ProvNum,ip.CarrierNum Code,null,null,null
FROM claimproc cp
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
WHERE cp.Status IN (1,4)/*received, supplemental*/
) A
WHERE A.TranDate=@Date
AND A.TranAmount<>0
) B
UNION ALL
SELECT '','','','--------','-----------','-----------','-----------','-----------',''
UNION ALL
SELECT '','','','MTD:' AS TxArea,
FORMAT((CASE WHEN ABS(B.Charge)>0.01 THEN B.Charge ELSE 0 END),2) AS Charge,
FORMAT((CASE WHEN ABS(B.Adjust)>0.01 THEN B.Adjust ELSE 0 END),2) AS Adjust,
FORMAT((CASE WHEN ABS(B.Writeoff)>0.01 THEN B.Writeoff ELSE 0 END),2) AS Writeoff,
FORMAT((CASE WHEN ABS(B.Payment)>0.01 THEN B.Payment ELSE 0 END),2) AS Payment,
null AS Bal
FROM
(
SELECT SUM(CASE WHEN A.TranType='Fee' THEN A.TranAmount ELSE 0 END) AS Charge,
SUM(CASE WHEN A.TranType='Adj' THEN A.TranAmount ELSE 0 END) AS Adjust,
-SUM(CASE WHEN A.TranType='Writeoff' THEN A.TranAmount ELSE 0 END) AS Writeoff,
-SUM(CASE WHEN A.TranType IN('Pay','InsPay') THEN A.TranAmount ELSE 0 END) AS Payment
FROM (
/*transaction table*/
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount,pl.ProvNum ProvNum,pl.CodeNum Code,pl.Surf Surf,pl.ToothNum ToothNum,pl.ToothRange ToothRange
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount,ps.ProvNum ProvNum,p.PayType Code,null,null,null
FROM paysplit ps
LEFT JOIN payment p ON p.PayNum=ps.PayNum
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum PatNum,cp.DateCp TranDate,-cp.InsPayAmt TranAmount,cp.ProvNum ProvNum,ip.CarrierNum Code,null,null,null
FROM claimproc cp
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
WHERE cp.Status IN (1,4)/*received, supplemental*/
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount,a.ProvNum ProvNum,a.AdjType Code,null,null,null
FROM adjustment a
UNION ALL
/*Claim writeoffs for the entire office history*/
SELECT 'Writeoff' AS TranType,cp.PatNum PatNum,cp.DateCp TranDate,-cp.Writeoff TranAmount,cp.ProvNum ProvNum,ip.CarrierNum Code,null,null,null
FROM claimproc cp
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
WHERE cp.Status IN (1,4)/*received, supplemental*/
) A
WHERE MONTH(A.TranDate)=MONTH(@Date) AND YEAR(A.TranDate)=YEAR(@Date)
AND A.TranAmount<>0
) B
UNION ALL
SELECT '','','','YTD:' AS TxArea,
FORMAT((CASE WHEN ABS(B.Charge)>0.01 THEN B.Charge ELSE 0 END),2) AS Charge,
FORMAT((CASE WHEN ABS(B.Adjust)>0.01 THEN B.Adjust ELSE 0 END),2) AS Adjust,
FORMAT((CASE WHEN ABS(B.Writeoff)>0.01 THEN B.Writeoff ELSE 0 END),2) AS Writeoff,
FORMAT((CASE WHEN ABS(B.Payment)>0.01 THEN B.Payment ELSE 0 END),2) AS Payment,
null AS Bal
FROM
(
SELECT SUM(CASE WHEN A.TranType='Fee' THEN A.TranAmount ELSE 0 END) AS Charge,
SUM(CASE WHEN A.TranType='Adj' THEN A.TranAmount ELSE 0 END) AS Adjust,
-SUM(CASE WHEN A.TranType='Writeoff' THEN A.TranAmount ELSE 0 END) AS Writeoff,
-SUM(CASE WHEN A.TranType IN('Pay','InsPay') THEN A.TranAmount ELSE 0 END) AS Payment
FROM (
/*transaction table*/
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount,pl.ProvNum ProvNum,pl.CodeNum Code,pl.Surf Surf,pl.ToothNum ToothNum,pl.ToothRange ToothRange
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount,ps.ProvNum ProvNum,p.PayType Code,null,null,null
FROM paysplit ps
LEFT JOIN payment p ON p.PayNum=ps.PayNum
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum PatNum,cp.DateCp TranDate,-cp.InsPayAmt TranAmount,cp.ProvNum ProvNum,ip.CarrierNum Code,null,null,null
FROM claimproc cp
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
WHERE cp.Status IN (1,4)/*received, supplemental*/
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount,a.ProvNum ProvNum,a.AdjType Code,null,null,null
FROM adjustment a
UNION ALL
/*Claim writeoffs for the entire office history*/
SELECT 'Writeoff' AS TranType,cp.PatNum PatNum,cp.DateCp TranDate,-cp.Writeoff TranAmount,cp.ProvNum ProvNum,ip.CarrierNum Code,null,null,null
FROM claimproc cp
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
WHERE cp.Status IN (1,4)/*received, supplemental*/
) A
WHERE YEAR(A.TranDate)=YEAR(@Date)
AND A.TranAmount<>0
) B
UNION ALL
SELECT '','','','--------','-----------','','','',''
UNION ALL
(
SELECT '','','','A/R:' AS TxArea,FORMAT(SUM(A.TranAmount),2) AS Charge,'','','',null AS Bal
FROM (
/*transaction table*/
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount,pl.ProvNum ProvNum,pl.CodeNum Code,pl.Surf Surf,pl.ToothNum ToothNum,pl.ToothRange ToothRange
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount,ps.ProvNum ProvNum,p.PayType Code,null,null,null
FROM paysplit ps
LEFT JOIN payment p ON p.PayNum=ps.PayNum
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum PatNum,cp.DateCp TranDate,-cp.InsPayAmt TranAmount,cp.ProvNum ProvNum,ip.CarrierNum Code,null,null,null
FROM claimproc cp
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
WHERE cp.Status IN (1,4)/*received, supplemental*/
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount,a.ProvNum ProvNum,a.AdjType Code,null,null,null
FROM adjustment a
UNION ALL
/*Claim writeoffs for the entire office history*/
SELECT 'Writeoff' AS TranType,cp.PatNum PatNum,cp.DateCp TranDate,-cp.Writeoff TranAmount,cp.ProvNum ProvNum,ip.CarrierNum Code,null,null,null
FROM claimproc cp
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
WHERE cp.Status IN (1,4)/*received, supplemental*/
) A
WHERE A.TranDate<=@Date AND A.TranAmount<>0
);
New patients from @StartDate to @EndDate with birthday in months between @StartDate and @EndDate, with Date of First Visit, Age, Birthdate, Name, Address, and Email. - Sorted by month, day for birthday.
/*697 New patients from @StartDate to @EndDate with birthday in months between @StartDate and @EndDate, with Date of First Visit, Age, Birthdate, Name, Address, and Email. Sorted by month, day for birthday.*/
SET @StartDate='2013-05-01' , @EndDate='2013-06-20';
SELECT A.DateFirstVisit, p.PatNum,
(YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) AS 'Age',
p.BirthDate, p.Address, p.Address2, p.City, p.State, p.ZIP,p.Email
FROM patient p
INNER JOIN (
SELECT pl.PatNum,MIN(pl.ProcDate) AS DateFirstVisit
FROM procedurelog pl
WHERE pl.ProcStatus=2
GROUP BY pl.PatNum
) A ON A.PatNum=p.PatNum AND A.DateFirstVisit BETWEEN @StartDate AND @EndDate
WHERE MONTH(p.BirthDate) BETWEEN MONTH(@StartDate) AND MONTH(@EndDate)
ORDER BY MONTH(BirthDate),DAY(BirthDate),p.LName, p.FName;
List all families with partial or complete offsetting balances -
/*698 List all families with partial or complete offsetting balances*/
SELECT Guarantor,LName,FName,BalTotal, AfterIns,/*FORMAT(SUM(IFNULL(PatBal,0)),2) AS PatBalSum*/
(CASE WHEN BalTotal=0 THEN 'Fully Offsetting'
WHEN AfterIns=0 THEN 'Fully Offsetting after InsEst'
ELSE 'Partially Offsetting' END) AS 'Offsetting'
FROM
(
SELECT p.PatNum, g.PatNum AS Guarantor, g.LName,g.FName , g.BalTotal, (g.BalTotal-g.InsEst) AS AfterIns,
/*procedure fees*/
(IFNULL((SELECT SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) FROM procedurelog pl WHERE pl.ProcStatus=2 AND pl.PatNum=p.PatNum),0)
/*Paysplits*/
+ IFNULL((SELECT -SUM(ps.SplitAmt) FROM paysplit ps WHERE ps.PayPlanNum=0 AND ps.PatNum=p.PatNum),0) /*Only splits not attached to payment plans*/
/*adjustments*/
+ IFNULL((SELECT SUM(a.AdjAmt) FROM adjustment a WHERE a.PatNum=p.PatNum),0)
/*Claim payments*/
+ IFNULL((SELECT -SUM(cp.InsPayAmt) FROM claimproc cp WHERE cp.Status IN (1,4,5,7) /*received, supplemental, CapClaim or CapComplete*/ AND cp.PatNum=p.PatNum),0)
/*Writeoffs*/
+ IFNULL((SELECT -SUM(cp.Writeoff) FROM claimproc cp WHERE cp.Status IN (1,4,5,7) /*received, supplemental, CapClaim or CapComplete*/ AND cp.PatNum=p.PatNum),0)
/*Payment plan principal*/
+ IFNULL((SELECT -SUM(pp.CompletedAmt) FROM payplan pp WHERE pp.PatNum=p.PatNum),0)) AS PatBal
FROM patient g
INNER JOIN patient p ON p.Guarantor=g.PatNum
GROUP BY p.PatNum
) AC
GROUP BY Guarantor /*, LName, FName, BalTotal, AfterIns*/
HAVING ABS(SUM(IFNULL(PatBal,0)))<SUM(ABS(IFNULL(PatBal,0)))
ORDER BY LName, FName;
Waiting Room Report, shows time each patient arrived, length waiting, was seated,chair time dismissed time, and Appt. Length. Also gives average waiting time - SEE REPLICATION WARNING for versions before 14.3.1.
/*699 Waiting Room Report, shows time each patient arrived, length waiting, was seated,chair time dismissed time, and Appt. Length.
also give average waiting time*/
/*WARNING: On versions before 14.3.1 that are using replication, do not run this query from multiple computers at the same time or replication will crash.*/
SET @FromDate='2013-06-01' , @ToDate='2013-06-15';
DROP TABLE IF EXISTS tmp1;
CREATE TABLE tmp1 AS
SELECT CONCAT(p.LName,', ',p.FName) AS 'Pat Name', LEFT(a.PatNum,15) AS 'Pat Num', AptDateTime,
LEFT((CASE WHEN DATE_FORMAT(DateTimeArrived,'%T')<>'00:00:00'/*when there is a real value*/
THEN DATE_FORMAT(DateTimeArrived,'%r')
ELSE '' END),12) AS 'TimeArrived',
LEFT((CASE WHEN DATE_FORMAT(DateTimeSeated,'%T')<>'00:00:00'/*when there is a real value*/
THEN DATE_FORMAT(DateTimeSeated,'%r')
ELSE '' END),12) AS 'TimeSeated',
LEFT((CASE WHEN DATE_FORMAT(DateTimeDismissed,'%T')<>'00:00:00'/*when there is a real value*/
THEN DATE_FORMAT(DateTimeDismissed,'%r')
ELSE '' END),12) AS 'TimeDismiss',
LEFT((CASE WHEN DATE_FORMAT(DateTimeSeated,'%T')<>'00:00:00' AND DATE_FORMAT(DateTimeArrived,'%T')<>'00:00:00'
THEN TIME_FORMAT(SEC_TO_TIME(TIME_TO_SEC(DateTimeSeated)-TIME_TO_SEC(DateTimeArrived)),'%H:%i')
ELSE '' END),5) AS 'WaitTime',
LEFT((CASE WHEN DATE_FORMAT(DateTimeSeated,'%T')<>'00:00:00' AND DATE_FORMAT(DateTimeDismissed,'%T')<>'00:00:00'
THEN TIME_FORMAT(SEC_TO_TIME(TIME_TO_SEC(DateTimeDismissed)-TIME_TO_SEC(DateTimeSeated)),'%H:%i')
ELSE '' END),5) AS 'ChairTime',
LEFT((CASE WHEN DATE_FORMAT(DateTimeDismissed,'%T')<>'00:00:00' AND DATE_FORMAT(DateTimeArrived,'%T')<>'00:00:00'
THEN TIME_FORMAT(SEC_TO_TIME(TIME_TO_SEC(DateTimeDismissed)-TIME_TO_SEC(DateTimeArrived)),'%H:%i')
ELSE '' END),5) AS 'ApptLength'
FROM Appointment a INNER JOIN patient p ON a.PatNum=p.PatNum
WHERE DATE(a.AptDateTime) BETWEEN @FromDate AND @ToDate
ORDER BY a.AptDateTime;
SELECT * FROM tmp1
UNION
SELECT 'Average Wait' AS 'Pat Name', '' AS 'Pat Num','' AS 'AptDateTime', '' AS TimeArrived, '' AS TimeSeated,'' AS TimeDismiss,
FORMAT((SELECT((SUM(TIME_TO_SEC(tmp1.WaitTime))/COUNT(tmp1.WaitTime))/60) FROM tmp1 WHERE tmp1.WaitTime<>''),1) AS WaitTime,
'' AS ChairTime, '' AS ApptLength;
DROP TABLE IF EXISTS tmp1;
Treatment planned procedures (summed by patient) for active patients that are not on the recall list and are without a scheduled OR planned apt, with phone nums. -
/*700 Treatment planned procedures (summed by patient) for active patients that are not on the recall list and are without a scheduled OR planned apt, with phone nums.*/
SELECT CONCAT(LName, ', ',FName, ' ', MiddleI) AS Patient, hmphone, wkphone, wirelessphone, SUM(ProcFee) AS '$FeeSum', CONCAT(Address, ' ', Address2) AS Address, City, State, Zip
FROM patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum AND ProcStatus=1
LEFT JOIN appointment ap ON patient.PatNum=ap.PatNum AND (ap.AptStatus=1 OR ap.AptStatus=6 )
LEFT OUTER JOIN recall re ON re.IsDisabled=0 AND re.RecallTypeNum IN(SELECT ValueString FROM preference WHERE PrefName='RecallTypesShowingInList') AND re.DateScheduled='0001-01-01' AND re.PatNum=patient.PatNum
WHERE ap.AptNum IS NULL AND patient.PatStatus=0 AND re.RecallNum IS NULL
GROUP BY patient.PatNum
ORDER BY patient.LName, patient.FName ASC;
List of all patients that shows if they have an appointment scheduled for this month with appointment date and time, phone number and address. -
/*701 List of all patients that shows if they have an appointment scheduled for this month with appointment date and time, phone number and address.*/
SELECT p.PatNum,
IF (MONTH(ap.AptDateTime)=MONTH(CURDATE()) AND YEAR(ap.AptDateTime) = YEAR(CURDATE()),'Yes','No') AS AppointmentThisMonth,
COALESCE(DATE_FORMAT(ap.AptDateTime,"%m/%d/%Y %h:%i %p"),'No Apt') AS AptDate, HmPhone, WkPhone, WirelessPhone, CONCAT(Address, ' ', Address2) AS Address
FROM patient p
LEFT JOIN appointment ap ON p.PatNum=ap.PatNum
AND MONTH(ap.AptDateTime)=MONTH(CURDATE()) AND YEAR(ap.AptDateTime)=YEAR(CURDATE())
ORDER BY AppointmentThisMonth DESC,PatNum;
Income report from @FromDate to @ToDate day totalled, separated by specific payment type with totals -
/*702 Income report from @StartDate to @EndDate day totalled, separated by specific payment type with totals*/
/*Query code written/modified: 02/21/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @StartDate='2018-01-01', @EndDate='2018-01-31';
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT a.DatePay,
DATE_FORMAT(a.DatePay, "%W") AS 'Weekday',
FORMAT(SUM(COALESCE((CASE WHEN a.PayType IN('Cash') AND a.Source='P' THEN a.Amount END),0)),2) AS 'PatCash',
FORMAT(SUM(COALESCE((CASE WHEN a.PayType IN('Check') AND a.Source='P' THEN a.Amount END),0)),2) AS 'PatChecks',
FORMAT(SUM(COALESCE((CASE WHEN a.PayType IN('Credit Card') AND a.Source='P' THEN a.Amount END),0)),2) AS 'PatCC',
FORMAT(SUM(COALESCE((CASE WHEN a.PayType IN('Care Credit Card') AND a.Source='P' THEN a.Amount END),0)),2) AS 'PatCareCredit',
FORMAT(SUM(COALESCE((CASE WHEN a.PayType IN('Patient Refund Check') AND a.Source='P' THEN a.Amount END),0)),2) AS 'PatRefundCheck',
FORMAT(SUM(COALESCE((CASE WHEN a.PayType NOT IN('Check','Cash','Credit Card','Care Credit Card','Patient Refund Check') AND a.Source='P' THEN a.Amount END),0)),2) AS 'PatMisc',
FORMAT(SUM(COALESCE((CASE WHEN a.PayType IN('EFT') AND a.Source='I' THEN a.Amount END),0)),2) AS 'InsEFT',
FORMAT(SUM(COALESCE((CASE WHEN a.PayType IN('Check') AND a.Source='I' THEN a.Amount END),0)),2) AS 'InsCheck',
FORMAT(SUM(COALESCE((CASE WHEN a.PayType NOT IN('Check','EFT') AND a.Source='I' THEN a.Amount END),0)),2) AS 'InsMisc',
FORMAT(SUM(COALESCE((CASE WHEN a.Source='P' THEN a.Amount END),0)),2) AS 'PatientTotal',
FORMAT(SUM(COALESCE((CASE WHEN a.Source='I' THEN a.Amount END),0)),2) AS 'InsTotal',
FORMAT(SUM(COALESCE(a.Amount,0)),2) AS 'DayTotal'
FROM (
SELECT pay.PayDate AS 'DatePay',
pay.PayAmt AS 'Amount',
def.ItemName AS 'PayType',
'P' AS 'Source'
FROM payment pay
INNER JOIN definition def
ON pay.PayType = def.DefNum
WHERE pay.PayDate BETWEEN @StartDate AND @EndDate
UNION ALL
SELECT clpay.CheckDate AS 'DatePay',
clpay.CheckAmt AS 'Amount',
def.ItemName AS 'PayType',
'I' AS 'Source'
FROM claimpayment clpay
INNER JOIN definition def
ON clpay.PayType = def.DefNum
WHERE clpay.CheckDate BETWEEN @StartDate AND @EndDate
) a
GROUP BY a.DatePay
ORDER BY a.DatePay
List of all patients that shows Name, Date First Visit, Fee Schedule(Rarely Used), Primary provider fee schedule (UCR), and all of the patients Primary and secondary ins fee schedules -
/*703 List of all patients that shows Name, Date First Visit, Fee Schedule(Rarely Used), Primary provider fee schedule (UCR), and all of the patients Primary and secondary ins fee schedules*/
/*Query code written/modified: 05/26/2015*/
SELECT p.PatNum,
pf.Description AS 'PrimaryProviderFeeSchedUCR',
CONCAT(COALESCE(nf1.Description,'N/A'), ', ', COALESCE(nf2.Description,'N/A')) AS 'NormalFeeScheds(Prim,Sec)',
CONCAT(COALESCE(cp1.Description,'N/A'), ', ', COALESCE(cp2.Description,'N/A')) AS 'CoPayFeeScheds(Prim,Sec)',
CONCAT(COALESCE(al1.Description,'N/A'), ', ', COALESCE(al2.Description,'N/A')) AS 'AllowedFeeScheds(Prim,Sec)',
COALESCE(rl.Description,'N/A') AS FeeScheduleRarelyUsed,
p.DateFirstVisit
FROM patient p
LEFT JOIN feesched rl ON rl.FeeSchedNum=p.FeeSched
LEFT JOIN provider pr ON pr.ProvNum=p.PriProv
LEFT JOIN feesched pf ON pf.FeeSchedNum=pr.FeeSched
LEFT JOIN patplan pp1 ON p.PatNum=pp1.PatNum AND pp1.Ordinal=1
LEFT JOIN inssub ib1 ON pp1.InsSubNum=ib1.InsSubNum
LEFT JOIN insplan ip1 ON ip1.PlanNum=ib1.PlanNum
LEFT JOIN feesched nf1 ON nf1.FeeSchedNum=ip1.FeeSched
LEFT JOIN feesched cp1 ON cp1.FeeSchedNum=ip1.CopayFeeSched
LEFT JOIN feesched al1 ON al1.FeeSchedNum=ip1.AllowedFeeSched
LEFT JOIN patplan pp2 ON p.PatNum=pp2.PatNum AND pp2.Ordinal=2
LEFT JOIN inssub ib2 ON pp2.InsSubNum=ib2.InsSubNum
LEFT JOIN insplan ip2 ON ip2.PlanNum=ib2.PlanNum
LEFT JOIN feesched nf2 ON nf2.FeeSchedNum=ip2.FeeSched
LEFT JOIN feesched cp2 ON cp2.FeeSchedNum=ip2.CopayFeeSched
LEFT JOIN feesched al2 ON al2.FeeSchedNum=ip2.AllowedFeeSched
GROUP BY PatNum
ORDER BY p.LName,p.FName,p.PatNum
New patients for a time span, who had a specified code completed in that appointment - Uses D0150 in example.
/*704 New patients for a time span, who had a specified code completed in that appointment (in this case D0150)*/
SET @FromDate='2013-07-01',@ToDate='2013-08-01';
SET @ExamCode='D0150';
SET @pos=0;
SELECT @pos:=@pos+1 AS Count,B.* FROM
(
SELECT p.PatNum,DATE_FORMAT(minProc.ProcDate,'%m-%d-%Y') AS DateFirstCompletedProc
FROM patient p
/*Oldest completed proc*/
INNER JOIN(
SELECT pl.PatNum,MIN(pl.ProcDate) AS ProcDate
FROM procedurelog pl
WHERE pl.ProcStatus=2
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY pl.PatNum
) minProc ON minProc.PatNum=p.PatNum
/*Procedures with date=lowest completed proc*/
INNER JOIN(
SELECT pl.PatNum,pl.ProcDate
FROM procedurelog pl
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum AND pc.ProcCode=@ExamCode
WHERE pl.ProcStatus=2
GROUP BY pl.PatNum
) procs ON procs.PatNum=p.PatNum AND procs.ProcDate=minProc.ProcDate
WHERE p.PatStatus=0
ORDER BY minProc.ProcDate
) B;
Outstanding balance report with last date seen(patient), aging(family), total balance(family), billing type(family), and payplan information(guarantor) - Will show one row for each payment plan a guarantor has.
/*705 Outstanding balance report with last date seen(patient), aging(family), total balance(family), billing type(family), and payplan information(guarantor)*/
/*Will show one row for each payment plan a guarantor has*/
SELECT p.PatNum,
c.Description AS 'Clinic',
DATE_FORMAT(lastseen.DateLastSeen,'%m/%d/%Y') AS LastDateSeen,
p.Guarantor,
g.BalTotal AS '$Total_',
g.Bal_0_30 AS '$0-30 DAYS_',
g.Bal_31_60 AS '$31-60 DAYS_',
g.Bal_61_90 AS '$61-90 DAYS_',
g.BalOver90 AS '$>90 DAYS_',
g.BillingType,
DATE_FORMAT(payplaninfo.PayPlanDate,'%m/%d/%Y') AS PayPlanDate,
DATE_FORMAT(payplaninfo.NextCharge,'%m/%d/%Y') AS PayPlanNextCharge,
payplaninfo.DueNow AS '$PayPlanBalance_'
FROM patient p
LEFT JOIN (
SELECT pl.PatNum, MAX(pl.ProcDate) AS DateLastSeen
FROM procedurelog pl
WHERE pl.ProcStatus=2
GROUP BY pl.PatNum
) lastseen ON lastseen.PatNum=p.PatNum
LEFT JOIN clinic c ON c.ClinicNum=p.ClinicNum
LEFT JOIN patient g ON g.PatNum=p.Guarantor
LEFT JOIN (
SELECT A.PatNum,
(CASE WHEN A.PlanNum=0 THEN '' ELSE 'X' END) AS Ins,
FORMAT(A.Principal,2) AS Principal,
FORMAT(A.Paid,2) AS Paid,
FORMAT(A.AccumDue-A.paid,2) AS DueNow,
FORMAT(A.DueTen-A.Paid,2) AS DueTen,
FORMAT(A.Principal-A.paid,2) Bal,
A.NextPayDate AS 'NextCharge',
A.PayPlanDate
FROM(
SELECT payplan.PatNum,
payplan.PlanNum,
payplan.PayPlanDate,
COALESCE((
SELECT SUM(Principal+Interest)
FROM payplancharge
WHERE payplancharge.PayPlanNum=payplan.PayPlanNum
AND ChargeDate<=CURDATE()
),0) AccumDue,
COALESCE((
SELECT SUM(Principal+Interest)
FROM payplancharge
WHERE payplancharge.PayPlanNum=payplan.PayPlanNum
AND ChargeDate<=CURDATE() + INTERVAL (SELECT ValueString FROM preference WHERE PrefName='PayPlansBillInAdvanceDays') DAY
),0) DueTen,
COALESCE((
SELECT SUM(SplitAmt)
FROM paysplit
WHERE paysplit.PayPlanNum=payplan.PayPlanNum
),0) Paid,
COALESCE((
SELECT SUM(Principal)
FROM payplancharge
WHERE payplancharge.PayPlanNum=payplan.PayPlanNum
),0) Principal,
( SELECT MIN(ChargeDate)
FROM payplancharge
WHERE payplancharge.PayPlanNum=payplan.PayPlanNum
AND ChargeDate >= CURDATE()
) AS NextPayDate
FROM payplan
GROUP BY payplan.PayPlanNum
) A
) payplaninfo ON payplaninfo.PatNum=g.PatNum
GROUP BY p.PatNum
ORDER BY p.LName, p.FName
List of all patients that shows Name, Date Last Visit, Fee Schedule(Rarely Used), Primary provider fee schedule (UCR), and all of the patients Primary and secondary fee schedules -
/*706 List of all patients that shows Name, Date Last Visit, Fee Schedule(Rarely Used), Primary provider fee schedule (UCR), and all of the patients Primary and secondary fee schedules*/
SELECT p.PatNum,
COALESCE(pf.Description,'N/A') AS 'PrimaryProviderFeeSchedUCR',
CONCAT(COALESCE(nf1.Description,'N/A'), ', ', COALESCE(nf2.Description,'N/A')) AS 'NormalFeeScheds(Prim,Sec)',
CONCAT(COALESCE(cp1.Description,'N/A'), ', ', COALESCE(cp2.Description,'N/A')) AS 'CoPayFeeScheds(Prim,Sec)',
CONCAT(COALESCE(al1.Description,'N/A'), ', ', COALESCE(al2.Description,'N/A')) AS 'AllowedFeeScheds(Prim,Sec)',
COALESCE(rl.Description,'N/A') AS FeeScheduleRarelyUsed,
MAX(pl.ProcDate) AS DateLastVisit
FROM patient p
LEFT JOIN procedurelog pl ON pl.PatNum=p.PatNum AND pl.ProcStatus=2
LEFT JOIN feesched rl ON rl.FeeSchedNum=p.FeeSched
LEFT JOIN provider pr ON pr.ProvNum=p.PriProv
LEFT JOIN feesched pf ON pf.FeeSchedNum=pr.FeeSched
LEFT JOIN patplan pp1 ON p.PatNum=pp1.PatNum AND pp1.Ordinal=1
LEFT JOIN inssub ib1 ON pp1.InsSubNum=ib1.InsSubNum
LEFT JOIN insplan ip1 ON ip1.PlanNum=ib1.PlanNum
LEFT JOIN feesched nf1 ON nf1.FeeSchedNum=ip1.FeeSched
LEFT JOIN feesched cp1 ON cp1.FeeSchedNum=ip1.CopayFeeSched
LEFT JOIN feesched al1 ON al1.FeeSchedNum=ip1.AllowedFeeSched
LEFT JOIN patplan pp2 ON p.PatNum=pp2.PatNum AND pp2.Ordinal=2
LEFT JOIN inssub ib2 ON pp2.InsSubNum=ib2.InsSubNum
LEFT JOIN insplan ip2 ON ip2.PlanNum=ib2.PlanNum
LEFT JOIN feesched nf2 ON nf2.FeeSchedNum=ip2.FeeSched
LEFT JOIN feesched cp2 ON cp2.FeeSchedNum=ip2.CopayFeeSched
LEFT JOIN feesched al2 ON al2.FeeSchedNum=ip2.AllowedFeeSched
GROUP BY PatNum
ORDER BY DateLastVisit DESC,p.LName,p.FName;
Patients who have had an exam sheet added to their chart in a date range -
/*707 Patients who have had an exam sheet added to their chart in a date range*/
SET @FromDate='2000-07-01', @ToDate='2013-07-31';
SELECT s.PatNum, DATE(s.DateTimeSheet) AS 'Date', s.Description AS 'SheetDescription'
FROM sheet s
LEFT JOIN patient p ON p.PatNum=s.PatNum
WHERE s.SheetType=13 AND s.DateTimeSheet BETWEEN @FromDate AND @ToDate
ORDER BY p.LName, p.FName, DateTimeSheet, SheetDescription
List of patients that do not have any scheduled appointments but have Planned appointments, Unscheduled appointments, or are past due for Recall. - With Name, Status, Primary and Secondary Insurance
/*708 List of patients that do not have any scheduled appointments but have Planned appointments, Unscheduled appointments, or are past due for Recall. With Name, Status, Primary and Secondary Insurance*/
SET @FromDate='2013-07-01', @ToDate='2013-07-31';
SELECT B.PatNum,
pap.AptType AS 'Planned Tracker',
unsched.AptType AS 'UnScheduled List',
r.AptType AS 'Recall List',
B.PatStatus,car1.CarrierName AS 'Primary Ins',
car2.CarrierName AS 'Secondary Ins'
/*List of patients with no scheduled appointment between @FromDate and @ToDate*/
FROM
(
SELECT p.PatNum,p.PatStatus,p.LName,p.FName
FROM patient p
/*Patients with a scheduled appointment in the future*/
LEFT JOIN (
SELECT DISTINCT ap.PatNum
FROM appointment ap
WHERE ap.AptStatus=1
AND DATE(ap.AptDateTime)>CURDATE()
) A ON A.patNum=p.PatNum
WHERE A.PatNum IS NULL
) B
/*Patients on the Planned Appointment Tracker that have an appointment planned*/
LEFT JOIN (
SELECT DISTINCT pap.PatNum,'Yes' AS AptType
FROM appointment pap
WHERE pap.AptStatus=6
AND pap.AptNum NOT IN (
SELECT sap.NextAptNum FROM appointment sap
WHERE sap.AptStatus=1
AND sap.NextAptNum!=0)
) pap ON pap.PatNum=B.PatNum
/*Patients on the Unscheduled/Broken Appointment List*/
LEFT JOIN (
SELECT DISTINCT PatNum,'Yes' AS AptType
FROM appointment unsched
WHERE unsched.AptStatus=3
OR unsched.AptStatus=5
) unsched ON unsched.PatNum=B.PatNum
/*Patients on the Recall List with a DueDate between @FromDate & @ToDate*/
LEFT JOIN (
SELECT DISTINCT r.PatNum,'Yes' AS AptType
FROM recall r
WHERE r.IsDisabled=0
AND r.DateDue BETWEEN @FromDate AND @ToDate
) r ON r.PatNum=B.PatNum
/*Primary Ins Information*/
LEFT JOIN (
SELECT pp.PatNum, pp.Ordinal, pp.InsSubNum
FROM patplan pp
WHERE pp.Ordinal=1
) pp1 ON pp1.PatNum=B.PatNum
LEFT JOIN inssub ib1 ON ib1.InsSubNum=pp1.InsSubNum
LEFT JOIN insplan ip1 ON ib1.PlanNum=ip1.PlanNum
LEFT JOIN carrier car1 ON car1.CarrierNum=ip1.CarrierNum
/*Secondary Ins Information*/
LEFT JOIN (
SELECT pp.PatNum, pp.Ordinal, pp.InsSubNum
FROM patplan pp
WHERE pp.Ordinal=2
) pp2 ON pp2.PatNum=B.PatNum
LEFT JOIN inssub ib2 ON ib2.InsSubNum=pp2.InsSubNum
LEFT JOIN insplan ip2 ON ib2.PlanNum=ip2.PlanNum
LEFT JOIN carrier car2 ON car2.CarrierNum=ip2.CarrierNum
/*Filter anyone not on the 3 lists*/
WHERE B.PatStatus IN (0,2)
AND (pap.AptType IS NOT NULL
OR unsched.AptType IS NOT NULL
OR r.AptType IS NOT NULL)
ORDER BY B.LName, B.FName;
Procedures completed for day(or date range) with latest procedure note, group note and tooth surface(s), and whether the note and group note is signed. - Only shows unsigned entries.
/*709 Procedures completed for day(or date range) with latest procedure note, group note and tooth surface(s), and whether the note and group note is signed. Only shows unsigned entries.*/
SET @FromDate='2014-01-01', @ToDate='2014-04-01';
SELECT A.ProcDate AS 'DateOfService',
A.Prov AS 'Provider',
A.Patient,
A.ToothNum AS 'Tooth',
A.Surf,
A.ProcCode,
A.AbbrDesc,
(CASE WHEN ISNULL(pn.Note) THEN 'None' WHEN pn.Note='' THEN 'None' ELSE pn.Note END) AS 'Note',
(CASE WHEN ISNULL(pn.Signature) THEN 'No Note'
WHEN LENGTH(pn.Signature)>0 THEN 'Signed'
ELSE 'Not Signed' END
) AS 'NoteSigned',
(CASE WHEN ISNULL(gn.Note) THEN 'None' ELSE gn.Note END) AS 'GroupNote',
(CASE WHEN ISNULL(gn.Signature) THEN 'No Note'
WHEN LENGTH(gn.Signature)>0 THEN 'Signed'
ELSE 'Not Signed' END
) AS 'GroupNoteSigned'
FROM (
SELECT CONCAT(p.LName,', ',p.FName) AS 'Patient',
pl.ProcDate,
pl.ToothNum,
pl.Surf,
pl.ProcNum,
pc.ProcCode,
pc.AbbrDesc,
prov.Abbr AS 'Prov',
gnote.MaxEntryDateTime AS 'GnoteMaxDateTime',
pnote.MaxEntryDateTime AS 'PnoteMaxDateTime'
FROM procedurelog pl
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
INNER JOIN patient p ON p.PatNum=pl.PatNum
INNER JOIN provider prov ON prov.ProvNum=pl.ProvNum
LEFT JOIN (
SELECT pl.ProcNum,MAX(gnote.EntryDateTime) AS MaxEntryDateTime
FROM procgroupitem pgi
INNER JOIN procedurelog pl ON pl.ProcNum=pgi.ProcNum
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus=2
INNER JOIN procedurelog gn ON gn.ProcNum=pgi.GroupNum
AND gn.ProcStatus=3
INNER JOIN procnote gnote ON gnote.ProcNum=gn.ProcNum
GROUP BY pl.ProcNum
) gnote ON gnote.ProcNum=pl.ProcNum
LEFT JOIN (
SELECT pl.ProcNum,MAX(pnote.EntryDateTime) AS MaxEntryDateTime
FROM procedurelog pl
INNER JOIN procnote pnote ON pnote.ProcNum=pl.ProcNum
WHERE pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus=2
GROUP BY pl.ProcNum
) pnote ON pnote.ProcNum=pl.ProcNum
WHERE pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus=2
GROUP BY pl.ProcNum
) A
LEFT JOIN procnote pn ON A.ProcNum=pn.ProcNum AND pn.EntryDateTime=A.PnoteMaxDateTime
LEFT JOIN (
SELECT pl.ProcNum,gnote.EntryDateTime,gnote.Note,gnote.Signature
FROM procgroupitem pgi
INNER JOIN procedurelog pl ON pl.ProcNum=pgi.ProcNum
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus=2
INNER JOIN procedurelog gn ON gn.ProcNum=pgi.GroupNum
AND gn.ProcStatus=3
INNER JOIN procnote gnote ON gnote.ProcNum=gn.ProcNum
) gn ON A.ProcNum=gn.ProcNum AND gn.EntryDateTime=A.GnoteMaxDateTime
HAVING NoteSigned!='Signed' AND GroupNoteSigned!='Signed'
ORDER BY DateOfService,Patient,ProcCode
Patient balances @AsOf date for patients that have not been seen after the user specified @CreditSince date variable. -
/*710 Patient balances @AsOf date for patients that have not been seen after the user specified @CreditSince date variable.*/
SET @AsOf='2013-08-12', @CreditSince='2011-01-01';
SELECT E.Guarantor AS GUARANTOR,E.Total AS TOTAL,
E.InsEst AS '-INS EST',E.PatEst AS '=PATIENT',
(CASE WHEN DATE_FORMAT(E.FamLastSeen,"%m/%d/%Y")='01/01/0001' THEN 'NeverSeen' ELSE DATE_FORMAT(E.FamLastSeen,"%m/%d/%Y") END) AS FamLastSeen
FROM (
SELECT 0 AS ItemOrder,CONCAT(D.LName,', ',D.FName) AS Guarantor,
FORMAT(ROUND(D.FamBal,2),2) AS Total,
FORMAT(ROUND(COALESCE(D.FamInsEst,0),2),2) AS InsEst,
FORMAT(ROUND(D.FamBal-COALESCE(D.FamInsEst,0),2),2) AS PatEst,
DATE(FamLastSeen) AS FamLastSeen
FROM (
/*Get the family level charges, credits, ins estimates, and date of last payment made on any family member*/
SELECT g.PatNum,g.LName,g.FName,SUM(B.PatBal) AS FamBal,SUM(B.Charges0to30) AS FamCharges0to30,SUM(B.Charges31to60) AS FamCharges31to60,
SUM(B.Charges61to90) AS FamCharges61to90,SUM(B.ChargesOver90) AS FamChargesOver90,SUM(B.Credits) AS FamCredits,
SUM(COALESCE(C.InsEst,0)) AS FamInsEst,MAX(COALESCE(DateLastSeen.PatLastSeen,'0001-01-01')) AS FamLastSeen
FROM (
/*Get Patient level charges and credits*/
SELECT RawPatTrans.PatNum,SUM(RawPatTrans.TranAmount) AS PatBal,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<=@AsOf AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 30 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges0to30,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 30 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 60 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges31to60,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 60 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges61to90,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS ChargesOver90,
-(SUM(CASE WHEN (RawPatTrans.TranAmount<0 AND RawPatTrans.TranDate<=@AsOf) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Credits
FROM (
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum AS PatNum,pl.ProcDate AS TranDate,
pl.ProcFee*(pl.UnitQty+pl.BaseUnits) AS TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum AS PatNum,ps.DatePay AS TranDate,
-ps.SplitAmt AS TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum AS PatNum,a.AdjDate AS TranDate,
a.AdjAmt AS TranAmount
FROM adjustment a
WHERE a.AdjAmt!=0
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum AS PatNum,cp.DateCp AS TranDate,
-cp.InsPayAmt-cp.Writeoff AS TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4,5,7)/*received,supplemental,CapClaim, or CapComplete*/
UNION ALL
/*Payment plan principal for the entire office history on or before the given date*/
SELECT 'PayPlan' AS TranType,pp.PatNum AS PatNum,pp.PayPlanDate AS TranDate,
-pp.CompletedAmt AS TranAmount
FROM payplan pp
WHERE pp.CompletedAmt!=0
GROUP BY pp.PayPlanNum
) RawPatTrans
WHERE TranDate<=@AsOf
GROUP BY RawPatTrans.PatNum
) B
LEFT JOIN (
/*Get patient level InsPayEst and Writeoffs from unreceived claims.*/
SELECT cp.PatNum,SUM(cp.InsPayEst+cp.Writeoff) AS InsEst
FROM claimproc cp
WHERE cp.PatNum!=0
AND ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR (cp.Status=1 AND cp.DateCP>@AsOf))
AND cp.ProcDate<=@ASOf
GROUP BY cp.PatNum
) C ON C.PatNum=B.PatNum
LEFT JOIN (
/*Get last date seen for each patient*/
SELECT ap.PatNum,MAX(ap.AptDateTime) AS PatLastSeen
FROM appointment ap
WHERE ap.AptStatus=2
GROUP BY ap.PatNum
) DateLastSeen ON DateLastSeen.PatNum=B.PatNum
INNER JOIN patient p ON p.PatNum=B.PatNum
INNER JOIN patient g ON g.PatNum=p.Guarantor
GROUP BY g.PatNum
) D
WHERE D.FamBal<-0.005
) E
WHERE @CreditSince > E.FamLastSeen
ORDER BY E.ItemOrder,E.Guarantor;
Count of patients that had an appointment on @ApptDate in the specified clinic, by provider. Also shows if they were rescheduled at the specified clinic on that day. - This query uses the Audit Trail to track rescheduled appointments and may be inaccurate for data entered on and after version 17.3.
/*711 Count of patients that had an appointment on @ApptDate in the specified clinic, by provider. Also shows if they were rescheduled at the specified clinic on that day.*/
/*Query code written/modified: 10/05/2017*/
SET @ApptDate='2016-04-19';
SET @ClinicAbbr = '%%'; /*Enter clinic abbreviation between %'s. Leave only %'s to run for all clinics.*/
SELECT IF(a.IsHygiene=1,COALESCE(provhyg.Abbr, prov.Abbr),prov.Abbr) AS 'Provider',
COUNT(a.PatNum) AS '#PatSeen',
COUNT(af.PatNum) AS '#PatRescheduled',
FORMAT((CASE WHEN MAX(af.PatNum) IS NOT NULL THEN (COUNT(af.PatNum)/COUNT(a.PatNum))*100 ELSE 0.00 END),2) AS '%Rescheduled',
COALESCE(SUM(af.Hyg),0) AS '#HygResched',
COALESCE(SUM(af.Prov), 0) AS '#ProvResched'
FROM appointment a
LEFT JOIN clinic c ON c.ClinicNum = a.ClinicNum
AND c.Abbr LIKE @ClinicAbbr
LEFT JOIN (
SELECT sl.PatNum,
(CASE WHEN a.IsHygiene = 1 THEN 1 ELSE 0 END) AS Hyg,
(CASE WHEN a.IsHygiene = 1 THEN 0 ELSE 1 END) AS Prov
FROM securitylog sl
INNER JOIN appointment a ON a.AptNum = sl.FKey
AND a.AptDateTime > @ApptDate + INTERVAL 1 DAY
LEFT JOIN clinic c ON c.ClinicNum = a.ClinicNum
WHERE LogDateTime BETWEEN @ApptDate AND @ApptDate + INTERVAL 1 DAY
AND (sl.PermType=25 OR sl.PermType=26) /*25 is ApptCreate, 26 is ApptMove*/
AND (CASE WHEN @ClinicAbbr = '%%' THEN TRUE ELSE c.Abbr LIKE @ClinicAbbr END)
GROUP BY sl.PatNum
)af ON af.PatNum=a.PatNum
LEFT JOIN provider prov ON a.ProvNum=prov.ProvNum
LEFT JOIN provider provhyg ON a.ProvHyg=provhyg.ProvNum
WHERE a.AptStatus=2 /*Complete*/
AND DATE(a.AptDateTime)=@ApptDate
AND (CASE WHEN @ClinicAbbr = '%%' THEN TRUE ELSE c.Abbr LIKE @ClinicAbbr END)
GROUP BY IF(a.IsHygiene=1,COALESCE(provhyg.Abbr, prov.Abbr),prov.Abbr);
Patients seen on a date that have family members due for Hyg appointment with name, family member, and due date. -
/*712 Patients seen on a date that have family members due for Hyg appointment with name, family member, and due date.*/
SET @DateFrom='2013-08-27';
SELECT CONCAT(p.LName,', ',p.FName) AS 'Patient Name',
fam.PatName AS 'Family Member',
(CASE WHEN fam.DateDue!='0001-01-01' THEN DATE_FORMAT(fam.DateDue,"%m/%d/%Y") ELSE 'Not Yet Seen' END) AS 'Recall Date Due',
fam.Description
FROM appointment a
INNER JOIN patient p ON p.PatNum=a.PatNum
LEFT JOIN (
SELECT fam.PatNum,
CONCAT(fam.LName,', ',fam.FName) AS PatName,
fam.Guarantor,
r.DateDue,
rt.Description
FROM patient fam
LEFT JOIN recall r ON r.PatNum=fam.PatNum
LEFT JOIN recalltype rt ON rt.RecallTypeNum=r.RecallTypeNum
LEFT JOIN recalltrigger rtr ON rtr.RecallTypeNum=rt.RecallTypeNum
LEFT JOIN procedurecode pc ON pc.CodeNum=rtr.CodeNum
WHERE r.IsDisabled=0
AND r.DateDue < CURDATE()
AND pc.ProcCode IN ('D1120', 'D1110', 'D4910')
AND NOT ISNULL(r.DateDue)
GROUP BY fam.PatNum, r.RecallTypeNum
)fam ON fam.Guarantor=p.Guarantor AND fam.PatNum<>p.PatNum
WHERE a.AptStatus=2
AND NOT ISNULL(fam.PatNum)
AND DATE(a.AptDateTime)=@DateFrom
List of active patients in alphabetical order with last appt, and next future appt, wireless phone, home phone, primary ins carrier, and secondary ins carrier. - Where the future appt is between @FromDate and @ToDate
/*713 List of active patients in alphabetical order with last appt, and next future appt, wireless phone, home phone, primary ins carrier, and secondary ins carrier. Where the future appt is between @FromDate and @ToDate*/
SET @FromDate='2013-08-23',@ToDate='2013-08-31';
SELECT p.PatNum AS 'Pat Num',
p.LName,
p.FName,
p.HmPhone,
p.WirelessPhone,
(SELECT MAX(a.AptDateTime) FROM appointment a WHERE a.PatNum=p.PatNum AND a.AptStatus=2) AS LastSeen,
nextsched.AptDateTime AS NextSchedApt,
COALESCE(car1.CarrierName,'NoIns') AS 'Primary Ins',
COALESCE(car2.CarrierName,'NoSecIns') AS 'Secondary Ins'
FROM patient p
LEFT JOIN(
SELECT MIN(a.AptDateTime) AS AptDateTime,
a.PatNum
FROM appointment a
WHERE a.AptStatus=1
AND DATE(a.AptDateTime)>CURDATE()
GROUP BY a.PatNum
) nextsched ON nextsched.PatNum=p.PatNum
/*Primary Ins Information*/
LEFT JOIN (
SELECT pp.PatNum,car1.CarrierName
FROM patplan pp
LEFT JOIN inssub ib1 ON ib1.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip1 ON ib1.PlanNum=ip1.PlanNum
LEFT JOIN carrier car1 ON car1.CarrierNum=ip1.CarrierNum
WHERE pp.Ordinal=1
) car1 ON car1.PatNum=p.PatNum
/*Secondary Ins Information*/
LEFT JOIN (
SELECT pp.PatNum,car2.CarrierName
FROM patplan pp
LEFT JOIN inssub ib2 ON ib2.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip2 ON ib2.PlanNum=ip2.PlanNum
LEFT JOIN carrier car2 ON car2.CarrierNum=ip2.CarrierNum
WHERE pp.Ordinal=2
) car2 ON car2.PatNum=p.PatNum
WHERE p.PatStatus=0
AND DATE(nextsched.AptDateTime) BETWEEN @FromDate AND @ToDate
ORDER BY p.LName, p.FName;
List of patients with appointments for a date range (in future or past) with estimated patient balance as of appointment date. - A/R for version before 14.3
/*714 List of patients with appointments for a date range (in future or past) with estimated patient balance as of appointment date.
Also lists Fees, Insurance payment estimate and patient portion, and primary insurance carrier*/
SET @FromDate='2013-09-13' , @ToDate='2013-09-30';
SELECT AllApt.PatNum,AllApt.AptDateTime,AllApt.PriCarrier,AllApt.Fees AS $Fees_,AllApt.InsPayEst AS $InsPayEst_,AllApt.PatPorEst AS $PatPorEst_,
AllApt.Aged+SUM(COALESCE(fa.PatPorEst,0)) AS $FutureEstBal_
FROM (
SELECT a.AptDateTime,
p.PatNum,
(CASE WHEN ISNULL(carrier.CarrierName)
THEN '*No Insurance'
ELSE (carrier.CarrierName)
END) AS 'PriCarrier',
SUM(pl.ProcFee) AS Fees,
COALESCE(SUM(CASE
WHEN cp.Status=1 OR cp.Status=4 THEN(cp.InsPayAmt)
WHEN cp.Status=0 THEN(cp.InsPayEst)
WHEN cp.Status=6 THEN(CASE WHEN cp.InsEstTotalOverride=-1 THEN(cp.InsEstTotal) ELSE (cp.InsEstTotalOverride)END)
END),0) AS InsPayEst,
/*Procfee - Writeoff - Insurance Estimate*/
(SUM(pl.ProcFee))
-(COALESCE(SUM(CASE
WHEN cp.Status=1 OR cp.Status=4 THEN(cp.WriteOff)
ELSE(CASE WHEN cp.WriteOffEstOverride=-1 THEN (CASE WHEN cp.WriteOffEst=-1 THEN cp.WriteOff ELSE (cp.WriteOffEst) END) ELSE (cp.WriteOffEstOverride)END)
END),0))
-(COALESCE(SUM(CASE
WHEN cp.Status=1 OR cp.Status=4 THEN(cp.InsPayAmt)
WHEN cp.Status=0 THEN(cp.InsPayEst)
WHEN cp.Status=6 THEN(CASE WHEN cp.InsEstTotalOverride=-1 THEN(cp.InsEstTotal) ELSE (cp.InsEstTotalOverride)END)
END),0)) AS PatPorEst,a.AptNum,
COALESCE(aging.PatEst,0) AS Aged
FROM appointment a
INNER JOIN patient p ON p.PatNum=a.PatNum /*just in case we need field FROM patient table*/
INNER JOIN procedurelog pl ON a.AptNum=pl.AptNum AND (DATE(a.AptDateTime) BETWEEN @FromDate AND @ToDate) AND a.AptStatus IN (1,2,4)/*appointment 1=sched, 2=complete or 4=ASAP */
LEFT JOIN claimproc cp ON cp.ProcNum=pl.ProcNum AND cp.Status IN (0,1,4,6)
LEFT JOIN patplan pp ON pp.PatNum=p.PatNum AND ORDINAL=1/*by current primary insurance*/
LEFT JOIN inssub iss ON pp.InsSubNum=iss.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=iss.PlanNum
LEFT JOIN carrier ON carrier.CarrierNum=ip.CarrierNum
LEFT JOIN
( /*Aging report to get current pat balance*/
SELECT D.PatNum,ROUND(D.FamBal-COALESCE(D.FamInsEst,0),2) AS PatEst
FROM (
/*Get the family level charges, credits, and ins estimates*/
SELECT p.PatNum,p.LName,p.FName,SUM(B.PatBal) AS FamBal,SUM(COALESCE(C.InsEst,0)) AS FamInsEst
FROM (
/*Get Patient level charges and credits*/
SELECT RawPatTrans.PatNum,SUM(RawPatTrans.TranAmount) AS PatBal
FROM (
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum AS PatNum,pl.ProcDate AS TranDate,
pl.ProcFee*(pl.UnitQty+pl.BaseUnits) AS TranAmount,pl.ClinicNum
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum AS PatNum,ps.DatePay AS TranDate,
-ps.SplitAmt AS TranAmount,ps.ClinicNum
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum AS PatNum,a.AdjDate AS TranDate,
a.AdjAmt AS TranAmount,a.ClinicNum
FROM adjustment a
WHERE a.AdjAmt!=0
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum AS PatNum,cp.DateCp AS TranDate,
-cp.InsPayAmt-cp.Writeoff AS TranAmount,cp.ClinicNum
FROM claimproc cp
WHERE cp.Status IN (1,4,5,7)/*received,supplemental,CapClaim, or CapComplete*/
UNION ALL
/*Payment plan principal for the entire office history on or before the given date*/
SELECT 'PayPlan' AS TranType,pp.PatNum AS PatNum,pp.PayPlanDate AS TranDate,
-pp.CompletedAmt AS TranAmount,MAX(ppc.ClinicNum) AS ClinicNum /*MAX gets valid ClinicNum if one exists, otherwise 0*/
FROM payplan pp
INNER JOIN payplancharge ppc ON ppc.PayPlanNum=pp.PayPlanNum
WHERE pp.CompletedAmt!=0
GROUP BY pp.PayPlanNum
) RawPatTrans
WHERE TranDate<=CURDATE()
GROUP BY RawPatTrans.PatNum
) B
LEFT JOIN (
/*Get patient level InsPayEst and Writeoffs from unreceived claims.*/
SELECT cp.PatNum,SUM(cp.InsPayEst+cp.Writeoff) AS InsEst
FROM claimproc cp
WHERE cp.PatNum!=0
AND ((cp.Status=0 AND cp.ProcDate<=CURDATE()) OR (cp.Status=1 AND cp.DateCP>CURDATE()))
AND cp.ProcDate<=CURDATE()
GROUP BY cp.PatNum
) C ON C.PatNum=B.PatNum
INNER JOIN patient p ON p.PatNum=B.PatNum
GROUP BY p.PatNum
) D
WHERE ABS(D.FamBal)>0.005
) aging ON aging.PatNum=p.PatNum
GROUP BY a.AptNum
) AllApt
/*Patient portion for scheduled appointments between CURDATE and ToDate*/
LEFT JOIN (
SELECT a.PatNum,
a.AptDateTime,
/*Procfee - Writeoff - Insurance Estimate*/
(SUM(pl.ProcFee))
-(COALESCE(SUM(CASE
WHEN cp.Status=1 OR cp.Status=4 THEN(cp.WriteOff)
ELSE(CASE WHEN cp.WriteOffEstOverride=-1 THEN (CASE WHEN cp.WriteOffEst=-1 THEN cp.WriteOff ELSE (cp.WriteOffEst) END) ELSE (cp.WriteOffEstOverride)END)
END),0))
-(COALESCE(SUM(CASE
WHEN cp.Status=1 OR cp.Status=4 THEN(cp.InsPayAmt)
WHEN cp.Status=0 THEN(cp.InsPayEst)
WHEN cp.Status=6 THEN(CASE WHEN cp.InsEstTotalOverride=-1 THEN(cp.InsEstTotal) ELSE (cp.InsEstTotalOverride)END)
END),0)) AS PatPorEst
FROM appointment a
INNER JOIN procedurelog pl ON a.AptNum=pl.AptNum AND (DATE(a.AptDateTime) BETWEEN CURDATE() AND @ToDate) AND a.AptStatus IN (1,4)/*appointment 1=sched or 4=ASAP */
LEFT JOIN claimproc cp ON cp.ProcNum=pl.ProcNum AND cp.Status IN (0,1,4,6)
GROUP BY a.AptNum
) fa ON fa.PatNum=AllApt.PatNum AND DATE(fa.AptDateTime) <= DATE(AllApt.AptDateTime)
GROUP BY AllApt.AptNum
ORDER BY AllApt.AptDateTime;
Completed medical procedures with insurance estimate but no claim. - With proceduredate in date range.
/*715 Completed medical procedures with insurance estimate but no claim. With proceduredate in date range.*/
SET @FromDate='2013-09-05' , @ToDate='2013-12-03';/*Change dates here*/
SELECT CONCAT(p.LName,', ',p.FName) AS 'Pat Name',
p.PatNum AS 'Pat#',
pl.ProcDate,
pc.ProcCode,
pl.MedicalCode,
car.CarrierName
FROM procedurelog pl
LEFT JOIN claimproc cp ON cp.ProcNum=pl.ProcNum
LEFT JOIN insplan ip ON cp.PlanNum=ip.PlanNum
LEFT JOIN carrier car ON car.CarrierNum=ip.CarrierNum
LEFT JOIN patient p ON p.PatNum=pl.PatNum
LEFT JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
WHERE pl.ProcStatus=2
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
AND ip.IsMedical=1
AND cp.Status=6
ORDER BY p.LName, p.FName
Appointments that are broken for a date range, with note, that do not have a future scheduled appointment. -
/*716 Appointments that are broken for a date range, with note, that do not have a future scheduled appointment.*/
SET @FromDate='2013-09-05', @ToDate='2013-12-31';/*change dates here*/
SELECT p.LName,p.FName, p.PatNum AS 'Pat#', a.AptDateTime, a.AptStatus, a.Note
FROM appointment a
INNER JOIN patient p ON a.PatNum=p.PatNum
LEFT JOIN(
SELECT fa.PatNum
FROM appointment fa
WHERE fa.AptStatus=1
AND DATE(fa.AptDateTime) >= CURDATE()
GROUP BY fa.PatNum
) fa ON fa.PatNum=a.PatNum
WHERE DATE(a.AptDateTime) BETWEEN @FromDate AND @ToDate
AND a.AptStatus=5
AND ISNULL(fa.PatNum);
List of patients that had their first completed procedure within a date range. Showing Provider, patient name, first completed procedure date, whether the patient is insured or not, amount paid on first visit, family balance. - Next scheduled appt after first visit, specific procedures from first visit, and user that marked 09970 complete on first visit.
/*717 List of patients that had their first completed procedure within a date range. Showing Provider, patient name, first completed procedure date, whether the patient is insured or not, amount paid on first visit, family balance, next completed appt after first visit, next scheduled appt after first visit, specific procedures from first visit, and user that marked 09970 complete on first visit*/
SET @StartDate='2015-01-01', @EndDate='2015-01-31';
SELECT A.ProvNum,
A.LName,
A.FName,
A.DateFirstVisit,
(CASE WHEN A.ProcCodes LIKE '%D0150%' THEN 'D0150'
WHEN A.ProcCodes LIKE '%D0140%' THEN 'D0140'
WHEN A.ProcCodes LIKE '%D0120%' THEN 'D0120'
WHEN A.ProcCodes LIKE '%D0160%' THEN 'D0160'
WHEN A.ProcCodes LIKE '%D0170%' THEN 'D0170'
WHEN A.ProcCodes LIKE '%D0180%' THEN 'D0180'
ELSE 'NONE' END) AS ExamType,
COALESCE(GROUP_CONCAT(DISTINCT UserOd.UserName),'NONE') AS UserName,
(CASE WHEN A.HasIns='I' THEN 'INS' ELSE 'NO INS' END) AS Insured,
A.TPAmount AS $TreatmentPlan_,
A.PayFirstVisit AS $PayFirstVisit_,
MIN(CASE WHEN NextVisit.Status=2 THEN NextVisit.Date ELSE NULL END) AS DateNextComplApt,
MIN(CASE WHEN NextVisit.Status=1 THEN NextVisit.Date ELSE NULL END) AS DateNextSchedApt,
guar.BalTotal
FROM (
SELECT p.PatNum,
p.LName,
p.FName,
p.Guarantor,
COALESCE(PatPay.Amount,0) AS PayFirstVisit,
pl.ProvNum,/*this is one of the provs that completed a proc on that first visit date, chosen by mysql at random*/
FirstVisit.Date AS DateFirstVisit,
GROUP_CONCAT(pc.ProcCode) AS ProcCodes,
p.HasIns,
COALESCE(TPd.Amount,0) AS TPAmount
FROM patient p
/*Get First Visit Date per patient only if First Visit Date in date range*/
INNER JOIN (
SELECT pl.PatNum,
MIN(pl.ProcDate) AS 'Date'
FROM procedurelog pl
WHERE pl.ProcStatus=2
GROUP BY pl.PatNum
) FirstVisit ON FirstVisit.PatNum=p.PatNum
AND FirstVisit.Date BETWEEN @StartDate AND @EndDate
/*Get all procedures completed on the first visit date*/
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
AND pl.ProcDate=FirstVisit.Date
AND pl.ProcStatus=2
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
/*Get total of TP'd work per patient*/
LEFT JOIN (
SELECT pl.PatNum,
SUM(pl.ProcFee) AS Amount
FROM procedurelog pl
WHERE pl.ProcStatus=1/*tp*/
GROUP BY pl.PatNum
) TPd ON TPd.PatNum=p.PatNum
/*Get total of patient payments for each patient on each date paid*/
LEFT JOIN (
SELECT ps.PatNum,
ps.DatePay AS 'Date',
SUM(ps.SplitAmt) AS Amount
FROM paysplit ps
GROUP BY ps.PatNum,ps.DatePay
) PatPay ON PatPay.PatNum=p.PatNum AND PatPay.Date=FirstVisit.Date
GROUP BY p.PatNum
) A
/*Get appts, sched or complete, for the pats in the above query, that are after the pat's first visit date*/
LEFT JOIN (
SELECT ap.PatNum,DATE(ap.AptDateTime) AS 'Date',
ap.AptStatus AS STATUS
FROM appointment ap
WHERE ap.AptStatus IN (1,2)/*sched,complete*/
) NextVisit ON NextVisit.PatNum=A.PatNum AND NextVisit.Date>A.DateFirstVisit
LEFT JOIN (
SELECT sl.PatNum,
DATE(sl.LogDateTime) AS LogDate,
u.UserName
FROM securitylog sl
INNER JOIN UserOD u ON sl.UserNum=u.UserNum
WHERE sl.PermType=23 /*completing procedure*/
AND sl.LogText LIKE('%09970%')
) UserOd ON UserOd.LogDate=A.DateFirstVisit AND UserOd.PatNum=A.PatNum
LEFT JOIN patient guar ON A.Guarantor=guar.PatNum
GROUP BY A.PatNum;
Aging for families with any balance - Shows values like the account module. Like internal AR report run with "Including negative balances". A/R for versions14.2 and before. For versions 14.3 and after, see query 1078.
/*718 Aging for families with any balance*/
SET @AsOf='2013-04-28';
SELECT E.Guarantor AS GUARANTOR,
E.0to30 AS '0-30 DAYS',E.31to60 AS '31-60 DAYS',
E.61to90 AS '61-90 DAYS',E.Over90 AS '>90 DAYS',E.Total AS TOTAL,
E.InsEst AS '-INS EST',E.PatEst AS '=PATIENT'
FROM (
SELECT 0 AS ItemOrder,CONCAT(D.LName,', ',D.FName) AS Guarantor,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60 THEN D.FamCharges0to30
WHEN D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30<=D.FamCredits THEN 0
ELSE D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30-D.FamCredits END)
,2),2) AS 0to30,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<D.FamChargesOver90+D.FamCharges61to90 THEN D.FamCharges31to60
WHEN D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60<=D.FamCredits THEN 0
ELSE D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60-D.FamCredits END)
,2),2) AS 31to60,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<=D.FamChargesOver90 THEN D.FamCharges61to90
WHEN D.FamChargesOver90+D.FamCharges61to90<=D.FamCredits THEN 0
ELSE D.FamChargesOver90+D.FamCharges61to90-D.FamCredits END)
,2),2) AS 61to90,
FORMAT(ROUND(
(CASE WHEN D.FamCredits>=D.FamChargesOver90 THEN 0
ELSE D.FamChargesOver90-D.FamCredits END)
,2),2) AS Over90,
FORMAT(ROUND(D.FamBal,2),2) AS Total,
FORMAT(ROUND(COALESCE(D.FamInsEst,0),2),2) AS InsEst,
FORMAT(ROUND(D.FamBal-COALESCE(D.FamInsEst,0),2),2) AS PatEst
FROM (
/*Get the family level charges, credits, and ins estimates*/
SELECT g.PatNum,g.LName,g.FName,SUM(B.PatBal) AS FamBal,SUM(B.Charges0to30) AS FamCharges0to30,SUM(B.Charges31to60) AS FamCharges31to60,
SUM(B.Charges61to90) AS FamCharges61to90,SUM(B.ChargesOver90) AS FamChargesOver90,SUM(B.Credits) AS FamCredits,
SUM(COALESCE(C.InsEst,0)) AS FamInsEst
FROM (
/*Get Patient level charges and credits*/
SELECT RawPatTrans.PatNum,SUM(RawPatTrans.TranAmount) AS PatBal,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<=@AsOf AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 30 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges0to30,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 30 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 60 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges31to60,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 60 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges61to90,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS ChargesOver90,
-(SUM(CASE WHEN (RawPatTrans.TranAmount<0 AND RawPatTrans.TranDate<=@AsOf) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Credits
FROM (
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum AS PatNum,pl.ProcDate AS TranDate,
pl.ProcFee*(pl.UnitQty+pl.BaseUnits) AS TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum AS PatNum,ps.DatePay AS TranDate,
-ps.SplitAmt AS TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum AS PatNum,a.AdjDate AS TranDate,
a.AdjAmt AS TranAmount
FROM adjustment a
WHERE a.AdjAmt!=0
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum AS PatNum,cp.DateCp AS TranDate,
-cp.InsPayAmt-cp.Writeoff AS TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4,5,7)/*received,supplemental,CapClaim, or CapComplete*/
UNION ALL
/*Payment plan principal for the entire office history on or before the given date*/
SELECT 'PayPlan' AS TranType,pp.PatNum AS PatNum,pp.PayPlanDate AS TranDate,
-pp.CompletedAmt AS TranAmount
FROM payplan pp
WHERE pp.CompletedAmt!=0
GROUP BY pp.PayPlanNum
) RawPatTrans
WHERE TranDate<=@AsOf
GROUP BY RawPatTrans.PatNum
) B
LEFT JOIN (
/*Get patient level InsPayEst and Writeoffs from unreceived claims.*/
SELECT cp.PatNum,SUM(cp.InsPayEst+cp.Writeoff) AS InsEst
FROM claimproc cp
WHERE cp.PatNum!=0
AND ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR (cp.Status=1 AND cp.DateCP>@AsOf))
AND cp.ProcDate<=@ASOf
GROUP BY cp.PatNum
) C ON C.PatNum=B.PatNum
INNER JOIN patient p ON p.PatNum=B.PatNum
INNER JOIN patient g ON g.PatNum=p.Guarantor
GROUP BY g.PatNum
) D
WHERE ABS(D.FamBal)>0.005
UNION ALL
SELECT 1 AS ItemOrder,'--------------------------------','---------------','---------------','---------------','---------------','---------------','---------------','---------------'
UNION ALL
SELECT 2 AS ItemOrder,'TOTALS:' AS Guarantor,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60 THEN D.FamCharges0to30
WHEN D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30<=D.FamCredits THEN 0
ELSE D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30-D.FamCredits END))
,2),2) AS 0to30,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<D.FamChargesOver90+D.FamCharges61to90 THEN D.FamCharges31to60
WHEN D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60<=D.FamCredits THEN 0
ELSE D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60-D.FamCredits END))
,2),2) AS 31to60,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<=D.FamChargesOver90 THEN D.FamCharges61to90
WHEN D.FamChargesOver90+D.FamCharges61to90<=D.FamCredits THEN 0
ELSE D.FamChargesOver90+D.FamCharges61to90-D.FamCredits END))
,2),2) AS 61to90,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits>=D.FamChargesOver90 THEN 0
ELSE D.FamChargesOver90-D.FamCredits END))
,2),2) AS Over90,
FORMAT(ROUND(SUM(D.FamBal),2),2) AS Total,
FORMAT(ROUND(SUM(COALESCE(D.FamInsEst,0)),2),2) AS InsEst,
FORMAT(ROUND(SUM(D.FamBal-COALESCE(D.FamInsEst,0)),2),2) AS PatEst
FROM (
/*Get the family level charges, credits, and ins estimates*/
SELECT g.PatNum,g.LName,g.FName,SUM(B.PatBal) AS FamBal,SUM(B.Charges0to30) AS FamCharges0to30,SUM(B.Charges31to60) AS FamCharges31to60,
SUM(B.Charges61to90) AS FamCharges61to90,SUM(B.ChargesOver90) AS FamChargesOver90,SUM(B.Credits) AS FamCredits,
SUM(COALESCE(C.InsEst,0)) AS FamInsEst
FROM (
/*Get Patient level charges and credits*/
SELECT RawPatTrans.PatNum,SUM(RawPatTrans.TranAmount) AS PatBal,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<=@AsOf AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 30 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges0to30,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 30 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 60 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges31to60,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 60 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges61to90,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS ChargesOver90,
-(SUM(CASE WHEN (RawPatTrans.TranAmount<0 AND RawPatTrans.TranDate<=@AsOf) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Credits
FROM (
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum AS PatNum,pl.ProcDate AS TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) AS TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum AS PatNum,ps.DatePay AS TranDate,-ps.SplitAmt AS TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum AS PatNum,a.AdjDate AS TranDate,a.AdjAmt AS TranAmount
FROM adjustment a
WHERE a.AdjAmt!=0
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum AS PatNum,cp.DateCp AS TranDate,-cp.InsPayAmt-cp.Writeoff AS TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4,5,7)/*received,supplemental,CapClaim, or CapComplete*/
UNION ALL
/*Payment plan principal for the entire office history on or before the given date*/
SELECT 'PayPlan' AS TranType,pp.PatNum AS PatNum,pp.PayPlanDate AS TranDate,-pp.CompletedAmt AS TranAmount
FROM payplan pp
WHERE pp.CompletedAmt!=0
) RawPatTrans
WHERE TranDate<=@AsOf
GROUP BY RawPatTrans.PatNum
) B
LEFT JOIN (
/*Get patient level InsPayEst and Writeoffs from unreceived claims.*/
SELECT cp.PatNum,SUM(cp.InsPayEst+cp.Writeoff) AS InsEst
FROM claimproc cp
WHERE cp.PatNum!=0
AND ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR (cp.Status=1 AND cp.DateCP>@AsOf))
AND cp.ProcDate<=@ASOf
GROUP BY cp.PatNum
) C ON C.PatNum=B.PatNum
INNER JOIN patient p ON p.PatNum=B.PatNum
INNER JOIN patient g ON g.PatNum=p.Guarantor
GROUP BY g.PatNum
) D
WHERE ABS(D.FamBal)>0.005
) E
ORDER BY E.ItemOrder,E.Guarantor;
Aging for families with any balance with 90 - 120. - A/R for versions 14.2 and before. For versions 14.3 and after, see query 1079.
/*719 Aging for families with any balance*/
SET @AsOf='2013-04-28';
SELECT E.Guarantor AS GUARANTOR,
E.0to30 AS '0-30 DAYS',E.31to60 AS '31-60 DAYS',
E.61to90 AS '61-90 DAYS',E.91to120 AS '91-120 DAYS',
E.Over120 AS '>120 DAYS',E.Total AS TOTAL,
E.InsEst AS '-INS EST',E.PatEst AS '=PATIENT'
FROM (
SELECT 0 AS ItemOrder,CONCAT(D.LName,', ',D.FName) AS Guarantor,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60 THEN D.FamCharges0to30
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30-D.FamCredits END)
,2),2) AS 0to30,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90 THEN D.FamCharges31to60
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60-D.FamCredits END)
,2),2) AS 31to60,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<=D.FamChargesOver120+D.FamCharges91to120 THEN D.FamCharges61to90
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90-D.FamCredits END)
,2),2) AS 61to90,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<=D.FamChargesOver120 THEN D.FamCharges91to120
WHEN D.FamChargesOver120+D.FamCharges91to120<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120-D.FamCredits END)
,2),2) AS 91to120,
FORMAT(ROUND(
(CASE WHEN D.FamCredits>=D.FamChargesOver120 THEN 0
ELSE D.FamChargesOver120-D.FamCredits END)
,2),2) AS Over120,
FORMAT(ROUND(D.FamBal,2),2) AS Total,
FORMAT(ROUND(COALESCE(D.FamInsEst,0),2),2) AS InsEst,
FORMAT(ROUND(D.FamBal-COALESCE(D.FamInsEst,0),2),2) AS PatEst
FROM (
/*Get the family level charges, credits, and ins estimates*/
SELECT g.PatNum,g.LName,g.FName,SUM(B.PatBal) AS FamBal,SUM(B.Charges0to30) AS FamCharges0to30,SUM(B.Charges31to60) AS FamCharges31to60,
SUM(B.Charges61to90) AS FamCharges61to90,SUM(B.Charges91to120) AS FamCharges91to120,SUM(B.ChargesOver120) AS FamChargesOver120,
SUM(B.Credits) AS FamCredits,SUM(COALESCE(C.InsEst,0)) AS FamInsEst
FROM (
/*Get Patient level charges and credits*/
SELECT RawPatTrans.PatNum,SUM(RawPatTrans.TranAmount) AS PatBal,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<=@AsOf AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 30 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges0to30,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 30 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 60 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges31to60,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 60 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges61to90,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 90 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 120 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges91to120,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 120 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS ChargesOver120,
-(SUM(CASE WHEN (RawPatTrans.TranAmount<0 AND RawPatTrans.TranDate<=@AsOf) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Credits
FROM (
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum AS PatNum,pl.ProcDate AS TranDate,
pl.ProcFee*(pl.UnitQty+pl.BaseUnits) AS TranAmount,pl.ClinicNum
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum AS PatNum,ps.DatePay AS TranDate,
-ps.SplitAmt AS TranAmount,ps.ClinicNum
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum AS PatNum,a.AdjDate AS TranDate,
a.AdjAmt AS TranAmount,a.ClinicNum
FROM adjustment a
WHERE a.AdjAmt!=0
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum AS PatNum,cp.DateCp AS TranDate,
-cp.InsPayAmt-cp.Writeoff AS TranAmount,cp.ClinicNum
FROM claimproc cp
WHERE cp.Status IN (1,4,5,7)/*received,supplemental,CapClaim, or CapComplete*/
UNION ALL
/*Payment plan principal for the entire office history on or before the given date*/
SELECT 'PayPlan' AS TranType,pp.PatNum AS PatNum,pp.PayPlanDate AS TranDate,
-pp.CompletedAmt AS TranAmount,MAX(ppc.ClinicNum) AS ClinicNum /*MAX gets valid ClinicNum if one exists, otherwise 0*/
FROM payplan pp
INNER JOIN payplancharge ppc ON ppc.PayPlanNum=pp.PayPlanNum
WHERE pp.CompletedAmt!=0
GROUP BY pp.PayPlanNum
) RawPatTrans
WHERE TranDate<=@AsOf
GROUP BY RawPatTrans.PatNum
) B
LEFT JOIN (
/*Get patient level InsPayEst and Writeoffs from unreceived claims.*/
SELECT cp.PatNum,SUM(cp.InsPayEst+cp.Writeoff) AS InsEst
FROM claimproc cp
WHERE cp.PatNum!=0
AND ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR (cp.Status=1 AND cp.DateCP>@AsOf))
AND cp.ProcDate<=@ASOf
GROUP BY cp.PatNum
) C ON C.PatNum=B.PatNum
INNER JOIN patient p ON p.PatNum=B.PatNum
INNER JOIN patient g ON g.PatNum=p.Guarantor
GROUP BY g.PatNum
) D
WHERE ABS(D.FamBal)>0.005
UNION ALL
SELECT 1 AS ItemOrder,'--------------------------------','---------------','---------------','---------------','---------------','---------------','---------------','---------------','---------------'
UNION ALL
SELECT 2 AS ItemOrder,'TOTALS:' AS Guarantor,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60 THEN D.FamCharges0to30
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30-D.FamCredits END))
,2),2) AS 0to30,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90 THEN D.FamCharges31to60
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60-D.FamCredits END))
,2),2) AS 31to60,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<=D.FamChargesOver120+D.FamCharges91to120 THEN D.FamCharges61to90
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90-D.FamCredits END))
,2),2) AS 61to90,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<=D.FamChargesOver120 THEN D.FamCharges91to120
WHEN D.FamChargesOver120+D.FamCharges91to120<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120-D.FamCredits END))
,2),2) AS 91to120,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits>=D.FamChargesOver120 THEN 0
ELSE D.FamChargesOver120-D.FamCredits END))
,2),2) AS Over120,
FORMAT(ROUND(SUM(D.FamBal),2),2) AS Total,
FORMAT(ROUND(SUM(COALESCE(D.FamInsEst,0)),2),2) AS InsEst,
FORMAT(ROUND(SUM(D.FamBal-COALESCE(D.FamInsEst,0)),2),2) AS PatEst
FROM (
/*Get the family level charges, credits, and ins estimates*/
SELECT g.PatNum,g.LName,g.FName,SUM(B.PatBal) AS FamBal,SUM(B.Charges0to30) AS FamCharges0to30,SUM(B.Charges31to60) AS FamCharges31to60,
SUM(B.Charges61to90) AS FamCharges61to90,SUM(B.Charges91to120) AS FamCharges91to120,SUM(B.ChargesOver120) AS FamChargesOver120,
SUM(B.Credits) AS FamCredits,SUM(COALESCE(C.InsEst,0)) AS FamInsEst
FROM (
/*Get Patient level charges and credits*/
SELECT RawPatTrans.PatNum,SUM(RawPatTrans.TranAmount) AS PatBal,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<=@AsOf AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 30 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges0to30,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 30 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 60 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges31to60,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 60 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges61to90,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 90 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 120 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges91to120,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 120 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS ChargesOver120,
-(SUM(CASE WHEN (RawPatTrans.TranAmount<0 AND RawPatTrans.TranDate<=@AsOf) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Credits
FROM (
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum AS PatNum,pl.ProcDate AS TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) AS TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum AS PatNum,ps.DatePay AS TranDate,-ps.SplitAmt AS TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum AS PatNum,a.AdjDate AS TranDate,a.AdjAmt AS TranAmount
FROM adjustment a
WHERE a.AdjAmt!=0
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum AS PatNum,cp.DateCp AS TranDate,-cp.InsPayAmt-cp.Writeoff AS TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4,5,7)/*received,supplemental,CapClaim, or CapComplete*/
UNION ALL
/*Payment plan principal for the entire office history on or before the given date*/
SELECT 'PayPlan' AS TranType,pp.PatNum AS PatNum,pp.PayPlanDate AS TranDate,-pp.CompletedAmt AS TranAmount
FROM payplan pp
WHERE pp.CompletedAmt!=0
) RawPatTrans
WHERE TranDate<=@AsOf
GROUP BY RawPatTrans.PatNum
) B
LEFT JOIN (
/*Get patient level InsPayEst and Writeoffs from unreceived claims.*/
SELECT cp.PatNum,SUM(cp.InsPayEst+cp.Writeoff) AS InsEst
FROM claimproc cp
WHERE cp.PatNum!=0
AND ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR (cp.Status=1 AND cp.DateCP>@AsOf))
AND cp.ProcDate<=@ASOf
GROUP BY cp.PatNum
) C ON C.PatNum=B.PatNum
INNER JOIN patient p ON p.PatNum=B.PatNum
INNER JOIN patient g ON g.PatNum=p.Guarantor
GROUP BY g.PatNum
) D
WHERE ABS(D.FamBal)>0.005
) E
ORDER BY E.ItemOrder,E.Guarantor;
Aging for families with any balance with 90 - 120 and billing type filter - A/R for versions 14.2 and before. For versions 14.3 and after, see query 1080
/*720 Aging for families with any balance with 90 - 120 and billing type filter*/
SET @AsOf='2013-04-28';
SET @BillingTypes='Standard Acount|Bad Debt - Precollections|Bad Debt - Sent to Collections|BWC|..NA|D/C|Ortho|H.S.|INS|PRIV|S/I|S/P|TRIP|Hold|Medical Card';
SELECT E.Guarantor AS GUARANTOR,E.BillingType,
E.0to30 AS '0-30 DAYS',E.31to60 AS '31-60 DAYS',
E.61to90 AS '61-90 DAYS',E.91to120 AS '91-120 DAYS',
E.Over120 AS '>120 DAYS',E.Total AS TOTAL,
E.InsEst AS '-INS EST',E.PatEst AS '=PATIENT'
FROM (
SELECT 0 AS ItemOrder,CONCAT(D.LName,', ',D.FName) AS Guarantor,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60 THEN D.FamCharges0to30
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30-D.FamCredits END)
,2),2) AS 0to30,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90 THEN D.FamCharges31to60
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60-D.FamCredits END)
,2),2) AS 31to60,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<=D.FamChargesOver120+D.FamCharges91to120 THEN D.FamCharges61to90
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90-D.FamCredits END)
,2),2) AS 61to90,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<=D.FamChargesOver120 THEN D.FamCharges91to120
WHEN D.FamChargesOver120+D.FamCharges91to120<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120-D.FamCredits END)
,2),2) AS 91to120,
FORMAT(ROUND(
(CASE WHEN D.FamCredits>=D.FamChargesOver120 THEN 0
ELSE D.FamChargesOver120-D.FamCredits END)
,2),2) AS Over120,
FORMAT(ROUND(D.FamBal,2),2) AS Total,
FORMAT(ROUND(COALESCE(D.FamInsEst,0),2),2) AS InsEst,
FORMAT(ROUND(D.FamBal-COALESCE(D.FamInsEst,0),2),2) AS PatEst,
D.BillingType
FROM (
/*Get the family level charges, credits, and ins estimates*/
SELECT g.PatNum,g.LName,g.FName,SUM(B.PatBal) AS FamBal,SUM(B.Charges0to30) AS FamCharges0to30,SUM(B.Charges31to60) AS FamCharges31to60,
SUM(B.Charges61to90) AS FamCharges61to90,SUM(B.Charges91to120) AS FamCharges91to120,SUM(B.ChargesOver120) AS FamChargesOver120,
SUM(B.Credits) AS FamCredits,SUM(COALESCE(C.InsEst,0)) AS FamInsEst,d.ItemName AS BillingType
FROM (
/*Get Patient level charges and credits*/
SELECT RawPatTrans.PatNum,SUM(RawPatTrans.TranAmount) AS PatBal,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<=@AsOf AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 30 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges0to30,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 30 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 60 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges31to60,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 60 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges61to90,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 90 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 120 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges91to120,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 120 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS ChargesOver120,
-(SUM(CASE WHEN (RawPatTrans.TranAmount<0 AND RawPatTrans.TranDate<=@AsOf) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Credits
FROM (
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum AS PatNum,pl.ProcDate AS TranDate,
pl.ProcFee*(pl.UnitQty+pl.BaseUnits) AS TranAmount,pl.ClinicNum
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum AS PatNum,ps.DatePay AS TranDate,
-ps.SplitAmt AS TranAmount,ps.ClinicNum
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum AS PatNum,a.AdjDate AS TranDate,
a.AdjAmt AS TranAmount,a.ClinicNum
FROM adjustment a
WHERE a.AdjAmt!=0
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum AS PatNum,cp.DateCp AS TranDate,
-cp.InsPayAmt-cp.Writeoff AS TranAmount,cp.ClinicNum
FROM claimproc cp
WHERE cp.Status IN (1,4,5,7)/*received,supplemental,CapClaim, or CapComplete*/
UNION ALL
/*Payment plan principal for the entire office history on or before the given date*/
SELECT 'PayPlan' AS TranType,pp.PatNum AS PatNum,pp.PayPlanDate AS TranDate,
-pp.CompletedAmt AS TranAmount,MAX(ppc.ClinicNum) AS ClinicNum /*MAX gets valid ClinicNum if one exists, otherwise 0*/
FROM payplan pp
INNER JOIN payplancharge ppc ON ppc.PayPlanNum=pp.PayPlanNum
WHERE pp.CompletedAmt!=0
GROUP BY pp.PayPlanNum
) RawPatTrans
WHERE TranDate<=@AsOf
GROUP BY RawPatTrans.PatNum
) B
LEFT JOIN (
/*Get patient level InsPayEst and Writeoffs from unreceived claims.*/
SELECT cp.PatNum,SUM(cp.InsPayEst+cp.Writeoff) AS InsEst
FROM claimproc cp
WHERE cp.PatNum!=0
AND ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR (cp.Status=1 AND cp.DateCP>@AsOf))
AND cp.ProcDate<=@ASOf
GROUP BY cp.PatNum
) C ON C.PatNum=B.PatNum
INNER JOIN patient p ON p.PatNum=B.PatNum
INNER JOIN patient g ON g.PatNum=p.Guarantor
INNER JOIN definition d ON g.BillingType=d.DefNum
WHERE d.ItemName REGEXP @BillingTypes
GROUP BY g.PatNum
) D
WHERE ABS(D.FamBal)>0.005
UNION ALL
SELECT 1 AS ItemOrder,'--------------------------------','---------------','---------------','---------------','---------------','---------------','---------------','---------------','---------------','---------------'
UNION ALL
SELECT 2 AS ItemOrder,'TOTALS:' AS Guarantor,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60 THEN D.FamCharges0to30
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30-D.FamCredits END))
,2),2) AS 0to30,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90 THEN D.FamCharges31to60
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60-D.FamCredits END))
,2),2) AS 31to60,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<=D.FamChargesOver120+D.FamCharges91to120 THEN D.FamCharges61to90
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90-D.FamCredits END))
,2),2) AS 61to90,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<=D.FamChargesOver120 THEN D.FamCharges91to120
WHEN D.FamChargesOver120+D.FamCharges91to120<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120-D.FamCredits END))
,2),2) AS 91to120,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits>=D.FamChargesOver120 THEN 0
ELSE D.FamChargesOver120-D.FamCredits END))
,2),2) AS Over120,
FORMAT(ROUND(SUM(D.FamBal),2),2) AS Total,
FORMAT(ROUND(SUM(COALESCE(D.FamInsEst,0)),2),2) AS InsEst,
FORMAT(ROUND(SUM(D.FamBal-COALESCE(D.FamInsEst,0)),2),2) AS PatEst,
'' AS BillingType
FROM (
/*Get the family level charges, credits, and ins estimates*/
SELECT g.PatNum,g.LName,g.FName,SUM(B.PatBal) AS FamBal,SUM(B.Charges0to30) AS FamCharges0to30,SUM(B.Charges31to60) AS FamCharges31to60,
SUM(B.Charges61to90) AS FamCharges61to90,SUM(B.Charges91to120) AS FamCharges91to120,SUM(B.ChargesOver120) AS FamChargesOver120,
SUM(B.Credits) AS FamCredits,SUM(COALESCE(C.InsEst,0)) AS FamInsEst
FROM (
/*Get Patient level charges and credits*/
SELECT RawPatTrans.PatNum,SUM(RawPatTrans.TranAmount) AS PatBal,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<=@AsOf AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 30 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges0to30,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 30 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 60 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges31to60,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 60 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges61to90,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 90 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 120 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges91to120,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 120 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS ChargesOver120,
-(SUM(CASE WHEN (RawPatTrans.TranAmount<0 AND RawPatTrans.TranDate<=@AsOf) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Credits
FROM (
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum AS PatNum,pl.ProcDate AS TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) AS TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum AS PatNum,ps.DatePay AS TranDate,-ps.SplitAmt AS TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum AS PatNum,a.AdjDate AS TranDate,a.AdjAmt AS TranAmount
FROM adjustment a
WHERE a.AdjAmt!=0
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum AS PatNum,cp.DateCp AS TranDate,-cp.InsPayAmt-cp.Writeoff AS TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4,5,7)/*received,supplemental,CapClaim, or CapComplete*/
UNION ALL
/*Payment plan principal for the entire office history on or before the given date*/
SELECT 'PayPlan' AS TranType,pp.PatNum AS PatNum,pp.PayPlanDate AS TranDate,-pp.CompletedAmt AS TranAmount
FROM payplan pp
WHERE pp.CompletedAmt!=0
) RawPatTrans
WHERE TranDate<=@AsOf
GROUP BY RawPatTrans.PatNum
) B
LEFT JOIN (
/*Get patient level InsPayEst and Writeoffs from unreceived claims.*/
SELECT cp.PatNum,SUM(cp.InsPayEst+cp.Writeoff) AS InsEst
FROM claimproc cp
WHERE cp.PatNum!=0
AND ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR (cp.Status=1 AND cp.DateCP>@AsOf))
AND cp.ProcDate<=@ASOf
GROUP BY cp.PatNum
) C ON C.PatNum=B.PatNum
INNER JOIN patient p ON p.PatNum=B.PatNum
INNER JOIN patient g ON g.PatNum=p.Guarantor
INNER JOIN definition d ON g.BillingType=d.DefNum
WHERE d.ItemName REGEXP @BillingTypes
GROUP BY g.PatNum
) D
WHERE ABS(D.FamBal)>0.005
) E
ORDER BY E.ItemOrder,E.Guarantor;
Aging for families with any balance with last family payment date - A/R for versions 14.2 and before. For versions 14.3 and after, see query 1081.
/*721 Aging for families with any balance with last family payment date. */
SET @AsOf='2013-04-28';
SELECT E.Guarantor AS GUARANTOR,
E.0to30 AS '0-30 DAYS',E.31to60 AS '31-60 DAYS',
E.61to90 AS '61-90 DAYS',E.Over90 AS '>90 DAYS',E.Total AS TOTAL,
E.InsEst AS '-INS EST',E.PatEst AS '=PATIENT',
(CASE WHEN E.FamLastPmt='01/01/0001' THEN 'NoPayments' ELSE E.FamLastPmt END) AS FamLastPmt
FROM (
SELECT 0 AS ItemOrder,CONCAT(D.LName,', ',D.FName) AS Guarantor,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60 THEN D.FamCharges0to30
WHEN D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30<=D.FamCredits THEN 0
ELSE D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30-D.FamCredits END)
,2),2) AS 0to30,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<D.FamChargesOver90+D.FamCharges61to90 THEN D.FamCharges31to60
WHEN D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60<=D.FamCredits THEN 0
ELSE D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60-D.FamCredits END)
,2),2) AS 31to60,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<=D.FamChargesOver90 THEN D.FamCharges61to90
WHEN D.FamChargesOver90+D.FamCharges61to90<=D.FamCredits THEN 0
ELSE D.FamChargesOver90+D.FamCharges61to90-D.FamCredits END)
,2),2) AS 61to90,
FORMAT(ROUND(
(CASE WHEN D.FamCredits>=D.FamChargesOver90 THEN 0
ELSE D.FamChargesOver90-D.FamCredits END)
,2),2) AS Over90,
FORMAT(ROUND(D.FamBal,2),2) AS Total,
FORMAT(ROUND(COALESCE(D.FamInsEst,0),2),2) AS InsEst,
FORMAT(ROUND(D.FamBal-COALESCE(D.FamInsEst,0),2),2) AS PatEst,
DATE_FORMAT(D.FamLastPmt,"%m/%d/%Y") AS FamLastPmt
FROM (
/*Get the family level charges, credits, ins estimates, and date of last payment made on any family member*/
SELECT g.PatNum,g.LName,g.FName,SUM(B.PatBal) AS FamBal,SUM(B.Charges0to30) AS FamCharges0to30,SUM(B.Charges31to60) AS FamCharges31to60,
SUM(B.Charges61to90) AS FamCharges61to90,SUM(B.ChargesOver90) AS FamChargesOver90,SUM(B.Credits) AS FamCredits,
SUM(COALESCE(C.InsEst,0)) AS FamInsEst,MAX(COALESCE(PayDate.PatLastPmt,'0001-01-01')) AS FamLastPmt
FROM (
/*Get Patient level charges and credits*/
SELECT RawPatTrans.PatNum,SUM(RawPatTrans.TranAmount) AS PatBal,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<=@AsOf AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 30 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges0to30,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 30 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 60 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges31to60,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 60 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges61to90,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS ChargesOver90,
-(SUM(CASE WHEN (RawPatTrans.TranAmount<0 AND RawPatTrans.TranDate<=@AsOf) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Credits
FROM (
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum AS PatNum,pl.ProcDate AS TranDate,
pl.ProcFee*(pl.UnitQty+pl.BaseUnits) AS TranAmount,pl.ClinicNum
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum AS PatNum,ps.DatePay AS TranDate,
-ps.SplitAmt AS TranAmount,ps.ClinicNum
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum AS PatNum,a.AdjDate AS TranDate,
a.AdjAmt AS TranAmount,a.ClinicNum
FROM adjustment a
WHERE a.AdjAmt!=0
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum AS PatNum,cp.DateCp AS TranDate,
-cp.InsPayAmt-cp.Writeoff AS TranAmount,cp.ClinicNum
FROM claimproc cp
WHERE cp.Status IN (1,4,5,7)/*received,supplemental,CapClaim, or CapComplete*/
UNION ALL
/*Payment plan principal for the entire office history on or before the given date*/
SELECT 'PayPlan' AS TranType,pp.PatNum AS PatNum,pp.PayPlanDate AS TranDate,
-pp.CompletedAmt AS TranAmount,MAX(ppc.ClinicNum) AS ClinicNum /*MAX gets valid ClinicNum if one exists, otherwise 0*/
FROM payplan pp
INNER JOIN payplancharge ppc ON ppc.PayPlanNum=pp.PayPlanNum
WHERE pp.CompletedAmt!=0
GROUP BY pp.PayPlanNum
) RawPatTrans
WHERE TranDate<=@AsOf
GROUP BY RawPatTrans.PatNum
) B
LEFT JOIN (
/*Get patient level InsPayEst and Writeoffs from unreceived claims.*/
SELECT cp.PatNum,SUM(cp.InsPayEst+cp.Writeoff) AS InsEst
FROM claimproc cp
WHERE cp.PatNum!=0
AND ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR (cp.Status=1 AND cp.DateCP>@AsOf))
AND cp.ProcDate<=@ASOf
GROUP BY cp.PatNum
) C ON C.PatNum=B.PatNum
LEFT JOIN (
/*Get last payment date for each patient*/
SELECT ps.PatNum,MAX(ps.DatePay) AS PatLastPmt
FROM paysplit ps
WHERE ps.DatePay<=@AsOf
GROUP BY ps.PatNum
) PayDate ON PayDate.PatNum=B.PatNum
INNER JOIN patient p ON p.PatNum=B.PatNum
INNER JOIN patient g ON g.PatNum=p.Guarantor
GROUP BY g.PatNum
) D
WHERE ABS(D.FamBal)>0.005
UNION ALL
SELECT 1 AS ItemOrder,'--------------------------------','---------------','---------------','---------------','---------------','---------------','---------------','---------------','---------------'
UNION ALL
SELECT 2 AS ItemOrder,'TOTALS:' AS Guarantor,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60 THEN D.FamCharges0to30
WHEN D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30<=D.FamCredits THEN 0
ELSE D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30-D.FamCredits END))
,2),2) AS 0to30,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<D.FamChargesOver90+D.FamCharges61to90 THEN D.FamCharges31to60
WHEN D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60<=D.FamCredits THEN 0
ELSE D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60-D.FamCredits END))
,2),2) AS 31to60,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<=D.FamChargesOver90 THEN D.FamCharges61to90
WHEN D.FamChargesOver90+D.FamCharges61to90<=D.FamCredits THEN 0
ELSE D.FamChargesOver90+D.FamCharges61to90-D.FamCredits END))
,2),2) AS 61to90,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits>=D.FamChargesOver90 THEN 0
ELSE D.FamChargesOver90-D.FamCredits END))
,2),2) AS Over90,
FORMAT(ROUND(SUM(D.FamBal),2),2) AS Total,
FORMAT(ROUND(SUM(COALESCE(D.FamInsEst,0)),2),2) AS InsEst,
FORMAT(ROUND(SUM(D.FamBal-COALESCE(D.FamInsEst,0)),2),2) AS PatEst,
'' AS FamLastPmt
FROM (
/*Get the family level charges, credits, and ins estimates*/
SELECT g.PatNum,g.LName,g.FName,SUM(B.PatBal) AS FamBal,SUM(B.Charges0to30) AS FamCharges0to30,SUM(B.Charges31to60) AS FamCharges31to60,
SUM(B.Charges61to90) AS FamCharges61to90,SUM(B.ChargesOver90) AS FamChargesOver90,SUM(B.Credits) AS FamCredits,
SUM(COALESCE(C.InsEst,0)) AS FamInsEst
FROM (
/*Get Patient level charges and credits*/
SELECT RawPatTrans.PatNum,SUM(RawPatTrans.TranAmount) AS PatBal,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<=@AsOf AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 30 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges0to30,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 30 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 60 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges31to60,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 60 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges61to90,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS ChargesOver90,
-(SUM(CASE WHEN (RawPatTrans.TranAmount<0 AND RawPatTrans.TranDate<=@AsOf) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Credits
FROM (
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum AS PatNum,pl.ProcDate AS TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) AS TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum AS PatNum,ps.DatePay AS TranDate,-ps.SplitAmt AS TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum AS PatNum,a.AdjDate AS TranDate,a.AdjAmt AS TranAmount
FROM adjustment a
WHERE a.AdjAmt!=0
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum AS PatNum,cp.DateCp AS TranDate,-cp.InsPayAmt-cp.Writeoff AS TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4,5,7)/*received,supplemental,CapClaim, or CapComplete*/
UNION ALL
/*Payment plan principal for the entire office history on or before the given date*/
SELECT 'PayPlan' AS TranType,pp.PatNum AS PatNum,pp.PayPlanDate AS TranDate,-pp.CompletedAmt AS TranAmount
FROM payplan pp
WHERE pp.CompletedAmt!=0
) RawPatTrans
WHERE TranDate<=@AsOf
GROUP BY RawPatTrans.PatNum
) B
LEFT JOIN (
/*Get patient level InsPayEst and Writeoffs from unreceived claims.*/
SELECT cp.PatNum,SUM(cp.InsPayEst+cp.Writeoff) AS InsEst
FROM claimproc cp
WHERE cp.PatNum!=0
AND ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR (cp.Status=1 AND cp.DateCP>@AsOf))
AND cp.ProcDate<=@ASOf
GROUP BY cp.PatNum
) C ON C.PatNum=B.PatNum
INNER JOIN patient p ON p.PatNum=B.PatNum
INNER JOIN patient g ON g.PatNum=p.Guarantor
GROUP BY g.PatNum
) D
WHERE ABS(D.FamBal)>0.005
) E
ORDER BY E.ItemOrder,E.Guarantor;
Special aging for families with any balance that subtracts writeoff estimates from aged balances. Includes 91-120 day column as well as >120 day column. - A/R for versions 14.2 and before. For versions 14.3 and after, see query 1082.
/*722 Special aging for families with any balance that subtracts writeoff estimates from aged balances. Includes 91-120 day column as well as >120 day column. Our internal aging report has a column named '-INS EST' that we subtract from the family balance to give an estimated patient portion. The '-INS EST' column is the amount insurance is expected to pay plus the estimated writeoff amount. This query instead takes the writeoff amount and subtracts it from the aged family balance based on the procedure date. So instead of subtracting it out of the 'TOTAL' column, it is subtracted from each of the aged columns, which are then summed to equal the 'TOTAL' column. The '-INS EST' column is now just the estimated insurance payment amount. If compared to our internal aging report, the '=PATIENT' column should not change. The 'TOTAL' column is the amount an office might actually expect to receive from their outstanding production, provided the estimated writeoffs are correct. This does inclued negative balances.*/
SET @AsOf='2013-07-01';
SELECT E.Guarantor AS GUARANTOR,
E.0to30 AS '0-30 DAYS',E.31to60 AS '31-60 DAYS',
E.61to90 AS '61-90 DAYS',E.91to120 AS '91-120 DAYS',
E.Over120 AS '>120 DAYS',E.Total AS TOTAL,
E.InsEst AS '-INS EST',E.PatEst AS '=PATIENT'
FROM (
SELECT 0 AS ItemOrder,CONCAT(D.LName,', ',D.FName) AS Guarantor,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60 THEN D.FamCharges0to30
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30-D.FamCredits END)
,2),2) AS 0to30,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90 THEN D.FamCharges31to60
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60-D.FamCredits END)
,2),2) AS 31to60,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<=D.FamChargesOver120+D.FamCharges91to120 THEN D.FamCharges61to90
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90-D.FamCredits END)
,2),2) AS 61to90,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<=D.FamChargesOver120 THEN D.FamCharges91to120
WHEN D.FamChargesOver120+D.FamCharges91to120<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120-D.FamCredits END)
,2),2) AS 91to120,
FORMAT(ROUND(
(CASE WHEN D.FamCredits>=D.FamChargesOver120 THEN 0
ELSE D.FamChargesOver120-D.FamCredits END)
,2),2) AS Over120,
FORMAT(ROUND(D.FamBal,2),2) AS Total,
FORMAT(ROUND(COALESCE(D.FamInsEst,0),2),2) AS InsEst,
FORMAT(ROUND(D.FamBal-COALESCE(D.FamInsEst,0),2),2) AS PatEst
FROM (
/*Get the family level charges, credits, and ins estimates*/
SELECT g.PatNum,g.LName,g.FName,SUM(B.PatBal)-SUM(COALESCE(WO.WOEst,0)) AS FamBal,
SUM(B.Charges0to30)-SUM(COALESCE(WO.WOEst0to30,0)) AS FamCharges0to30,
SUM(B.Charges31to60)-SUM(COALESCE(WO.WOEst31to60,0)) AS FamCharges31to60,
SUM(B.Charges61to90)-SUM(COALESCE(WO.WOEst61to90,0)) AS FamCharges61to90,
SUM(B.Charges91to120)-SUM(COALESCE(WO.WOEst91to120,0)) AS FamCharges91to120,
SUM(B.ChargesOver120)-SUM(COALESCE(WO.WOEstOver120,0)) AS FamChargesOver120,
SUM(B.Credits) AS FamCredits,SUM(COALESCE(InsPay.InsPayEst,0)) AS FamInsEst
FROM (
/*Get Patient level charges and credits*/
SELECT RawPatTrans.PatNum,SUM(RawPatTrans.TranAmount) AS PatBal,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<=@AsOf AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 30 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges0to30,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 30 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 60 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges31to60,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 60 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges61to90,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 90 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 120 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges91to120,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 120 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS ChargesOver120,
-(SUM(CASE WHEN (RawPatTrans.TranAmount<0 AND RawPatTrans.TranDate<=@AsOf) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Credits
FROM (
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum AS PatNum,pl.ProcDate AS TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) AS TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum AS PatNum,ps.DatePay AS TranDate,-ps.SplitAmt AS TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum AS PatNum,a.AdjDate AS TranDate,a.AdjAmt AS TranAmount
FROM adjustment a
WHERE a.AdjAmt!=0
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum AS PatNum,cp.DateCp AS TranDate,-cp.InsPayAmt-cp.Writeoff AS TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4,5,7)/*received,supplemental,CapClaim, or CapComplete*/
UNION ALL
/*Payment plan principal for the entire office history on or before the given date*/
SELECT 'PayPlan' AS TranType,pp.PatNum AS PatNum,pp.PayPlanDate AS TranDate,-pp.CompletedAmt AS TranAmount
FROM payplan pp
WHERE pp.CompletedAmt!=0
) RawPatTrans
WHERE TranDate<=@AsOf
GROUP BY RawPatTrans.PatNum
) B
LEFT JOIN (
/*Get patient level InsPayEst from unreceived claims.*/
SELECT cp.PatNum,SUM(cp.InsPayEst) AS InsPayEst
FROM claimproc cp
WHERE cp.PatNum!=0
AND ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR (cp.Status=1 AND cp.DateCP>@AsOf))
AND cp.ProcDate<=@ASOf
GROUP BY cp.PatNum
) InsPay ON InsPay.PatNum=B.PatNum
LEFT JOIN (
/*Get patient level InsPayEst from unreceived claims.*/
SELECT cp.PatNum,SUM(cp.Writeoff) AS WOEst,
SUM(CASE WHEN (cp.ProcDate<=@AsOf AND cp.ProcDate>=(@AsOf-INTERVAL 30 DAY)) THEN cp.Writeoff ELSE 0 END) AS WOEst0to30,
SUM(CASE WHEN (cp.ProcDate<(@AsOf-INTERVAL 30 DAY) AND cp.ProcDate>=(@AsOf-INTERVAL 60 DAY)) THEN cp.Writeoff ELSE 0 END) AS WOEst31to60,
SUM(CASE WHEN (cp.ProcDate<(@AsOf-INTERVAL 60 DAY) AND cp.ProcDate>=(@AsOf-INTERVAL 90 DAY)) THEN cp.Writeoff ELSE 0 END) AS WOEst61to90,
SUM(CASE WHEN (cp.ProcDate<(@AsOf-INTERVAL 90 DAY) AND cp.ProcDate>=(@AsOf-INTERVAL 120 DAY)) THEN cp.Writeoff ELSE 0 END) AS WOEst91to120,
SUM(CASE WHEN cp.ProcDate<(@AsOf-INTERVAL 120 DAY) THEN cp.Writeoff ELSE 0 END) AS WOEstOver120
FROM claimproc cp
WHERE cp.PatNum!=0
AND ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR (cp.Status=1 AND cp.DateCP>@AsOf))
AND cp.ProcDate<=@ASOf
GROUP BY cp.PatNum
) WO ON WO.PatNum=B.PatNum
INNER JOIN patient p ON p.PatNum=B.PatNum
INNER JOIN patient g ON g.PatNum=p.Guarantor
GROUP BY g.PatNum
) D
WHERE ABS(D.FamBal)>0.005
UNION ALL
SELECT 1 AS ItemOrder,'--------------------------------','---------------','---------------','---------------','---------------','---------------','---------------','---------------','---------------'
UNION ALL
SELECT 2 AS ItemOrder,'TOTALS:' AS Guarantor,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60 THEN D.FamCharges0to30
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30-D.FamCredits END))
,2),2) AS 0to30,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90 THEN D.FamCharges31to60
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90+D.FamCharges31to60-D.FamCredits END))
,2),2) AS 31to60,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<=D.FamChargesOver120+D.FamCharges91to120 THEN D.FamCharges61to90
WHEN D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120+D.FamCharges61to90-D.FamCredits END))
,2),2) AS 61to90,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits<=D.FamChargesOver120 THEN D.FamCharges91to120
WHEN D.FamChargesOver120+D.FamCharges91to120<=D.FamCredits THEN 0
ELSE D.FamChargesOver120+D.FamCharges91to120-D.FamCredits END))
,2),2) AS 91to120,
FORMAT(ROUND(SUM(
(CASE WHEN D.FamCredits>=D.FamChargesOver120 THEN 0
ELSE D.FamChargesOver120-D.FamCredits END))
,2),2) AS Over120,
FORMAT(ROUND(SUM(D.FamBal),2),2) AS Total,
FORMAT(ROUND(SUM(COALESCE(D.FamInsEst,0)),2),2) AS InsEst,
FORMAT(ROUND(SUM(D.FamBal-COALESCE(D.FamInsEst,0)),2),2) AS PatEst
FROM (
/*Get the family level charges, credits, and ins estimates*/
SELECT g.PatNum,g.LName,g.FName,SUM(B.PatBal)-SUM(COALESCE(WO.WOEst,0)) AS FamBal,
SUM(B.Charges0to30)-SUM(COALESCE(WO.WOEst0to30,0)) AS FamCharges0to30,
SUM(B.Charges31to60)-SUM(COALESCE(WO.WOEst31to60,0)) AS FamCharges31to60,
SUM(B.Charges61to90)-SUM(COALESCE(WO.WOEst61to90,0)) AS FamCharges61to90,
SUM(B.Charges91to120)-SUM(COALESCE(WO.WOEst91to120,0)) AS FamCharges91to120,
SUM(B.ChargesOver120)-SUM(COALESCE(WO.WOEstOver120,0)) AS FamChargesOver120,
SUM(B.Credits) AS FamCredits,SUM(COALESCE(InsPay.InsPayEst,0)) AS FamInsEst
FROM (
/*Get Patient level charges and credits*/
SELECT RawPatTrans.PatNum,SUM(RawPatTrans.TranAmount) AS PatBal,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<=@AsOf AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 30 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges0to30,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 30 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 60 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges31to60,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 60 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges61to90,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 90 DAY) AND RawPatTrans.TranDate>=(@AsOf-INTERVAL 120 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges91to120,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AsOf-INTERVAL 120 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS ChargesOver120,
-(SUM(CASE WHEN (RawPatTrans.TranAmount<0 AND RawPatTrans.TranDate<=@AsOf) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Credits
FROM (
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum AS PatNum,pl.ProcDate AS TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) AS TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum AS PatNum,ps.DatePay AS TranDate,-ps.SplitAmt AS TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum AS PatNum,a.AdjDate AS TranDate,a.AdjAmt AS TranAmount
FROM adjustment a
WHERE a.AdjAmt!=0
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum AS PatNum,cp.DateCp AS TranDate,-cp.InsPayAmt-cp.Writeoff AS TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4,5,7)/*received,supplemental,CapClaim, or CapComplete*/
UNION ALL
/*Payment plan principal for the entire office history on or before the given date*/
SELECT 'PayPlan' AS TranType,pp.PatNum AS PatNum,pp.PayPlanDate AS TranDate,-pp.CompletedAmt AS TranAmount
FROM payplan pp
WHERE pp.CompletedAmt!=0
) RawPatTrans
WHERE TranDate<=@AsOf
GROUP BY RawPatTrans.PatNum
) B
LEFT JOIN (
/*Get patient level InsPayEst from unreceived claims.*/
SELECT cp.PatNum,SUM(cp.InsPayEst) AS InsPayEst
FROM claimproc cp
WHERE cp.PatNum!=0
AND ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR (cp.Status=1 AND cp.DateCP>@AsOf))
AND cp.ProcDate<=@ASOf
GROUP BY cp.PatNum
) InsPay ON InsPay.PatNum=B.PatNum
LEFT JOIN (
/*Get patient level InsPayEst from unreceived claims.*/
SELECT cp.PatNum,SUM(cp.Writeoff) AS WOEst,
SUM(CASE WHEN (cp.ProcDate<=@AsOf AND cp.ProcDate>=(@AsOf-INTERVAL 30 DAY)) THEN cp.Writeoff ELSE 0 END) AS WOEst0to30,
SUM(CASE WHEN (cp.ProcDate<(@AsOf-INTERVAL 30 DAY) AND cp.ProcDate>=(@AsOf-INTERVAL 60 DAY)) THEN cp.Writeoff ELSE 0 END) AS WOEst31to60,
SUM(CASE WHEN (cp.ProcDate<(@AsOf-INTERVAL 60 DAY) AND cp.ProcDate>=(@AsOf-INTERVAL 90 DAY)) THEN cp.Writeoff ELSE 0 END) AS WOEst61to90,
SUM(CASE WHEN (cp.ProcDate<(@AsOf-INTERVAL 90 DAY) AND cp.ProcDate>=(@AsOf-INTERVAL 120 DAY)) THEN cp.Writeoff ELSE 0 END) AS WOEst91to120,
SUM(CASE WHEN cp.ProcDate<(@AsOf-INTERVAL 120 DAY) THEN cp.Writeoff ELSE 0 END) AS WOEstOver120
FROM claimproc cp
WHERE cp.PatNum!=0
AND ((cp.Status=0 AND cp.ProcDate<=@AsOf) OR (cp.Status=1 AND cp.DateCP>@AsOf))
AND cp.ProcDate<=@ASOf
GROUP BY cp.PatNum
) WO ON WO.PatNum=B.PatNum
INNER JOIN patient p ON p.PatNum=B.PatNum
INNER JOIN patient g ON g.PatNum=p.Guarantor
GROUP BY g.PatNum
) D
WHERE ABS(D.FamBal)>0.005
) E
ORDER BY E.ItemOrder,E.Guarantor;
Money made fee schedules for a time period -
/*723 Show how much money is being made from each fee schedule for a time period.*/
SET @FromDate='2012-07-01',@ToDate='2012-07-31';
SELECT A.FeeSchedule,A.$Production_,A.$Adjustment_,A.$Writeoff_,(A.$Production_+A.$Adjustment_-A.$Writeoff_) AS $NetProd_,A.$InsPay_,A.$PatPay_,A.$TotPay_
FROM
(
SELECT (CASE WHEN (fs1.Description IS NULL AND fs2.Description IS NULL) THEN fs3.Description
WHEN (fs1.Description IS NULL AND fs2.Description IS NOT NULL) THEN fs2.Description
WHEN (fs1.Description IS NOT NULL) THEN fs1.Description ELSE NULL END) AS FeeSchedule,
SUM(CASE WHEN (RawTable.TranType='Fee') THEN RawTable.TranAmount ELSE 0 END) AS $Production_,
SUM(CASE WHEN (RawTable.TranType='Adj') THEN RawTable.TranAmount ELSE 0 END) AS $Adjustment_,
SUM(CASE WHEN (RawTable.TranType='Writeoff') THEN RawTable.TranAmount ELSE 0 END) AS $Writeoff_,
SUM(CASE WHEN (RawTable.TranType='InsPay') THEN RawTable.TranAmount ELSE 0 END) AS $InsPay_,
SUM(CASE WHEN (RawTable.TranType='Pay') THEN RawTable.TranAmount ELSE 0 END) AS $PatPay_,
SUM(CASE WHEN (RawTable.TranType='Pay' OR RawTable.TranType='InsPay') THEN RawTable.TranAmount ELSE 0 END) AS $TotPay_
FROM
(
/*Get the completed procedure dates and charges for the entire office history on or before the given date*/
SELECT 'Fee' AS TranType,pl.PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2
/*Paysplits for the entire office history on or before the given date*/
UNION ALL
SELECT 'Pay' AS TranType,ps.PatNum,ps.ProcDate TranDate,ps.SplitAmt TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
/*Get the adjustment dates and amounts for the entire office history on or before the given date*/
UNION ALL
SELECT 'Adj' AS TranType, a.PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount
FROM adjustment a
/*Claim payments for the entire office history on or before the given date*/
UNION ALL
SELECT 'InsPay' AS TranType,cp.PatNum,cp.DateCp TranDate,cp.InsPayAmt TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4)/*received, supplemental*/
/*Claim writeoffs for the entire office history on or before the given date*/
UNION ALL
SELECT 'Writeoff' AS TranType,cp.PatNum,cp.DateCp TranDate,cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4)/*received, supplemental*/
) RawTable
INNER JOIN patient p ON p.PatNum=RawTable.PatNum
INNER JOIN provider pv ON p.PriProv=pv.ProvNum
INNER JOIN feesched fs3 ON fs3.FeeSchedNum=pv.FeeSched
LEFT JOIN feesched fs2 ON fs2.FeeSchedNum=p.FeeSched
LEFT JOIN patplan pp ON pp.PatNum=p.PatNum AND pp.Ordinal=1
LEFT JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=ib.PlanNum
LEFT JOIN feesched fs1 ON ip.FeeSched=fs1.FeeSchedNum
WHERE RawTable.TranDate BETWEEN @FromDate AND @ToDate
GROUP BY FeeSchedule) A
ORDER BY FeeSchedule;
Patients whose first proc of codes D0150 or D0140 was completed in the date range, but who do not currently have a scheduled appointment - With total production, total income, ins used, ins remaining, amount of work tp'd, and procs tp'd
/*724 Patients whose first proc of codes D0150 or D0140 was completed in the date range,
but who do not currently have a scheduled appointment. With total production,total income,
insurance amount used and remaining, amount of work tp'd and procs tp'd*/
SET @StartDate='2013-01-01',@EndDate='2013-06-01';/*<--Set date range here*/
SELECT B.*,COALESCE(FORMAT(C.AnnualMax,2),'NoIns') AS AnnualMax,COALESCE(FORMAT(C.AmountUsed,2),'NoIns') AS AmountUsed,
COALESCE(FORMAT(C.AmtRemaining,2),'NoIns') AS AmountRemaining,COALESCE(FORMAT(C.TreatPlanned,2),'NoPlan') AS AmountTPd,
COALESCE(C.TPdProcs,'NoTPdProcs') AS ProcsTPd
FROM patient p
INNER JOIN (
SELECT p.PatNum,d.ItemName AS BillingType,A.FirstProcDate AS DateFirstProc,Procs.Amount AS $TotProd_,
COALESCE(PatPay.Amount,0)+COALESCE(InsPay.Amount,0) AS $TotPmts_
FROM patient p
INNER JOIN definition d ON d.DefNum=p.BillingType
INNER JOIN (
/*Get pats and date of first proc of codes D0150 or D0140*/
SELECT p.PatNum,MIN(pl.ProcDate) AS FirstProcDate
FROM patient p
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
AND pl.ProcStatus=2
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
AND pc.ProcCode IN('D0150','D0140')/*<--Add more codes here if necessary*/
GROUP BY p.PatNum
) A ON A.PatNum=p.PatNum
INNER JOIN (
SELECT pl.PatNum,SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits)) AS Amount
FROM procedurelog pl
WHERE pl.ProcStatus=2
GROUP BY pl.PatNum
) Procs ON Procs.PatNum=A.PatNum
LEFT JOIN (
SELECT ps.PatNum,SUM(ps.SplitAmt) AS Amount
FROM paysplit ps
GROUP BY ps.PatNum
) PatPay ON PatPay.PatNum=p.PatNum
LEFT JOIN (
SELECT cp.PatNum,SUM(cp.InsPayAmt) AS Amount
FROM claimproc cp
WHERE cp.Status IN(1,4)/*Received,Supplemental*/
GROUP BY cp.PatNum
) InsPay ON InsPay.PatNum=p.PatNum
WHERE A.FirstProcDate BETWEEN @StartDate AND @EndDate
) B ON B.PatNum=p.PatNum
LEFT JOIN (
SELECT patient.PatNum,
SUM(COALESCE(tempannualmax.AnnualMax,0)) AS AnnualMax,
SUM(COALESCE(tempused.AmtUsed,0)) AS AmountUsed,
(CASE WHEN ISNULL(SUM(tempused.AmtUsed)) THEN (SUM(COALESCE(tempannualmax.AnnualMax,0))) ELSE (SUM(COALESCE(tempannualmax.AnnualMax,0))-SUM(COALESCE(tempused.AmtUsed,0))) END)
AS AmtRemaining,
tempplanned.AmtPlanned AS TreatPlanned,tempplanned.TPdProcs
FROM patient
LEFT JOIN patplan ON patient.PatNum=patplan.PatNum
LEFT JOIN inssub ON inssub.InsSubNum=patplan.InsSubNum
LEFT JOIN (
SELECT benefit.PlanNum, benefit.MonetaryAmt AS AnnualMax
FROM benefit
LEFT JOIN covcat ON covcat.CovCatNum = benefit.CovCatNum
WHERE benefit.BenefitType = 5 /* limitation */
AND benefit.TimePeriod = 2 /* calendar year */
AND (covcat.EbenefitCat=1 OR ISNULL(covcat.EbenefitCat))
AND benefit.MonetaryAmt <> 0
) tempannualmax ON tempannualmax.PlanNum=inssub.PlanNum
LEFT JOIN (
SELECT patient.PatNum, SUM(pl.ProcFee) AS AmtPlanned,
GROUP_CONCAT(pc.ProcCode) AS TPdProcs
FROM procedurelog pl
INNER JOIN procedurecode pc ON pc.CodeNum=pl.CodeNum
LEFT JOIN patient ON patient.PatNum=pl.PatNum
LEFT JOIN appointment a ON a.PatNum=patient.PatNum AND a.AptStatus=1/*sched*/
WHERE pl.ProcStatus = 1 /*treatment planned*/
AND ISNULL(a.AptNum)
GROUP BY patient.PatNum
) tempplanned ON tempplanned.PatNum=patient.PatNum
LEFT JOIN (
SELECT patplan.PatPlanNum,
SUM(IFNULL(claimproc.InsPayAmt,0)) AS AmtUsed
FROM claimproc
LEFT JOIN inssub ON claimproc.PlanNum=inssub.PlanNum
LEFT JOIN patplan ON patplan.PatNum = claimproc.PatNum
AND patplan.InsSubNum=inssub.InsSubNum
WHERE claimproc.Status IN (1,3,4)
AND claimproc.ProcDate BETWEEN makedate(year(curdate()), 1)
AND makedate(year(curdate())+1, 1) /*current calendar year*/
GROUP BY patplan.PatPlanNum
) tempused ON tempused.PatPlanNum=patplan.PatPlanNum
WHERE (CASE WHEN ISNULL(tempused.AmtUsed) THEN (COALESCE(tempannualmax.AnnualMax,0)) ELSE (COALESCE(tempannualmax.AnnualMax,0)-COALESCE(tempused.AmtUsed,0)) END)>.01
AND PatStatus=0
GROUP BY patient.PatNum
) C ON C.PatNum=B.PatNum
WHERE NOT EXISTS(SELECT * FROM appointment a WHERE a.PatNum=p.PatNum AND a.AptStatus=1)
ORDER BY p.LName,p.FName;
Patients with age, address, phone numbers, and last visit date, whose last completed procedure is not in the date range. - Whose age is also between the age range.
/*725 Patients with age, address, phone numbers, and last visit date, whose last completed procedure is not in the date range.
Whose age is also between the age range.*/
SET @FromDate='2012-01-01',@ToDate='2012-06-01';/*<-----Set date range here----*/
SET @FromAge=12,@ToAge=30;/*<-----Set age range here---*/
SELECT p.LName AS LastName,p.FName AS FirstName,
(CASE WHEN (YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5))<120
THEN (YEAR(CURDATE())-YEAR(Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(Birthdate,5)) ELSE 'NONE' END) AS Age,
p.Address,p.Address2,p.HmPhone AS HomePhone,p.WirelessPhone,DATE_FORMAT(Last.LastSeen,"%m/%d/%Y") AS LastVisit
FROM patient p
LEFT JOIN
(/*Get max appointment date for all patients*/
SELECT pl.PatNum,MAX(pl.ProcDate) AS LastSeen
FROM procedurelog pl
WHERE pl.ProcStatus=2 /*Completed*/
GROUP BY pl.PatNum
) Last ON Last.PatNum=p.PatNum
WHERE Last.LastSeen NOT BETWEEN @FromDate AND @ToDate
HAVING Age BETWEEN @FromAge AND @ToAge
ORDER BY p.LName,p.FName;
Patients without any procs completed in date range and date of last completed proc -
/*726 Patients without any procs completed in date range and date of last completed proc*/
SET @pos=0,@FromDate='2012-01-01',@ToDate='2012-12-31';
SELECT p.LName,p.FName,p.Address,p.Address2,p.City,p.State,p.Zip,p.HmPhone,p.WkPhone,p.WirelessPhone,DATE(A.LastVisit) AS DateLastVisit
FROM
(
SELECT p.PatNum,MAX(ProcDate) AS LastVisit
FROM patient p
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum
WHERE pl.ProcStatus=2
GROUP BY pl.PatNum
) A
INNER JOIN patient p ON p.PatNum=A.PatNum
WHERE A.PatNum NOT IN(SELECT pl.PatNum FROM procedurelog pl WHERE pl.ProcStatus=2 AND pl.ProcDate BETWEEN @FromDate AND @ToDate)
ORDER BY LName,FName;
For patients seen today, balance before today's procedures, amounts from today's procedures, and ending balance with insurance pay estimates, writeoff estimates, and patient payment estimates for today's procedures. -
/*727 For patients seen today, balance before today's procedures, amounts from today's procedures, and ending balance with insurance pay estimates, writeoff estimates, and patient payment estimates for today's procedures.*/
/*Query code written/modified: 02/16/2016*/
SELECT CURDATE() AS DATE,CONCAT(p.LName,', ',p.FName) AS PatientName,
SUM(CASE WHEN TranDate<CURDATE() THEN TranAmount ELSE 0 END) AS $PreviousBal_,
SUM(CASE WHEN (TranDate=CURDATE() AND TranType='Fee') THEN TranAmount ELSE 0 END) AS $TotalFee_,
-SUM(CASE WHEN TranType='InsPayEst' THEN TranAmount ELSE 0 END) AS $InsPayEst_,
-SUM(CASE WHEN TranType='WriteOffEst' THEN TranAmount ELSE 0 END) AS $WriteOffEst_,
SUM(CASE WHEN (TranDate=CURDATE() AND (TranType='Fee' OR TranType='InsPayEst' OR TranType='WriteOffEst')) THEN TranAmount ELSE 0 END) AS $PatPayEst_,
SUM(CASE WHEN (TranDate=CURDATE() AND TranType='Adj') THEN TranAmount ELSE 0 END) AS $Adjustment_,
-SUM(CASE WHEN (TranDate=CURDATE() AND TranType='Pay') THEN TranAmount ELSE 0 END) AS $PatPayment_,
-SUM(CASE WHEN (TranDate=CURDATE() AND TranType='InsPay') THEN TranAmount ELSE 0 END) AS $InsPayment_,
SUM(CASE WHEN (TranType!='InsPayEst' AND TranType!='WriteOffEst') THEN TranAmount ELSE 0 END) AS $Balance_,
c.Note AS Notes
FROM patient p
INNER JOIN (
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType, pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum PatNum,ps.ProcDate TranDate,-ps.SplitAmt TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType, a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount
FROM adjustment a
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum PatNum,cp.DateCP TranDate,-cp.InsPayAmt TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4)/*received, supplemental*/
UNION ALL
/*Claim writeoffs for the entire office history*/
SELECT 'Writeoff' AS TranType,cp.PatNum PatNum,cp.DateCP TranDate,-cp.Writeoff TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4)/*received, supplemental*/
UNION ALL
/*Payment plan principal for the entire office history on or before the given date*/
SELECT 'PayPlan' AS TranType,pp.PatNum PatNum,pp.PayPlanDate TranDate,-pp.CompletedAmt TranAmount
FROM payplan pp
UNION ALL
/*InsEstTotal from the claimprocs for today's procedures*/
SELECT 'InsPayEst' AS TranType,cp.PatNum PatNum,cp.ProcDate TranDate,-cp.InsEstTotal TranAmount
FROM claimproc cp
WHERE cp.ProcDate=CURDATE()
AND cp.Status IN (0,6)/*Not Received,Estimate*/
UNION ALL
/*WriteOffEst for today's procedures from claimprocs*/
SELECT 'WriteOffEst' AS TranType,cp.PatNum PatNum,cp.ProcDate TranDate,-cp.WriteOffEst TranAmount
FROM claimproc cp
WHERE cp.ProcDate=CURDATE()
AND cp.Status IN (0,6)/*Not Received,Estimate*/
) RawPatTrans ON p.PatNum=RawPatTrans.PatNum
LEFT JOIN (
SELECT cl.PatNum,GROUP_CONCAT(cl.Note SEPARATOR ' | ') AS Note
FROM commlog cl
WHERE DATE(cl.CommDateTime)=CURDATE()
GROUP BY cl.PatNum
) c ON c.PatNum=RawPatTrans.PatNum
WHERE RawPatTrans.PatNum IN (SELECT PatNum FROM procedurelog pl WHERE pl.ProcDate=CURDATE() AND pl.ProcStatus=2)
GROUP BY RawPatTrans.PatNum;
Payment Plan report for patients with specific billing type, with Principal,Paid,DueNow,Due in 10 days, and Balance with totals -
/*728 FOR VERSION 16.1 and earlier, for version 16.2 and later use #1212. Payment Plan report for patients with specific billing type, with Principal,Paid,DueNow,Due in 10 days, and Balance with totals and count of payment plans*/
SET @BillingType='Standard Account'/*@BillingType='Coupon Book'*/;
SELECT B.Guarantor,B.BillingType,B.Ins,B.Principal,B.Paid,B.DueNow AS 'Due Now',B.DueTen AS 'Due in 10 Days',B.Bal
FROM
(
(
SELECT 1 AS ItemOrder,CONCAT(A.LName,', ',(CASE WHEN A.Preferred!='' THEN CONCAT('\'',A.Preferred,'\' ') ELSE '' END),A.FName,' ',A.MiddleI) AS Guarantor,
A.BillingType,
(CASE WHEN A.PlanNum=0 THEN '' ELSE 'X' END) AS Ins,
FORMAT(A.principal,2) AS Principal,
FORMAT(CASE WHEN a.plannum=0 THEN A.paid ELSE A.Inspay END,2) AS Paid,
FORMAT(CASE WHEN a.plannum=0 THEN A.accumDue-A.paid ELSE A.accumDue-A.Inspay END,2) AS DueNow,
FORMAT(CASE WHEN a.plannum=0 THEN A.dueTen-A.Paid ELSE A.dueTen-A.Inspay END,2) AS DueTen,
FORMAT(CASE WHEN a.plannum=0 THEN A.principal-A.paid ELSE A.principal-A.Inspay END,2) Bal
FROM(
SELECT FName,LName,MiddleI,PlanNum,Preferred,d.ItemName BillingType,
COALESCE(
(
SELECT SUM(Principal+Interest)
FROM payplancharge
WHERE payplancharge.PayPlanNum=payplan.PayPlanNum
AND ChargeDate<=CURDATE()
),0) accumDue,
COALESCE(
(
SELECT SUM(Principal+Interest)
FROM payplancharge
WHERE payplancharge.PayPlanNum=payplan.PayPlanNum
AND ChargeDate<=CURDATE() + INTERVAL (SELECT ValueString FROM preference WHERE PrefName='PayPlansBillInAdvanceDays') DAY
),0) dueTen,
COALESCE(
(
SELECT SUM(SplitAmt)
FROM paysplit
WHERE paysplit.PayPlanNum=payplan.PayPlanNum
),0) paid,
COALESCE(
(
SELECT SUM(Principal)
FROM payplancharge
WHERE payplancharge.PayPlanNum=payplan.PayPlanNum
),0) principal,
COALESCE(
(SELECT SUM(InsPayAmt)
FROM claimproc
WHERE claimproc.PayPlanNum=payplan.PayPlanNum
),0) inspay
FROM payplan
LEFT JOIN patient ON patient.PatNum=payplan.Guarantor
INNER JOIN definition d ON d.DefNum=patient.BillingType
GROUP BY payplan.PayPlanNum
) A
WHERE A.BillingType=@BillingType
)
UNION ALL
(SELECT 2 AS ItemOrder,'','----------------','----','-------------','-------------','-------------','-------------','-------------')
UNION ALL
(
SELECT 3 AS ItemOrder,'' AS Guarantor,'Totals:' AS BillingType,
(CASE WHEN A.PlanNum=0 THEN '' ELSE 'X' END) AS Ins,
FORMAT(SUM(A.principal),2) AS Principal,
FORMAT(SUM(CASE WHEN a.plannum=0 THEN A.paid ELSE A.Inspay END),2) AS Paid,
FORMAT(SUM(A.accumDue-A.paid-A.Inspay),2) AS DueNow,
FORMAT(SUM(A.dueTen-A.Paid-A.Inspay),2) AS DueTen,
FORMAT(SUM(A.principal)-SUM(A.Inspay)-SUM(A.paid),2) AS Bal
FROM(
SELECT payplan.PayPlanNum,PlanNum,d.ItemName BillingType,
(
SELECT SUM(Principal+Interest)
FROM payplancharge
WHERE payplancharge.PayPlanNum=payplan.PayPlanNum
AND ChargeDate<=CURDATE()
) accumDue,
(
SELECT SUM(Principal+Interest)
FROM payplancharge
WHERE payplancharge.PayPlanNum=payplan.PayPlanNum
AND ChargeDate<=CURDATE() + INTERVAL (SELECT ValueString FROM preference WHERE PrefName='PayPlansBillInAdvanceDays') DAY
) dueTen,
(
SELECT SUM(SplitAmt)
FROM paysplit
WHERE paysplit.PayPlanNum=payplan.PayPlanNum
) paid,
(
SELECT SUM(Principal)
FROM payplancharge
WHERE payplancharge.PayPlanNum=payplan.PayPlanNum
) principal,
COALESCE((SELECT SUM(InsPayAmt)
FROM claimproc
WHERE claimproc.PayPlanNum=payplan.PayPlanNum
),0) inspay
FROM payplan
LEFT JOIN patient ON patient.PatNum=payplan.Guarantor
INNER JOIN definition d ON d.DefNum=patient.BillingType
GROUP BY payplan.PayPlanNum
) A
WHERE A.BillingType=@BillingType
)
ORDER BY ItemOrder,Guarantor
) B;
Total of family completed procedures in date range and current aging amounts with referral source and city of residence. Date range based on completed procedure date. - Ordered by guarantor last name then first name.
/*730 Total of family completed procedures in date range and current aging amounts with referral source and city of residence. Date range based on completed procedure date.*/
SET @FromDate='2012-01-01', @ToDate='2012-06-30'; /*<-----Change Date Range Here----*/
SELECT g.PatNum, (CASE WHEN (YEAR(CURDATE())-YEAR(g.Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(g.Birthdate,5))<120 THEN (YEAR(CURDATE())-YEAR(g.Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(g.Birthdate,5)) ELSE 'NONE' END) AS Age, SUM(pl.ProcFee) AS $CompletedProcs, g.Bal_0_30, g.Bal_31_60, g.Bal_61_90, g.BalOver90, g.City, CONCAT(r.LName, ", ", r.FName) AS ReferralSource
FROM patient p
INNER JOIN patient g ON p.Guarantor=g.PatNum
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum AND pl.ProcDate BETWEEN @FromDate AND @ToDate AND pl.ProcStatus=2
LEFT JOIN refattach ra ON ra.PatNum=g.PatNum
LEFT JOIN referral r ON r.ReferralNum=ra.ReferralNum
GROUP BY g.PatNum
ORDER BY g.LName, g.FName;
Total of family completed procedures in date range and current aging amounts with referral source and city of residence. Date range based on completed procedure date. - Exactly like query 730 but ordered by $CompletedProcs
/*731 Total of family completed procedures in date range and current aging amounts with referral source and city of residence. Date range based on completed procedure date.*/
SET @FromDate='2012-01-01', @ToDate='2012-06-30'; /*<-----Change Date Range Here----*/
SELECT A.* FROM
(
SELECT g.PatNum, (CASE WHEN (YEAR(CURDATE())-YEAR(g.Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(g.Birthdate,5))<120 THEN (YEAR(CURDATE())-YEAR(g.Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(g.Birthdate,5)) ELSE 'NONE' END) AS Age, SUM(pl.ProcFee) AS $CompletedProcs, g.Bal_0_30, g.Bal_31_60, g.Bal_61_90, g.BalOver90, g.City, CONCAT(r.LName, ", ", r.FName) AS ReferralSource
FROM patient p
INNER JOIN patient g ON p.Guarantor=g.PatNum
INNER JOIN procedurelog pl ON pl.PatNum=p.PatNum AND pl.ProcDate BETWEEN @FromDate AND @ToDate AND pl.ProcStatus=2
LEFT JOIN refattach ra ON ra.PatNum=g.PatNum
LEFT JOIN referral r ON r.ReferralNum=ra.ReferralNum
GROUP BY g.PatNum
) A
ORDER BY A.$CompletedProcs;
Number of patients referred from a user specified source - For Versions 17.1 and greater. Please update your version accordingly. Date range based on referral date.
/*732 Number of patients referred from a user specified source*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 06/23/2018*/
SET @FromDate='2018-01-01',@ToDate='2018-12-31'; /*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @RefLName='%%',@RefFName='%%'; /*Change referral source here or leave %% for all*/
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT CONCAT(r.LName, ',', r.FName) AS RefName,
COUNT(distinct ra.PatNum) AS NumReferred
FROM referral r
LEFT JOIN refattach ra
ON r.ReferralNum=ra.ReferralNum
AND ra.RefDate BETWEEN @FromDate AND @ToDate
AND ra.RefType = 1 /*RefFrom*/
WHERE (r.LName LIKE @RefLName AND r.FName LIKE @RefFName)
GROUP BY r.ReferralNum;
Number of patients referred from all other referral sources other than specified. - For Versions 17.1 and greater. Please update your version accordingly. (The negative of #732). Date range based on referral date.
/*733 Number of patients referred from all other referral sources other than specified*/
/*For Versions 17.1 and greater. Please update your version accordingly.*/
/*Query code written/modified: 08/08/2018*/
/*Change dates between the ' ' in format 'YYYY-mm-dd'*/
SET @FromDate='2018-01-01' , @ToDate='2018-01-31';
SET @RefLName='%%',@RefFName='%john%'; /*Change referral source here or leave %% for all*/
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT CONCAT(r.LName, ',', r.FName) AS RefName,
COUNT(*) AS NumReferred
FROM referral r
LEFT JOIN refattach ra
ON r.ReferralNum=ra.ReferralNum
AND ra.RefDate BETWEEN @FromDate AND @ToDate
AND ra.RefType = 1 /*RefFrom*/
WHERE NOT (r.LName LIKE @RefLName AND r.FName LIKE @RefFName)
GROUP BY r.ReferralNum;
For day set and provider selected, the production, adjustments, and writeoffs. - With totals and a patient count, where patient is counted if there is some production on that day.
/*734 For day set and provider selected, the production, adjustments, and writeoffs.
With totals and a patient count, where patient is counted if there is some production on that day.*/
SET @ReportDate='2013-01-15',@ProvAbbr='15';/*<-----Set Date and Provider Abbreviation Here--*/
SELECT A.Patient,A.Production,A.Adjust,A.Writeoff
FROM
(
SELECT 0 AS ItemOrder,CONCAT('Report Date: ',DATE_FORMAT(@ReportDate, '%m/%d/%Y'),' .') AS Patient,CONCAT('Provider: ',@ProvAbbr,' .') AS Production,
LPAD('.',15,' ') AS Adjust,'' AS Writeoff
UNION ALL
SELECT 1 AS ItemOrder,'--------------','--------','--------','--------'
UNION ALL
SELECT 2 AS ItemOrder,CONCAT(p.LName,', ',p.FName,p.MiddleI) AS Patient,
FORMAT(SUM(CASE WHEN RawPatTrans.TranType='Fee' THEN RawPatTrans.TranAmount ELSE 0 END),2) AS Production,
FORMAT(SUM(CASE WHEN RawPatTrans.TranType='Adj' THEN RawPatTrans.TranAmount ELSE 0 END),2) AS Adjust,
FORMAT(-SUM(CASE WHEN RawPatTrans.TranType='Writeoff' THEN RawPatTrans.TranAmount ELSE 0 END),2) AS Writeoff
FROM (
/*transaction table*/
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum AS PatNum,pl.ProcDate TranDate,
pl.ProcFee*(pl.UnitQty+pl.BaseUnits)-IFNULL(SUM(cp.Writeoff),0) TranAmount,
pl.ProvNum ProvNum
FROM procedurelog pl
LEFT JOIN claimproc cp ON pl.ProcNum=cp.ProcNum AND cp.Status=7 /*CapComplete writeoffs subtracted*/
WHERE pl.ProcStatus=2
GROUP BY pl.ProcNum
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum AS PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount,a.ProvNum ProvNum
FROM adjustment a
UNION ALL
/*Claim writeoffs for the entire office history*/
SELECT 'Writeoff' AS TranType,cp.PatNum AS PatNum,cp.DateCp TranDate,cp.Writeoff TranAmount,cp.ProvNum ProvNum
FROM claimproc cp
WHERE cp.Status IN (1,4)/*received, supplemental*/
) RawPatTrans
INNER JOIN provider pv ON pv.ProvNum=RawPatTrans.ProvNum
INNER JOIN patient p ON p.PatNum=RawPatTrans.PatNum
WHERE RawPatTrans.TranDate=@ReportDate
AND pv.Abbr=@ProvAbbr
GROUP BY RawPatTrans.PatNum
UNION ALL
SELECT 3 AS ItemOrder,'--------------','--------','--------','--------'
UNION ALL
SELECT 4 AS ItemOrder,CONCAT('PatientCount: ',SUM(CASE WHEN ABS(Totals.Production)>0 THEN 1 ELSE 0 END)) AS Patient,
FORMAT(SUM(Totals.Production),2) AS Production,FORMAT(SUM(Totals.Adjust),2) AS Adjust,
FORMAT(SUM(Totals.Writeoff),2) AS Writeoff
FROM (
SELECT RawPatTrans.PatNum,
SUM(CASE WHEN RawPatTrans.TranType='Fee' THEN RawPatTrans.TranAmount ELSE 0 END) AS Production,
SUM(CASE WHEN RawPatTrans.TranType='Adj' THEN RawPatTrans.TranAmount ELSE 0 END) AS Adjust,
-SUM(CASE WHEN RawPatTrans.TranType='Writeoff' THEN RawPatTrans.TranAmount ELSE 0 END) AS Writeoff
FROM (
/*transaction table*/
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum AS PatNum,pl.ProcDate TranDate,
pl.ProcFee*(pl.UnitQty+pl.BaseUnits)-IFNULL(SUM(cp.Writeoff),0) TranAmount,
pl.ProvNum ProvNum
FROM procedurelog pl
LEFT JOIN claimproc cp ON pl.ProcNum=cp.ProcNum AND cp.Status=7 /*CapComplete writeoffs subtracted*/
WHERE pl.ProcStatus=2
GROUP BY pl.ProcNum
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum AS PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount,a.ProvNum ProvNum
FROM adjustment a
UNION ALL
/*Claim writeoffs for the entire office history*/
SELECT 'Writeoff' AS TranType,cp.PatNum AS PatNum,cp.DateCp TranDate,cp.Writeoff TranAmount,cp.ProvNum ProvNum
FROM claimproc cp
WHERE cp.Status IN (1,4)/*received, supplemental*/
) RawPatTrans
INNER JOIN provider pv ON pv.ProvNum=RawPatTrans.ProvNum
WHERE RawPatTrans.TranDate=@ReportDate
AND pv.Abbr=@ProvAbbr
GROUP BY RawPatTrans.PatNum
) Totals
UNION ALL
SELECT 5 AS ItemOrder,'--------------','--------','--------','--------'
UNION ALL
SELECT 6 AS ItemOrder,'Net Production' AS Patient,
FORMAT(SUM(NetTotals.Production)+SUM(NetTotals.Adjust)+SUM(NetTotals.Writeoff),2) AS Production,'',''
FROM (
SELECT RawPatTrans.PatNum,
SUM(CASE WHEN RawPatTrans.TranType='Fee' THEN RawPatTrans.TranAmount ELSE 0 END) AS Production,
SUM(CASE WHEN RawPatTrans.TranType='Adj' THEN RawPatTrans.TranAmount ELSE 0 END) AS Adjust,
-SUM(CASE WHEN RawPatTrans.TranType='Writeoff' THEN RawPatTrans.TranAmount ELSE 0 END) AS Writeoff
FROM (
/*transaction table*/
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum AS PatNum,pl.ProcDate TranDate,
pl.ProcFee*(pl.UnitQty+pl.BaseUnits)-IFNULL(SUM(cp.Writeoff),0) TranAmount,
pl.ProvNum ProvNum
FROM procedurelog pl
LEFT JOIN claimproc cp ON pl.ProcNum=cp.ProcNum AND cp.Status=7 /*CapComplete writeoffs subtracted*/
WHERE pl.ProcStatus=2
GROUP BY pl.ProcNum
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum AS PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount,a.ProvNum ProvNum
FROM adjustment a
UNION ALL
/*Claim writeoffs for the entire office history*/
SELECT 'Writeoff' AS TranType,cp.PatNum AS PatNum,cp.DateCp TranDate,cp.Writeoff TranAmount,cp.ProvNum ProvNum
FROM claimproc cp
WHERE cp.Status IN (1,4)/*received, supplemental*/
) RawPatTrans
INNER JOIN provider pv ON pv.ProvNum=RawPatTrans.ProvNum
WHERE RawPatTrans.TranDate=@ReportDate
AND pv.Abbr=@ProvAbbr
GROUP BY RawPatTrans.PatNum
) NetTotals
) A
WHERE ((A.ItemOrder=2 AND ABS(A.Production)>0.005) OR A.ItemOrder!=2)
ORDER BY A.ItemOrder,A.Patient;
List of patients whose first visit is before @FromDate variable, production and income from procedures completed in date range, age of patient and date of first visit. - Also included patient income and insurance income for calculating total income.
/*735 List of patients whose first visit is before @FromDate variable, production and income from procedures completed in date range, age of patient and date of first visit. Included adjustment and writeoff amounts to calculate total production (Production+Adjustments-Writeoffs). Also included patient income and insurance income for calculating total income. Set date range for desired time span.*/
SET @FromDate='2012-01-01' , @ToDate='2012-06-07';
SELECT D.PatNum, D.Age, D.DateFirstVisit, D.$Production, D.$Adjustments, D.$Writeoff, D.$Production+D.$Adjustments-D.$Writeoff AS $TotalProduction, SUM(COALESCE(ps.SplitAmt, 0)) AS $PatIncome, D.$InsIncome, SUM(COALESCE(ps.SplitAmt, 0))+D.$InsIncome AS $TotalIncome FROM (SELECT C.*, SUM(COALESCE(cp.WriteOff, 0)) AS $Writeoff, SUM(COALESCE(cp.InsPayAmt, 0)) AS $InsIncome FROM (SELECT B.*, SUM(COALESCE(ad.AdjAmt, 0)) AS $Adjustments FROM (SELECT A.*, SUM(COALESCE(pl.ProcFee, 0)) AS $Production FROM (SELECT DISTINCT(p.PatNum), (YEAR(CURDATE())-YEAR(p.Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(p.Birthdate,5)) AS Age, DATE(p.DateFirstVisit) AS DateFirstVisit FROM patient p WHERE DATE(p.DateFirstVisit) < @FromDate AND DATE(p.DateFirstVisit) > '0001-01-01' AND (YEAR(CURDATE())-YEAR(p.Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(p.Birthdate,5)) >10) A
INNER JOIN procedurelog pl ON pl.PatNum = A.PatNum AND pl.ProcStatus=2 AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY A.PatNum) B
LEFT JOIN adjustment ad ON ad.PatNum=B.PatNum AND ad.AdjDate BETWEEN @FromDate AND @ToDate
GROUP BY B.PatNum) C
LEFT JOIN claimproc cp ON cp.PatNum=C.PatNum AND cp.DateCP BETWEEN @FromDate AND @ToDate
GROUP BY C.PatNum) D
LEFT JOIN paysplit ps ON ps.PatNum=D.PatNum AND ps.DatePay BETWEEN @FromDate AND @ToDate
GROUP BY D.PatNum
ORDER BY DateFirstVisit;
List of patients whose first visit is between date range, production and income from procedures completed in date range, age of patient and date of first visit. - Inverse of query #735
/*736 List of patients whose first visit is between date range, production and income from procedures completed in date range, age of patient and date of first visit. Included adjustment and writeoff amounts to calculate total production (Production+Adjustments-Writeoffs). Also included patient income and insurance income for calculating total income. Set date range for desired time span.*/
SET @FromDate='2012-01-01' , @ToDate='2012-06-07';
SELECT D.PatNum, D.Age, D.DateFirstVisit, D.$Production, D.$Adjustments, D.$Writeoff, D.$Production+D.$Adjustments-D.$Writeoff AS $TotalProduction, SUM(COALESCE(ps.SplitAmt, 0)) AS $PatIncome, D.$InsIncome, SUM(COALESCE(ps.SplitAmt, 0))+D.$InsIncome AS $TotalIncome FROM (SELECT C.*, SUM(COALESCE(cp.WriteOff, 0)) AS $Writeoff, SUM(COALESCE(cp.InsPayAmt, 0)) AS $InsIncome FROM (SELECT B.*, SUM(COALESCE(ad.AdjAmt, 0)) AS $Adjustments FROM (SELECT A.*, SUM(COALESCE(pl.ProcFee, 0)) AS $Production FROM (SELECT DISTINCT(p.PatNum), (YEAR(CURDATE())-YEAR(p.Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(p.Birthdate,5)) AS Age, DATE(p.DateFirstVisit) AS DateFirstVisit FROM patient p WHERE DATE(p.DateFirstVisit) BETWEEN @FromDate AND @ToDate AND (YEAR(CURDATE())-YEAR(p.Birthdate)) - (RIGHT(CURDATE(),5)<RIGHT(p.Birthdate,5)) >10) A
INNER JOIN procedurelog pl ON pl.PatNum = A.PatNum AND pl.ProcStatus=2 AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY A.PatNum) B
LEFT JOIN adjustment ad ON ad.PatNum=B.PatNum AND ad.AdjDate BETWEEN @FromDate AND @ToDate
GROUP BY B.PatNum) C
LEFT JOIN claimproc cp ON cp.PatNum=C.PatNum AND cp.DateCP BETWEEN @FromDate AND @ToDate
GROUP BY C.PatNum) D
LEFT JOIN paysplit ps ON ps.PatNum=D.PatNum AND ps.DatePay BETWEEN @FromDate AND @ToDate
GROUP BY D.PatNum
ORDER BY DateFirstVisit;
Recalled patients in a given time period, prophy or perio special type recalls only - Results could include new patients with their first visit date showing in the "DatePrevious" column
/*737 Recalled patients in a given time period, prophy or perio special type recalls only*/
SET @pos=0,
@FromDate='2013-01-01',
@ToDate='2013-04-01';
SELECT @pos:=@pos+1 AS '#',A.*
FROM (
SELECT p.FName,p.LName,r.DatePrevious,rt.Description
FROM patient p
INNER JOIN recall r ON r.PatNum=p.PatNum
INNER JOIN recalltype rt ON rt.RecallTypeNum=r.RecallTypeNum
WHERE r.DatePrevious BETWEEN @FromDate AND @ToDate
AND r.RecallTypeNum IN (SELECT pr.ValueString FROM preference pr WHERE pr.PrefName LIKE '%RecallTypeSpecial%')
GROUP BY p.PatNum,r.DatePrevious
ORDER BY p.LName,p.FName,r.DatePrevious ASC
) A;
All recalls with DateDue in the date range, with date scheduled, date of pat's last completed proc and ins carrier -
/*738 All recalls with DateDue in the date range, with date scheduled, date of pat's last completed proc and ins carrier*/
SET @FromDate='2013-01-01',@ToDate='2013-03-31';
SELECT p.LName,p.FName,rp.Description AS RecallType,IF(r.IsDisabled=1,'Yes','No') AS IsDisabled,r.DateDue,r.DateScheduled,
d.ItemName AS RecallStatus,A.LastVisit AS DateLastVisit,COALESCE(c.CarrierName,'NoIns') AS Carrier
FROM recall r
INNER JOIN patient p ON p.PatNum=r.PatNum
INNER JOIN recalltrigger rt ON rt.RecallTypeNum=r.RecallTypeNum
INNER JOIN recalltype rp ON rp.RecallTypeNum=rt.RecallTypeNum
LEFT JOIN definition d ON r.RecallStatus=d.DefNum
LEFT JOIN (
SELECT pl.PatNum,MAX(pl.ProcDate) AS LastVisit
FROM procedurelog pl
WHERE pl.ProcStatus=2
GROUP BY pl.PatNum
) A ON A.PatNum=r.PatNum
LEFT JOIN patplan pp ON pp.PatNum=p.PatNum AND pp.Ordinal=1 /*Primary*/
LEFT JOIN inssub ib ON ib.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=ib.PlanNum
LEFT JOIN carrier c ON c.CarrierNum=ip.CarrierNum
WHERE r.DateDue BETWEEN @FromDate AND @ToDate
GROUP BY p.PatNum,r.RecallTypeNum
ORDER BY p.LName,p.FName;
For all procedures completed in the date range, the fee schedule attached to the claim, sum of procedure fees, sum of writeoffs, and net production=procedure fees - writeoffs - For the writeoff amount: If the claim is received or supplemental we use the actual writeoff amount. If the claim is not recieved or if the procedure is complete and there is an estimate but no claim has been created yet, then we use the writeoff estimat
/*739 For all procedures completed in the date range, the fee schedule attached to the claim, sum of procedure fees,
sum of writeoffs, and net production=procedure fees - writeoffs. For the writeoff amount: If the claim is received
or supplemental we use the actual writeoff amount. If the claim is not recieved or if the procedure is complete and there
is an estimate but no claim has been created yet, then we use the writeoff estimate.*/
SET @StartDate='2012-01-01',@EndDate='2012-12-31';/*<----Change Date Range Here*/
SELECT (CASE WHEN ISNULL(A.Description) THEN 'NoInsurance' ELSE A.Description END) AS FeeSchedule,
SUM(A.GrossProd) AS $GrossProduction_,SUM(A.Writeoff) AS '$Writeoff(est)_',SUM(A.GrossProd)-SUM(A.Writeoff) AS $NetProduction_
FROM (
SELECT fs.Description,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) AS GrossProd,
SUM(CASE WHEN cp.Status IN (1,4) /*Received,Supplemental*/ THEN cp.Writeoff
WHEN cp.Status IN (0,6) /*NotReceived,Estimate*/ AND cp.WriteoffEst!=-1 THEN cp.WriteoffEst
ELSE 0 END) AS Writeoff
FROM claimproc cp
INNER JOIN procedurelog pl ON cp.ProcNum=pl.ProcNum AND pl.ProcStatus=2 AND pl.ProcDate BETWEEN @StartDate AND @EndDate
LEFT JOIN insplan ip ON ip.PlanNum=cp.PlanNum
LEFT JOIN feesched fs ON fs.FeeSchedNum=ip.FeeSched
GROUP BY pl.ProcNum
) A
GROUP BY A.Description;
Production, Total Production, Patient Payments, Insurance Payments, and Insurance Estimates broken down by Patient and Date of Service within a date range. With Aging of account - Report between FromDate & ToDate. Aging as of AgingDate. Meant to be exported to excel/open office.
/*740 Production, Total Production, Patient Payments, Insurance Payments, and Insurance Estimates broken down by Patient and Date of Service within a date range. With Aging of account*/
/*Report between FromDate & ToDate. Aging as of AgingDate*/
SET @FromDate='2013-09-01', @ToDate='2013-09-16', @AgingDate=CURDATE();
SELECT Tbl.PatNum AS 'Pat #',
CONCAT(p.LName,', ',p.FName) AS 'Patient',
Tbl.ServiceDate AS 'Service Date',
COALESCE(GROUP_CONCAT(Tbl.DateClaimSent),'') AS 'Date Claim Sent',
COALESCE(MAX(Tbl.Production),'') AS 'Production',
COALESCE(GROUP_CONCAT(Tbl.ProcedureCodes),'') AS 'Procedures',
CASE WHEN (ISNULL(MAX(Tbl.Production)) AND ISNULL(MAX(Tbl.AdjustmentsForDate)) AND ISNULL(MAX(Tbl.WriteOffsForDate))) THEN '' ELSE (COALESCE(MAX(Tbl.Production),0)+COALESCE(MAX(Tbl.AdjustmentsForDate),0)-COALESCE(MAX(Tbl.WriteOffsForDate),0))END AS 'Total Production',
COALESCE(GROUP_CONCAT(Tbl.DatePatientPayment),'') AS 'Date Patient Payment',
COALESCE(MAX(Tbl.AmountofPatientPayment),'') AS 'Amount Patient Payment',
COALESCE(MAX(Tbl.InsurancePaymentAmount),'') AS 'Insurance Payment Amount',
COALESCE(MAX(Tbl.InsurancePaymentEstimate),'') AS 'Insurance Payment Estimate',
COALESCE(GROUP_CONCAT(Tbl.DateInsurancePayment),'') AS 'Date Insurance Payment',
COALESCE((CASE WHEN Aging.0to30=0.00 THEN '' ELSE Aging.0to30 END),'') AS 'Balance 0-30 Days',
COALESCE((CASE WHEN Aging.31to60=0.00 THEN '' ELSE Aging.31to60 END),'') AS '31-60 Days',
COALESCE((CASE WHEN Aging.61to90=0.00 THEN '' ELSE Aging.61to90 END),'') AS '61-90 Days',
COALESCE((CASE WHEN Aging.Over90=0.00 THEN '' ELSE Aging.Over90 END),'') AS 'Over 90 Days',
COALESCE(Aging.Total,'0.00') AS 'Total Balance'
FROM(
/* Adjustments */
SELECT adj.PatNum,
adj.AdjDate AS ServiceDate,
NULL AS DateClaimSent,
NULL AS Production,
NULL AS ProcedureCodes,
NULL AS DatePatientPayment,
NULL AS AmountofPatientPayment,
NULL AS InsurancePaymentAmount,
NULL AS InsurancePaymentEstimate,
NULL AS DateInsurancePayment,
SUM(adj.AdjAmt) AS AdjustmentsForDate,
NULL AS WriteOffsForDate
FROM adjustment adj
WHERE adj.AdjDate BETWEEN @FromDate AND @ToDate
GROUP BY adj.PatNum,adj.AdjDate
UNION ALL
/* Patient Payments*/
SELECT pay.PatNum,
pay.PayDate AS ServiceDate,
NULL AS DateClaimSent,
NULL AS Production,
NULL AS ProcedureCodes,
pay.PayDate AS DatePatientPayment,
SUM(pay.PayAmt) AS AmountofPatientPayment,
NULL AS InsurancePaymentAmount,
NULL AS InsurancePaymentEstimate,
NULL AS DateInsurancePayment,
NULL AS AdjustmentsForDate,
NULL AS WriteOffsForDate
FROM payment pay
WHERE pay.PayDate BETWEEN @FromDate AND @ToDate
GROUP BY pay.PatNum,pay.PayDate
UNION ALL
/* Procedures / Procedure Codes*/
SELECT Procs.PatNum,
Procs.ProcDate AS ServiceDate,
COALESCE(Claims.DateSent,'') AS DateClaimSent,
COALESCE(Procs.FeesForDate,'') AS Production,
COALESCE(Procs.ProcedureCodes,'') AS ProcedureCodes,
NULL AS DatePatientPayment,
NULL AS AmountofPatientPayment,
COALESCE(Claims.FeesForDate,'') AS InsurancePaymentAmount,
COALESCE(Claims.EstFeesForDate,'') AS InsurancePaymentEstimate,
COALESCE(Claims.DateCP,'') AS DateInsurancePayment,
NULL AS AdjustmentsForDate,
Claims.WriteOffForDate AS WriteOffsForDate
FROM (
SELECT proc.PatNum,
proc.ProcDate,
SUM(proc.ProcFee) AS FeesForDate,
GROUP_CONCAT(DISTINCT COALESCE(pc.ProcCode,'') ORDER BY pc.ProcCode) AS ProcedureCodes
FROM procedurelog proc
INNER JOIN procedureCode pc ON proc.CodeNum=pc.CodeNum AND pc.ProcCode!='~GRP~'
WHERE proc.ProcStatus=2 AND proc.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY proc.PatNum,proc.ProcDate
) Procs
/* Claims / Writeoffs / Insurance Payments */
LEFT JOIN (
SELECT cp.PatNum,
cp.ProcDate,
SUM(CASE WHEN cp.Status IN(1,4) THEN cp.InsPayAmt END) AS FeesForDate,
SUM(CASE WHEN cp.Status=0 THEN cp.InsPayEst END) AS EstFeesForDate,
COALESCE(GROUP_CONCAT(DISTINCT (CASE WHEN c.DateSent='0001-01-01' THEN 'Not Sent' ELSE c.DateSent END) ORDER BY c.DateSent),'') AS DateSent,
COALESCE(GROUP_CONCAT(DISTINCT (CASE WHEN cp.Status=0 THEN 'NotYetPaid' ELSE cp.DateCP END) ORDER BY cp.DateCP),'') AS DateCP,
COALESCE(SUM(cp.WriteOff),'') AS WriteOffForDate
FROM claimproc cp
LEFT JOIN claim c ON c.ClaimNum=cp.ClaimNum
WHERE cp.Status IN(0,1,4) AND cp.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY cp.PatNum,cp.ProcDate
) Claims ON Claims.PatNum=Procs.PatNum AND Claims.ProcDate=Procs.ProcDate
GROUP BY Procs.PatNum,Procs.ProcDate
) Tbl
/* Patient Name / Guarantor*/
LEFT JOIN patient p ON Tbl.PatNum=p.PatNum
/* Aging*/
LEFT JOIN(
SELECT D.PatNum AS Guarantor,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60 THEN D.FamCharges0to30
WHEN D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30<=D.FamCredits THEN 0
ELSE D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60+D.FamCharges0to30-D.FamCredits END)
,2),2) AS 0to30,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<D.FamChargesOver90+D.FamCharges61to90 THEN D.FamCharges31to60
WHEN D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60<=D.FamCredits THEN 0
ELSE D.FamChargesOver90+D.FamCharges61to90+D.FamCharges31to60-D.FamCredits END)
,2),2) AS 31to60,
FORMAT(ROUND(
(CASE WHEN D.FamCredits<=D.FamChargesOver90 THEN D.FamCharges61to90
WHEN D.FamChargesOver90+D.FamCharges61to90<=D.FamCredits THEN 0
ELSE D.FamChargesOver90+D.FamCharges61to90-D.FamCredits END)
,2),2) AS 61to90,
FORMAT(ROUND(
(CASE WHEN D.FamCredits>=D.FamChargesOver90 THEN 0
ELSE D.FamChargesOver90-D.FamCredits END)
,2),2) AS Over90,
FORMAT(ROUND(D.FamBal,2),2) AS Total,
FORMAT(ROUND(COALESCE(D.FamInsEst,0),2),2) AS InsEst,
FORMAT(ROUND(D.FamBal-COALESCE(D.FamInsEst,0),2),2) AS PatEst
FROM (
/*Get the family level charges, credits, and ins estimates*/
SELECT g.PatNum,g.LName,g.FName,SUM(B.PatBal) AS FamBal,SUM(B.Charges0to30) AS FamCharges0to30,SUM(B.Charges31to60) AS FamCharges31to60,
SUM(B.Charges61to90) AS FamCharges61to90,SUM(B.ChargesOver90) AS FamChargesOver90,SUM(B.Credits) AS FamCredits,
SUM(COALESCE(C.InsEst,0)) AS FamInsEst
FROM (
/*Get Patient level charges and credits*/
SELECT RawPatTrans.PatNum,SUM(RawPatTrans.TranAmount) AS PatBal,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<=@AgingDate AND RawPatTrans.TranDate>=(@AgingDate-INTERVAL 30 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges0to30,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AgingDate-INTERVAL 30 DAY) AND RawPatTrans.TranDate>=(@AgingDate-INTERVAL 60 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges31to60,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AgingDate-INTERVAL 60 DAY) AND RawPatTrans.TranDate>=(@AgingDate-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Charges61to90,
(SUM(CASE WHEN (RawPatTrans.TranAmount>0 AND RawPatTrans.TranDate<(@AgingDate-INTERVAL 90 DAY)) THEN RawPatTrans.TranAmount ELSE 0 END)) AS ChargesOver90,
-(SUM(CASE WHEN (RawPatTrans.TranAmount<0 AND RawPatTrans.TranDate<=@AgingDate) THEN RawPatTrans.TranAmount ELSE 0 END)) AS Credits
FROM (
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum AS PatNum,pl.ProcDate AS TranDate,
pl.ProcFee*(pl.UnitQty+pl.BaseUnits) AS TranAmount
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum AS PatNum,ps.DatePay AS TranDate,
-ps.SplitAmt AS TranAmount
FROM paysplit ps
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum AS PatNum,a.AdjDate AS TranDate,
a.AdjAmt AS TranAmount
FROM adjustment a
WHERE a.AdjAmt!=0
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum AS PatNum,cp.DateCp AS TranDate,
-cp.InsPayAmt-cp.Writeoff AS TranAmount
FROM claimproc cp
WHERE cp.Status IN (1,4,5,7)/*received,supplemental,CapClaim, or CapComplete*/
UNION ALL
/*Payment plan principal for the entire office history on or before the given date*/
SELECT 'PayPlan' AS TranType,pp.PatNum AS PatNum,pp.PayPlanDate AS TranDate,
-pp.CompletedAmt AS TranAmount
FROM payplan pp
WHERE pp.CompletedAmt!=0
GROUP BY pp.PayPlanNum
) RawPatTrans
WHERE TranDate<=@AgingDate
GROUP BY RawPatTrans.PatNum
) B
LEFT JOIN (
/*Get patient level InsPayEst and Writeoffs from unreceived claims.*/
SELECT cp.PatNum,SUM(cp.InsPayEst+cp.Writeoff) AS InsEst
FROM claimproc cp
WHERE cp.PatNum!=0
AND ((cp.Status=0 AND cp.ProcDate<=@AgingDate) OR (cp.Status=1 AND cp.DateCP>@AgingDate))
AND cp.ProcDate<=@AgingDate
GROUP BY cp.PatNum
) C ON C.PatNum=B.PatNum
INNER JOIN patient p ON p.PatNum=B.PatNum
INNER JOIN patient g ON g.PatNum=p.Guarantor
GROUP BY g.PatNum
) D
WHERE ABS(D.FamBal)>0.005
)Aging ON Aging.Guarantor=p.Guarantor
GROUP BY Tbl.PatNum,Tbl.ServiceDate
ORDER BY Tbl.ServiceDate,Tbl.PatNum
Claims with a Custom Tracking type set with date of service in a date range -
/*741 Claims with a Custom Tracking type set with date of service in a date range*/
SET @FromDate='2012-09-19', @ToDate='2013-09-30';
SELECT c.PatNum,
c.PatNum AS 'Pat#',
c.DateService AS 'Date of Service',
c.DateSent AS 'Date Sent',
c.DateReceived AS 'Date Received',
c.PlanNum,
c.ProvTreat,
c.ClaimFee AS '$ClaimFee_',
c.InsPayEst AS '$InsPayEst_',
c.InsPayAmt AS '$InsPayAmt_',
c.DedApplied AS '$DedApplied_',
c.ReasonUnderpaid AS 'Reason Underpaid',
c.ClaimNote AS 'Claim Note',
d.ItemName AS 'Custom Tracking'
FROM claim c
LEFT JOIN Definition d ON c.CustomTracking = d.DefNum
WHERE c.DateService BETWEEN @FromDate AND @ToDate
AND c.CustomTracking!=0
ORDER BY c.DateService,c.PatNum
Total production by assistant over date range, ONLY COUNTS completed production in appointments -
/*742 Total production by assistant over date range, ONLY COUNTS completed production in appointments!*/
/*Query code written/modified: 03/21/2018*/
SET @FromDate='2017-01-01', @ToDate='2017-01-31' ;/*change dates here*/
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT CONCAT(e.FName, ' ',e.LName) AS Assistant,
SUM(ProcFee*(pl.UnitQty+pl.BaseUnits)) AS $Production__
FROM procedurelog pl
INNER JOIN appointment a
ON a.AptNum=pl.AptNum
INNER JOIN employee e
ON a.Assistant=e.EmployeeNum
WHERE ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus = 2 /*Complete*/
GROUP BY a.Assistant;
Scheduled and unscheduled procedures for patients with a scheduled appointment in a date range -
/*743 Scheduled and unscheduled procedures for patients with a scheduled appointment in a date range*/
SET @FromDate='2013-10-02' , @ToDate='2013-10-03';
SELECT patient.PatNum,
CONCAT(pv.LName, ', ',pv.FName) AS Provider,
COALESCE(DATE_FORMAT(a.AptDateTime, '%l:%i %p %m/%d/%Y'),'Unscheduled') AS 'Appt Date-Time',
pc.ProcCode,
LEFT(AbbrDesc,13) AS AbbrDesc,
pl.ProcFee AS '$Fee_',
pl.ProcFee-(COALESCE(SUM(cp.InsPayEst),0)+COALESCE(SUM(cp.WriteOff),0)) AS '$PatPort_',
LEFT(a.Note, 30) AS AbrAptNote
FROM (SELECT app.PatNum FROM appointment app
WHERE app.AptStatus IN(1,4)
AND DATE(app.AptDateTime) >=@FromDate
AND DATE(app.AptDateTime)<=@ToDate
GROUP BY app.PatNum) patient
INNER JOIN procedurelog pl ON patient.PatNum=pl.PatNum AND pl.ProcStatus=1
INNER JOIN procedurecode pc ON pl.CodeNum= pc.CodeNum
INNER JOIN provider pv ON pv.ProvNum=pl.ProvNum
LEFT JOIN appointment a ON a.AptNum=pl.AptNum AND a.AptStatus IN(1,4) AND DATE(a.AptDateTime)>CURDATE()
LEFT JOIN claimproc cp ON cp.ProcNum=pl.ProcNum AND cp.Status=6 /*estimate*/
GROUP BY pl.ProcNum
ORDER BY patient.PatNum,COALESCE(a.AptDateTime,'3000-01-01');
Average Daily Production by provider, without hidden providers or hygienists -
/*744 Average Daily Production by provider. Without hidden providers or hygienists*/
SET @FromDate='2013-10-01', @ToDate='2013-10-07';
SELECT *,
$GrossProd+$Writeoffs+$Adjustments $NetProd,
$GrossProd/DaysWorked $AveGrossPr,
($GrossProd+$Writeoffs+$Adjustments)/DaysWorked $AveNetPr
FROM (
SELECT pr.Abbr,
pr.LName,
pr.FName,
(
SELECT COUNT(DISTINCT pl.ProcDate)
FROM procedurelog pl
WHERE pl.ProvNum=pr.ProvNum
AND pl.ProcStatus=2
AND (pl.ProcDate BETWEEN @FromDate AND @ToDate)
) DaysWorked,
(
SELECT SUM(pl.ProcFee*(pl.UnitQty+pl.BaseUnits))
FROM procedurelog pl
WHERE pl.ProvNum=pr.ProvNum
AND pl.ProcStatus=2
AND (pl.ProcDate BETWEEN @FromDate AND @ToDate)
) $GrossProd,
(
SELECT SUM(-cp.WriteOff)
FROM claimproc cp
WHERE cp.Status IN(0,1,4,5,7) /*received, not received, supplemental, CapClaim or CapComplete*/
AND cp.ProvNum=pr.ProvNum
AND (cp.ProcDate BETWEEN @FromDate AND @ToDate)
) $Writeoffs,
(
SELECT SUM(-a.AdjAmt)
FROM adjustment a
WHERE a.ProvNum=pr.ProvNum
AND (a.AdjDate BETWEEN @FromDate AND @ToDate)
) $Adjustments
FROM provider pr
WHERE pr.IsHidden = 0
AND pr.IsSecondary = 0
) A;
Outstanding insurance estimates aged by date of service 0 to 30, 30 to 60, 60 to 90 etc summed by carrier -
/*745 Insurance aging report. Outstanding insurance estimates aged by date of service 0 to 30, 30 to 60, 60 to 90 etc. Summed by carrier*/
SELECT A.CarrierName,
SUM(Ins0to30) AS $Ins0to30_ ,
SUM(Ins30to60) AS $Ins30to60_,
SUM(Ins60to90) AS $Ins60to90_,
SUM(InsOver90) AS $InsOver90_,
SUM(InsPayEst) AS $SumInsPayEst_
FROM (
SELECT ClaimNum,
InsPayEst,
DateService,
ip.CarrierNum,
carrier.CarrierName,
IF((TO_DAYS(CURDATE())-TO_DAYS(DateService))> 90,InsPayEst,0) AS 'InsOver90',
IF((TO_DAYS(CURDATE())-TO_DAYS(DateService))> 60,IF((TO_DAYS(CURDATE())-TO_DAYS(DateService))<= 90, InsPayEst,0),0) AS 'Ins60to90',
IF((TO_DAYS(CURDATE())-TO_DAYS(DateService))> 30,IF((TO_DAYS(CURDATE())-TO_DAYS(DateService))<= 60, InsPayEst,0),0) AS 'Ins30to60',
IF((TO_DAYS(CURDATE())-TO_DAYS(DateService))<= 30,InsPayEst,0) AS 'Ins0to30'
FROM claim
INNER JOIN insplan ip ON ip.PlanNum=claim.PlanNum
INNER JOIN carrier ON carrier.CarrierNum=ip.CarrierNum
WHERE ClaimStatus='S'
AND ClaimType!="PreAuth"
) A
GROUP BY A.CarrierNum;
Time Card summary for all Employees for last full month. With custom multiplier -
/*746 Time Card summary for all Employees for last full month. With custom multiplier*/
/*Query code written/modified: 02/26/2018*/
SET @FromDate=DATE_FORMAT(NOW() - INTERVAL 1 MONTH, '%Y-%m-01') , @ToDate=DATE_FORMAT(NOW(), '%Y-%m-01')- INTERVAL 1 DAY;
SET @Multiplier=2;
/*---------------------DO NOT MODIFY BELOW THIS LINE---------------------*/
SELECT *,(OverTime+RegHours) AS HoursWorked, ((OverTime+RegHours)*@Multiplier) AS HoursWithMult, ((OverTime+RegHours)*(2*@Multiplier)) AS HoursWithMultHyg
FROM (
SELECT e.FName,
e.LName,
FORMAT(
SUM(TIME_TO_SEC(IF((TIME_TO_SEC(TimeDisplayed2)>0 AND c.ClockStatus IN(0,1)), TIMEDIFF(TimeDisplayed2, TimeDisplayed1),0)))/3600,2
) AS RawHours,
FORMAT(
(IFNULL((SELECT SUM(TIME_TO_SEC(ta.RegHours)) FROM timeadjust ta WHERE ta.EmployeeNum=e.EmployeeNum AND DATE(ta.TimeEntry) BETWEEN @FromDate AND @ToDate),0) /*adj reg hours*/ +
IFNULL((SELECT SUM(TIME_TO_SEC(ta.OTimeHours)) FROM timeadjust ta WHERE ta.EmployeeNum=e.EmployeeNum AND DATE(ta.TimeEntry) BETWEEN @FromDate AND @ToDate),0) /*adj OT hours*/ +
SUM(TIME_TO_SEC(IF(c.ClockStatus IN(0,1),IF(c.AdjustIsOverRidden, c.Adjust, c.AdjustAuto),0))))/3600,2
) AS AdHours,
FORMAT(
SUM(TIME_TO_SEC(IF((TIME_TO_SEC(c.TimeDisplayed2)>0 AND c.ClockStatus=2), TIMEDIFF(c.TimeDisplayed2, c.TimeDisplayed1),0)))/3600,2
) AS BreakTot,
FORMAT(
(SUM(TIME_TO_SEC(IF((TIME_TO_SEC(c.TimeDisplayed2)>0 AND c.ClockStatus=2), TIMEDIFF(c.TimeDisplayed2, c.TimeDisplayed1),0)))+
SUM(TIME_TO_SEC(IF(c.ClockStatus IN(0,1),IF(c.AdjustIsOverRidden, c.Adjust, c.AdjustAuto),0))) /*minus (+) adjustments*/)/3600,2
) AS BreakAdj,
FORMAT(
(IFNULL((SELECT SUM(TIME_TO_SEC(ta.OTimeHours)) FROM timeadjust ta WHERE ta.EmployeeNum =e.EmployeeNum AND DATE(ta.TimeEntry) BETWEEN @FromDate AND @ToDate),0) /*adj OT hours*/ +
SUM(TIME_TO_SEC(IF(c.ClockStatus IN(0,1) AND c.OTimeHours<>'-01:00:00', (c.OTimeHours),0)))+
SUM(TIME_TO_SEC(IF(c.ClockStatus IN(0,1),c.OTimeAuto,0))))/3600,2
) AS OverTime,
FORMAT(
(IFNULL((SELECT SUM(TIME_TO_SEC(ta.RegHours)) FROM timeadjust ta WHERE ta.EmployeeNum =e.EmployeeNum AND DATE(ta.TimeEntry) BETWEEN @FromDate AND @ToDate),0) /*adj reg hours*/ +
SUM(TIME_TO_SEC(IF((TIME_TO_SEC(c.TimeDisplayed2)>0 AND c.ClockStatus IN(0,1)), TIMEDIFF(c.TimeDisplayed2, c.TimeDisplayed1),0)))+
SUM(TIME_TO_SEC(IF(c.ClockStatus IN(0,1),IF(c.AdjustIsOverRidden, c.Adjust, c.AdjustAuto),0)))- /*minus (+) adjustments*/
SUM(TIME_TO_SEC(IF(c.ClockStatus IN(0,1) AND c.OTimeHours<>'-01:00:00', c.OTimeHours,0)))- /*minus Overtime*/
SUM(TIME_TO_SEC(IF(c.ClockStatus IN(0,1) , c.OTimeAuto,0))))/3600,2
) AS RegHours /*minus Overtime Auto*/
FROM employee e
LEFT JOIN clockEvent c
ON c.EmployeeNum=e.EmployeeNum
AND (DATE(c.TimeDisplayed1) BETWEEN @FromDate AND @ToDate)
GROUP BY c.EmployeeNum
) a
Count of unique active patients seen in a date range with the specified code completed -
/*747 Count of unique active patients seen in a date range with the specified code completed*/
SET @FromDate='2013-10-25' , @ToDate='2013-11-25';
SET @Code='%11107%';
SELECT COUNT(*) AS 'Number of unique patients seen'
FROM (
SELECT DISTINCT pl.PatNum
FROM procedurelog pl
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
INNER JOIN patient p ON p.PatNum=pl.PatNum
WHERE pc.ProcCode LIKE @Code
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus=2
AND p.PatStatus=0
) A
List of procedures, claim information and patient payments in a date range for a particular provider, including only specific procedure codes and excluding specific carriers -
/*748 List of procedures, claim information and patient payments in a date range for a particular provider, including only specific procedure codes and excluding specific carriers*/
SET @FromDate='2013-09-01', @ToDate='2013-09-31'; /* change date here*/
SET @ProvAbbr='%DOC%'; /*Change provider abbreviation here*/
/*Change list of proc codes below*/
/*Change list of carriers to exclude below*/
SELECT C.PatNum,
C.Date,
C.ProvNum,
C.ProcCode,
C.PriInsName,
C.ProcFee AS '$ProcFee_',
C.InsPayEst AS '$InsPayEst_',
C.InsPaidAmt AS '$InsPaidAmt_',
C.OtherPayment AS '$OtherPayment_',
C.OtherPaymentType
FROM(
SELECT A.*
FROM(
SELECT 1 AS ItemOrder,
p.PatNum,
pl.ProcDate AS 'Date',
pl.ProvNum,
pc.ProcCode,
car.CarrierName AS 'PriInsName',
pl.ProcFee,
(
SELECT SUM(cp.InsPayEst)
FROM claimproc cp
WHERE cp.ProcNum=pl.ProcNum
AND cp.Status IN (0,1,4)
) AS 'InsPayEst',
(
SELECT SUM(cp.InsPayAmt)
FROM claimproc cp
WHERE cp.ProcNum=pl.ProcNum
AND cp.Status IN (1,4)
) AS 'InsPaidAmt',
NULL AS 'OtherPayment',
NULL AS 'OtherPaymentType'
FROM procedurelog pl
INNER JOIN patient p ON p.PatNum=pl.PatNum /*just in case we need field from patient table*/
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
INNER JOIN provider prov ON prov.ProvNum=pl.ProvNum
LEFT JOIN claimproc cp ON cp.ProcNum=pl.ProcNum
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
LEFT JOIN carrier car ON car.CarrierNum=ip.CarrierNum
LEFT JOIN (
SELECT p.PatNum, SUM(p.PayAmt) AS PatPayAmt
FROM payment p
WHERE p.PayDate BETWEEN @FromDate AND @ToDate
GROUP BY p.PatNum
) patpay ON patpay.PatNum=pl.PatNum
WHERE pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus=2
AND pc.ProcCode IN('D0150','D0150c','D0120','D0120c','D0272','D0274','D0210','D1110','D1120','D1203','D4341','D1208')
AND car.CarrierName NOT LIKE '%DMO%'
AND car.CarrierName NOT LIKE '%DHMO%'
AND car.CarrierName NOT LIKE '%UCCI Plus%'
AND car.CarrierName NOT LIKE '%Delta Care%'
AND car.CarrierName NOT LIKE '%Dominion%'
AND car.CarrierName NOT LIKE '%Aetna Medicare%'
AND car.CarrierName NOT LIKE '%Value Plan%'
AND prov.Abbr LIKE @ProvAbbr
GROUP BY pl.ProcNum
UNION ALL
SELECT 1 AS ItemOrder,
p.PatNum,
p.PayDate AS 'Date',
NULL AS ProvNum,
NULL AS ProcCode,
NULL AS 'PriInsName',
NULL AS 'ProcFee',
NULL AS 'InsPayEst',
NULL AS 'InsPaidAmt',
SUM(ps.SplitAmt) AS PatPayment,
d.Itemname AS 'PatPaymentType'
FROM payment p
INNER JOIN paysplit ps ON ps.PayNum=p.PayNum
INNER JOIN provider prov ON prov.ProvNum=ps.ProvNum
INNER JOIN definition d ON p.PayType=d.DefNum
WHERE p.PayDate BETWEEN @FromDate AND @ToDate
AND prov.Abbr LIKE @ProvAbbr
GROUP BY p.PayNum
) A
UNION ALL
SELECT 2 AS ItemOrder,
'------' AS PatNum,
'------' AS 'Date',
'------' AS ProvNum,
'------' AS ProcCode,
'------' AS 'PriInsName',
'------' AS 'ProcFee',
'------' AS 'InsPayEst',
'------' AS 'InsPaidAmt',
'------' AS OtherPayment,
'------' AS 'OtherPaymentType'
UNION ALL
SELECT 3 AS ItemOrder,
'Totals:' AS PatNum,
NULL AS 'Date',
NULL AS ProvNum,
NULL AS ProcCode,
NULL AS 'PriInsName',
SUM(B.ProcFee) AS 'ProcFee',
SUM(B.InsPayEst) AS 'InsPayEst',
SUM(B.InsPaidAmt) AS 'InsPaidAmt',
SUM(B.OtherPayment) AS OtherPayment,
NULL AS 'OtherPaymentType'
FROM(
SELECT pl.ProcFee AS 'ProcFee',
(
SELECT SUM(cp.InsPayEst)
FROM claimproc cp
WHERE cp.ProcNum=pl.ProcNum
AND cp.Status IN (0,1,4)
) AS 'InsPayEst',
(
SELECT SUM(cp.InsPayAmt)
FROM claimproc cp
WHERE cp.ProcNum=pl.ProcNum
AND cp.Status IN (1,4)
) AS 'InsPaidAmt',
NULL AS OtherPayment
FROM procedurelog pl
INNER JOIN patient p ON p.PatNum=pl.PatNum /*just in case we need field from patient table*/
INNER JOIN procedurecode pc ON pl.CodeNum=pc.CodeNum
INNER JOIN provider prov ON prov.ProvNum=pl.ProvNum
LEFT JOIN claimproc cp ON cp.ProcNum=pl.ProcNum
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
LEFT JOIN carrier car ON car.CarrierNum=ip.CarrierNum
LEFT JOIN (
SELECT p.PatNum, SUM(p.PayAmt) AS PatPayAmt
FROM payment p
WHERE p.PayDate BETWEEN @FromDate AND @ToDate
GROUP BY p.PatNum
) patpay ON patpay.PatNum=pl.PatNum
WHERE pl.ProcDate BETWEEN @FromDate AND @ToDate
AND pl.ProcStatus=2
AND pc.ProcCode IN('D0150','D0150c','D0120','D0120c','D0272','D0274','D0210','D1110','D1120','D1203','D4341','D1208')
AND car.CarrierName NOT LIKE '%DMO%'
AND car.CarrierName NOT LIKE '%DHMO%'
AND car.CarrierName NOT LIKE '%UCCI Plus%'
AND car.CarrierName NOT LIKE '%Delta Care%'
AND car.CarrierName NOT LIKE '%Dominion%'
AND car.CarrierName NOT LIKE '%Aetna Medicare%'
AND car.CarrierName NOT LIKE '%Value Plan%'
AND prov.Abbr LIKE @ProvAbbr
GROUP BY pl.ProcNum
UNION ALL
SELECT NULL AS 'ProcFee',
NULL AS 'InsPayEst',
NULL AS 'InsPaidAmt',
p.PayAmt AS PatPayment
FROM payment p
INNER JOIN definition d ON p.PayType=d.DefNum
WHERE p.PayDate BETWEEN @FromDate AND @ToDate
GROUP BY p.PatNum
)B
)C
LEFT JOIN patient p ON C.PatNum=p.PatNum
ORDER BY C.ItemOrder,C.Date,p.LName,p.FName;
Insurance info for patients with apts in date range with plannotes and custom patfield -
/*749 Insurance info for patients with apts in date range with plannotes and custom patfield*/
SET @FromDate='2013-10-30', @ToDate='2013-11-30';
SELECT p.LName,
p.FName,
p.Birthdate,
a.AptDateTime,
p.SSN,
IFNULL(c.CarrierName, 'none') PriCarrier,IFNULL(ins.SubscriberID, 'none') PriSubID, IFNULL(c.Phone,'none') PriCarPhone,
IFNULL(c2.CarrierName, 'none') SecCarrier,
/*Add if desired IFNULL(ins2.SubscriberID, 'none') SecSubID,*/
IFNULL(c2.Phone,'none') SecCarPhone,
ip.PlanNote AS PriPlanNote,
ip2.PlanNote AS SecPlanNote,
pf.FieldValue AS 'InsuranceLastVerified'
FROM patient p
INNER JOIN appointment a ON p.PatNum=a.PatNum
LEFT JOIN patplan pp ON pp.PatNum=p.PatNum AND pp.Ordinal=1
LEFT JOIN inssub ins ON ins.InsSubNum=pp.InsSubNum
LEFT JOIN insplan ip ON ip.PlanNum=ins.PlanNum
LEFT JOIN carrier c ON c.CarrierNum=ip.CarrierNum
LEFT JOIN patplan pp2 ON pp2.PatNum=p.PatNum AND pp2.Ordinal=2
LEFT JOIN inssub ins2 ON ins2.InsSubNum=pp2.InsSubNum
LEFT JOIN insplan ip2 ON ip2.PlanNum=ins2.PlanNum
LEFT JOIN carrier c2 ON c2.CarrierNum=ip2.CarrierNum
LEFT JOIN patfield pf ON pf.PatNum=p.PatNum AND pf.FieldName LIKE '%Insurance Last Verified%'
WHERE DATE(a.aptdatetime) BETWEEN @FromDate AND @ToDate;
Waiting Room Report, shows time each patient arrived, length waiting, was seated,chair time, dismissed time, Dentist on appointment and Operatory - Also gives average waiting time in minutes
/*750 Waiting Room Report, shows time each patient arrived, length waiting, was seated,chair time, dismissed time, Dentist on appointment and Operatory. Also gives average waiting time in minutes*/
SET @FromDate='2013-10-30' , @ToDate='2013-11-30';
SELECT * FROM (
SELECT CONCAT(p.LName,', ',p.FName) AS 'Pat Name',
LEFT(a.PatNum,15) AS 'Pat Num',AptDateTime,
a.ProvNum,
a.Op,
LEFT((CASE WHEN DATE_FORMAT(DateTimeArrived,'%T')<>'00:00:00'/*when there is a real value*/
THEN DATE_FORMAT(DateTimeArrived,'%r') ELSE '' END),12) AS TimeArrived,
LEFT((CASE WHEN DATE_FORMAT(DateTimeSeated,'%T')<>'00:00:00'/*when there is a real value*/
THEN DATE_FORMAT(DateTimeSeated,'%r') ELSE '' END),12) AS TimeSeated,
LEFT((CASE WHEN DATE_FORMAT(DateTimeDismissed,'%T')<>'00:00:00'/*when there is a real value*/
THEN DATE_FORMAT(DateTimeDismissed,'%r') ELSE '' END),12) AS TimeDismiss,
LEFT((CASE WHEN DATE_FORMAT(DateTimeSeated,'%T')<>'00:00:00' AND DATE_FORMAT(DateTimeArrived,'%T')<>'00:00:00' THEN TIME_FORMAT(SEC_TO_TIME(TIME_TO_SEC(DateTimeSeated)-TIME_TO_SEC(DateTimeArrived)),'%H:%i') ELSE '' END),5) AS WaitTime,
LEFT((CASE WHEN DATE_FORMAT(DateTimeSeated,'%T')<>'00:00:00' AND DATE_FORMAT(DateTimeDismissed,'%T')<>'00:00:00' THEN TIME_FORMAT(SEC_TO_TIME(TIME_TO_SEC(DateTimeDismissed)-TIME_TO_SEC(DateTimeSeated)),'%H:%i') ELSE '' END),5) AS ChairTime
FROM appointment a
INNER JOIN patient p ON a.PatNum=p.PatNum
WHERE DATE(a.AptDateTime) BETWEEN @FromDate AND @ToDate
ORDER BY a.AptDateTime
)tmp1
UNION
SELECT 'Average Wait' AS 'Pat Name',
'' AS 'Pat Num',
'' AS 'AptDateTime',
'' AS ProvNum,
'' AS Op,
'' AS TimeArrived,
'' AS TimeSeated,
'' AS TimeDismiss,
FORMAT(
(SELECT (SUM(TIME_TO_SEC(tmp1.WaitTime))/COUNT(tmp1.WaitTime))/60
FROM (
SELECT CONCAT(p.LName,', ',p.FName) AS 'Pat Name',
LEFT(a.PatNum,15) AS 'Pat Num',AptDateTime,
a.ProvNum,
a.Op,
LEFT((CASE WHEN DATE_FORMAT(DateTimeArrived,'%T')<>'00:00:00'/*when there is a real value*/
THEN DATE_FORMAT(DateTimeArrived,'%r') ELSE '' END),12) AS TimeArrived,
LEFT((CASE WHEN DATE_FORMAT(DateTimeSeated,'%T')<>'00:00:00'/*when there is a real value*/
THEN DATE_FORMAT(DateTimeSeated,'%r') ELSE '' END),12) AS TimeSeated,
LEFT((CASE WHEN DATE_FORMAT(DateTimeDismissed,'%T')<>'00:00:00'/*when there is a real value*/
THEN DATE_FORMAT(DateTimeDismissed,'%r') ELSE '' END),12) AS TimeDismiss,
LEFT((CASE WHEN DATE_FORMAT(DateTimeSeated,'%T')<>'00:00:00' AND DATE_FORMAT(DateTimeArrived,'%T')<>'00:00:00' THEN TIME_FORMAT(SEC_TO_TIME(TIME_TO_SEC(DateTimeSeated)-TIME_TO_SEC(DateTimeArrived)),'%H:%i') ELSE '' END),5) AS WaitTime,
LEFT((CASE WHEN DATE_FORMAT(DateTimeSeated,'%T')<>'00:00:00' AND DATE_FORMAT(DateTimeDismissed,'%T')<>'00:00:00' THEN TIME_FORMAT(SEC_TO_TIME(TIME_TO_SEC(DateTimeDismissed)-TIME_TO_SEC(DateTimeSeated)),'%H:%i') ELSE '' END),5) AS ChairTime
FROM appointment a
INNER JOIN patient p ON a.PatNum=p.PatNum
WHERE DATE(a.AptDateTime) BETWEEN @FromDate AND @ToDate
ORDER BY a.AptDateTime
)tmp1
WHERE tmp1.WaitTime<>''),1
) AS WaitTime,
'' AS ChairTime;
Daily procedures report in custom data range with claim and carrier information -
/*751 Daily procedures report in custom date range with claim and carrier information*/
SET @FromDate='2013-11-11', @ToDate='2013-12-01';
/*-------------------- Do not modify under this line --------------------*/
SELECT
pl.ProcDate,
p.PatNum AS 'Pat#',
CONCAT(p.LName,', ',p.FName,' ',p.MiddleI) AS 'Name',
pc.ProcCode,
pl.ToothNum,
LEFT(pc.Descript,40)AS Description,
car.CarrierName,
car.Phone,
(CASE WHEN cl.ClaimStatus='U' THEN 'Unsent'
WHEN cl.ClaimStatus='H' THEN 'HoldForPrimary'
WHEN cl.ClaimStatus='W' THEN 'WaitingToSend'
WHEN cl.ClaimStatus='S' THEN 'Sent'
WHEN cl.ClaimStatus='R' THEN 'Received'
ELSE '' END
) AS ClaimStatus,
(pl.ProcFee * (pl.BaseUnits + pl.UnitQty)) AS '$ProcFee_',
cp.InsPayAmt '$InsPayAmt_'
FROM procedurelog pl
INNER JOIN patient p
ON p.PatNum=pl.PatNum
INNER JOIN procedurecode pc
ON pl.CodeNum=pc.CodeNum
INNER JOIN provider prov
ON prov.ProvNum=pl.ProvNum
LEFT JOIN claimproc cp
ON pl.ProcNum=cp.ProcNum
LEFT JOIN claim cl
ON cp.ClaimNum=cl.ClaimNum
LEFT JOIN insplan ip
ON ip.PlanNum=cl.PlanNum
LEFT JOIN carrier car
ON ip.CarrierNum=car.CarrierNum
WHERE pl.ProcStatus = 2 -- Complete
AND cp.Status IN (0,1,6)
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
GROUP BY pl.ProcNum,cp.ClaimProcNum
ORDER BY pl.ProcDate,NAME,CarrierName,pc.ProcCode,ToothNum;
Production and income report over date range with specific provider and billing type - Insurance writeoffs by ins payment date, so assume that any PPOs are entered as Category Percentage
/*752 Production and income report over date range with specific provider and billing type. Insurance writeoffs by ins payment date, so assume that any PPOs are entered as Category Percentage. */
SET @FromDate='2013-11-06' , @ToDate='2013-12-01';
SET @BillingType='%Standard%', @ProviderAbbr='%Doc1%';
SELECT DATE AS ServiceDate,$Prod_,$Adjust_,$Writeoff_,$TotProd_,$PatIncome_,$InsIncome_,$TotIncome_
FROM(
SELECT 6 AS ItemOrder,
DATE_FORMAT(Trans.TDate,'%m/%d/%Y') AS DATE,
SUM(CASE WHEN Trans.TranType='Prod' THEN Trans.TranAmount WHEN Trans.TranType='Cap' THEN Trans.Writeoff ELSE 0 END) AS $Prod_,
SUM(CASE WHEN Trans.TranType='Adj' THEN Trans.TranAmount ELSE 0 END) AS $Adjust_,
SUM(CASE WHEN Trans.TranType='Writeoff' THEN Trans.Writeoff ELSE 0 END) AS $Writeoff_,
SUM(CASE WHEN Trans.TranType IN('Prod','Adj') THEN Trans.TranAmount WHEN Trans.TranType IN('Writeoff','Cap') THEN Trans.Writeoff ELSE 0 END) AS $TotProd_,
SUM(CASE WHEN Trans.TranType='PatPay' THEN Trans.TranAmount ELSE 0 END) AS $PatIncome_,
SUM(CASE WHEN Trans.TranType IN('InsPay') THEN Trans.TranAmount ELSE 0 END) AS $InsIncome_,
SUM(CASE WHEN Trans.TranType IN('PatPay','InsPay') THEN Trans.TranAmount ELSE 0 END) AS $TotIncome_
FROM (
/*Prod*/
SELECT 'Prod' AS TranType,pl.ProcDate AS TDate,pl.ProvNum,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) AS TranAmount,0 AS Writeoff
FROM procedurelog pl
INNER JOIN patient p ON p.Patnum=pl.PatNum
INNER JOIN definition d ON d.DefNum=p.BillingType
INNER JOIN provider prov ON pl.ProvNum=prov.ProvNum
WHERE pl.ProcStatus=2
AND prov.Abbr LIKE @ProviderAbbr
AND d.ItemName LIKE @BillingType
AND pl.ProcDate BETWEEN @FromDate AND @ToDate
UNION ALL
/*Adj*/
SELECT 'Adj' AS TranType,a.AdjDate AS TDate,a.ProvNum,a.AdjAmt AS TranAmount,0 AS Writeoff
FROM adjustment a
INNER JOIN patient p ON p.Patnum=a.PatNum
INNER JOIN definition d ON d.DefNum=p.BillingType
INNER JOIN provider prov ON a.ProvNum=prov.ProvNum
WHERE a.AdjDate BETWEEN @FromDate AND @ToDate
AND d.ItemName LIKE @BillingType
AND prov.Abbr LIKE @ProviderAbbr
UNION ALL
/*PatInc*/
SELECT 'PatPay' AS TranType, ps.DatePay AS TDate,ps.ProvNum,ps.SplitAmt AS TranAmount,0 AS Writeoff
FROM paysplit ps
INNER JOIN patient p ON p.Patnum=ps.PatNum
INNER JOIN definition d ON d.DefNum=p.BillingType
INNER JOIN provider prov ON ps.ProvNum=prov.ProvNum
WHERE ps.IsDiscount=0 AND ps.DatePay BETWEEN @FromDate AND @ToDate
AND d.ItemName LIKE @BillingType
AND prov.Abbr LIKE @ProviderAbbr
UNION ALL
/*InsIncome*/
SELECT 'InsPay' AS TranType,cp.DateCP AS TDate,cp.ProvNum,cp.InsPayAmt AS TranAmount,0
FROM claimproc cp
INNER JOIN claimpayment cpm ON cp.ClaimPaymentNum=cpm.ClaimPaymentNum
INNER JOIN patient p ON p.Patnum=cp.PatNum
INNER JOIN definition d ON d.DefNum=p.BillingType
INNER JOIN provider prov ON cp.ProvNum=prov.ProvNum
WHERE cp.DateCP BETWEEN @FromDate AND @ToDate
AND d.ItemName LIKE @BillingType
AND prov.Abbr LIKE @ProviderAbbr
AND cp.Status IN(1,4)
UNION ALL
/*Writeoff*/
SELECT 'Writeoff' AS TranType,cp.DateCP AS TDate,cp.ProvNum,0 AS TranAmount,-cp.WriteOff AS Writeoff
FROM claimproc cp
INNER JOIN patient p ON p.Patnum=cp.PatNum
INNER JOIN definition d ON d.DefNum=p.BillingType
INNER JOIN provider prov ON cp.ProvNum=prov.ProvNum
WHERE cp.DateCP BETWEEN @FromDate AND @ToDate
AND d.ItemName LIKE @BillingType
AND prov.Abbr LIKE @ProviderAbbr
AND cp.Status IN(1,4)
UNION ALL
/*Capitation*/
SELECT 'Cap' AS TranType,cp.DateCP AS TDate,cp.ProvNum,cp.InsPayAmt AS TranAmount,-cp.Writeoff AS Writeoff
FROM claimproc cp
INNER JOIN patient p ON p.Patnum=cp.PatNum
INNER JOIN definition d ON d.DefNum=p.BillingType
INNER JOIN provider prov ON cp.ProvNum=prov.ProvNum
WHERE cp.Status=7
AND d.ItemName LIKE @BillingType
AND prov.Abbr LIKE @ProviderAbbr
AND cp.DateCP BETWEEN @FromDate AND @ToDate
) Trans
GROUP BY Trans.TDate
UNION ALL
SELECT 5 AS ItemOrder,
'-------------' AS DATE,
NULL AS $Prod_,
NULL AS $Adjust_,
NULL AS $Writeoff_,
NULL AS $TotProd_,
NULL AS $PatIncome_,
NULL AS $InsIncome_,
NULL AS $TotIncome_
UNION ALL
SELECT 4 AS ItemOrder,
CONCAT('ProviderAbbr: ',REPLACE(@ProviderAbbr,'%','')) AS DATE,
NULL AS $Prod_,
NULL AS $Adjust_,
NULL AS $Writeoff_,
NULL AS $TotProd_,
NULL AS $PatIncome_,
NULL AS $InsIncome_,
NULL AS $TotIncome_
UNION ALL
SELECT 3 AS ItemOrder,
CONCAT('BillingType: ',REPLACE(@BillingType,'%','')) AS DATE,
NULL AS $Prod_,
NULL AS $Adjust_,
NULL AS $Writeoff_,
NULL AS $TotProd_,
NULL AS $PatIncome_,
NULL AS $InsIncome_,
NULL AS $TotIncome_
UNION ALL
SELECT 2 AS ItemOrder,
CONCAT('ToDate: ',DATE_FORMAT(@ToDate,'%m/%d/%Y')) AS DATE,
NULL AS $Prod_,
NULL AS $Adjust_,
NULL AS $Writeoff_,
NULL AS $TotProd_,
NULL AS $PatIncome_,
NULL AS $InsIncome_,
NULL AS $TotIncome_
UNION ALL
SELECT 1 AS ItemOrder,
CONCAT('FromDate: ',DATE_FORMAT(@FromDate,'%m/%d/%Y')) AS DATE,
NULL AS $Prod_,
NULL AS $Adjust_,
NULL AS $Writeoff_,
NULL AS $TotProd_,
NULL AS $PatIncome_,
NULL AS $InsIncome_,
NULL AS $TotIncome_
) A
ORDER BY ItemOrder,DATE;
Patients seen in the last 3 years with Address, City, State, Zip, Birthdate, Date of last visit, and Primary and Secondary insurance carrier names -
/*753 Patients seen in the last 3 years with Address, City, State, Zip, Birthdate, Date of last visit, and Primary and Secondary insurance carrier names.*/
SELECT p.LName,p.FName,
p.Address,p.Address2,p.City,p.State,p.Zip,
p.Birthdate,
lastvisit.LDate AS 'DateLastVisit',
carrier1.CarrierName AS 'PrimaryInsCarrier',
carrier2.CarrierName AS 'SecondaryInsCarrier'
FROM patient p
INNER JOIN (
SELECT PatNum,MAX(pl.ProcDate) AS LDate
FROM procedurelog pl
WHERE pl.ProcStatus=2
GROUP BY PatNum
) lastvisit ON lastvisit.Patnum=p.PatNum AND lastvisit.LDate>(CURDATE()-INTERVAL 3 YEAR)
LEFT JOIN patplan pp1 ON pp1.PatNum=p.PatNum AND pp1.ORDINAL=1 /*by current primary insurance*/
LEFT JOIN inssub iss1 ON pp1.InsSubNum=iss1.InsSubNum
LEFT JOIN insplan ip1 ON ip1.PlanNum=iss1.PlanNum
LEFT JOIN carrier carrier1 ON carrier1.CarrierNum=ip1.CarrierNum
LEFT JOIN patplan pp2 ON pp2.PatNum=p.PatNum AND pp2.ORDINAL=2 /*by current secondary insurance*/
LEFT JOIN inssub iss2 ON pp2.InsSubNum=iss2.InsSubNum
LEFT JOIN insplan ip2 ON ip2.PlanNum=iss2.PlanNum
LEFT JOIN carrier carrier2 ON carrier2.CarrierNum=ip2.CarrierNum
WHERE p.PatStatus=0
ORDER BY p.LName,p.FName,Birthdate ASC
Outstanding Insurance Claims older than 1 day old with PatNum,MedicaidID,Birthdate and Subscriber's SSN -
/*754 Outstanding Insurance Claims older than 1 day old with PatNum,MedicaidID,Birthdate and Subscriber's SSN*/
SELECT car.CarrierName,
p.MedicaidID,
sub.SSN AS 'SubscriberSSN',
p.Birthdate,
p.PatNum AS 'Pat#',
CONCAT(p.LName,', ',p.FName) AS 'PatientName',
(CASE WHEN c.ClaimType='P' THEN 'Primary'
WHEN c.ClaimType='S' THEN 'Secondary'
WHEN c.ClaimType='Cap' THEN 'Capitation'
ELSE c.ClaimType
END) AS ClaimType,
c.DateService,
c.DateSent,
c.ClaimFee AS '$Amount_'
FROM claim c
INNER JOIN patient p ON p.PatNum=c.PatNum
INNER JOIN insplan ip ON ip.PlanNum=c.PlanNum
INNER JOIN carrier car ON car.CarrierNum=ip.CarrierNum
INNER JOIN inssub iss ON iss.InsSubNum=c.InsSubNum
INNER JOIN patient sub ON sub.PatNum=iss.Subscriber
WHERE c.ClaimStatus='S'
AND c.DateSent < (CURDATE() - INTERVAL 1 DAY)
AND c.ClaimType != 'PreAuth'
ORDER BY car.CarrierName,c.DateService;
Shows all transactions for the date set, MTD totals, YTD totals and A/R as of date set. - A/R for version before 14.3
/*755 Shows all transactions for the date set, MTD totals, YTD totals and A/R as of date set.*/
SET @Date='2019-06-03';/*<----SET DATE HERE---*/ /*Use CURDATE() for current date*/
SELECT CONCAT('Day Sheet For: ',DATE_FORMAT(@Date,'%m/%d/%Y')) AS 'ID - Name','' AS Dr,'' AS Description,
'' AS TxArea,NULL AS Charge,NULL AS Adjust,NULL AS Writeoff,NULL AS Payment
UNION ALL
SELECT '' AS 'ID - Name','' AS Dr,'' AS Description,'' AS TxArea,NULL AS Charge,NULL AS Adjust,NULL AS Writeoff,NULL AS Payment
UNION ALL
SELECT CONCAT(AllTrans.PatNum,' - ',AllTrans.LName,', ',AllTrans.FName) AS 'ID - Name',pv.Abbr AS Dr,
LEFT(AllTrans.Description,35) AS Description,AllTrans.TxArea,FORMAT(AllTrans.Charge,2) AS Charge,FORMAT(AllTrans.Adjust,2) AS Adjust,FORMAT(-AllTrans.Writeoff,2) AS Writeoff,
FORMAT(-AllTrans.Payment,2) AS Payment
FROM (
SELECT p.PatNum,p.LName,p.FName,A.ProvNum,
(CASE WHEN A.TranType='Fee' THEN CONCAT(pc.ProcCode,' - ',pc.Descript)
WHEN A.TranType IN('Pay','Adj') THEN CONCAT(A.TranType,' - ',d.ItemName)
WHEN A.TranType='Writeoff' THEN CONCAT(A.TranType,' - ',c.CarrierName)
ELSE 'Payment Plan' END) AS Description,
(CASE WHEN A.TranType='Fee' AND (pc.TreatArea IN(4,5,6)) THEN A.Surf
WHEN A.TranType='Fee' AND pc.TreatArea=1 THEN CONCAT(A.ToothNum, ", ", A.Surf)
WHEN A.TranType='Fee' AND pc.TreatArea=2 THEN A.ToothNum
WHEN A.TranType='Fee' AND pc.TreatArea=7 THEN A.ToothRange
WHEN A.TranType='Fee' AND pc.TreatArea NOT IN(1,2,4,5,6,7) THEN 'Mouth'
ELSE '' END) AS TxArea,
(CASE WHEN A.TranType='Fee' THEN A.TranAmount ELSE NULL END) AS Charge,
(CASE WHEN A.TranType='Adj' THEN A.TranAmount ELSE NULL END) AS Adjust,
NULL AS Writeoff,
(CASE WHEN A.TranType='Pay' THEN A.TranAmount ELSE NULL END) AS Payment
FROM (
/*transaction table*/
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount,pl.ProvNum ProvNum,pl.CodeNum CODE,pl.Surf Surf,pl.ToothNum ToothNum,pl.ToothRange ToothRange
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum PatNum,ps.DatePay TranDate,-ps.SplitAmt TranAmount,ps.ProvNum ProvNum,p.PayType CODE,NULL,NULL,NULL
FROM paysplit ps
LEFT JOIN payment p ON p.PayNum=ps.PayNum
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
AND ps.SplitAmt<>0
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount,a.ProvNum ProvNum,a.AdjType CODE,NULL,NULL,NULL
FROM adjustment a
) A
INNER JOIN patient p ON p.PatNum=A.PatNum
LEFT JOIN procedurecode pc ON pc.CodeNum=A.Code
LEFT JOIN definition d ON d.DefNum=A.Code
LEFT JOIN carrier c ON c.CarrierNum=A.Code
WHERE A.TranDate=@Date
UNION ALL
(
SELECT p.PatNum,p.LName,p.FName,A.ProvNum,
CONCAT(A.TranType,' - ',c.CarrierName) AS Description,
'' AS TxArea,NULL AS Charge,NULL AS Adjust,
(CASE WHEN A.TranType='Writeoff' THEN A.TranAmount ELSE NULL END) AS Writeoff,
(CASE WHEN A.TranType='InsPay' THEN A.TranAmount ELSE NULL END) AS Payment
FROM (
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum PatNum,cp.DateCp TranDate,-SUM(cp.InsPayAmt) TranAmount,cp.ProvNum ProvNum,ip.CarrierNum CODE
FROM claimproc cp
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
WHERE cp.Status IN (1,4)/*received, supplemental*/
AND cp.InsPayAmt<>0
GROUP BY cp.PatNum,cp.DateCp
UNION ALL
/*Claim writeoffs for the entire office history*/
SELECT 'Writeoff' AS TranType,cp.PatNum PatNum,cp.DateCp TranDate,-cp.Writeoff TranAmount,cp.ProvNum ProvNum,ip.CarrierNum CODE
FROM claimproc cp
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
WHERE cp.Status IN (1,4)/*received, supplemental*/
AND cp.Writeoff<>0
) A
INNER JOIN patient p ON p.PatNum=A.PatNum
LEFT JOIN carrier c ON c.CarrierNum=A.Code
WHERE A.TranDate=@Date
)
ORDER BY LName,FName,Description
) AllTrans
LEFT JOIN provider pv ON pv.ProvNum=AllTrans.ProvNum
UNION ALL
SELECT '','','','----------','-------------','-------------','-------------','-------------'
UNION ALL
SELECT '','','','Totals:' AS TxArea,
FORMAT((CASE WHEN ABS(B.Charge)>0.01 THEN B.Charge ELSE 0 END),2) AS Charge,
FORMAT((CASE WHEN ABS(B.Adjust)>0.01 THEN B.Adjust ELSE 0 END),2) AS Adjust,
FORMAT((CASE WHEN ABS(B.Writeoff)>0.01 THEN B.Writeoff ELSE 0 END),2) AS Writeoff,
FORMAT((CASE WHEN ABS(B.Payment)>0.01 THEN B.Payment ELSE 0 END),2) AS Payment
FROM
(
SELECT SUM(CASE WHEN A.TranType='Fee' THEN A.TranAmount ELSE 0 END) AS Charge,
SUM(CASE WHEN A.TranType='Adj' THEN A.TranAmount ELSE 0 END) AS Adjust,
-SUM(CASE WHEN A.TranType='Writeoff' THEN A.TranAmount ELSE 0 END) AS Writeoff,
-SUM(CASE WHEN A.TranType IN('Pay','InsPay') THEN A.TranAmount ELSE 0 END) AS Payment
FROM (
/*transaction table*/
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount,pl.ProvNum ProvNum,pl.CodeNum CODE,pl.Surf Surf,pl.ToothNum ToothNum,pl.ToothRange ToothRange
FROM procedurelog pl
WHERE pl.ProcStatus=2
UNION ALL
/*Paysplits for the entire office history*/
SELECT 'Pay' AS TranType,ps.PatNum PatNum,ps.DatePay TranDate,-ps.SplitAmt TranAmount,ps.ProvNum ProvNum,p.PayType CODE,NULL,NULL,NULL
FROM paysplit ps
LEFT JOIN payment p ON p.PayNum=ps.PayNum
WHERE ps.PayPlanNum=0 /*Only splits not attached to payment plans*/
UNION ALL
/*Claim payments for the entire office history*/
SELECT 'InsPay' AS TranType,cp.PatNum PatNum,cp.DateCp TranDate,-cp.InsPayAmt TranAmount,cp.ProvNum ProvNum,ip.CarrierNum CODE,NULL,NULL,NULL
FROM claimproc cp
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
WHERE cp.Status IN (1,4)/*received, supplemental*/
UNION ALL
/*Get the adjustment dates and amounts for the entire office history*/
SELECT 'Adj' AS TranType,a.PatNum PatNum,a.AdjDate TranDate,a.AdjAmt TranAmount,a.ProvNum ProvNum,a.AdjType CODE,NULL,NULL,NULL
FROM adjustment a
UNION ALL
/*Claim writeoffs for the entire office history*/
SELECT 'Writeoff' AS TranType,cp.PatNum PatNum,cp.DateCp TranDate,-cp.Writeoff TranAmount,cp.ProvNum ProvNum,ip.CarrierNum CODE,NULL,NULL,NULL
FROM claimproc cp
LEFT JOIN claim cl ON cl.ClaimNum=cp.ClaimNum
LEFT JOIN insplan ip ON ip.PlanNum=cl.PlanNum
WHERE cp.Status IN (1,4)/*received, supplemental*/
) A
WHERE A.TranDate=@Date
AND A.TranAmount<>0
) B
UNION ALL
SELECT '','','','----------','-------------','-------------','-------------','-------------'
UNION ALL
SELECT '','','','MTD:' AS TxArea,
FORMAT((CASE WHEN ABS(B.Charge)>0.01 THEN B.Charge ELSE 0 END),2) AS Charge,
FORMAT((CASE WHEN ABS(B.Adjust)>0.01 THEN B.Adjust ELSE 0 END),2) AS Adjust,
FORMAT((CASE WHEN ABS(B.Writeoff)>0.01 THEN B.Writeoff ELSE 0 END),2) AS Writeoff,
FORMAT((CASE WHEN ABS(B.Payment)>0.01 THEN B.Payment ELSE 0 END),2) AS Payment
FROM
(
SELECT SUM(CASE WHEN A.TranType='Fee' THEN A.TranAmount ELSE 0 END) AS Charge,
SUM(CASE WHEN A.TranType='Adj' THEN A.TranAmount ELSE 0 END) AS Adjust,
-SUM(CASE WHEN A.TranType='Writeoff' THEN A.TranAmount ELSE 0 END) AS Writeoff,
-SUM(CASE WHEN A.TranType IN('Pay','InsPay') THEN A.TranAmount ELSE 0 END) AS Payment
FROM (
/*transaction table*/
/*Get the completed procedure dates and charges for the entire office history*/
SELECT 'Fee' AS TranType,pl.PatNum PatNum,pl.ProcDate TranDate,pl.ProcFee*(pl.UnitQty+pl.BaseUnits) TranAmount,pl.ProvNum ProvNum,pl.CodeNum CODE,pl.Surf Surf,pl.ToothNum ToothNum,pl.ToothRange ToothRange
FROM procedu
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment