SQL: Immunizations by Age 2 - HEDIS Combo 2

There are two versions of this SQL: Firebird and MySQL. The MySQL version only applies to clients who are have migrated to MySQL.. All other Practices should continue to use the Firebird version of this code. Click to expand and copy the code you need. If you are unsure which code to use, please check with your Practice Administrator.

About

This report 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 to see whether they pass or fail the HEDIS CIS-2 metric.

Combination
DTap
IPV
MMR
HiB
Hep B
VZV
PCV
Hep A
RV
Influenza
Combination 2
4
3
1
3
3
1
-
-
-
-

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

Caveats

  • The listed provider is the PCP according to the Register (F2).
  • 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.
  • The influenza antigens are not listed in this report.

SQL Code: Firebird

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 and t.mmr >=1 and t.vzv>=1 and t.hib >=3 and t.ipv >=3 and t.hepB >=3) 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, rota.total_cvx as rota, 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 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) rota on rota.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
) t
order by ins_carrier_code


SQL Code: MySQL

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 and t.mmr >=1 and t.vzv>=1 and t.hib >=3 and t.ipv >=3 and t.hepB >=3) 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, rota.total_cvx as rota, 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 from
(
select patno, birthdat, staffname, ins_carrier_code, (timestampdiff(month,birthdat,curdate()))/12 as age from register
inner join staff1 on staff1.staffid=register.addr_id
where status_pat = 'ACTIVE'  and  (timestampdiff(month,birthdat,curdate()))/12  >= 1.8 and  (timestampdiff(month,birthdat,curdate()))/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) rota on rota.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
) t
order by ins_carrier_code