Skip to content

Commit

Permalink
Add more date/time translations (#1357)
Browse files Browse the repository at this point in the history
For SQL server, redshift, postgres, and snowflake.
  • Loading branch information
ablack3 authored Jan 9, 2024
1 parent a40c03a commit 068a88f
Show file tree
Hide file tree
Showing 15 changed files with 328 additions and 4 deletions.
4 changes: 4 additions & 0 deletions NEWS.md
Original file line number Diff line number Diff line change
@@ -1,5 +1,9 @@
# dbplyr (development version)

* Add translations for clock functions `add_years()`, `add_days()`,
`date_build()`, `get_year()`, `get_month()`, `get_day()`,
and `base::difftime()` on SQL server, Redshift, Snowflake, and Postgres.

* SQL server: `filter()` does a better job of converting logical vectors
from bit to boolean (@ejneer, #1288).

Expand Down
37 changes: 36 additions & 1 deletion R/backend-mssql.R
Original file line number Diff line number Diff line change
Expand Up @@ -350,6 +350,41 @@ simulate_mssql <- function(version = "15.0") {
sql_expr(DATEPART(QUARTER, !!x))
}
},

# clock ---------------------------------------------------------------
add_days = function(x, n, ...) {
check_dots_empty()
sql_expr(DATEADD(DAY, !!n, !!x))
},
add_years = function(x, n, ...) {
check_dots_empty()
sql_expr(DATEADD(YEAR, !!n, !!x))
},
date_build = function(year, month = 1L, day = 1L, ..., invalid = NULL) {
sql_expr(DATEFROMPARTS(!!year, !!month, !!day))
},
get_year = function(x) {
sql_expr(DATEPART('year', !!x))
},
get_month = function(x) {
sql_expr(DATEPART('month', !!x))
},
get_day = function(x) {
sql_expr(DATEPART('day', !!x))
},

difftime = function(time1, time2, tz, units = "days") {

if (!missing(tz)) {
cli::cli_abort("The {.arg tz} argument is not supported for SQL backends.")
}

if (units[1] != "days") {
cli::cli_abort('The only supported value for {.arg units} on SQL backends is "days"')
}

sql_expr(DATEDIFF(day, !!time1, !!time2))
}
)

if (mssql_version(con) >= "11.0") { # MSSQL 2012
Expand Down Expand Up @@ -607,7 +642,7 @@ mssql_update_where_clause <- function(qry) {
}

qry$where <- lapply(
qry$where,
qry$where,
function(x) set_expr(x, bit_to_boolean(get_expr(x)))
)
qry
Expand Down
26 changes: 25 additions & 1 deletion R/backend-oracle.R
Original file line number Diff line number Diff line change
Expand Up @@ -145,7 +145,31 @@ sql_translation.Oracle <- function(con) {

# lubridate --------------------------------------------------------------
today = function() sql_expr(TRUNC(CURRENT_TIMESTAMP)),
now = function() sql_expr(CURRENT_TIMESTAMP)
now = function() sql_expr(CURRENT_TIMESTAMP),

# clock ------------------------------------------------------------------
add_days = function(x, n, ...) {
check_dots_empty()
sql_expr((!!x + NUMTODSINTERVAL(!!n, 'day')))
},
add_years = function(x, n, ...) {
check_dots_empty()
sql_expr((!!x + NUMTODSINTERVAL(!!n * 365.25, 'day')))
},

difftime = function(time1, time2, tz, units = "days") {

if (!missing(tz)) {
cli::cli_abort("The {.arg tz} argument is not supported for SQL backends.")
}

if (units[1] != "days") {
cli::cli_abort('The only supported value for {.arg units} on SQL backends is "days"')
}

sql_expr(CEIL(CAST(!!time2 %AS% DATE) - CAST(!!time1 %AS% DATE)))
}

),
base_odbc_agg,
base_odbc_win
Expand Down
35 changes: 35 additions & 0 deletions R/backend-postgres.R
Original file line number Diff line number Diff line change
Expand Up @@ -235,6 +235,41 @@ sql_translation.PqConnection <- function(con) {
)
sql_expr(DATE_TRUNC(!!unit, !!x))
},

# clock ---------------------------------------------------------------
add_days = function(x, n, ...) {
check_dots_empty()
glue_sql2(sql_current_con(), "({.col x} + {.val n}*INTERVAL'1 day')")
},
add_years = function(x, n, ...) {
check_dots_empty()
glue_sql2(sql_current_con(), "({.col x} + {.val n}*INTERVAL'1 year')")
},
date_build = function(year, month = 1L, day = 1L, ..., invalid = NULL) {
sql_expr(make_date(!!year, !!month, !!day))
},
get_year = function(x) {
sql_expr(date_part('year', !!x))
},
get_month = function(x) {
sql_expr(date_part('month', !!x))
},
get_day = function(x) {
sql_expr(date_part('day', !!x))
},

difftime = function(time1, time2, tz, units = "days") {

if (!missing(tz)) {
cli::cli_abort("The {.arg tz} argument is not supported for SQL backends.")
}

if (units[1] != "days") {
cli::cli_abort('The only supported value for {.arg units} on SQL backends is "days"')
}

sql_expr((CAST(!!time2 %AS% DATE) - CAST(!!time1 %AS% DATE)))
},
),
sql_translator(.parent = base_agg,
cor = sql_aggregate_2("CORR"),
Expand Down
35 changes: 35 additions & 0 deletions R/backend-redshift.R
Original file line number Diff line number Diff line change
Expand Up @@ -60,6 +60,41 @@ sql_translation.RedshiftConnection <- function(con) {
str_replace = sql_not_supported("str_replace"),
str_replace_all = function(string, pattern, replacement) {
sql_expr(REGEXP_REPLACE(!!string, !!pattern, !!replacement))
},

# clock ---------------------------------------------------------------
add_days = function(x, n, ...) {
check_dots_empty()
sql_expr(DATEADD(DAY, !!n, !!x))
},
add_years = function(x, n, ...) {
check_dots_empty()
sql_expr(DATEADD(YEAR, !!n, !!x))
},
date_build = function(year, month = 1L, day = 1L, ..., invalid = NULL) {
glue_sql2(sql_current_con(), "TO_DATE(CAST({.val year} AS TEXT) || '-' CAST({.val month} AS TEXT) || '-' || CAST({.val day} AS TEXT)), 'YYYY-MM-DD')")
},
get_year = function(x) {
sql_expr(DATE_PART('year', !!x))
},
get_month = function(x) {
sql_expr(DATE_PART('month', !!x))
},
get_day = function(x) {
sql_expr(DATE_PART('day', !!x))
},

difftime = function(time1, time2, tz, units = "days") {

if (!missing(tz)) {
cli::cli_abort("The {.arg tz} argument is not supported for SQL backends.")
}

if (units[1] != "days") {
cli::cli_abort('The only supported value for {.arg units} on SQL backends is "days"')
}

sql_expr(DATEDIFF(day, !!time1, !!time2))
}
),
sql_translator(.parent = postgres$aggregate,
Expand Down
35 changes: 35 additions & 0 deletions R/backend-snowflake.R
Original file line number Diff line number Diff line change
Expand Up @@ -210,6 +210,41 @@ sql_translation.Snowflake <- function(con) {
)
sql_expr(DATE_TRUNC(!!unit, !!x))
},
# clock ---------------------------------------------------------------
add_days = function(x, n, ...) {
check_dots_empty()
sql_expr(DATEADD(DAY, !!n, !!x))
},
add_years = function(x, n, ...) {
check_dots_empty()
sql_expr(DATEADD(YEAR, !!n, !!x))
},
date_build = function(year, month = 1L, day = 1L, ..., invalid = NULL) {
# https://docs.snowflake.com/en/sql-reference/functions/date_from_parts
sql_expr(DATE_FROM_PARTS(!!year, !!month, !!day))
},
get_year = function(x) {
sql_expr(DATE_PART('year', !!x))
},
get_month = function(x) {
sql_expr(DATE_PART('month', !!x))
},
get_day = function(x) {
sql_expr(DATE_PART('day', !!x))
},

difftime = function(time1, time2, tz, units = "days") {

if (!missing(tz)) {
cli::cli_abort("The {.arg tz} argument is not supported for SQL backends.")
}

if (units[1] != "days") {
cli::cli_abort('The only supported value for {.arg units} on SQL backends is "days"')
}

sql_expr(DATEDIFF(day, !!time1, !!time2))
},
# LEAST / GREATEST on Snowflake will not respect na.rm = TRUE by default (similar to Oracle/Access)
# https://docs.snowflake.com/en/sql-reference/functions/least
# https://docs.snowflake.com/en/sql-reference/functions/greatest
Expand Down
37 changes: 36 additions & 1 deletion R/backend-spark-sql.R
Original file line number Diff line number Diff line change
Expand Up @@ -36,7 +36,42 @@ simulate_spark_sql <- function() simulate_dbi("Spark SQL")
#' @export
`sql_translation.Spark SQL` <- function(con) {
sql_variant(
base_odbc_scalar,
sql_translator(.parent = base_odbc_scalar,
# clock ---------------------------------------------------------------
add_days = function(x, n, ...) {
check_dots_empty()
sql_expr(date_add(!!x, !!n))
},
add_years = function(x, n, ...) {
check_dots_empty()
sql_expr(add_months(!!!x, !!n*12))
},
date_build = function(year, month = 1L, day = 1L, ..., invalid = NULL) {
sql_expr(make_date(!!year, !!month, !!day))
},
get_year = function(x) {
sql_expr(date_part('YEAR', !!x))
},
get_month = function(x) {
sql_expr(date_part('MONTH', !!x))
},
get_day = function(x) {
sql_expr(date_part('DAY', !!x))
},

difftime = function(time1, time2, tz, units = "days") {

if (!missing(tz)) {
cli::cli_abort("The {.arg tz} argument is not supported for SQL backends.")
}

if (units[1] != "days") {
cli::cli_abort('The only supported value for {.arg units} on SQL backends is "days"')
}

sql_expr(datediff(!!time2, !!time1))
}
),
sql_translator(.parent = base_odbc_agg,
var = sql_aggregate("VARIANCE", "var"),
quantile = sql_quantile("PERCENTILE"),
Expand Down
2 changes: 1 addition & 1 deletion R/tidyeval.R
Original file line number Diff line number Diff line change
Expand Up @@ -163,7 +163,7 @@ partial_eval_sym <- function(sym, data, env) {
}

is_namespaced_dplyr_call <- function(call) {
packages <- c("base", "dplyr", "stringr", "lubridate")
packages <- c("base", "dplyr", "stringr", "lubridate", "clock")
is_symbol(call[[1]], "::") && is_symbol(call[[2]], packages)
}

Expand Down
21 changes: 21 additions & 0 deletions tests/testthat/test-backend-mssql.R
Original file line number Diff line number Diff line change
Expand Up @@ -124,6 +124,27 @@ test_that("custom lubridate functions translated correctly", {
expect_error(test_translate_sql(quarter(x, fiscal_start = 5)))
})

test_that("custom clock functions translated correctly", {
local_con(simulate_mssql())
expect_equal(test_translate_sql(add_years(x, 1)), sql("DATEADD(YEAR, 1.0, `x`)"))
expect_equal(test_translate_sql(add_days(x, 1)), sql("DATEADD(DAY, 1.0, `x`)"))
expect_error(test_translate_sql(add_days(x, 1, "dots", "must", "be empty")))
expect_equal(test_translate_sql(date_build(2020, 1, 1)), sql("DATEFROMPARTS(2020.0, 1.0, 1.0)"))
expect_equal(test_translate_sql(date_build(year_column, 1L, 1L)), sql("DATEFROMPARTS(`year_column`, 1, 1)"))
expect_equal(test_translate_sql(get_year(date_column)), sql("DATEPART('year', `date_column`)"))
expect_equal(test_translate_sql(get_month(date_column)), sql("DATEPART('month', `date_column`)"))
expect_equal(test_translate_sql(get_day(date_column)), sql("DATEPART('day', `date_column`)"))
})

test_that("difftime is translated correctly", {
local_con(simulate_mssql())
expect_equal(test_translate_sql(difftime(start_date, end_date, units = "days")), sql("DATEDIFF(day, `start_date`, `end_date`)"))
expect_equal(test_translate_sql(difftime(start_date, end_date)), sql("DATEDIFF(day, `start_date`, `end_date`)"))

expect_error(test_translate_sql(difftime(start_date, end_date, units = "auto")))
expect_error(test_translate_sql(difftime(start_date, end_date, tz = "UTC", units = "days")))
})

test_that("last_value_sql() translated correctly", {
con <- simulate_mssql()
expect_equal(
Expand Down
16 changes: 16 additions & 0 deletions tests/testthat/test-backend-oracle.R
Original file line number Diff line number Diff line change
Expand Up @@ -82,3 +82,19 @@ test_that("copy_inline uses UNION ALL", {
copy_inline(con, y, types = types) %>% remote_query()
})
})

test_that("custom clock functions translated correctly", {
local_con(simulate_oracle())
expect_equal(test_translate_sql(add_years(x, 1)), sql("(`x` + NUMTODSINTERVAL(1.0 * 365.25, 'day'))"))
expect_equal(test_translate_sql(add_days(x, 1)), sql("(`x` + NUMTODSINTERVAL(1.0, 'day'))"))
expect_error(test_translate_sql(add_days(x, 1, "dots", "must", "be empty")))
})

test_that("difftime is translated correctly", {
local_con(simulate_oracle())
expect_equal(test_translate_sql(difftime(start_date, end_date, units = "days")), sql("CEIL(CAST(`end_date` AS DATE) - CAST(`start_date` AS DATE))"))
expect_equal(test_translate_sql(difftime(start_date, end_date)), sql("CEIL(CAST(`end_date` AS DATE) - CAST(`start_date` AS DATE))"))

expect_error(test_translate_sql(difftime(start_date, end_date, units = "auto")))
expect_error(test_translate_sql(difftime(start_date, end_date, tz = "UTC", units = "days")))
})
21 changes: 21 additions & 0 deletions tests/testthat/test-backend-postgres.R
Original file line number Diff line number Diff line change
Expand Up @@ -88,6 +88,27 @@ test_that("custom lubridate functions translated correctly", {
expect_equal(test_translate_sql(floor_date(x, 'week')), sql("DATE_TRUNC('week', `x`)"))
})

test_that("custom clock functions translated correctly", {
local_con(simulate_postgres())
expect_equal(test_translate_sql(add_years(x, 1)), sql("(`x` + 1.0*INTERVAL'1 year')"))
expect_equal(test_translate_sql(add_days(x, 1)), sql("(`x` + 1.0*INTERVAL'1 day')"))
expect_error(test_translate_sql(add_days(x, 1, "dots", "must", "be empty")))
expect_equal(test_translate_sql(date_build(2020, 1, 1)), sql("MAKE_DATE(2020.0, 1.0, 1.0)"))
expect_equal(test_translate_sql(date_build(year_column, 1L, 1L)), sql("MAKE_DATE(`year_column`, 1, 1)"))
expect_equal(test_translate_sql(get_year(date_column)), sql("DATE_PART('year', `date_column`)"))
expect_equal(test_translate_sql(get_month(date_column)), sql("DATE_PART('month', `date_column`)"))
expect_equal(test_translate_sql(get_day(date_column)), sql("DATE_PART('day', `date_column`)"))
})

test_that("difftime is translated correctly", {
local_con(simulate_postgres())
expect_equal(test_translate_sql(difftime(start_date, end_date, units = "days")), sql("(CAST(`end_date` AS DATE) - CAST(`start_date` AS DATE))"))
expect_equal(test_translate_sql(difftime(start_date, end_date)), sql("(CAST(`end_date` AS DATE) - CAST(`start_date` AS DATE))"))

expect_error(test_translate_sql(difftime(start_date, end_date, units = "auto")))
expect_error(test_translate_sql(difftime(start_date, end_date, tz = "UTC", units = "days")))
})

test_that("custom window functions translated correctly", {
local_con(simulate_postgres())

Expand Down
21 changes: 21 additions & 0 deletions tests/testthat/test-backend-redshift.R
Original file line number Diff line number Diff line change
Expand Up @@ -57,3 +57,24 @@ test_that("copy_inline uses UNION ALL", {
copy_inline(con, y, types = types) %>% remote_query()
})
})

test_that("custom clock functions translated correctly", {
local_con(simulate_redshift())
expect_equal(test_translate_sql(add_years(x, 1)), sql("DATEADD(YEAR, 1.0, `x`)"))
expect_equal(test_translate_sql(add_days(x, 1)), sql("DATEADD(DAY, 1.0, `x`)"))
expect_error(test_translate_sql(add_days(x, 1, "dots", "must", "be empty")))
expect_equal(test_translate_sql(date_build(2020, 1, 1)), sql("TO_DATE(CAST(2020.0 AS TEXT) || '-' CAST(1.0 AS TEXT) || '-' || CAST(1.0 AS TEXT)), 'YYYY-MM-DD')"))
expect_equal(test_translate_sql(date_build(year_column, 1L, 1L)), sql("TO_DATE(CAST(`year_column` AS TEXT) || '-' CAST(1 AS TEXT) || '-' || CAST(1 AS TEXT)), 'YYYY-MM-DD')"))
expect_equal(test_translate_sql(get_year(date_column)), sql("DATE_PART('year', `date_column`)"))
expect_equal(test_translate_sql(get_month(date_column)), sql("DATE_PART('month', `date_column`)"))
expect_equal(test_translate_sql(get_day(date_column)), sql("DATE_PART('day', `date_column`)"))
})

test_that("difftime is translated correctly", {
local_con(simulate_redshift())
expect_equal(test_translate_sql(difftime(start_date, end_date, units = "days")), sql("DATEDIFF(day, `start_date`, `end_date`)"))
expect_equal(test_translate_sql(difftime(start_date, end_date)), sql("DATEDIFF(day, `start_date`, `end_date`)"))

expect_error(test_translate_sql(difftime(start_date, end_date, units = "auto")))
expect_error(test_translate_sql(difftime(start_date, end_date, tz = "UTC", units = "days")))
})
Loading

0 comments on commit 068a88f

Please sign in to comment.