forked from OHDSI/ShinyDeploy
-
Notifications
You must be signed in to change notification settings - Fork 1
/
Copy pathDataPulls.R
458 lines (433 loc) · 18.1 KB
/
DataPulls.R
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
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
getExposureName <- function(connection, exposureId) {
sql <- "SELECT exposure_name FROM single_exposure_of_interest WHERE exposure_id = @exposure_id
UNION ALL SELECT exposure_name FROM combi_exposure_of_interest WHERE exposure_id = @exposure_id"
sql <- SqlRender::render(sql, exposure_id = exposureId)
sql <- SqlRender::translate(sql, targetDialect = connection@dbms)
exposureName <- querySql(connection, sql)
return(exposureName[1, 1])
}
getExposureDescription <- function(connection, exposureId) {
sql <- "SELECT description FROM single_exposure_of_interest WHERE exposure_id = @exposure_id
UNION ALL SELECT exposure_name FROM combi_exposure_of_interest WHERE exposure_id = @exposure_id"
sql <- SqlRender::render(sql, exposure_id = exposureId)
sql <- SqlRender::translate(sql, targetDialect = connection@dbms)
exposureDescription <- querySql(connection, sql)
return(exposureDescription[1, 1])
}
getOutcomeName <- function(connection, outcomeId) {
sql <- "SELECT outcome_name FROM outcome_of_interest WHERE outcome_id = @outcome_id"
sql <- SqlRender::render(sql, outcome_id = outcomeId)
sql <- SqlRender::translate(sql, targetDialect = connection@dbms)
outcomeName <- querySql(connection, sql)
return(outcomeName[1, 1])
}
getIndications <- function(connection) {
sql <- "SELECT indication_id, indication_name FROM indication"
sql <- SqlRender::translate(sql, targetDialect = connection@dbms)
indications <- querySql(connection, sql)
colnames(indications) <- SqlRender::snakeCaseToCamelCase(colnames(indications))
return(indications)
}
getExposures <- function(connection, filterByCmResults = TRUE) {
sql <- "SELECT * FROM (
SELECT exposure_id, exposure_name, indication_id, 0 AS combi FROM single_exposure_of_interest
UNION ALL SELECT exposure_id, exposure_name, indication_id, 1 AS combi FROM combi_exposure_of_interest
) exposure
INNER JOIN exposure_group
ON exposure.exposure_id = exposure_group.exposure_id
{@filter_by_cm_results} ? {
INNER JOIN exposure_ids
ON exposure_ids.exposure_id = exposure.exposure_id
}
;"
sql <- SqlRender::render(sql, filter_by_cm_results = filterByCmResults)
sql <- SqlRender::translate(sql, targetDialect = connection@dbms)
exposures <- querySql(connection, sql)
colnames(exposures) <- SqlRender::snakeCaseToCamelCase(colnames(exposures))
return(exposures)
}
getOutcomes <- function(connection) {
sql <- "SELECT outcome_id, outcome_name, indication_id FROM outcome_of_interest"
sql <- SqlRender::translate(sql, targetDialect = connection@dbms)
outcomes <- querySql(connection, sql)
colnames(outcomes) <- SqlRender::snakeCaseToCamelCase(colnames(outcomes))
return(outcomes)
}
getAnalyses <- function(connection) {
sql <- "SELECT analysis_id, description FROM cohort_method_analysis"
sql <- SqlRender::translate(sql, targetDialect = connection@dbms)
analyses <- querySql(connection, sql)
colnames(analyses) <- SqlRender::snakeCaseToCamelCase(colnames(analyses))
return(analyses)
}
getDatabases <- function(connection) {
sql <- "SELECT * FROM database"
sql <- SqlRender::translate(sql, targetDialect = connection@dbms)
databases <- querySql(connection, sql)
colnames(databases) <- SqlRender::snakeCaseToCamelCase(colnames(databases))
return(databases)
}
getDatabaseDetails <- function(connection, databaseId) {
sql <- "SELECT * FROM database WHERE database_id = '@database_id'"
sql <- SqlRender::render(sql, database_id = databaseId)
sql <- SqlRender::translate(sql, targetDialect = connection@dbms)
databaseDetails <- querySql(connection, sql)
colnames(databaseDetails) <- SqlRender::snakeCaseToCamelCase(colnames(databaseDetails))
databaseDetails$description <- sub("\\n", " ", databaseDetails$description)
databaseDetails$description <- sub("JDMC", "JMDC", databaseDetails$description) # TODO Fix in schema
return(databaseDetails)
}
getIndicationForExposure <- function(connection,
exposureIds = c()) {
sql <- "SELECT exposure_id, indication_id FROM single_exposure_of_interest WHERE"
sql <- paste(sql, paste0("exposure_id IN (", paste(exposureIds, collapse = ", "), ")"))
sql <- SqlRender::translate(sql, targetDialect = connection@dbms)
indications <- querySql(connection, sql)
colnames(indications) <- SqlRender::snakeCaseToCamelCase(colnames(indications))
return(indications)
}
getTcoDbs <- function(connection,
targetIds = c(),
comparatorIds = c(),
outcomeIds = c(),
databaseIds = c(),
operator = "AND",
limit = 0) {
sql <- "SELECT target_id, comparator_id, outcome_id, database_id FROM cohort_method_result WHERE analysis_id = 1 AND se_log_rr IS NOT NULL"
if (limit != 0) {
sql <- gsub("SELECT target_id", sprintf("SELECT TOP %s target_id", limit), sql)
}
parts <- c()
if (length(targetIds) != 0) {
parts <- c(parts, paste0("target_id IN (", paste(targetIds, collapse = ", "), ")"))
}
if (length(comparatorIds) != 0) {
parts <- c(parts, paste0("comparator_id IN (", paste(comparatorIds, collapse = ", "), ")"))
}
if (length(outcomeIds) != 0) {
parts <- c(parts, paste0("outcome_id IN (", paste(outcomeIds, collapse = ", "), ")"))
}
if (length(databaseIds) != 0) {
parts <- c(parts, paste0("database_id IN ('", paste(databaseIds, collapse = "', '"), "')"))
}
if (length(parts) != 0) {
if (operator == "AND") {
sql <- paste(sql, "AND", paste(parts, collapse = " AND "))
} else {
sql <- paste(sql, "AND", paste(parts, collapse = " OR "))
}
}
sql <- paste0(sql, ";")
sql <- SqlRender::translate(sql, targetDialect = connection@dbms)
tcoDbs <- querySql(connection, sql)
colnames(tcoDbs) <- SqlRender::snakeCaseToCamelCase(colnames(tcoDbs))
return(tcoDbs)
}
getTcoDbsStrict <- function(connection, exposureIds = c(), outcomeIds = c(), databaseIds = c()) {
sql <- "SELECT TOP 100 target_id, comparator_id, outcome_id, database_id FROM cohort_method_result WHERE analysis_id = 1"
parts <- c()
if (length(exposureIds) != 0) {
for (exposureId in exposureIds) {
parts <- c(parts,
paste0("(target_id = ", exposureId, " OR comparator_id = ", exposureId, ")"))
}
}
if (length(outcomeIds) != 0) {
parts <- c(parts, paste0("outcome_id IN (", paste(outcomeIds, collapse = ", "), ")"))
}
if (length(databaseIds) != 0) {
parts <- c(parts, paste0("database_id IN ('", paste(databaseIds, collapse = "', '"), "')"))
}
if (length(parts) != 0) {
sql <- paste(sql, "AND", paste(parts, collapse = " AND "))
}
sql <- paste0(sql, ";")
sql <- SqlRender::translate(sql, targetDialect = connection@dbms)
tcoDbs <- querySql(connection, sql)
colnames(tcoDbs) <- SqlRender::snakeCaseToCamelCase(colnames(tcoDbs))
return(tcoDbs)
}
getMainResults <- function(connection,
targetIds = c(),
comparatorIds = c(),
outcomeIds = c(),
databaseIds = c(),
analysisIds = c(),
estimatesOnly = FALSE) {
if (estimatesOnly) {
sql <- "SELECT calibrated_log_rr, calibrated_se_log_rr, calibrated_ci_95_lb, calibrated_ci_95_ub FROM cohort_method_result"
} else {
sql <- "SELECT * FROM cohort_method_result"
}
parts <- c()
if (length(targetIds) != 0) {
parts <- c(parts, paste0("target_id IN (", paste(targetIds, collapse = ", "), ")"))
}
if (length(comparatorIds) != 0) {
parts <- c(parts, paste0("comparator_id IN (", paste(comparatorIds, collapse = ", "), ")"))
}
if (length(outcomeIds) != 0) {
parts <- c(parts, paste0("outcome_id IN (", paste(outcomeIds, collapse = ", "), ")"))
}
if (length(databaseIds) != 0) {
parts <- c(parts, paste0("database_id IN ('", paste(databaseIds, collapse = "', '"), "')"))
}
if (length(analysisIds) != 0) {
parts <- c(parts, paste0("analysis_id IN ('", paste(analysisIds, collapse = "', '"), "')"))
}
if (length(parts) != 0) {
sql <- paste(sql, "WHERE", paste(parts, collapse = " AND "))
}
sql <- SqlRender::translate(sql, targetDialect = connection@dbms)
results <- querySql(connection, sql)
colnames(results) <- SqlRender::snakeCaseToCamelCase(colnames(results))
return(results)
}
getControlResults <- function(connection, targetId, comparatorId, analysisId, databaseId) {
sql <- "SELECT *
FROM cohort_method_result
INNER JOIN (
SELECT outcome_id,
outcome_name,
CAST(1 AS FLOAT) AS effect_size
FROM negative_control_outcome
UNION ALL
SELECT outcome_id,
outcome_name,
effect_size
FROM positive_control_outcome
) outcomes
ON cohort_method_result.outcome_id = outcomes.outcome_id
WHERE target_id = @target_id
AND comparator_id = @comparator_id
AND database_id = '@database_id'
AND analysis_id = @analysis_id"
sql <- SqlRender::render(sql,
target_id = targetId,
comparator_id = comparatorId,
database_id = databaseId,
analysis_id = analysisId)
results <- querySql(connection, sql)
colnames(results) <- SqlRender::snakeCaseToCamelCase(colnames(results))
return(results)
}
getCmFollowUpDist <- function(connection,
targetId,
comparatorId,
outcomeId,
databaseId,
analysisId) {
sql <- "SELECT target_min_days,
target_p10_days,
target_p25_days,
target_median_days,
target_p75_days,
target_p90_days,
target_max_days,
comparator_min_days,
comparator_p10_days,
comparator_p25_days,
comparator_median_days,
comparator_p75_days,
comparator_p90_days,
comparator_max_days
FROM cm_follow_up_dist
WHERE target_id = @target_id
AND comparator_id = @comparator_id
AND outcome_id = @outcome_id
AND database_id = '@database_id'
AND analysis_id = @analysis_id"
sql <- SqlRender::render(sql,
target_id = targetId,
comparator_id = comparatorId,
outcome_id = outcomeId,
database_id = databaseId,
analysis_id = analysisId)
sql <- SqlRender::translate(sql, targetDialect = connection@dbms)
followUpDist <- querySql(connection, sql)
colnames(followUpDist) <- SqlRender::snakeCaseToCamelCase(colnames(followUpDist))
return(followUpDist)
}
getCovariateBalance <- function(connection,
targetId,
comparatorId,
databaseId,
analysisId,
outcomeId = NULL) {
sql <- "SELECT covariate.covariate_id, covariate_name, covariate_analysis_id,
target_mean_before,
comparator_mean_before,
std_diff_before,
target_mean_after,
comparator_mean_after,
std_diff_after
FROM covariate_balance
INNER JOIN covariate
ON covariate_balance.covariate_id = covariate.covariate_id
AND covariate_balance.database_id = covariate.database_id
WHERE target_id = @target_id
AND comparator_id = @comparator_id
AND covariate.database_id = '@database_id'
AND analysis_id = @analysis_id
{@outcome_id == \"\"} ? {AND outcome_id IS NULL} : {AND outcome_id = @outcome_id}"
sql <- SqlRender::render(sql,
target_id = targetId,
comparator_id = comparatorId,
database_id = databaseId,
analysis_id = analysisId,
outcome_id = outcomeId)
sql <- SqlRender::translate(sql, targetDialect = connection@dbms)
balance <- querySql(connection, sql)
colnames(balance) <- c("covariateId",
"covariateName",
"analysisId",
"beforeMatchingMeanTreated",
"beforeMatchingMeanComparator",
"beforeMatchingStdDiff",
"afterMatchingMeanTreated",
"afterMatchingMeanComparator",
"afterMatchingStdDiff")
balance$absBeforeMatchingStdDiff <- abs(balance$beforeMatchingStdDiff)
balance$absAfterMatchingStdDiff <- abs(balance$afterMatchingStdDiff)
return(balance)
}
getPs <- function(connection, targetIds, comparatorIds, databaseId = "") {
sql <- "SELECT database_id,
target_id,
comparator_id,
preference_score,
target_density,
comparator_density
FROM preference_score_dist
WHERE target_id IN (@target_ids)
AND comparator_id IN (@comparator_ids)
{@database_id != \"\"} ? {AND database_id = '@database_id'};"
sql <- SqlRender::render(sql,
target_ids = targetIds,
comparator_ids = comparatorIds,
database_id = databaseId)
sql <- SqlRender::translate(sql, targetDialect = connection@dbms)
ps <- querySql(connection, sql)
colnames(ps) <- SqlRender::snakeCaseToCamelCase(colnames(ps))
if (databaseId != "") {
ps$databaseId <- NULL
}
return(ps)
}
getKaplanMeier <- function(connection, targetId, comparatorId, outcomeId, databaseId, analysisId) {
sql <- "SELECT time,
target_at_risk,
comparator_at_risk,
target_survival,
target_survival_lb,
target_survival_ub,
comparator_survival,
comparator_survival_lb,
comparator_survival_ub
FROM kaplan_meier_dist
WHERE target_id = @target_id
AND comparator_id = @comparator_id
AND outcome_id = @outcome_id
AND database_id = '@database_id'
AND analysis_id = @analysis_id"
sql <- SqlRender::render(sql,
target_id = targetId,
comparator_id = comparatorId,
outcome_id = outcomeId,
database_id = databaseId,
analysis_id = analysisId)
sql <- SqlRender::translate(sql, targetDialect = connection@dbms)
ps <- querySql(connection, sql)
colnames(ps) <- SqlRender::snakeCaseToCamelCase(colnames(ps))
return(ps)
}
getAttrition <- function(connection, targetId, comparatorId, outcomeId, analysisId, databaseId) {
sql <- "SELECT exposure_id,
sequence_number,
description,
subjects
FROM attrition
WHERE (target_id IS NULL OR target_id = @target_id)
AND (comparator_id IS NULL OR comparator_id = @comparator_id)
AND (outcome_id IS NULL OR outcome_id = @outcome_id)
AND (exposure_id = @target_id OR exposure_id = @comparator_id)
AND (analysis_id IS NULL OR analysis_id = @analysis_id)
AND database_id = '@database_id'"
sql <- SqlRender::render(sql,
target_id = targetId,
comparator_id = comparatorId,
outcome_id = outcomeId,
analysis_id = analysisId,
database_id = databaseId)
sql <- SqlRender::translate(sql, targetDialect = connection@dbms)
attrition <- querySql(connection, sql)
colnames(attrition) <- SqlRender::snakeCaseToCamelCase(colnames(attrition))
if (any(grepl("Mono-therapy", attrition$description)) &
any(grepl("Duo-therapy", attrition$description))) {
attrition$description <- gsub("(Mono-therapy)|(Duo-therapy)", "Mono/duo-therapy", attrition$description)
}
targetAttrition <- attrition[attrition$exposureId == targetId, ]
comparatorAttrition <- attrition[attrition$exposureId == comparatorId, ]
colnames(targetAttrition)[colnames(targetAttrition) == "subjects"] <- "targetPersons"
targetAttrition$exposureId <- NULL
colnames(comparatorAttrition)[colnames(comparatorAttrition) == "subjects"] <- "comparatorPersons"
comparatorAttrition$exposureId <- NULL
attrition <- merge(targetAttrition, comparatorAttrition)
attrition <- attrition[order(attrition$sequenceNumber), ]
return(attrition)
}
getStudyPeriod <- function(connection, targetId, comparatorId, databaseId) {
sql <- "SELECT min_date,
max_date
FROM comparison_summary
WHERE target_id = @target_id
AND comparator_id = @comparator_id
AND database_id = '@database_id'"
sql <- SqlRender::render(sql,
target_id = targetId,
comparator_id = comparatorId,
database_id = databaseId)
sql <- SqlRender::translate(sql, targetDialect = connection@dbms)
studyPeriod <- querySql(connection, sql)
colnames(studyPeriod) <- SqlRender::snakeCaseToCamelCase(colnames(studyPeriod))
return(studyPeriod)
}
getCovariateBalanceSummary <- function(connection, targetId, comparatorId, analysisId) {
sql <- "SELECT database_id,
COUNT(*) AS covariate_count,
PERCENTILE_DISC(ARRAY[0, 0.25,0.5,0.75,1]) WITHIN GROUP (ORDER BY std_diff_before) AS percentiles_before,
PERCENTILE_DISC(ARRAY[0, 0.25,0.5,0.75,1]) WITHIN GROUP (ORDER BY std_diff_after) AS percentiles_after
FROM covariate_balance
WHERE target_id = @target_id
AND comparator_id = @comparator_id
AND outcome_id IS NULL
AND analysis_id = @analysis_id
GROUP BY database_id;"
sql <- SqlRender::render(sql,
target_id = targetId,
comparator_id = comparatorId,
analysis_id = analysisId)
sql <- SqlRender::translate(sql, targetDialect = connection@dbms)
balanceSummary <- querySql(connection, sql)
colnames(balanceSummary) <- SqlRender::snakeCaseToCamelCase(colnames(balanceSummary))
return(balanceSummary)
}
getNegativeControlEstimates <- function(connection, targetId, comparatorId, analysisId) {
sql <- "SELECT database_id,
log_rr,
se_log_rr
FROM cohort_method_result
INNER JOIN negative_control_outcome
ON cohort_method_result.outcome_id = negative_control_outcome.outcome_id
WHERE target_id = @target_id
AND comparator_id = @comparator_id
AND analysis_id = @analysis_id
AND se_log_rr IS NOT NULL;"
sql <- SqlRender::render(sql,
target_id = targetId,
comparator_id = comparatorId,
analysis_id = analysisId)
results <- querySql(connection, sql)
colnames(results) <- SqlRender::snakeCaseToCamelCase(colnames(results))
return(results)
}