Skip to content
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
2 changes: 2 additions & 0 deletions NAMESPACE
Original file line number Diff line number Diff line change
Expand Up @@ -60,6 +60,8 @@ S3method(db_supports_table_alias_with_as,TestConnection)
S3method(db_table_temporary,"Microsoft SQL Server")
S3method(db_table_temporary,DBIConnection)
S3method(db_table_temporary,HDB)
S3method(db_table_temporary,OraConnection)
S3method(db_table_temporary,Oracle)
S3method(dbplyr_as_join_by,character)
S3method(dbplyr_as_join_by,default)
S3method(dbplyr_as_join_by,dplyr_join_by)
Expand Down
1 change: 1 addition & 0 deletions NEWS.md
Original file line number Diff line number Diff line change
@@ -1,5 +1,6 @@
# dbplyr (development version)

* Oracle temporary tables now use private temporary tables (Oracle 18c+) instead of global temporary tables. This ensures data persists correctly and table names are automatically prefixed with `ORA$PTT_` (#750).
* CTEs now correctly quote table names when the same query is used multiple times (#1559).
* New `last_sql()` retrieves the most recent SQL query generated by dbplyr, which is useful for debugging (#1471).
* Custom translations of functions starting with `.` work (@MichaelChirico, #1529).
Expand Down
42 changes: 40 additions & 2 deletions R/backend-oracle.R
Original file line number Diff line number Diff line change
Expand Up @@ -203,10 +203,45 @@ sql_table_analyze.Oracle <- function(con, table, ...) {
sql_glue2(con, "ANALYZE TABLE {.tbl table} COMPUTE STATISTICS")
}

is_oracle_temporary_table <- function(table, con) {
grepl("^ORA\\$PTT_", table_path_name(table, con), ignore.case = TRUE)
}

#' @export
db_table_temporary.Oracle <- function(con, table, temporary, ...) {
if (!temporary) {
list(table = table, temporary = FALSE)
} else if (!is_oracle_temporary_table(table, con)) {
new_name <- paste0("ORA$PTT_", table_path_name(table, con))
cli::cli_inform(
paste0("Created a temporary table named ", new_name),
class = c("dbplyr_message_temp_table", "dbplyr_message")
)
list(table = table_path(new_name), temporary = FALSE)
} else {
list(table = table, temporary = FALSE)
}
}

#' @export
sql_query_save.Oracle <- function(con, sql, name, temporary = TRUE, ...) {
type <- if (temporary) "GLOBAL TEMPORARY TABLE" else "TABLE"
sql_glue2(con, "CREATE {.sql type} {.tbl name} AS\n{sql}")
# Since db_table_temporary handles the prefix, `temporary` here is always
# FALSE for temp tables (the name already has ORA$PTT_ prefix)

# ON COMMIT PRESERVE ROWS creates a session-specific temporary table
if (is_oracle_temporary_table(name, con)) {
sql_glue2(
con,
"
CREATE PRIVATE TEMPORARY TABLE {.tbl name}
ON COMMIT PRESERVE ROWS
AS
{sql}
"
)
} else {
sql_glue2(con, "CREATE TABLE {.tbl name} AS\n{sql}")
}
}

#' @export
Expand Down Expand Up @@ -253,6 +288,9 @@ sql_query_explain.OraConnection <- sql_query_explain.Oracle
#' @export
sql_table_analyze.OraConnection <- sql_table_analyze.Oracle

#' @export
db_table_temporary.OraConnection <- db_table_temporary.Oracle

#' @export
sql_query_save.OraConnection <- sql_query_save.Oracle

Expand Down
18 changes: 13 additions & 5 deletions tests/testthat/_snaps/backend-oracle.md
Original file line number Diff line number Diff line change
Expand Up @@ -40,6 +40,13 @@
RETURNING `df_x`.`a`, `df_x`.`b` AS `b2`
;

# db_table_temporary adds ORA$PTT_ prefix

Code
result <- db_table_temporary(con, table_path("tbl"), temporary = TRUE)
Message
Created a temporary table named ORA$PTT_tbl

# generates custom sql

Code
Expand Down Expand Up @@ -69,18 +76,19 @@
---

Code
sql_query_save(con, sql("SELECT * FROM foo"), in_schema("schema", "tbl"))
sql_query_save(con, sql("SELECT * FROM foo"), "ORA$PTT_tbl")
Output
<SQL> CREATE GLOBAL TEMPORARY TABLE `schema`.`tbl` AS
<SQL> CREATE PRIVATE TEMPORARY TABLE `ORA$PTT_tbl`
ON COMMIT PRESERVE ROWS
AS
SELECT * FROM foo

---

Code
sql_query_save(con, sql("SELECT * FROM foo"), in_schema("schema", "tbl"),
temporary = FALSE)
sql_query_save(con, sql("SELECT * FROM foo"), "tbl", temporary = FALSE)
Output
<SQL> CREATE TABLE `schema`.`tbl` AS
<SQL> CREATE TABLE `tbl` AS
SELECT * FROM foo

---
Expand Down
31 changes: 25 additions & 6 deletions tests/testthat/test-backend-oracle.R
Original file line number Diff line number Diff line change
Expand Up @@ -68,6 +68,27 @@ test_that("`sql_query_upsert()` is correct", {
)
})

test_that("db_table_temporary adds ORA$PTT_ prefix", {
con <- simulate_oracle()

# Adds prefix (with message) for temporary tables
expect_snapshot(
result <- db_table_temporary(con, table_path("tbl"), temporary = TRUE)
)
expect_equal(as.character(result$table), "ORA$PTT_tbl")
expect_false(result$temporary)

# Doesn't double-prefix if already has ORA$PTT_
result <- db_table_temporary(con, table_path("ORA$PTT_tbl"), temporary = TRUE)
expect_equal(as.character(result$table), "ORA$PTT_tbl")
expect_false(result$temporary)

# Returns table unchanged for non-temporary
result <- db_table_temporary(con, table_path("tbl"), temporary = FALSE)
expect_equal(as.character(result$table), "tbl")
expect_false(result$temporary)
})

test_that("generates custom sql", {
con <- simulate_oracle()

Expand All @@ -77,15 +98,13 @@ test_that("generates custom sql", {
lf <- lazy_frame(x = 1, con = con)
expect_snapshot(left_join(lf, lf, by = "x", na_matches = "na"))

# With ORA$PTT_ prefix -> creates PRIVATE TEMPORARY TABLE
expect_snapshot(sql_query_save(con, sql("SELECT * FROM foo"), "ORA$PTT_tbl"))
# Without ORA$PTT_ prefix -> creates regular TABLE
expect_snapshot(sql_query_save(
con,
sql("SELECT * FROM foo"),
in_schema("schema", "tbl")
))
expect_snapshot(sql_query_save(
con,
sql("SELECT * FROM foo"),
in_schema("schema", "tbl"),
"tbl",
temporary = FALSE
))

Expand Down
Loading