SQL: Childhood Immunization (Combo 10)

About

This report looks for active patients who are (on the run date of the report) between the ages of 1.8 years (that is 21.6 months) and not yet 2 years and looks to see whether they pass or fail.

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

Caveats

  • The Provider shown is the PCP according to the patient's Basic Information.
  • It looks at all vaccines, both historical and administered by the Practice.
  • Even if a vaccine refusal is documented in OP, it does not change the calculations as per HEDIS specifications.
  • It also lists children who are, as of TODAY, between 1.8 years old (that is, 21.6 months) but not yet 2 years old. If you want to look at a different cohort based on how old they are now, you can change the 1.8 and 2.

Code

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

select t.patno, t.ins_carrier_code, t.age, t.staffname, 
case when t.dtap >=4 then 'pass' else 'fail' end as dtap_det, case when t.mmr >=1 then 'pass' else 'fail' end mmr_det, 
case when t.pcv >=4 then 'pass' else 'fail' end as pcv_det, 
case when t.vzv>=1 then 'pass' else 'fail' end as vzv_det,
case when t.hib >=3 then 'pass' else 'fail' end as hib_det,
case when t.hepA >=1 then 'pass' else 'fail' end as hepA_det,
 case when t.hepB >=3 then 'pass' else 'fail' end as hepB_det,case when t.ipv >=3 then 'pass' else 'fail' end as ipv_det,
case when t.rotatotal >=2 then 'pass' else 'fail' end as rota_det,
case when t.flu >=2 then 'pass' else 'fail' end as flu_det,
case when (t.dtap>=4 and t.mmr >=1 and t.vzv>=1 and t.pcv>=4 and t.hib >=3 and t.ipv >=3 and t.hepB >=3 and t.rotatotal>=2 and t.flu>=2 and t.hepA>=1) then 'pass' else 'fail' end as CIS_complete 
from
(
select r.patno, r.birthdat, r.ins_carrier_code, r.age, r.staffname, mmr.total_cvx as mmr, vzv.total_cvx as vzv, rotatotal.total_cvx as rotatotal, pcv.total_cvx as pcv, hepa.total_cvx as hepa, hepB.total_cvx as hepB, ipv.total_cvx as ipv, hib.total_cvx as hib, dtap.total_cvx as dtap, flu.total_cvx as flu from
(
select patno, birthdat, staffname, ins_carrier_code, datediff(month,birthdat,cast('today' as date))/12 as age from register
inner join staff1 on staff1.staffid=register.addr_id
where status_pat = 'ACTIVE'  and  datediff(month,birthdat,cast('today' as date))/12 > 1.8 and  datediff(month,birthdat,cast('today' as date))/12 <2
) r
left outer join (select patno,  count(cvxcode) as total_cvx from vaccine1 where cvxcode in ('03','94') group by patno ) mmr on mmr.patno = r.patno
left outer join (select patno,  count(cvxcode) as total_cvx from vaccine1 where cvxcode in ('21','94') group by patno) vzv on vzv.patno = r.patno
left outer join (select patno,  count(cvxcode) as total_cvx from vaccine1 where cvxcode in ('119','116') group by patno) rotatotal on rotatotal.patno = r.patno
left outer join (select patno, count(cvxcode) as total_cvx from vaccine1 where cvxcode in ('20','50','106','120','110') group by patno) dtap on dtap.patno = r.patno
left outer join (select patno,  count(cvxcode) as total_cvx from vaccine1 where cvxcode in ('133') group by patno) pcv on pcv.patno = r.patno
left outer join (select patno, count(cvxcode) as total_cvx from vaccine1 where cvxcode in ('50','46','47','48','49','51','120') group by patno) hib on hib.patno = r.patno
left outer join (select patno, count(cvxcode) as total_cvx from vaccine1 where cvxcode in ('83') group by patno) hepA on hepa.patno = r.patno
left outer join (select patno, count(cvxcode) as total_cvx from vaccine1 where cvxcode in ('110','51','08','44') group by patno) hepB on hepB.patno = r.patno
left outer join (select patno, count(cvxcode) as total_cvx from vaccine1 where cvxcode in ('110','120','10') group by patno) ipv on ipv.patno = r.patno
left outer join (select patno, count(cvxcode) as total_cvx from vaccine1 where cvxcode in ('149','15','150','151','153','155','158','160','161','166','168','171','185','186','197','200','201') group by patno) flu on flu.patno = r.patno
) t
order by ins_carrier_code