Higher dose Proton Pump Inhibitors (PPIs)

Below are the database queries which are used to create this measure. These are run against a copy of the BSA prescribing data which we store in Google BigQuery. We're working on making our BigQuery tables publicly available at which point it will be possible to run and modify these queries yourself. But even where code and database queries are not directly useable by others we believe it is always preferable to make them public.

Description Prescribing of higher dose Proton Pump Inhibitors compared with prescribing of all PPIs (excluding liquids)
Why it matters PPIs are used to reduce acid levels in the stomach, in order to treat conditions such as gastro-oesophageal reflux disease. NICE guidance recommends that the lowest dose is used to treat the symptoms. Although PPIs are safe drugs, their use has been associated with an increase in a number of disorders, including Clostridium difficile infection and a higher risk of community-aquired pneunmonia. This measure looks at strengths of PPIs issued that exceed the low doses of PPIs defined in the NICE guidance.
Tags Standard, Gastrointestinal system, NICE, Safety
Implies cost savings No
Authored by richard.croker
Checked by andrew.brown
Last reviewed 2024-08-09
Next review due 2025-08-09
History View change history on GitHub →

Numerator SQL

SELECT
     CAST(month AS DATE) AS month,
     practice AS practice_id,
     SUM(p.items) AS numerator
 FROM hscic.normalised_prescribing p  INNER JOIN dmd.vmp vmp ON CONCAT(SUBSTR(p.bnf_code,0,9),'AA', SUBSTR(p.bnf_code,-2), SUBSTR(p.bnf_code,-2)) = vmp.bnf_code -- joins prescribing data to vmp table using generic BNF code 
 INNER JOIN dmd.vpi AS vpi ON vmp.id = vpi.vmp -- joins vmp to vpi table to get ingredient strengths (strnt_nmrtr_val) 
 INNER JOIN dmd.ont AS ont ON vmp.id = ont.vmp -- joins vmp to ont table to get formulation codes 
 INNER JOIN dmd.ontformroute AS route ON ont.form = route.cd -- joins ont table to ontform table to get formulation names
 WHERE route.descr IN ( 'tablet.oral', 'tabletgastro-resistant.oral', 'capsulegastro-resistant.oral', 'tabletdispersiblegastro-resistant.oral' ) AND ( COALESCE(vpi.bs_subid, vpi.ing) = 396047003 # Esomeprazole - all salts (all strengths) (ing code) 
 OR ( COALESCE(vpi.bs_subid, vpi.ing) = 386888004 AND strnt_nmrtr_val/COALESCE(strnt_dnmtr_val,1) >15 # Lansoprazole (strengths higher than 15mg) (ing code) 
 ) OR ( COALESCE(vpi.bs_subid, vpi.ing) = 387137007 AND strnt_nmrtr_val/COALESCE(strnt_dnmtr_val,1) >10 # Omeprazole - all salts (strengths higher than 10mg) (ing code) 
 ) OR ( COALESCE(vpi.bs_subid, vpi.ing) = 395821003 AND strnt_nmrtr_val/COALESCE(strnt_dnmtr_val,1) >20 # Pantoprazole - all salts (strengths higher than 20mg) (ing code) 
 ) OR ( COALESCE(vpi.bs_subid, vpi.ing) = 387013009 # Rabeprazole sodium (strengths higher than 10mg) (ing code) 
 AND strnt_nmrtr_val/COALESCE(strnt_dnmtr_val,1) >10 ) )
 GROUP BY month, practice_id

Denominator SQL

SELECT
     CAST(month AS DATE) AS month,
     practice AS practice_id,
     SUM(p.items) AS denominator
 FROM hscic.normalised_prescribing p  INNER JOIN dmd.vmp vmp ON CONCAT(SUBSTR(p.bnf_code,0,9),'AA', SUBSTR(p.bnf_code,-2), SUBSTR(p.bnf_code,-2)) = vmp.bnf_code -- joins prescribing data to vmp table using generic BNF code 
 INNER JOIN dmd.vpi AS vpi ON vmp.id = vpi.vmp -- joins vmp to vpi table to get ingredient strengths (strnt_nmrtr_val) 
 INNER JOIN dmd.ont AS ont ON vmp.id = ont.vmp -- joins vmp to ont table to get formulation codes 
 INNER JOIN dmd.ontformroute AS route ON ont.form = route.cd -- joins ont table to ontform table to get formulation names
 WHERE route.descr IN ( 'tablet.oral', 'tabletgastro-resistant.oral', 'capsulegastro-resistant.oral', 'tabletdispersiblegastro-resistant.oral' ) AND ( COALESCE(vpi.bs_subid, vpi.ing) = 396047003 # Esomeprazole - all salts (all strengths) (ing code) 
 OR COALESCE(vpi.bs_subid, vpi.ing) = 386888004 # Lansoprazole (all strengths) (ing code) 
 OR COALESCE(vpi.bs_subid, vpi.ing) = 387137007 # Omeprazole - all salts (all strengths) (ing code) 
 OR COALESCE(vpi.bs_subid, vpi.ing) = 395821003 # Pantoprazole - all salts (all strengths) (ing code) 
 OR COALESCE(vpi.bs_subid, vpi.ing) = 387013009 # Rabeprazole sodium (all strengths) (ing code) 
 )
 GROUP BY month, practice_id
Feedback