From 8a259e1cffda88ccdd3e87fe28ca2527e67eeabf Mon Sep 17 00:00:00 2001 From: Andrew Barros Date: Mon, 2 Mar 2020 08:29:01 -0500 Subject: [PATCH] Create views for vasoactive infusion durations similar to MIMIC-III --- concepts/durations/dopamine_durations.sql | 80 +++++++++++++++++++ concepts/durations/epinepherine_durations.sql | 80 +++++++++++++++++++ .../durations/norepinepherine_durations.sql | 80 +++++++++++++++++++ .../durations/phenylepherine_durations.sql | 80 +++++++++++++++++++ concepts/durations/vasopressin_durations.sql | 80 +++++++++++++++++++ concepts/durations/vasopressor_durations.sql | 11 +++ 6 files changed, 411 insertions(+) create mode 100644 concepts/durations/dopamine_durations.sql create mode 100644 concepts/durations/epinepherine_durations.sql create mode 100644 concepts/durations/norepinepherine_durations.sql create mode 100644 concepts/durations/phenylepherine_durations.sql create mode 100644 concepts/durations/vasopressin_durations.sql create mode 100644 concepts/durations/vasopressor_durations.sql diff --git a/concepts/durations/dopamine_durations.sql b/concepts/durations/dopamine_durations.sql new file mode 100644 index 0000000..03f6345 --- /dev/null +++ b/concepts/durations/dopamine_durations.sql @@ -0,0 +1,80 @@ + +-- This query extracts durations of vasopressin administration. +-- It is heavily based on the MIMIC-III duration code +-- Consecutive durations are numbered and administations are ended after 18 hours without +-- a charted value. 18 hours is a little arbitrary, but there are some vasopressin infusions +-- that are long standing and non-titrated (and will have 14 hour gaps in charting) + +CREATE OR REPLACE FUNCTION SAFE_CAST_TO_NUMERIC(v_input text) RETURNS NUMERIC AS $$ +-- This casts a string to a numeric value without throwing an exception if the +-- sting is not 'numeric-like'. For BigQuery, use SAFE_CAST(x AS NUMERIC) +DECLARE v_numeric_value NUMERIC DEFAULT NULL; +BEGIN + BEGIN + v_numeric_value := v_input::NUMERIC; + EXCEPTION WHEN OTHERS THEN + RETURN NULL; + END; +RETURN v_numeric_value; +END; +$$ LANGUAGE plpgsql; + +DROP MATERIALIZED VIEW IF EXISTS dopaminedurations; +CREATE MATERIALIZED VIEW dopaminedurations AS +WITH drug_events AS ( + SELECT + patientunitstayid + , infusionoffset + , drugrate + , CASE WHEN SAFE_CAST_TO_NUMERIC(drugrate) > 0 THEN 1 ELSE 0 END AS vasopressor_event + , CASE WHEN drugrate LIKE '%OFF%' THEN 1 + WHEN SAFE_CAST_TO_NUMERIC(drugrate) = 0 THEN 1 + ELSE 0 END AS stop_event + FROM + infusiondrug + WHERE + LOWER(drugname) LIKE 'dopamine%' +), d0 AS ( + SELECT + patientunitstayid + , infusionoffset + , drugrate + , vasopressor_event + , stop_event + , LAG(InfusionOffset, 1) OVER (PARTITION BY patientunitstayid ORDER BY infusionoffset) AS InfusionOffsetLag + FROM + drug_events +), d1 AS ( + SELECT + patientunitstayid + , infusionoffset + , drugrate + , vasopressor_event + , stop_event + , CASE + -- Case 1: The row prior was a stop event. This is either part of a string of zeros + -- or the start of a new event + WHEN Lag(stop_event, 1, 1) OVER (PARTITION BY patientunitstayid ORDER BY infusionoffset) = 1 THEN + CASE WHEN stop_event = 1 THEN 0 ELSE 1 END + -- Case 2: If the row prior was more than 18 hours ago, end this is a new event + WHEN InfusionOffset - InfusionOffsetLag > (18*60) THEN 1 + -- Otherwise, This is _not_ a new event. + ELSE 0 + END AS new_event + FROM d0 +), d2 AS ( + SELECT + d1.* + -- Generate a sequential integer for convience + , SUM(new_event) OVER (PARTITION BY patientunitstayid ORDER BY infusionoffset) AS vasopressor_episode + FROM + d1 +) +SELECT + patientunitstayid + , 'Dopamine' AS Drug + , vasopressor_episode + , MIN(infusionoffset) AS start_offset + , MAX(infusionoffset) AS end_offset +FROM d2 +GROUP BY patientunitstayid, vasopressor_episode; diff --git a/concepts/durations/epinepherine_durations.sql b/concepts/durations/epinepherine_durations.sql new file mode 100644 index 0000000..b26022a --- /dev/null +++ b/concepts/durations/epinepherine_durations.sql @@ -0,0 +1,80 @@ + +-- This query extracts durations of vasopressin administration. +-- It is heavily based on the MIMIC-III duration code +-- Consecutive durations are numbered and administations are ended after 18 hours without +-- a charted value. 18 hours is a little arbitrary, but there are some vasopressin infusions +-- that are long standing and non-titrated (and will have 14 hour gaps in charting) + +CREATE OR REPLACE FUNCTION SAFE_CAST_TO_NUMERIC(v_input text) RETURNS NUMERIC AS $$ +-- This casts a string to a numeric value without throwing an exception if the +-- sting is not 'numeric-like'. For BigQuery, use SAFE_CAST(x AS NUMERIC) +DECLARE v_numeric_value NUMERIC DEFAULT NULL; +BEGIN + BEGIN + v_numeric_value := v_input::NUMERIC; + EXCEPTION WHEN OTHERS THEN + RETURN NULL; + END; +RETURN v_numeric_value; +END; +$$ LANGUAGE plpgsql; + +DROP MATERIALIZED VIEW IF EXISTS epinephrinedurations; +CREATE MATERIALIZED VIEW epinephrinedurations AS +WITH drug_events AS ( + SELECT + patientunitstayid + , infusionoffset + , drugrate + , CASE WHEN SAFE_CAST_TO_NUMERIC(drugrate) > 0 THEN 1 ELSE 0 END AS vasopressor_event + , CASE WHEN drugrate LIKE '%OFF%' THEN 1 + WHEN SAFE_CAST_TO_NUMERIC(drugrate) = 0 THEN 1 + ELSE 0 END AS stop_event + FROM + infusiondrug + WHERE + LOWER(drugname) LIKE 'epinephrine%' +), d0 AS ( + SELECT + patientunitstayid + , infusionoffset + , drugrate + , vasopressor_event + , stop_event + , LAG(InfusionOffset, 1) OVER (PARTITION BY patientunitstayid ORDER BY infusionoffset) AS InfusionOffsetLag + FROM + drug_events +), d1 AS ( + SELECT + patientunitstayid + , infusionoffset + , drugrate + , vasopressor_event + , stop_event + , CASE + -- Case 1: The row prior was a stop event. This is either part of a string of zeros + -- or the start of a new event + WHEN Lag(stop_event, 1, 1) OVER (PARTITION BY patientunitstayid ORDER BY infusionoffset) = 1 THEN + CASE WHEN stop_event = 1 THEN 0 ELSE 1 END + -- Case 2: If the row prior was more than 18 hours ago, end this is a new event + WHEN InfusionOffset - InfusionOffsetLag > (18*60) THEN 1 + -- Otherwise, This is _not_ a new event. + ELSE 0 + END AS new_event + FROM d0 +), d2 AS ( + SELECT + d1.* + -- Generate a sequential integer for convience + , SUM(new_event) OVER (PARTITION BY patientunitstayid ORDER BY infusionoffset) AS vasopressor_episode + FROM + d1 +) +SELECT + patientunitstayid + , 'Epinephrine' AS Drug + , vasopressor_episode + , MIN(infusionoffset) AS start_offset + , MAX(infusionoffset) AS end_offset +FROM d2 +GROUP BY patientunitstayid, vasopressor_episode; diff --git a/concepts/durations/norepinepherine_durations.sql b/concepts/durations/norepinepherine_durations.sql new file mode 100644 index 0000000..3e6cb27 --- /dev/null +++ b/concepts/durations/norepinepherine_durations.sql @@ -0,0 +1,80 @@ + +-- This query extracts durations of vasopressin administration. +-- It is heavily based on the MIMIC-III duration code +-- Consecutive durations are numbered and administations are ended after 18 hours without +-- a charted value. 18 hours is a little arbitrary, but there are some vasopressin infusions +-- that are long standing and non-titrated (and will have 14 hour gaps in charting) + +CREATE OR REPLACE FUNCTION SAFE_CAST_TO_NUMERIC(v_input text) RETURNS NUMERIC AS $$ +-- This casts a string to a numeric value without throwing an exception if the +-- sting is not 'numeric-like'. For BigQuery, use SAFE_CAST(x AS NUMERIC) +DECLARE v_numeric_value NUMERIC DEFAULT NULL; +BEGIN + BEGIN + v_numeric_value := v_input::NUMERIC; + EXCEPTION WHEN OTHERS THEN + RETURN NULL; + END; +RETURN v_numeric_value; +END; +$$ LANGUAGE plpgsql; + +DROP MATERIALIZED VIEW IF EXISTS norepinephrinedurations; +CREATE MATERIALIZED VIEW norepinephrinedurations AS +WITH drug_events AS ( + SELECT + patientunitstayid + , infusionoffset + , drugrate + , CASE WHEN SAFE_CAST_TO_NUMERIC(drugrate) > 0 THEN 1 ELSE 0 END AS vasopressor_event + , CASE WHEN drugrate LIKE '%OFF%' THEN 1 + WHEN SAFE_CAST_TO_NUMERIC(drugrate) = 0 THEN 1 + ELSE 0 END AS stop_event + FROM + infusiondrug + WHERE + LOWER(drugname) LIKE 'norepinephrine%' +), d0 AS ( + SELECT + patientunitstayid + , infusionoffset + , drugrate + , vasopressor_event + , stop_event + , LAG(InfusionOffset, 1) OVER (PARTITION BY patientunitstayid ORDER BY infusionoffset) AS InfusionOffsetLag + FROM + drug_events +), d1 AS ( + SELECT + patientunitstayid + , infusionoffset + , drugrate + , vasopressor_event + , stop_event + , CASE + -- Case 1: The row prior was a stop event. This is either part of a string of zeros + -- or the start of a new event + WHEN Lag(stop_event, 1, 1) OVER (PARTITION BY patientunitstayid ORDER BY infusionoffset) = 1 THEN + CASE WHEN stop_event = 1 THEN 0 ELSE 1 END + -- Case 2: If the row prior was more than 18 hours ago, end this is a new event + WHEN InfusionOffset - InfusionOffsetLag > (18*60) THEN 1 + -- Otherwise, This is _not_ a new event. + ELSE 0 + END AS new_event + FROM d0 +), d2 AS ( + SELECT + d1.* + -- Generate a sequential integer for convience + , SUM(new_event) OVER (PARTITION BY patientunitstayid ORDER BY infusionoffset) AS vasopressor_episode + FROM + d1 +) +SELECT + patientunitstayid + , 'Norepinephrine' AS Drug + , vasopressor_episode + , MIN(infusionoffset) AS start_offset + , MAX(infusionoffset) AS end_offset +FROM d2 +GROUP BY patientunitstayid, vasopressor_episode; diff --git a/concepts/durations/phenylepherine_durations.sql b/concepts/durations/phenylepherine_durations.sql new file mode 100644 index 0000000..3f066e8 --- /dev/null +++ b/concepts/durations/phenylepherine_durations.sql @@ -0,0 +1,80 @@ + +-- This query extracts durations of vasopressin administration. +-- It is heavily based on the MIMIC-III duration code +-- Consecutive durations are numbered and administations are ended after 18 hours without +-- a charted value. 18 hours is a little arbitrary, but there are some vasopressin infusions +-- that are long standing and non-titrated (and will have 14 hour gaps in charting) + +CREATE OR REPLACE FUNCTION SAFE_CAST_TO_NUMERIC(v_input text) RETURNS NUMERIC AS $$ +-- This casts a string to a numeric value without throwing an exception if the +-- sting is not 'numeric-like'. For BigQuery, use SAFE_CAST(x AS NUMERIC) +DECLARE v_numeric_value NUMERIC DEFAULT NULL; +BEGIN + BEGIN + v_numeric_value := v_input::NUMERIC; + EXCEPTION WHEN OTHERS THEN + RETURN NULL; + END; +RETURN v_numeric_value; +END; +$$ LANGUAGE plpgsql; + +DROP MATERIALIZED VIEW IF EXISTS phenylephrinedurations; +CREATE MATERIALIZED VIEW phenylephrinedurations AS +WITH drug_events AS ( + SELECT + patientunitstayid + , infusionoffset + , drugrate + , CASE WHEN SAFE_CAST_TO_NUMERIC(drugrate) > 0 THEN 1 ELSE 0 END AS vasopressor_event + , CASE WHEN drugrate LIKE '%OFF%' THEN 1 + WHEN SAFE_CAST_TO_NUMERIC(drugrate) = 0 THEN 1 + ELSE 0 END AS stop_event + FROM + infusiondrug + WHERE + LOWER(drugname) LIKE 'phenylephrine%' +), d0 AS ( + SELECT + patientunitstayid + , infusionoffset + , drugrate + , vasopressor_event + , stop_event + , LAG(InfusionOffset, 1) OVER (PARTITION BY patientunitstayid ORDER BY infusionoffset) AS InfusionOffsetLag + FROM + drug_events +), d1 AS ( + SELECT + patientunitstayid + , infusionoffset + , drugrate + , vasopressor_event + , stop_event + , CASE + -- Case 1: The row prior was a stop event. This is either part of a string of zeros + -- or the start of a new event + WHEN Lag(stop_event, 1, 1) OVER (PARTITION BY patientunitstayid ORDER BY infusionoffset) = 1 THEN + CASE WHEN stop_event = 1 THEN 0 ELSE 1 END + -- Case 2: If the row prior was more than 18 hours ago, end this is a new event + WHEN InfusionOffset - InfusionOffsetLag > (18*60) THEN 1 + -- Otherwise, This is _not_ a new event. + ELSE 0 + END AS new_event + FROM d0 +), d2 AS ( + SELECT + d1.* + -- Generate a sequential integer for convience + , SUM(new_event) OVER (PARTITION BY patientunitstayid ORDER BY infusionoffset) AS vasopressor_episode + FROM + d1 +) +SELECT + patientunitstayid + , 'Phenylephrine' AS Drug + , vasopressor_episode + , MIN(infusionoffset) AS start_offset + , MAX(infusionoffset) AS end_offset +FROM d2 +GROUP BY patientunitstayid, vasopressor_episode; diff --git a/concepts/durations/vasopressin_durations.sql b/concepts/durations/vasopressin_durations.sql new file mode 100644 index 0000000..b36654f --- /dev/null +++ b/concepts/durations/vasopressin_durations.sql @@ -0,0 +1,80 @@ + +-- This query extracts durations of vasopressin administration. +-- It is heavily based on the MIMIC-III duration code +-- Consecutive durations are numbered and administations are ended after 18 hours without +-- a charted value. 18 hours is a little arbitrary, but there are some vasopressin infusions +-- that are long standing and non-titrated (and will have 14 hour gaps in charting) + +CREATE OR REPLACE FUNCTION SAFE_CAST_TO_NUMERIC(v_input text) RETURNS NUMERIC AS $$ +-- This casts a string to a numeric value without throwing an exception if the +-- sting is not 'numeric-like'. For BigQuery, use SAFE_CAST(x AS NUMERIC) +DECLARE v_numeric_value NUMERIC DEFAULT NULL; +BEGIN + BEGIN + v_numeric_value := v_input::NUMERIC; + EXCEPTION WHEN OTHERS THEN + RETURN NULL; + END; +RETURN v_numeric_value; +END; +$$ LANGUAGE plpgsql; + +DROP MATERIALIZED VIEW IF EXISTS vasopressindurations; +CREATE MATERIALIZED VIEW vasopressindurations AS +WITH drug_events AS ( + SELECT + patientunitstayid + , infusionoffset + , drugrate + , CASE WHEN SAFE_CAST_TO_NUMERIC(drugrate) > 0 THEN 1 ELSE 0 END AS vasopressor_event + , CASE WHEN drugrate LIKE '%OFF%' THEN 1 + WHEN SAFE_CAST_TO_NUMERIC(drugrate) = 0 THEN 1 + ELSE 0 END AS stop_event + FROM + infusiondrug + WHERE + LOWER(drugname) LIKE 'vasopressin%' +), d0 AS ( + SELECT + patientunitstayid + , infusionoffset + , drugrate + , vasopressor_event + , stop_event + , LAG(InfusionOffset, 1) OVER (PARTITION BY patientunitstayid ORDER BY infusionoffset) AS InfusionOffsetLag + FROM + drug_events +), d1 AS ( + SELECT + patientunitstayid + , infusionoffset + , drugrate + , vasopressor_event + , stop_event + , CASE + -- Case 1: The row prior was a stop event. This is either part of a string of zeros + -- or the start of a new event + WHEN Lag(stop_event, 1, 1) OVER (PARTITION BY patientunitstayid ORDER BY infusionoffset) = 1 THEN + CASE WHEN stop_event = 1 THEN 0 ELSE 1 END + -- Case 2: If the row prior was more than 18 hours ago, end this is a new event + WHEN InfusionOffset - InfusionOffsetLag > (18*60) THEN 1 + -- Otherwise, This is _not_ a new event. + ELSE 0 + END AS new_event + FROM d0 +), d2 AS ( + SELECT + d1.* + -- Generate a sequential integer for convience + , SUM(new_event) OVER (PARTITION BY patientunitstayid ORDER BY infusionoffset) AS vasopressor_episode + FROM + d1 +) +SELECT + patientunitstayid + , 'Vasopressin' AS Drug + , vasopressor_episode + , MIN(infusionoffset) AS start_offset + , MAX(infusionoffset) AS end_offset +FROM d2 +GROUP BY patientunitstayid, vasopressor_episode; diff --git a/concepts/durations/vasopressor_durations.sql b/concepts/durations/vasopressor_durations.sql new file mode 100644 index 0000000..0c5d0bf --- /dev/null +++ b/concepts/durations/vasopressor_durations.sql @@ -0,0 +1,11 @@ +DROP MATERIALIZED VIEW IF EXISTS vasopressordurations; +CREATE MATERIALIZED VIEW vasopressordurations AS +SELECT * FROM epinephrinedurations +UNION ALL +SELECT * FROM norepinephrinedurations +UNION ALL +SELECT * FROM phenylephrinedurations +UNION ALL +SELECT * FROM vasopressindurations +UNION ALL +SELECT * FROM dopaminedurations;