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 disposable insulin devices as percentage of all insulin prescribing |
---|---|
Why it matters | |
Tags | |
Implies cost savings | No |
History | View change history on GitHub → |
SELECT
CAST(month AS DATE) AS month,
practice AS practice_id,
SUM(items) AS numerator
FROM hscic.normalised_prescribing p INNER JOIN dmd.vmp v --this joins data table to dm+d vmp table
ON CONCAT(SUBSTR(p.bnf_code,0,9),SUBSTR(p.bnf_code,-2)) = CONCAT(SUBSTR(v.bnf_code,0,9),SUBSTR(v.bnf_code,-2)) --joins both brand and generics to vmp table
INNER JOIN dmd.vtm t --this joins VMP table to VTM table
ON v.vtm = t.id INNER JOIN dmd.unitofmeasure u --this joins to unit of measure table to get device details
ON v.unit_dose_uom = u.cd
WHERE lOWER(t.nm) LIKE '%insulin%' -- filters to any insulin
and LOWER(u.descr) = 'pre-filled disposable injection' -- filters to disposable pens
GROUP BY month, practice_id
SELECT
CAST(month AS DATE) AS month,
practice AS practice_id,
SUM(items) AS denominator
FROM hscic.normalised_prescribing p INNER JOIN dmd.vmp v --this joins data table to dm+d vmp table
ON CONCAT(SUBSTR(p.bnf_code,0,9),SUBSTR(p.bnf_code,-2)) = CONCAT(SUBSTR(v.bnf_code,0,9),SUBSTR(v.bnf_code,-2)) --joins both brand and generics to vmp table
INNER JOIN dmd.vtm t --this joins VMP table to VTM table
ON v.vtm = t.id INNER JOIN dmd.unitofmeasure u --this joins to unit of measure table to get device details
ON v.unit_dose_uom = u.cd
WHERE lOWER(t.nm) LIKE '%insulin%' -- filters to any insulin
and LOWER(u.descr) IN('pre-filled disposable injection', 'cartridge') -- filters to disposable pens and catridges
GROUP BY month, practice_id