Low and medium intensity statins

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 Items of low and medium intensity statins as a percentage of items of all statins.
Why it matters NICE guidance on lipid modification recommends the use of a high-intensity statin (i.e. one that reduces LDL cholesterol by 40% or more). A table showing the percentage reduction of LDL cholesterol by statin doses can be found in the BNF and you can read our research paper on suboptimal statin treatment regimens in the British Journal of General Practice.Please note, we have excluded liquid preparations from this measure.
Tags Cardiovascular system, Standard, Efficacy, NICE
Implies cost savings No
Authored by richard.croker
Checked by andrew.brown
Last reviewed 2024-02-12
Next review due 2025-02-12
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 ('capsule.oral','tablet.oral','tabletchewable.oral','tabletmodified-release.oral') -- selects only solid dose form oral formulations 
 AND ((vpi.ing = 725658002 AND strnt_nmrtr_val/(COALESCE(strnt_dnmtr_val,1)) <20) --Atorvastatin calcium trihydrate (strengths lower than 20mg) (ing code) 
 OR (vpi.ing = 406435003 AND strnt_nmrtr_val/(COALESCE(strnt_dnmtr_val,1))<10) --Rosuvastatin calcium (strengths lower than 10mg) (ing code) 
 OR (vpi.ing = 387584000 AND strnt_nmrtr_val/(COALESCE(strnt_dnmtr_val,1)) <80) --Simvastatin (strengths lower than 80mg) (ing code) 
 OR vpi.ing = 108597004 --Cerivastatin sodium (all strengths) (ing code) 
 OR vpi.ing = 412392009 --Fluvastatin sodium (all strengths) (ing code) 
 OR vpi.ing = 96306007) --Pravastatin sodium (all strengths) (ing code)
 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 ('capsule.oral','tablet.oral','tabletchewable.oral','tabletmodified-release.oral') -- selects only solid dose form oral formulations 
 AND (vpi.ing = 725658002 --Atorvastatin calcium trihydrate (all strengths) (ing code) 
 OR vpi.ing = 406435003 --Rosuvastatin calcium (all strengths) (ing code) 
 OR vpi.ing = 387584000 --Simvastatin (all strengths) (ing code) 
 OR vpi.ing = 108597004 --Cerivastatin sodium (all strengths) (ing code) 
 OR vpi.ing = 412392009 --Fluvastatin sodium (all strengths) (ing code) 
 OR vpi.ing = 96306007) --Pravastatin sodium (all strengths) (ing code)
 GROUP BY month, practice_id
Feedback