Skip to content

Commit

Permalink
changes to height and weight queries based on feedback
Browse files Browse the repository at this point in the history
  • Loading branch information
Georgetilston committed Mar 15, 2024
1 parent 8a3d051 commit c703665
Show file tree
Hide file tree
Showing 4 changed files with 9 additions and 32 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -15,14 +15,14 @@
-- - temp-table-name: string - the name of the temp table that this will produce

-- OUTPUT: Temp tables as follows:
-- #Patients - list of patient ids of the cohort
-- (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} measurement before/after
-- the index date
IF OBJECT_ID('tempdb..{param:temp-table-name}TEMP1') IS NOT NULL DROP TABLE {param:temp-table-name}TEMP1;
-- 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}
Expand All @@ -35,23 +35,14 @@ IF OBJECT_ID('tempdb..{param:temp-table-name}TEMP1') IS NOT NULL DROP TABLE {par
{if:comparison=<=}
SELECT FK_Patient_Link_ID, MAX(EventDate) AS EventDate
{endif:comparison}
INTO {param:temp-table-name}TEMP1
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}'
GROUP BY FK_Patient_Link_ID;

-- Then we join to that table in order to get the value of that measurement
IF OBJECT_ID('tempdb..{param:temp-table-name}') IS NOT NULL DROP TABLE {param:temp-table-name};
SELECT p.FK_Patient_Link_ID, p.EventDate AS DateOfFirstValue, MAX(p.Value) AS [Value]
INTO {param:temp-table-name}
FROM {param:gp-events-table} p
INNER JOIN {param:temp-table-name}TEMP1 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 = '{param:code-set}' AND Version = {param:version})
{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 p.FK_Patient_Link_ID, p.EventDate;
GROUP BY FK_Patient_Link_ID;
Original file line number Diff line number Diff line change
Expand Up @@ -45,8 +45,7 @@ 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 of zero and values outside the specified range
AND TRY_CONVERT(DECIMAL(10,3), [Value]) != 0
-- 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;
Expand Down
10 changes: 2 additions & 8 deletions shared/Reusable queries for data extraction/query-get-height.sql
Original file line number Diff line number Diff line change
Expand Up @@ -18,10 +18,10 @@

-- 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-closest-value-to-date.sql all-patients:false 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
--> 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-closest-value-to-date.sql all-patients:false 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
--> 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)
Expand All @@ -47,12 +47,6 @@ 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)
{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 p.FK_Patient_Link_ID, p.EventDate;

-- Create the output PatientHeight temp table. We combine the m and cm tables from above
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -32,7 +32,6 @@ WHERE Units IS NULL
AND Value IS NOT NULL
AND Value <> ''
AND TRY_CONVERT(DECIMAL(10,3), [Value]) BETWEEN 0.1 AND 500
AND TRY_CONVERT(DECIMAL(10,3), [Value]) != 0
AND EventDate <= '{param:date}'
AND SuppliedCode IN (SELECT code FROM #AllCodes WHERE Concept = 'weight' AND Version = 1)
{if:all-patients=false}
Expand All @@ -46,12 +45,6 @@ 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)
{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 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.
Expand Down

0 comments on commit c703665

Please sign in to comment.