11-- THIS SCRIPT IS AUTOMATICALLY GENERATED. DO NOT EDIT IT DIRECTLY.
22DROP TABLE IF EXISTS ventilation; CREATE TABLE ventilation AS
3- -- Calculate duration of mechanical ventilation.
3+ -- Classify oxygen devices and ventilator modes into six clinical categories.
4+
5+ -- Categories include..
6+ -- Invasive oxygen delivery types:
7+ -- Tracheostomy (with or without positive pressure ventilation)
8+ -- InvasiveVent (positive pressure ventilation via endotracheal tube, could be oro/nasotracheal or tracheostomy)
9+ -- Non invasive oxygen delivery types (divided similar to doi:10.1001/jama.2020.9524):
10+ -- NonInvasiveVent (non-invasive positive pressure ventilation)
11+ -- HFNC (high flow nasal oxygen / cannula)
12+ -- SupplementalOxygen (all other non-rebreather, facemask, face tent, nasal prongs...)
13+ -- No oxygen device:
14+ -- None
15+
16+ -- When conflicting settings occur (rare), the priority is:
17+ -- trach > mech vent > NIV > high flow > o2
18+
419-- Some useful cases for debugging:
520-- stay_id = 30019660 has a tracheostomy placed in the ICU
621-- stay_id = 30000117 has explicit documentation of extubation
7- -- classify vent settings into modes
22+
23+ -- first we collect all times which have relevant documentation
824WITH tm AS
925(
1026 SELECT stay_id, charttime
@@ -25,11 +41,13 @@ WITH tm AS
2541 -- tracheostomy
2642 WHEN o2_delivery_device_1 IN
2743 (
28- ' Tracheostomy tube'
29- -- 'Trach mask ' -- 16435 observations
44+ ' Tracheostomy tube' ,
45+ ' Trach mask ' -- 16435 observations
46+ -- 'T-piece', -- 1135 observations (T-piece could be either InvasiveVent or Tracheostomy)
47+
3048 )
31- THEN ' Trach '
32- -- mechanical ventilation
49+ THEN ' Tracheostomy '
50+ -- mechanical / invasive ventilation
3351 WHEN o2_delivery_device_1 IN
3452 (
3553 ' Endotracheal tube'
@@ -100,30 +118,33 @@ WITH tm AS
100118 ' NIV-ST'
101119 )
102120 THEN ' NonInvasiveVent'
103- -- high flow
121+ -- high flow nasal cannula
104122 when o2_delivery_device_1 IN
105123 (
106- ' High flow neb' , -- 10785 observations
107124 ' High flow nasal cannula' -- 925 observations
108125 )
109- THEN ' HighFlow '
110- -- normal oxygen delivery
126+ THEN ' HFNC '
127+ -- non rebreather
111128 WHEN o2_delivery_device_1 in
112- (
113- ' Nasal cannula ' , -- 153714 observations
129+ (
130+ ' Non-rebreather ' , -- 5182 observations
114131 ' Face tent' , -- 24601 observations
115132 ' Aerosol-cool' , -- 24560 observations
116- ' Non-rebreather' , -- 5182 observations
117133 ' Venti mask ' , -- 1947 observations
118134 ' Medium conc mask ' , -- 1888 observations
119- ' T-piece' , -- 1135 observations
120135 ' Ultrasonic neb' , -- 9 observations
121136 ' Vapomist' , -- 3 observations
122- ' Oxymizer' -- 1301 observations
137+ ' Oxymizer' , -- 1301 observations
138+ ' High flow neb' , -- 10785 observations
139+ ' Nasal cannula'
123140 )
124- THEN ' Oxygen'
125- -- Not categorized:
126- -- 'Other', 'None'
141+ THEN ' SupplementalOxygen'
142+ WHEN o2_delivery_device_1 in
143+ (
144+ ' None'
145+ )
146+ THEN ' None'
147+ -- not categorized: other
127148 ELSE NULL END AS ventilation_status
128149 FROM tm
129150 LEFT JOIN mimic_derived .ventilator_setting vs
@@ -138,8 +159,8 @@ WITH tm AS
138159 SELECT
139160 stay_id, charttime
140161 -- source data columns, here for debug
141- , o2_delivery_device_1
142- , vent_mode
162+ -- , o2_delivery_device_1
163+ -- , vent_mode
143164 -- carry over the previous charttime which had the same state
144165 , LAG(charttime, 1 ) OVER (PARTITION BY stay_id, ventilation_status ORDER BY charttime) AS charttime_lag
145166 -- bring back the next charttime, regardless of the state
@@ -155,34 +176,42 @@ WITH tm AS
155176(
156177 SELECT
157178 stay_id
158- -- source data columns, here for debug
159- , o2_delivery_device_1
160- , vent_mode
161- , charttime_lag
162179 , charttime
180+ , charttime_lag
163181 , charttime_lead
164182 , ventilation_status
165183
184+ -- source data columns, here for debug
185+ -- , o2_delivery_device_1
186+ -- , vent_mode
187+
166188 -- calculate the time since the last event
167189 , DATETIME_DIFF(charttime,charttime_lag,' MINUTE' )/ 60 as ventduration
168190
169191 -- now we determine if the current ventilation status is "new", or continuing the previous
170192 , CASE
193+ -- if lag is null, this is the first event for the patient
194+ WHEN ventilation_status_lag IS NULL THEN 1
171195 -- a 14 hour gap always initiates a new event
172196 WHEN DATETIME_DIFF(charttime,charttime_lag,' HOUR' ) >= 14 THEN 1
173- WHEN ventilation_status_lag IS NULL THEN 1
174197 -- not a new event if identical to the last row
175198 WHEN ventilation_status_lag != ventilation_status THEN 1
176199 ELSE 0
177- END AS new_status
200+ END AS new_ventilation_event
178201 FROM vd0
179202)
180203, vd2 as
181204(
182- SELECT vd1.*
205+ SELECT vd1 .stay_id , vd1 .charttime
206+ , ventduration, new_ventilation_event
183207 -- create a cumulative sum of the instances of new ventilation
184- -- this results in a monotonic integer assigned to each instance of ventilation
185- , SUM (new_status) OVER (PARTITION BY stay_id ORDER BY charttime) AS vent_num
208+ -- this results in a monotonically increasing integer assigned
209+ -- to each instance of ventilation
210+ , SUM (new_ventilation_event) OVER
211+ (
212+ PARTITION BY stay_id
213+ ORDER BY charttime
214+ ) AS vent_seq
186215 FROM vd1
187216)
188217-- create the durations for each ventilation instance
@@ -200,9 +229,10 @@ SELECT stay_id
200229 END
201230 ) AS endtime
202231 -- all rows with the same vent_num will have the same ventilation_status
203- -- for efficiency, we use an aggregate here, but we could equally well group by this column
232+ -- for efficiency, we use an aggregate here,
233+ -- but we could equally well group by this column
204234 , MAX (ventilation_status) AS ventilation_status
205235FROM vd2
206- GROUP BY stay_id, vent_num
236+ GROUP BY stay_id, vent_seq
207237HAVING min (charttime) != max (charttime)
208238;
0 commit comments