Skip to content

Commit

Permalink
Merge pull request #1470 from MIT-LCP/kdigo_fixes
Browse files Browse the repository at this point in the history
KDIGO improvements
  • Loading branch information
alistairewj authored Feb 3, 2023
2 parents 30c7bcc + 5504c41 commit 3e0978f
Show file tree
Hide file tree
Showing 2 changed files with 119 additions and 63 deletions.
46 changes: 38 additions & 8 deletions mimic-iv/concepts/organfailure/kdigo_stages.sql
Original file line number Diff line number Diff line change
Expand Up @@ -43,12 +43,15 @@ WITH cr_stg AS
WHEN uo.uo_rt_6hr IS NULL THEN NULL
-- require patient to be in ICU for at least 6 hours to stage UO
WHEN uo.charttime <= DATETIME_ADD(ie.intime, INTERVAL '6' HOUR) THEN 0
-- require the UO rate to be calculated over half the period
-- i.e. for uo rate over 24 hours, require documentation at least 12 hr apart
WHEN uo.uo_tm_24hr >= 11 AND uo.uo_rt_24hr < 0.3 THEN 3
WHEN uo.uo_tm_12hr >= 5 AND uo.uo_rt_12hr = 0 THEN 3
WHEN uo.uo_tm_12hr >= 5 AND uo.uo_rt_12hr < 0.5 THEN 2
WHEN uo.uo_tm_6hr >= 2 AND uo.uo_rt_6hr < 0.5 THEN 1
-- require the UO rate to be calculated over duration specified in KDIGO
-- Stage 3: <0.3 ml/kg/h for >=24 hours
WHEN uo.uo_tm_24hr >= 24 AND uo.uo_rt_24hr < 0.3 THEN 3
-- *or* anuria for >= 12 hours
WHEN uo.uo_tm_12hr >= 12 AND uo.uo_rt_12hr = 0 THEN 3
-- Stage 2: <0.5 ml/kg/h for >= 12 hours
WHEN uo.uo_tm_12hr >= 12 AND uo.uo_rt_12hr < 0.5 THEN 2
-- Stage 1: <0.5 ml/kg/h for 6–12 hours
WHEN uo.uo_tm_6hr >= 6 AND uo.uo_rt_6hr < 0.5 THEN 1
ELSE 0 END AS aki_stage_uo
FROM `physionet-data.mimiciv_derived.kdigo_uo` uo
INNER JOIN `physionet-data.mimiciv_icu.icustays` ie
Expand All @@ -62,7 +65,8 @@ crrt_stg AS (
CASE
WHEN charttime IS NOT NULL THEN 3
ELSE NULL END AS aki_stage_crrt
FROM `physionet-data.mimic_derived.crrt`
FROM `physionet-data.mimiciv_derived.crrt`
WHERE crrt_mode IS NOT NULL
)
-- get all charttimes documented
, tm_stg AS
Expand All @@ -78,7 +82,6 @@ FROM `physionet-data.mimic_derived.crrt`
SELECT
stay_id, charttime
FROM crrt_stg

)
SELECT
ie.subject_id
Expand All @@ -100,6 +103,33 @@ SELECT
COALESCE(uo.aki_stage_uo,0),
COALESCE(crrt.aki_stage_crrt,0)
) AS aki_stage

-- We intend to combine together the scores from creatinine/UO by left joining
-- from the above temporary table which has all possible charttime.
-- This will guarantee we include all creatinine/UO measurements.

-- However, we have times where urine output is measured, but not creatinine.
-- Thus we end up with NULLs for the creatinine column(s). Naively calculating
-- the highest stage across the columns will often only consider one stage.
-- For example, consider the following rows:
-- stay_id=123, time=10:00, cr_low_7day=4.0, uo_rt_6hr=NULL will give stage 3
-- stay_id=123, time=10:30, cr_low_7day=NULL, uo_rt_6hr=0.3 will give stage 1
-- This results in the stage alternating from low/high across rows.

-- To overcome this, we create a new column which carries forward the highest
-- KDIGO stage from the last 6 hours. In most cases, this smooths out any discontinuity.
, MAX(
GREATEST(
COALESCE(cr.aki_stage_creat,0),
COALESCE(uo.aki_stage_uo,0),
COALESCE(crrt.aki_stage_crrt,0)
)
) OVER
(
PARTITION BY ie.subject_id
ORDER BY DATETIME_DIFF(tm.charttime, ie.intime, SECOND)
RANGE BETWEEN 21600 PRECEDING AND CURRENT ROW
) AS aki_stage_smoothed
FROM `physionet-data.mimiciv_icu.icustays` ie
-- get all possible charttimes as listed in tm_stg
LEFT JOIN tm_stg tm
Expand Down
136 changes: 81 additions & 55 deletions mimic-iv/concepts/organfailure/kdigo_uo.sql
Original file line number Diff line number Diff line change
@@ -1,55 +1,69 @@
with ur_stg as
WITH uo_stg1 AS
(
select io.stay_id, io.charttime
-- we have joined each row to all rows preceding within 24 hours
-- we can now sum these rows to get total UO over the last 24 hours
-- we can use case statements to restrict it to only the last 6/12 hours
-- therefore we have three sums:
-- 1) over a 6 hour period
-- 2) over a 12 hour period
-- 3) over a 24 hour period
-- note that we assume data charted at charttime corresponds to 1 hour of UO
-- therefore we use '5' and '11' to restrict the period, rather than 6/12
-- this assumption may overestimate UO rate when documentation is done less than hourly
SELECT ie.stay_id, uo.charttime
, DATETIME_DIFF(charttime, intime, SECOND) AS seconds_since_admit
, COALESCE(
DATETIME_DIFF(charttime, LAG(charttime) OVER (PARTITION BY ie.stay_id ORDER BY charttime), SECOND)/3600.0,
1
) AS hours_since_previous_row
, urineoutput
FROM `physionet-data.mimiciv_icu.icustays` ie
INNER JOIN `physionet-data.mimiciv_derived.urine_output` uo
ON ie.stay_id = uo.stay_id
)
, uo_stg2 as
(
select stay_id, charttime
, hours_since_previous_row
, urineoutput
-- Use the RANGE partition to limit the summation to the last X hours.
-- RANGE operates using numeric, so we convert the charttime into seconds
-- since admission, and then filter to X seconds prior to the current row.
-- where X can be 21600 (6 hours), 43200 (12 hours), or 86400 (24 hours).
, SUM(urineoutput) OVER
(
PARTITION BY stay_id
ORDER BY seconds_since_admit
RANGE BETWEEN 21600 PRECEDING AND CURRENT ROW
) AS urineoutput_6hr

, SUM(urineoutput) OVER
(
PARTITION BY stay_id
ORDER BY seconds_since_admit
RANGE BETWEEN 43200 PRECEDING AND CURRENT ROW
) AS urineoutput_12hr

, SUM(urineoutput) OVER
(
PARTITION BY stay_id
ORDER BY seconds_since_admit
RANGE BETWEEN 86400 PRECEDING AND CURRENT ROW
) AS urineoutput_24hr

-- 6 hours
, sum(case when iosum.charttime >= DATETIME_SUB(io.charttime, interval '5' hour)
then iosum.urineoutput
else null end) as UrineOutput_6hr
-- 12 hours
, sum(case when iosum.charttime >= DATETIME_SUB(io.charttime, interval '11' hour)
then iosum.urineoutput
else null end) as UrineOutput_12hr
-- 24 hours
, sum(iosum.urineoutput) as UrineOutput_24hr

-- calculate the number of hours over which we've tabulated UO
, ROUND(CAST(
DATETIME_DIFF(io.charttime,
-- below MIN() gets the earliest time that was used in the summation
MIN(case when iosum.charttime >= DATETIME_SUB(io.charttime, interval '5' hour)
then iosum.charttime
else null end),
SECOND) AS NUMERIC)/3600.0, 4)
AS uo_tm_6hr
-- repeat extraction for 12 hours and 24 hours
, ROUND(CAST(
DATETIME_DIFF(io.charttime,
MIN(case when iosum.charttime >= DATETIME_SUB(io.charttime, interval '11' hour)
then iosum.charttime
else null end),
SECOND) AS NUMERIC)/3600.0, 4)
AS uo_tm_12hr
, ROUND(CAST(
DATETIME_DIFF(io.charttime, MIN(iosum.charttime), SECOND)
AS NUMERIC)/3600.0, 4) AS uo_tm_24hr
from `physionet-data.mimiciv_derived.urine_output` io
-- this join gives all UO measurements over the 24 hours preceding this row
left join `physionet-data.mimiciv_derived.urine_output` iosum
on io.stay_id = iosum.stay_id
and iosum.charttime <= io.charttime
and iosum.charttime >= DATETIME_SUB(io.charttime, interval '23' hour)
group by io.stay_id, io.charttime
-- repeat the summations using the hours_since_previous_row column
-- this gives us the amount of time the UO was calculated over
, SUM(hours_since_previous_row) OVER
(
PARTITION BY stay_id
ORDER BY seconds_since_admit
RANGE BETWEEN 21600 PRECEDING AND CURRENT ROW
) AS uo_tm_6hr

, SUM(hours_since_previous_row) OVER
(
PARTITION BY stay_id
ORDER BY seconds_since_admit
RANGE BETWEEN 43200 PRECEDING AND CURRENT ROW
) AS uo_tm_12hr

, SUM(hours_since_previous_row) OVER
(
PARTITION BY stay_id
ORDER BY seconds_since_admit
RANGE BETWEEN 86400 PRECEDING AND CURRENT ROW
) AS uo_tm_24hr
from uo_stg1
)
select
ur.stay_id
Expand All @@ -58,15 +72,27 @@ select
, ur.urineoutput_6hr
, ur.urineoutput_12hr
, ur.urineoutput_24hr
-- calculate rates - adding 1 hour as we assume data charted at 10:00 corresponds to previous hour
, ROUND(CAST((ur.UrineOutput_6hr/wd.weight/(uo_tm_6hr+1)) AS NUMERIC), 4) AS uo_rt_6hr
, ROUND(CAST((ur.UrineOutput_12hr/wd.weight/(uo_tm_12hr+1)) AS NUMERIC), 4) AS uo_rt_12hr
, ROUND(CAST((ur.UrineOutput_24hr/wd.weight/(uo_tm_24hr+1)) AS NUMERIC), 4) AS uo_rt_24hr

-- calculate rates while requiring UO documentation over at least N hours
-- as specified in KDIGO guidelines 2012 pg19
, CASE
WHEN uo_tm_6hr >= 6 AND uo_tm_6hr < 12
THEN ROUND(CAST((ur.urineoutput_6hr/wd.weight/uo_tm_6hr) AS NUMERIC), 4)
ELSE NULL END AS uo_rt_6hr
, CASE
WHEN uo_tm_12hr >= 12
THEN ROUND(CAST((ur.urineoutput_12hr/wd.weight/uo_tm_12hr) AS NUMERIC), 4)
ELSE NULL END AS uo_rt_12hr
, CASE
WHEN uo_tm_24hr >= 24
THEN ROUND(CAST((ur.urineoutput_24hr/wd.weight/uo_tm_24hr) AS NUMERIC), 4)
ELSE NULL END AS uo_rt_24hr

-- number of hours between current UO time and earliest charted UO within the X hour window
, uo_tm_6hr
, uo_tm_12hr
, uo_tm_24hr
from ur_stg ur
from uo_stg2 ur
left join `physionet-data.mimiciv_derived.weight_durations` wd
on ur.stay_id = wd.stay_id
and ur.charttime >= wd.starttime
Expand Down

0 comments on commit 3e0978f

Please sign in to comment.