Skip to content

Commit

Permalink
Allow Oracle to correctly explain queries (#1354)
Browse files Browse the repository at this point in the history
Fixes #1353
  • Loading branch information
thomashulst authored Dec 21, 2023
1 parent e898906 commit 267a12e
Show file tree
Hide file tree
Showing 4 changed files with 26 additions and 6 deletions.
2 changes: 2 additions & 0 deletions NAMESPACE
Original file line number Diff line number Diff line change
Expand Up @@ -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)
Expand Down
2 changes: 2 additions & 0 deletions NEWS.md
Original file line number Diff line number Diff line change
@@ -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).

Expand Down
24 changes: 20 additions & 4 deletions R/backend-oracle.R
Original file line number Diff line number Diff line change
Expand Up @@ -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())")
)
}

Expand Down Expand Up @@ -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
Expand Down Expand Up @@ -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

Expand Down
4 changes: 2 additions & 2 deletions tests/testthat/_snaps/backend-oracle.md
Original file line number Diff line number Diff line change
Expand Up @@ -41,8 +41,8 @@
Code
sql_query_explain(con, sql("SELECT * FROM foo"))
Output
<SQL> EXPLAIN PLAN FOR SELECT * FROM foo;
SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY()));
<SQL> EXPLAIN PLAN FOR SELECT * FROM foo
<SQL> SELECT PLAN_TABLE_OUTPUT FROM TABLE(DBMS_XPLAN.DISPLAY())

---

Expand Down

0 comments on commit 267a12e

Please sign in to comment.