-
Notifications
You must be signed in to change notification settings - Fork 2
/
sedativedurations.sql
306 lines (282 loc) · 8.9 KB
/
sedativedurations.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
-- This query extracts durations of sedative administration
-- Consecutive administrations are numbered 1, 2, ...
-- Total time on the drug can be calculated from this table
-- by grouping using ICUSTAY_ID
-- select only the ITEMIDs from the inputevents_cv table related to sedative
DROP MATERIALIZED VIEW IF EXISTS mimiciii.SEDATIVEDURATIONS;
CREATE MATERIALIZED VIEW mimiciii.SEDATIVEDURATIONS as
with io_cv as
(
select
icustay_id, charttime, itemid, stopped
-- ITEMIDs (42273, 42802) accidentally store rate in amount column
, case
when itemid in (42273, 42802)
then amount
else rate
end as rate
, case
when itemid in (42273, 42802)
then rate
else amount
end as amount
from inputevents_cv
where itemid in
(
30124,30150,30308,30118,30149,30131
)
)
-- select only the ITEMIDs from the inputevents_mv table related to sedative
, io_mv as
(
select
icustay_id, linkorderid, starttime, endtime
from inputevents_mv io
-- Subselect the sedative ITEMIDs
where itemid in
(
221668,221744,225972,225942,222168
)
and statusdescription != 'Rewritten' -- only valid orders
)
, sedativecv1 as
(
select
icustay_id, charttime, itemid
-- case statement determining whether the ITEMID is an instance of sedative usage
, 1 as sedative
-- the 'stopped' column indicates if a sedative has been disconnected
, max(case when stopped in ('Stopped','D/C''d') then 1
else 0 end) as sedative_stopped
, max(case when rate is not null then 1 else 0 end) as sedative_null
, max(rate) as sedative_rate
, max(amount) as sedative_amount
from io_cv
group by icustay_id, charttime, itemid
)
, sedativecv2 as
(
select v.*
, sum(sedative_null) over (partition by icustay_id, itemid order by charttime) as sedative_partition
from
sedativecv1 v
)
, sedativecv3 as
(
select v.*
, first_value(sedative_rate) over (partition by icustay_id, itemid, sedative_partition order by charttime) as sedative_prevrate_ifnull
from
sedativecv2 v
)
, sedativecv4 as
(
select
icustay_id
, charttime
, itemid
-- , (CHARTTIME - (LAG(CHARTTIME, 1) OVER (partition by icustay_id, vaso order by charttime))) AS delta
, sedative
, sedative_rate
, sedative_amount
, sedative_stopped
, sedative_prevrate_ifnull
-- We define start time here
, case
when sedative = 0 then null
-- if this is the first instance of the sedative drug
when sedative_rate > 0 and
LAG(sedative_prevrate_ifnull,1)
OVER
(
partition by icustay_id, itemid, sedative, sedative_null
order by charttime
)
is null
then 1
-- you often get a string of 0s
-- we decide not to set these as 1, just because it makes sedativenum sequential
when sedative_rate = 0 and
LAG(sedative_prevrate_ifnull,1)
OVER
(
partition by icustay_id, itemid, sedative
order by charttime
)
= 0
then 0
-- sometimes you get a string of NULL, associated with 0 volumes
-- same reason as before, we decide not to set these as 1
-- sedative_prevrate_ifnull is equal to the previous value *iff* the current value is null
when sedative_prevrate_ifnull = 0 and
LAG(sedative_prevrate_ifnull,1)
OVER
(
partition by icustay_id, itemid, sedative
order by charttime
)
= 0
then 0
-- If the last recorded rate was 0, newsedative = 1
when LAG(sedative_prevrate_ifnull,1)
OVER
(
partition by icustay_id, itemid, sedative
order by charttime
) = 0
then 1
-- If the last recorded sedative was D/C'd, newsedative = 1
when
LAG(sedative_stopped,1)
OVER
(
partition by icustay_id, itemid, sedative
order by charttime
)
= 1 then 1
-- ** not sure if the below is needed
--when (CHARTTIME - (LAG(CHARTTIME, 1) OVER (partition by icustay_id, vaso order by charttime))) > (interval '4 hours') then 1
else null
end as sedative_start
FROM
sedativecv3
)
-- propagate start/stop flags forward in time
, sedativecv5 as
(
select v.*
, SUM(sedative_start) OVER (partition by icustay_id, itemid, sedative order by charttime) as sedative_first
FROM
sedativecv4 v
)
, sedativecv6 as
(
select v.*
-- We define end time here
, case
when sedative = 0
then null
-- If the recorded sedative was D/C'd, this is an end time
when sedative_stopped = 1
then sedative_first
-- If the rate is zero, this is the end time
when sedative_rate = 0
then sedative_first
-- the last row in the table is always a potential end time
-- this captures patients who die/are discharged while on sedatives
-- in principle, this could add an extra end time for the sedative
-- however, since we later group on sedative_start, any extra end times are ignored
when LEAD(CHARTTIME,1)
OVER
(
partition by icustay_id, itemid, sedative
order by charttime
) is null
then sedative_first
else null
end as sedative_stop
from sedativecv5 v
)
-- -- if you want to look at the results of the table before grouping:
-- select
-- icustay_id, charttime, vaso, vaso_rate, vaso_amount
-- , case when vaso_stopped = 1 then 'Y' else '' end as stopped
-- , vaso_start
-- , vaso_first
-- , vaso_stop
-- from vasocv6 order by charttime;
, sedativecv as
(
-- below groups together sedative administrations into groups
select
icustay_id
, itemid
-- the first non-null rate is considered the starttime
, min(case when sedative_rate is not null then charttime else null end) as starttime
-- the *first* time the first/last flags agree is the stop time for this duration
, min(case when sedative_first = sedative_stop then charttime else null end) as endtime
from sedativecv6
where
sedative_first is not null -- bogus data
and
sedative_first != 0 -- sometimes *only* a rate of 0 appears, i.e. the drug is never actually delivered
and
icustay_id is not null -- there are data for "floating" admissions, we don't worry about these
group by icustay_id, itemid, sedative_first
having -- ensure start time is not the same as end time
min(charttime) != min(case when sedative_first = sedative_stop then charttime else null end)
and
max(sedative_rate) > 0 -- if the rate was always 0 or null, we consider it not a real drug delivery
)
-- we do not group by ITEMID in below query
-- this is because we want to collapse all sedative together
, sedativecv_grp as
(
SELECT
s1.icustay_id,
s1.starttime,
MIN(t1.endtime) AS endtime
FROM sedativecv s1
INNER JOIN sedativecv t1
ON s1.icustay_id = t1.icustay_id
AND s1.starttime <= t1.endtime
AND NOT EXISTS(SELECT * FROM sedativecv t2
WHERE t1.icustay_id = t2.icustay_id
AND t1.endtime >= t2.starttime
AND t1.endtime < t2.endtime)
WHERE NOT EXISTS(SELECT * FROM sedativecv s2
WHERE s1.icustay_id = s2.icustay_id
AND s1.starttime > s2.starttime
AND s1.starttime <= s2.endtime)
GROUP BY s1.icustay_id, s1.starttime
ORDER BY s1.icustay_id, s1.starttime
)
-- now we extract the associated data for metavision patients
-- do not need to group by itemid because we group by linkorderid
, sedativemv as
(
select
icustay_id, linkorderid
, min(starttime) as starttime, max(endtime) as endtime
from io_mv
group by icustay_id, linkorderid
)
, sedativemv_grp as
(
SELECT
s1.icustay_id,
s1.starttime,
MIN(t1.endtime) AS endtime
FROM sedativemv s1
INNER JOIN sedativemv t1
ON s1.icustay_id = t1.icustay_id
AND s1.starttime <= t1.endtime
AND NOT EXISTS(SELECT * FROM sedativemv t2
WHERE t1.icustay_id = t2.icustay_id
AND t1.endtime >= t2.starttime
AND t1.endtime < t2.endtime)
WHERE NOT EXISTS(SELECT * FROM sedativemv s2
WHERE s1.icustay_id = s2.icustay_id
AND s1.starttime > s2.starttime
AND s1.starttime <= s2.endtime)
GROUP BY s1.icustay_id, s1.starttime
ORDER BY s1.icustay_id, s1.starttime
)
select
icustay_id
-- generate a sequential integer for convenience
, ROW_NUMBER() over (partition by icustay_id order by starttime) as sedativenum
, starttime, endtime
, extract(epoch from endtime - starttime)/60/60 AS duration_hours
-- add durations
from
sedativecv_grp
UNION
select
icustay_id
, ROW_NUMBER() over (partition by icustay_id order by starttime) as sedativenum
, starttime, endtime
, extract(epoch from endtime - starttime)/60/60 AS duration_hours
-- add durations
from
sedativemv_grp
order by icustay_id, sedativenum;