diff --git a/NAMESPACE b/NAMESPACE index 9677e24b3..231fd305d 100644 --- a/NAMESPACE +++ b/NAMESPACE @@ -55,6 +55,8 @@ S3method(db_copy_to,DBIConnection) S3method(db_create_index,DBIConnection) S3method(db_desc,DBIConnection) S3method(db_explain,DBIConnection) +S3method(db_explain,OraConnection) +S3method(db_explain,Oracle) S3method(db_query_fields,DBIConnection) S3method(db_query_fields,PostgreSQLConnection) S3method(db_save_query,DBIConnection) diff --git a/NEWS.md b/NEWS.md index da9ab66ad..316b50d0d 100644 --- a/NEWS.md +++ b/NEWS.md @@ -1,5 +1,7 @@ # dbplyr (development version) +* `db_explain()` now works for Oracle (@thomashulst, #1353). + * Database errors now show the generated SQL, which hopefully will make it faster to track down problems (#1401). diff --git a/R/backend-oracle.R b/R/backend-oracle.R index dcae5b1d2..e66ef1b52 100644 --- a/R/backend-oracle.R +++ b/R/backend-oracle.R @@ -144,10 +144,11 @@ sql_translation.Oracle <- function(con) { #' @export sql_query_explain.Oracle <- function(con, sql, ...) { - glue_sql2( - con, - "EXPLAIN PLAN FOR {sql};\n", - "SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY()));", + + # https://docs.oracle.com/en/database/oracle/oracle-database/19/tgsql/generating-and-displaying-execution-plans.html + c( + glue_sql2(con, "EXPLAIN PLAN FOR {sql}"), + glue_sql2(con, "SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY())") ) } @@ -182,6 +183,18 @@ sql_expr_matches.Oracle <- function(con, x, y, ...) { glue_sql2(con, "decode({x}, {y}, 0, 1) = 0") } +#' @export +db_explain.Oracle <- function(con, sql, ...) { + sql <- sql_query_explain(con, sql, ...) + + msg <- "Can't explain query." + db_execute(con, sql[[1]], msg) # EXPLAIN PLAN + expl <- db_get_query(con, sql[[2]], msg) # DBMS_XPLAN.DISPLAY + + out <- utils::capture.output(print(expl)) + paste(out, collapse = "\n") +} + #' @export db_supports_table_alias_with_as.Oracle <- function(con) { FALSE @@ -219,6 +232,9 @@ setdiff.OraConnection <- setdiff.tbl_Oracle #' @export sql_expr_matches.OraConnection <- sql_expr_matches.Oracle +#' @export +db_explain.OraConnection <- db_explain.Oracle + #' @export db_supports_table_alias_with_as.OraConnection <- db_supports_table_alias_with_as.Oracle diff --git a/tests/testthat/_snaps/backend-oracle.md b/tests/testthat/_snaps/backend-oracle.md index 72e3f07bb..5ede3c406 100644 --- a/tests/testthat/_snaps/backend-oracle.md +++ b/tests/testthat/_snaps/backend-oracle.md @@ -41,8 +41,8 @@ Code sql_query_explain(con, sql("SELECT * FROM foo")) Output - EXPLAIN PLAN FOR SELECT * FROM foo; - SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY())); + EXPLAIN PLAN FOR SELECT * FROM foo + SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY()) ---