Skip to content

Commit

Permalink
Merge pull request #200 from rw251/update-height-query
Browse files Browse the repository at this point in the history
Update height and weight queries
  • Loading branch information
Georgetilston committed Mar 15, 2024
2 parents 393c72a + c703665 commit e627740
Show file tree
Hide file tree
Showing 4 changed files with 167 additions and 15 deletions.
@@ -0,0 +1,48 @@
{if:verbose}
--┌───────────────────────────────────────────────────┐
--│ Find the closest diagnosis to a particular date │
--└───────────────────────────────────────────────────┘

-- OBJECTIVE: To find the closest diagnosis for a particular disease and a given date.

-- INPUT: A variable:
-- - date: date - (YYYY-MM-DD) the date to look around
-- - comparison: inequality sign (>, <, >= or <=) e.g. if '>' then will look for the first value strictly after the date
-- - all-patients: boolean - (true/false) if true, then all patients are included, otherwise only those in the pre-existing #Patients table.
-- - gp-events-table: string - (table name) the name of the table containing the GP events. Usually is "SharedCare.GP_Events" but can be anything with the columns: FK_Patient_Link_ID, EventDate, and SuppliedCode
-- - code-set: string - the name of the code set to be used. Must be one from the repository.
-- - version: number - the code set version
-- - temp-table-name: string - the name of the temp table that this will produce

-- OUTPUT: Temp tables as follows:
-- (temp table name specified in parameter) FK_Patient_Link_ID, EventDate
{endif:verbose}

--> CODESET {param:code-set}:{param:version}

-- First we get the date of the nearest {param:code-set} diagnosis before/after the specified date

IF OBJECT_ID('tempdb..{param:temp-table-name}') IS NOT NULL DROP TABLE {param:temp-table-name};
{if:comparison=>}
SELECT FK_Patient_Link_ID, MIN(EventDate) AS EventDate
{endif:comparison}
{if:comparison=>=}
SELECT FK_Patient_Link_ID, MIN(EventDate) AS EventDate
{endif:comparison}
{if:comparison=<}
SELECT FK_Patient_Link_ID, MAX(EventDate) AS EventDate
{endif:comparison}
{if:comparison=<=}
SELECT FK_Patient_Link_ID, MAX(EventDate) AS EventDate
{endif:comparison}
INTO {param:temp-table-name}
FROM {param:gp-events-table}
WHERE SuppliedCode IN (SELECT code FROM #AllCodes WHERE Concept = '{param:code-set}' AND Version = {param:version})
AND EventDate {param:comparison} '{param:date}'
{if:patients}
AND p.FK_Patient_Link_ID IN (SELECT FK_Patient_Link_ID FROM {param:patients})
{endif:patients}
{if:all-patients=false}
AND p.FK_Patient_Link_ID IN (SELECT FK_Patient_Link_ID FROM #Patients)
{endif:all-patients}
GROUP BY FK_Patient_Link_ID;
Expand Up @@ -3,9 +3,12 @@
--│ Find the closest value to a particular date │
--└───────────────────────────────────────────────┘

-- OBJECTIVE: To find the first diagnosis for a particular disease for every patient.
-- OBJECTIVE: To find the closest value for a particular test to a given date.

-- INPUT: A variable:
-- - min-value: number - the smallest permitted value. Values lower than this will be disregarded.
-- - max-value: number - the largest permitted value. Values higher than this will be disregarded.
-- - unit: string - if a particular unit is required can enter it here. If any then use '%'
-- - date: date - (YYYY-MM-DD) the date to look around
-- - comparison: inequality sign (>, <, >= or <=) e.g. if '>' then will look for the first value strictly after the date
-- - all-patients: boolean - (true/false) if true, then all patients are included, otherwise only those in the pre-existing #Patients table.
Expand Down Expand Up @@ -41,6 +44,10 @@ WHERE SuppliedCode IN (SELECT code FROM #AllCodes WHERE Concept = '{param:code-s
AND EventDate {param:comparison} '{param:date}'
AND [Value] IS NOT NULL
AND [Value] != '0'
AND Units LIKE '{param:unit}'
-- as these are all tests, we can ignore values values outside the specified range
AND TRY_CONVERT(DECIMAL(10,3), [Value]) >= {param:min-value}
AND TRY_CONVERT(DECIMAL(10,3), [Value]) <= {param:max-value}
GROUP BY FK_Patient_Link_ID;

-- Then we join to that table in order to get the value of that measurement
Expand Down
62 changes: 48 additions & 14 deletions shared/Reusable queries for data extraction/query-get-height.sql
Expand Up @@ -6,42 +6,76 @@
-- OBJECTIVE: Gets the most recent measurement of a person's height

-- INPUT: A variable:
-- - date: date - (yyyy-mm-dd) the date for which you want to find the most recent measurement
-- - all-patients: boolean - (true/false) if true, then all patients are included, otherwise only those in the pre-existing #Patients table.
-- - gp-events-table: string - (table name) the name of the table containing the GP events. Usually is "SharedCare.GP_Events" but can be anything with the columns: FK_Patient_Link_ID, EventDate, and SuppliedCode

-- OUTPUT: Temp table called #PatientHeight with columns:
-- - FK_Patient_Link_ID - unique patient id
-- - HeightInCentimetres - int - the most recent height in cm
-- - HeightDate - date (YYYY/MM/DD) - the date of the most recent height measurement
-- - HeightInCentimetres - int - the most recent height measurement before the specified date, in cm
-- - HeightDate - date (YYYY/MM/DD) - the date of the most recent height measurement before the specified date
{endif:verbose}

-- Height is almost always recorded in either metres or centimetres, so
-- first we get the most recent value for height where the unit is 'm'
--> EXECUTE query-get-most-recent-value.sql min-value:0.01 max-value:2.5 unit:m all-patients:{param:all-patients} gp-events-table:{param:gp-events-table} code-set:height version:1 max-or-min:max temp-table-name:#PatientHeightInMetres
--> EXECUTE query-get-closest-value-to-date.sql all-patients:{param:all-patients} min-value:0.01 max-value:2.5 unit:m date:{param:date} comparison:<= gp-events-table:{param:gp-events-table} code-set:height version:1 temp-table-name:#PatientHeightInMetres

-- Now we do the same but for 'cm'
--> EXECUTE query-get-most-recent-value.sql min-value:10 max-value:250 unit:cm all-patients:{param:all-patients} gp-events-table:{param:gp-events-table} code-set:height version:1 max-or-min:max temp-table-name:#PatientHeightInCentimetres

--> EXECUTE query-get-closest-value-to-date.sql all-patients:{param:all-patients} min-value:10 max-value:250 unit:cm date:{param:date} comparison:<= gp-events-table:{param:gp-events-table} code-set:height version:1 temp-table-name:#PatientHeightInCentimetres
-- NB the units are standardised so 'm' and 'cm' dominate. You do not get units like 'metres'.

-- now include records that don't have a unit value but have a height recording (there are only useful records with NULL for unit, not a blank value)

IF OBJECT_ID('tempdb..#PatientHeightNoUnitsTEMP1') IS NOT NULL DROP TABLE #PatientHeightNoUnitsTEMP1;
SELECT FK_Patient_Link_ID, MAX(EventDate) AS EventDate
INTO #PatientHeightNoUnitsTEMP1
FROM {param:gp-events-table}
WHERE Units IS NULL
AND Value IS NOT NULL
AND Value <> ''
AND TRY_CONVERT(DECIMAL(10,3), [Value]) != 0
AND EventDate <= '{param:date}'
AND SuppliedCode IN (SELECT code FROM #AllCodes WHERE Concept = 'height' AND Version = 1)
{if:all-patients=false}
AND FK_Patient_Link_ID IN (SELECT FK_Patient_Link_ID FROM #Patients)
{endif:all-patients}
GROUP BY FK_Patient_Link_ID

IF OBJECT_ID('tempdb..#PatientHeightNoUnits') IS NOT NULL DROP TABLE #PatientHeightNoUnits;
SELECT p.FK_Patient_Link_ID, p.EventDate AS DateOfFirstValue, MAX(p.Value) AS [Value]
INTO #PatientHeightNoUnits
FROM {param:gp-events-table} p
INNER JOIN #PatientHeightNoUnitsTEMP1 sub ON sub.FK_Patient_Link_ID = p.FK_Patient_Link_ID AND sub.EventDate = p.EventDate
WHERE SuppliedCode IN (SELECT code FROM #AllCodes WHERE Concept = 'height' AND Version = 1)
GROUP BY p.FK_Patient_Link_ID, p.EventDate;

-- Create the output PatientHeight temp table. We combine the m and cm tables from above
-- to find the most recent height for each person. We multiply the height in metres by 100
-- to standardise the output to centimetres.
IF OBJECT_ID('tempdb..#PatientHeight') IS NOT NULL DROP TABLE #PatientHeight;
SELECT
CASE WHEN hm.FK_Patient_Link_ID IS NULL THEN hcm.FK_Patient_Link_ID ELSE hm.FK_Patient_Link_ID END AS FK_Patient_Link_ID,
CASE
WHEN hm.FK_Patient_Link_ID IS NULL THEN hcm.MostRecentValue
WHEN hcm.FK_Patient_Link_ID IS NULL THEN hm.MostRecentValue * 100
WHEN hm.MostRecentDate > hcm.MostRecentDate THEN hm.MostRecentValue * 100
ELSE hcm.MostRecentValue
WHEN hm.FK_Patient_Link_ID IS NULL THEN TRY_CONVERT(DECIMAL(10,3), hcm.[Value])
WHEN hcm.FK_Patient_Link_ID IS NULL THEN TRY_CONVERT(DECIMAL(10,3), hm.[Value]) * 100
WHEN hm.DateOfFirstValue > hcm.DateOfFirstValue THEN TRY_CONVERT(DECIMAL(10,3), hm.[Value]) * 100
ELSE TRY_CONVERT(DECIMAL(10,3), hcm.[Value])
END AS HeightInCentimetres,
CASE
WHEN hm.FK_Patient_Link_ID IS NULL THEN hcm.MostRecentDate
WHEN hcm.FK_Patient_Link_ID IS NULL THEN hm.MostRecentDate
WHEN hm.MostRecentDate > hcm.MostRecentDate THEN hm.MostRecentDate
ELSE hcm.MostRecentDate
WHEN hm.FK_Patient_Link_ID IS NULL THEN hcm.DateOfFirstValue
WHEN hcm.FK_Patient_Link_ID IS NULL THEN hm.DateOfFirstValue
WHEN hm.DateOfFirstValue > hcm.DateOfFirstValue THEN hm.DateOfFirstValue
ELSE hcm.DateOfFirstValue
END AS HeightDate
INTO #PatientHeight
FROM #PatientHeightInCentimetres hcm
FULL JOIN #PatientHeightInMetres hm ON hm.FK_Patient_Link_ID = hcm.FK_Patient_Link_ID;
FULL JOIN #PatientHeightInMetres hm ON hm.FK_Patient_Link_ID = hcm.FK_Patient_Link_ID
UNION ALL
SELECT
hno.FK_Patient_Link_ID,
CASE WHEN (TRY_CONVERT(DECIMAL(10,3), [Value])) BETWEEN 0.01 AND 2.5
THEN (TRY_CONVERT(DECIMAL(10,3), [Value])) * 100
ELSE (TRY_CONVERT(DECIMAL(10,3), [Value]))
END,
HeightDate = DateOfFirstValue
FROM #PatientHeightNoUnits hno
63 changes: 63 additions & 0 deletions shared/Reusable queries for data extraction/query-get-weight.sql
@@ -0,0 +1,63 @@
{if:verbose}
--┌──────────────────────────┐
--│ Gets a patient's Weight │
--└──────────────────────────┘

-- OBJECTIVE: Gets the most recent measurement of a person's Weight, in kilograms

-- INPUT: A variable:
-- - date: date - (yyyy-mm-dd) the date for which you want to find the most recent measurement
-- - all-patients: boolean - (true/false) if true, then all patients are included, otherwise only those in the pre-existing #Patients table.
-- - gp-events-table: string - (table name) the name of the table containing the GP events. Usually is "SharedCare.GP_Events" but can be anything with the columns: FK_Patient_Link_ID, EventDate, and SuppliedCode

-- OUTPUT: Temp table called #PatientWeight with columns:
-- - FK_Patient_Link_ID - unique patient id
-- - WeightInKilograms - int - the most recent Weight measurement before the specified date, in kg
-- - WeightDate - date (YYYY/MM/DD) - the date of the most recent Weight measurement before the specified date
{endif:verbose}

-- Weight is almost always recorded in kilograms, so
-- first we get the most recent value for Weight where the unit is 'kg'
--> EXECUTE query-get-closest-value-to-date.sql all-patients:false min-value:0.1 max-value:500 unit:kg date:{param:date} comparison:<= gp-events-table:{param:gp-events-table} code-set:weight version:1 temp-table-name:#PatientWeightInKilograms

-- NB the units are standardised so 'kg' dominates. You do not get units like 'kilograms'.

-- now include records that don't have a unit value but have a Weight recording (there are only useful records with NULL for unit, not a blank value)

IF OBJECT_ID('tempdb..#PatientWeightNoUnitsTEMP1') IS NOT NULL DROP TABLE #PatientWeightNoUnitsTEMP1;
SELECT FK_Patient_Link_ID, MAX(EventDate) AS EventDate
INTO #PatientWeightNoUnitsTEMP1
FROM {param:gp-events-table}
WHERE Units IS NULL
AND Value IS NOT NULL
AND Value <> ''
AND TRY_CONVERT(DECIMAL(10,3), [Value]) BETWEEN 0.1 AND 500
AND EventDate <= '{param:date}'
AND SuppliedCode IN (SELECT code FROM #AllCodes WHERE Concept = 'weight' AND Version = 1)
{if:all-patients=false}
AND FK_Patient_Link_ID IN (SELECT FK_Patient_Link_ID FROM #Patients)
{endif:all-patients}
GROUP BY FK_Patient_Link_ID

IF OBJECT_ID('tempdb..#PatientWeightNoUnits') IS NOT NULL DROP TABLE #PatientWeightNoUnits;
SELECT p.FK_Patient_Link_ID, p.EventDate AS DateOfFirstValue, MAX(p.Value) AS [Value]
INTO #PatientWeightNoUnits
FROM {param:gp-events-table} p
INNER JOIN #PatientWeightNoUnitsTEMP1 sub ON sub.FK_Patient_Link_ID = p.FK_Patient_Link_ID AND sub.EventDate = p.EventDate
WHERE SuppliedCode IN (SELECT code FROM #AllCodes WHERE Concept = 'weight' AND Version = 1)
GROUP BY p.FK_Patient_Link_ID, p.EventDate;

-- Create the output PatientWeight temp table, with vlaues in kg. We combine the kg and 'no unit' tables from above.
IF OBJECT_ID('tempdb..#PatientWeight') IS NOT NULL DROP TABLE #PatientWeight;
SELECT
wkg.FK_Patient_Link_ID,
WeightInKilograms = TRY_CONVERT(DECIMAL(10,3),wkg.[Value]),
WeightDate = wkg.DateOfFirstValue
INTO #PatientWeight
FROM #PatientWeightInKilograms wkg
UNION ALL
SELECT
wno.FK_Patient_Link_ID,
WeightInKilograms = TRY_CONVERT(DECIMAL(10,3),wno.[Value]),
WeightDate = DateOfFirstValue
FROM #PatientWeightNoUnits wno

0 comments on commit e627740

Please sign in to comment.