From 77df050b332512d826f1cb14dee0cb0ec35ee1e6 Mon Sep 17 00:00:00 2001 From: Adam Black Date: Sun, 27 Aug 2023 17:41:44 -0400 Subject: [PATCH 01/14] Add mssql translations for two clock functions --- R/backend-mssql.R | 10 ++++++++++ tests/testthat/test-backend-mssql.R | 13 +++++++++++++ 2 files changed, 23 insertions(+) diff --git a/R/backend-mssql.R b/R/backend-mssql.R index 830f51b26..138c9ef95 100644 --- a/R/backend-mssql.R +++ b/R/backend-mssql.R @@ -350,6 +350,16 @@ simulate_mssql <- function(version = "15.0") { sql_expr(DATEPART(QUARTER, !!x)) } }, + + # clock --------------------------------------------------------------- + add_days = function(x, n, ...) { + rlang::check_dots_empty(...) + sql_expr(DATEADD(DAY, !!n, !!x)) + }, + add_years = function(x, n, ...) { + rlang::check_dots_empty(...) + sql_expr(DATEADD(YEAR, !!n, !!x)) + } ) if (mssql_version(con) >= "11.0") { # MSSQL 2012 diff --git a/tests/testthat/test-backend-mssql.R b/tests/testthat/test-backend-mssql.R index dfc05c91a..fa5b2358a 100644 --- a/tests/testthat/test-backend-mssql.R +++ b/tests/testthat/test-backend-mssql.R @@ -124,6 +124,19 @@ 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, 1L)), sql("DATEADD(YEAR, 1, `x`)")) + expect_equal(test_translate_sql(add_years(x, 1)), sql("DATEADD(YEAR, 1.0, `x`)")) + expect_equal(test_translate_sql(add_days(x, 1L)), sql("DATEADD(DAY, 1, `x`)")) + expect_equal(test_translate_sql(add_days(x, 1)), sql("DATEADD(DAY, 1.0, `x`)")) + + expect_equal(test_translate_sql(clock::add_years(x, 1)), sql("DATEADD(YEAR, 1.0, `x`)")) + expect_equal(test_translate_sql(clock::add_days(x, 1)), sql("DATEADD(DAY, 1.0, `x`)")) + + expect_error(test_translate_sql(add_days(x, 1, "dots must be empty"))) +}) + test_that("last_value_sql() translated correctly", { con <- simulate_mssql() expect_equal( From 8eaa86ebd7e677fe4f935f2a4442e80df5934e22 Mon Sep 17 00:00:00 2001 From: Adam Black Date: Mon, 28 Aug 2023 09:32:20 -0400 Subject: [PATCH 02/14] strip namespace for clock function translation --- R/tidyeval.R | 2 +- tests/testthat/test-backend-mssql.R | 8 +------- tests/testthat/test-tidyeval.R | 1 + 3 files changed, 3 insertions(+), 8 deletions(-) diff --git a/R/tidyeval.R b/R/tidyeval.R index dfc6519ff..d18fe2cce 100644 --- a/R/tidyeval.R +++ b/R/tidyeval.R @@ -163,7 +163,7 @@ partial_eval_sym <- function(sym, data, env) { } is_namespaced_dplyr_call <- function(call) { - packages <- c("dplyr", "stringr", "lubridate") + packages <- c("dplyr", "stringr", "lubridate", "clock") is_symbol(call[[1]], "::") && is_symbol(call[[2]], packages) } diff --git a/tests/testthat/test-backend-mssql.R b/tests/testthat/test-backend-mssql.R index fa5b2358a..09768ca40 100644 --- a/tests/testthat/test-backend-mssql.R +++ b/tests/testthat/test-backend-mssql.R @@ -126,15 +126,9 @@ test_that("custom lubridate functions translated correctly", { test_that("custom clock functions translated correctly", { local_con(simulate_mssql()) - expect_equal(test_translate_sql(add_years(x, 1L)), sql("DATEADD(YEAR, 1, `x`)")) expect_equal(test_translate_sql(add_years(x, 1)), sql("DATEADD(YEAR, 1.0, `x`)")) - expect_equal(test_translate_sql(add_days(x, 1L)), sql("DATEADD(DAY, 1, `x`)")) expect_equal(test_translate_sql(add_days(x, 1)), sql("DATEADD(DAY, 1.0, `x`)")) - - expect_equal(test_translate_sql(clock::add_years(x, 1)), sql("DATEADD(YEAR, 1.0, `x`)")) - expect_equal(test_translate_sql(clock::add_days(x, 1)), sql("DATEADD(DAY, 1.0, `x`)")) - - expect_error(test_translate_sql(add_days(x, 1, "dots must be empty"))) + expect_error(test_translate_sql(add_days(x, 1, "dots", "must", "be empty"))) }) test_that("last_value_sql() translated correctly", { diff --git a/tests/testthat/test-tidyeval.R b/tests/testthat/test-tidyeval.R index aeceeaf80..1719f8c48 100644 --- a/tests/testthat/test-tidyeval.R +++ b/tests/testthat/test-tidyeval.R @@ -44,6 +44,7 @@ test_that("namespaced calls to dplyr functions are stripped", { # hack to avoid check complaining about not declared imports expect_equal(partial_eval(rlang::parse_expr("stringr::str_to_lower(x)"), lf), expr(str_to_lower(x))) expect_equal(partial_eval(rlang::parse_expr("lubridate::today()"), lf), expr(today())) + expect_equal(partial_eval(rlang::parse_expr("clock::add_years(x, 1)"), lf), expr(add_years(x, 1))) }) test_that("use quosure environment for unevaluted formulas", { From 07e1a5a10ab9be438359a1c540be3655bdd8c2ed Mon Sep 17 00:00:00 2001 From: Adam Black Date: Fri, 10 Nov 2023 11:50:47 +0100 Subject: [PATCH 03/14] add datediff translation on mssql --- R/backend-mssql.R | 25 +++++++++++++++++++++++-- tests/testthat/test-backend-mssql.R | 18 ++++++++++++++++++ 2 files changed, 41 insertions(+), 2 deletions(-) diff --git a/R/backend-mssql.R b/R/backend-mssql.R index 138c9ef95..b1559c085 100644 --- a/R/backend-mssql.R +++ b/R/backend-mssql.R @@ -353,12 +353,33 @@ simulate_mssql <- function(version = "15.0") { # clock --------------------------------------------------------------- add_days = function(x, n, ...) { - rlang::check_dots_empty(...) + check_dots_empty() sql_expr(DATEADD(DAY, !!n, !!x)) }, add_years = function(x, n, ...) { - rlang::check_dots_empty(...) + check_dots_empty() sql_expr(DATEADD(YEAR, !!n, !!x)) + }, + + difftime = function(time1, time2, tz, units) { + + if (!missing(tz)) { + cli::cli_abort("The `tz` argument is not supported for SQL backends.") + } + + if (!(units[1] %in% c("secs", "mins", "hours", "days", "weeks", "years"))) { + cli::cli_abort('The units argument must be one of "secs", "mins", "hours", "days", "weeks".') + } + + datepart <- switch(units[1], + years = expr(year), + weeks = expr(week), + days = expr(day), + hours = expr(hour), + mins = expr(minute), + secs = expr(second)) + + sql_expr(DATEDIFF(!!datepart, !!time1, !!time2)) } ) diff --git a/tests/testthat/test-backend-mssql.R b/tests/testthat/test-backend-mssql.R index 09768ca40..73aee747e 100644 --- a/tests/testthat/test-backend-mssql.R +++ b/tests/testthat/test-backend-mssql.R @@ -131,6 +131,24 @@ test_that("custom clock functions translated correctly", { expect_error(test_translate_sql(add_days(x, 1, "dots", "must", "be empty"))) }) +test_that("difftime is translated correctly", { + local_con(simulate_mssql()) + # years is not supported by base::difftime version but seems useful for SQL + expect_equal(test_translate_sql(difftime(start_date, end_date, units = "years")), sql("DATEDIFF(year, `start_date`, `end_date`)")) + expect_equal(test_translate_sql(difftime(start_date, end_date, units = "weeks")), sql("DATEDIFF(week, `start_date`, `end_date`)")) + 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, units = "mins")), sql("DATEDIFF(minute, `start_date`, `end_date`)")) + expect_equal(test_translate_sql(difftime(start_date, end_date, units = "hours")), sql("DATEDIFF(hour, `start_date`, `end_date`)")) + expect_equal(test_translate_sql(difftime(start_date, end_date, units = "secs")), sql("DATEDIFF(second, `start_date`, `end_date`)")) + + # auto units is not supported + expect_error(test_translate_sql(difftime(start_date, end_date, units = "auto"))) + # units must be specified + expect_error(test_translate_sql(difftime(start_date, end_date))) + # tz is not supported + 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( From 93568838f6191c3c712cfbd5f23bd06e59a32282 Mon Sep 17 00:00:00 2001 From: Adam Black Date: Fri, 10 Nov 2023 14:36:39 +0100 Subject: [PATCH 04/14] only support units='days' in difftime sql translation --- R/backend-mssql.R | 18 +++++------------- tests/testthat/test-backend-mssql.R | 11 +---------- 2 files changed, 6 insertions(+), 23 deletions(-) diff --git a/R/backend-mssql.R b/R/backend-mssql.R index b1559c085..187785e63 100644 --- a/R/backend-mssql.R +++ b/R/backend-mssql.R @@ -361,25 +361,17 @@ simulate_mssql <- function(version = "15.0") { sql_expr(DATEADD(YEAR, !!n, !!x)) }, - difftime = function(time1, time2, tz, units) { + difftime = function(time1, time2, tz, units = "days") { if (!missing(tz)) { - cli::cli_abort("The `tz` argument is not supported for SQL backends.") + cli::cli_abort("The {.arg tz} argument is not supported for SQL backends.") } - if (!(units[1] %in% c("secs", "mins", "hours", "days", "weeks", "years"))) { - cli::cli_abort('The units argument must be one of "secs", "mins", "hours", "days", "weeks".') + if (units[1] != "days") { + cli::cli_abort('The only supported value for {.arg units} on SQL backends is "days"') } - datepart <- switch(units[1], - years = expr(year), - weeks = expr(week), - days = expr(day), - hours = expr(hour), - mins = expr(minute), - secs = expr(second)) - - sql_expr(DATEDIFF(!!datepart, !!time1, !!time2)) + sql_expr(DATEDIFF(day, !!time1, !!time2)) } ) diff --git a/tests/testthat/test-backend-mssql.R b/tests/testthat/test-backend-mssql.R index 73aee747e..8850b8f47 100644 --- a/tests/testthat/test-backend-mssql.R +++ b/tests/testthat/test-backend-mssql.R @@ -133,19 +133,10 @@ test_that("custom clock functions translated correctly", { test_that("difftime is translated correctly", { local_con(simulate_mssql()) - # years is not supported by base::difftime version but seems useful for SQL - expect_equal(test_translate_sql(difftime(start_date, end_date, units = "years")), sql("DATEDIFF(year, `start_date`, `end_date`)")) - expect_equal(test_translate_sql(difftime(start_date, end_date, units = "weeks")), sql("DATEDIFF(week, `start_date`, `end_date`)")) 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, units = "mins")), sql("DATEDIFF(minute, `start_date`, `end_date`)")) - expect_equal(test_translate_sql(difftime(start_date, end_date, units = "hours")), sql("DATEDIFF(hour, `start_date`, `end_date`)")) - expect_equal(test_translate_sql(difftime(start_date, end_date, units = "secs")), sql("DATEDIFF(second, `start_date`, `end_date`)")) + expect_equal(test_translate_sql(difftime(start_date, end_date)), sql("DATEDIFF(day, `start_date`, `end_date`)")) - # auto units is not supported expect_error(test_translate_sql(difftime(start_date, end_date, units = "auto"))) - # units must be specified - expect_error(test_translate_sql(difftime(start_date, end_date))) - # tz is not supported expect_error(test_translate_sql(difftime(start_date, end_date, tz = "UTC", units = "days"))) }) From 78d5e5472992be681dc7ebd285bebce9f5224817 Mon Sep 17 00:00:00 2001 From: Adam Black Date: Fri, 10 Nov 2023 14:37:29 +0100 Subject: [PATCH 05/14] add difftime, add_years, and add_days translations for oracle --- R/backend-oracle.R | 26 +++++++++++++++++++++++++- tests/testthat/test-backend-oracle.R | 16 ++++++++++++++++ 2 files changed, 41 insertions(+), 1 deletion(-) diff --git a/R/backend-oracle.R b/R/backend-oracle.R index dcae5b1d2..63cf56a2b 100644 --- a/R/backend-oracle.R +++ b/R/backend-oracle.R @@ -135,7 +135,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 diff --git a/tests/testthat/test-backend-oracle.R b/tests/testthat/test-backend-oracle.R index 5c299600f..875a1d16d 100644 --- a/tests/testthat/test-backend-oracle.R +++ b/tests/testthat/test-backend-oracle.R @@ -72,3 +72,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"))) +}) From 1109f8b41ac7d09f6888bf58d118f1279616307b Mon Sep 17 00:00:00 2001 From: Adam Black Date: Fri, 10 Nov 2023 15:02:17 +0100 Subject: [PATCH 06/14] add date function translations for postgres --- R/backend-postgres.R | 23 +++++++++++++++++++++++ tests/testthat/test-backend-postgres.R | 16 ++++++++++++++++ 2 files changed, 39 insertions(+) diff --git a/R/backend-postgres.R b/R/backend-postgres.R index 812c033bb..308d3e1f4 100644 --- a/R/backend-postgres.R +++ b/R/backend-postgres.R @@ -235,6 +235,29 @@ sql_translation.PqConnection <- function(con) { ) sql_expr(DATE_TRUNC(!!unit, !!x)) }, + + # clock --------------------------------------------------------------- + add_days = function(x, n, ...) { + check_dots_empty() + sql_expr((!!x + !!n%*INTERVAL%'1 day')) + }, + add_years = function(x, n, ...) { + check_dots_empty() + sql_expr((!!x + !!n%*INTERVAL%'1 year')) + }, + + 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"), diff --git a/tests/testthat/test-backend-postgres.R b/tests/testthat/test-backend-postgres.R index d62d737b4..8fd400b50 100644 --- a/tests/testthat/test-backend-postgres.R +++ b/tests/testthat/test-backend-postgres.R @@ -88,6 +88,22 @@ 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"))) +}) + +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()) From b0e457be32e5baa17782876707fe5da72eaf0319 Mon Sep 17 00:00:00 2001 From: Adam Black Date: Fri, 10 Nov 2023 15:09:06 +0100 Subject: [PATCH 07/14] Add date function translations on redshift --- R/backend-redshift.R | 23 +++++++++++++++++++++++ tests/testthat/test-backend-redshift.R | 16 ++++++++++++++++ 2 files changed, 39 insertions(+) diff --git a/R/backend-redshift.R b/R/backend-redshift.R index 735085ebb..c2039b64c 100644 --- a/R/backend-redshift.R +++ b/R/backend-redshift.R @@ -60,6 +60,29 @@ 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)) + }, + + 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, diff --git a/tests/testthat/test-backend-redshift.R b/tests/testthat/test-backend-redshift.R index 9e90aa192..3e1cdde02 100644 --- a/tests/testthat/test-backend-redshift.R +++ b/tests/testthat/test-backend-redshift.R @@ -57,3 +57,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_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"))) +}) + +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"))) +}) From 93fb131949763c5a9b8c48d40c19dde45ffbf225 Mon Sep 17 00:00:00 2001 From: Adam Black Date: Fri, 10 Nov 2023 16:16:40 +0100 Subject: [PATCH 08/14] add date function translations for snowflake and spark --- R/backend-snowflake.R | 22 ++++++++++++++++++++++ R/backend-spark-sql.R | 25 ++++++++++++++++++++++++- tests/testthat/test-backend-snowflake.R | 16 ++++++++++++++++ tests/testthat/test-backend-spark-sql.R | 15 +++++++++++++++ 4 files changed, 77 insertions(+), 1 deletion(-) create mode 100644 tests/testthat/test-backend-spark-sql.R diff --git a/R/backend-snowflake.R b/R/backend-snowflake.R index 5774be3cf..76da21c11 100644 --- a/R/backend-snowflake.R +++ b/R/backend-snowflake.R @@ -195,6 +195,28 @@ 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)) + }, + + 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 diff --git a/R/backend-spark-sql.R b/R/backend-spark-sql.R index 79a556107..be6eb1962 100644 --- a/R/backend-spark-sql.R +++ b/R/backend-spark-sql.R @@ -36,7 +36,30 @@ 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)) + }, + + 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"), diff --git a/tests/testthat/test-backend-snowflake.R b/tests/testthat/test-backend-snowflake.R index b1f37b14a..3d728700d 100644 --- a/tests/testthat/test-backend-snowflake.R +++ b/tests/testthat/test-backend-snowflake.R @@ -98,6 +98,22 @@ 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_snowflake()) + 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"))) +}) + +test_that("difftime is translated correctly", { + local_con(simulate_snowflake()) + 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("min() and max()", { local_con(simulate_snowflake()) diff --git a/tests/testthat/test-backend-spark-sql.R b/tests/testthat/test-backend-spark-sql.R new file mode 100644 index 000000000..48a1a9372 --- /dev/null +++ b/tests/testthat/test-backend-spark-sql.R @@ -0,0 +1,15 @@ +test_that("custom clock functions translated correctly", { + local_con(simulate_spark_sql()) + expect_equal(test_translate_sql(add_years(x, 1)), sql("ADD_MONTHS('`x`', 1.0 * 12.0)")) + expect_equal(test_translate_sql(add_days(x, 1)), sql("DATE_ADD(`x`, 1.0)")) + expect_error(test_translate_sql(add_days(x, 1, "dots", "must", "be empty"))) +}) + +test_that("difftime is translated correctly", { + local_con(simulate_spark_sql()) + expect_equal(test_translate_sql(difftime(start_date, end_date, units = "days")), sql("DATEDIFF(`end_date`, `start_date`)")) + expect_equal(test_translate_sql(difftime(start_date, end_date)), sql("DATEDIFF(`end_date`, `start_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"))) +}) From 6e8a92c71568077440f44134a36c60281496e728 Mon Sep 17 00:00:00 2001 From: Adam Black Date: Tue, 26 Dec 2023 16:34:05 +0100 Subject: [PATCH 09/14] add date_build, get_year, get_month, get_day translations for postgres. --- R/backend-postgres.R | 16 ++++++++++++++-- tests/testthat/test-backend-postgres.R | 9 +++++++-- 2 files changed, 21 insertions(+), 4 deletions(-) diff --git a/R/backend-postgres.R b/R/backend-postgres.R index 308d3e1f4..3a3a6a9b3 100644 --- a/R/backend-postgres.R +++ b/R/backend-postgres.R @@ -239,11 +239,23 @@ sql_translation.PqConnection <- function(con) { # clock --------------------------------------------------------------- add_days = function(x, n, ...) { check_dots_empty() - sql_expr((!!x + !!n%*INTERVAL%'1 day')) + glue_sql2(sql_current_con(), "({.col x} + {.val n}*INTERVAL'1 day')") }, add_years = function(x, n, ...) { check_dots_empty() - sql_expr((!!x + !!n%*INTERVAL%'1 year')) + 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") { diff --git a/tests/testthat/test-backend-postgres.R b/tests/testthat/test-backend-postgres.R index 8fd400b50..0517f195e 100644 --- a/tests/testthat/test-backend-postgres.R +++ b/tests/testthat/test-backend-postgres.R @@ -90,9 +90,14 @@ test_that("custom lubridate functions translated correctly", { 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_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", { From 0693ef1c79e60c4a25ee7b6c021e7c0b9cb6b201 Mon Sep 17 00:00:00 2001 From: Adam Black Date: Tue, 26 Dec 2023 20:54:20 +0100 Subject: [PATCH 10/14] Add redshift clock function translations for date_build, get_year, get_month, get_day --- R/backend-redshift.R | 12 ++++++++++++ tests/testthat/test-backend-redshift.R | 5 +++++ 2 files changed, 17 insertions(+) diff --git a/R/backend-redshift.R b/R/backend-redshift.R index c2039b64c..f40186f3e 100644 --- a/R/backend-redshift.R +++ b/R/backend-redshift.R @@ -71,6 +71,18 @@ sql_translation.RedshiftConnection <- function(con) { 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") { diff --git a/tests/testthat/test-backend-redshift.R b/tests/testthat/test-backend-redshift.R index 3e1cdde02..55e66b20f 100644 --- a/tests/testthat/test-backend-redshift.R +++ b/tests/testthat/test-backend-redshift.R @@ -63,6 +63,11 @@ test_that("custom clock functions translated correctly", { 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", { From 477179efba85025b26fa59547372764c99574279 Mon Sep 17 00:00:00 2001 From: Adam Black Date: Tue, 26 Dec 2023 21:23:43 +0100 Subject: [PATCH 11/14] add snowflake translations for clock functions date_build, get_year, get_month, get_day. --- R/backend-snowflake.R | 13 +++++++++++++ tests/testthat/test-backend-snowflake.R | 5 +++++ 2 files changed, 18 insertions(+) diff --git a/R/backend-snowflake.R b/R/backend-snowflake.R index edcb174f5..a72561524 100644 --- a/R/backend-snowflake.R +++ b/R/backend-snowflake.R @@ -219,6 +219,19 @@ sql_translation.Snowflake <- function(con) { 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") { diff --git a/tests/testthat/test-backend-snowflake.R b/tests/testthat/test-backend-snowflake.R index c63329700..c628308d5 100644 --- a/tests/testthat/test-backend-snowflake.R +++ b/tests/testthat/test-backend-snowflake.R @@ -107,6 +107,11 @@ test_that("custom clock functions translated correctly", { 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("DATE_FROM_PARTS(2020.0, 1.0, 1.0)")) + expect_equal(test_translate_sql(date_build(year_column, 1L, 1L)), sql("DATE_FROM_PARTS(`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", { From a46896374e81db17b5507d9f33565b4859e42565 Mon Sep 17 00:00:00 2001 From: Adam Black Date: Tue, 26 Dec 2023 21:29:01 +0100 Subject: [PATCH 12/14] Add mssql clock translations for date_build, get_year, get_month, get_day. --- R/backend-mssql.R | 14 +++++++++++++- tests/testthat/test-backend-mssql.R | 5 +++++ 2 files changed, 18 insertions(+), 1 deletion(-) diff --git a/R/backend-mssql.R b/R/backend-mssql.R index 976c891eb..71880030d 100644 --- a/R/backend-mssql.R +++ b/R/backend-mssql.R @@ -360,6 +360,18 @@ simulate_mssql <- function(version = "15.0") { 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") { @@ -630,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 diff --git a/tests/testthat/test-backend-mssql.R b/tests/testthat/test-backend-mssql.R index 981d6ecb6..880aeb1d0 100644 --- a/tests/testthat/test-backend-mssql.R +++ b/tests/testthat/test-backend-mssql.R @@ -129,6 +129,11 @@ test_that("custom clock functions translated correctly", { 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", { From 2374dad63ad064c75432df227273cb9b9fdbff25 Mon Sep 17 00:00:00 2001 From: Adam Black Date: Tue, 26 Dec 2023 21:41:38 +0100 Subject: [PATCH 13/14] Add spark sql translations for clock functions date_build, get_year, get_month, get_day. --- R/backend-spark-sql.R | 12 ++++++++++++ tests/testthat/test-backend-spark-sql.R | 5 +++++ 2 files changed, 17 insertions(+) diff --git a/R/backend-spark-sql.R b/R/backend-spark-sql.R index be6eb1962..5b43651b5 100644 --- a/R/backend-spark-sql.R +++ b/R/backend-spark-sql.R @@ -46,6 +46,18 @@ simulate_spark_sql <- function() simulate_dbi("Spark SQL") 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") { diff --git a/tests/testthat/test-backend-spark-sql.R b/tests/testthat/test-backend-spark-sql.R index 48a1a9372..e1276c7a0 100644 --- a/tests/testthat/test-backend-spark-sql.R +++ b/tests/testthat/test-backend-spark-sql.R @@ -3,6 +3,11 @@ test_that("custom clock functions translated correctly", { expect_equal(test_translate_sql(add_years(x, 1)), sql("ADD_MONTHS('`x`', 1.0 * 12.0)")) expect_equal(test_translate_sql(add_days(x, 1)), sql("DATE_ADD(`x`, 1.0)")) 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", { From 12b06cf6275728d3da9228e79e36cc4bacf1e62d Mon Sep 17 00:00:00 2001 From: Adam Black Date: Tue, 26 Dec 2023 21:50:19 +0100 Subject: [PATCH 14/14] update News --- NEWS.md | 4 ++++ 1 file changed, 4 insertions(+) diff --git a/NEWS.md b/NEWS.md index 9dfbc547f..c1fb3f5e2 100644 --- a/NEWS.md +++ b/NEWS.md @@ -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).