diff --git a/NEWS.md b/NEWS.md index 496fc7d0b..70164c416 100644 --- a/NEWS.md +++ b/NEWS.md @@ -2,7 +2,9 @@ * `across(everything())` doesn't select grouping columns created via `.by` in `summarise()` (@mgirlich, #1493). - + +* New translations of clock function `date_count_between()` for SQL server, Redshift, Snowflake, Postgres, and Spark (@edward-burn, #1495). + * Spark SQL backend now supports persisting tables with `compute(x, name = I("x.y.z"), temporary = FALSE)` (@zacdav-db, #1502). diff --git a/R/backend-mssql.R b/R/backend-mssql.R index 1850e6d89..015c1f2a0 100644 --- a/R/backend-mssql.R +++ b/R/backend-mssql.R @@ -372,6 +372,18 @@ simulate_mssql <- function(version = "15.0") { get_day = function(x) { sql_expr(DATEPART(DAY, !!x)) }, + date_count_between = function(start, end, precision, ..., n = 1L){ + + check_dots_empty() + if (precision != "day") { + cli_abort("{.arg precision} must be {.val day} on SQL backends.") + } + if (n != 1) { + cli_abort("{.arg n} must be {.val 1} on SQL backends.") + } + + sql_expr(DATEDIFF(DAY, !!start, !!end)) + }, difftime = function(time1, time2, tz, units = "days") { diff --git a/R/backend-postgres.R b/R/backend-postgres.R index 5f9f0ba6f..b93289a0b 100644 --- a/R/backend-postgres.R +++ b/R/backend-postgres.R @@ -248,6 +248,18 @@ sql_translation.PqConnection <- function(con) { date_build = function(year, month = 1L, day = 1L, ..., invalid = NULL) { sql_expr(make_date(!!year, !!month, !!day)) }, + date_count_between = function(start, end, precision, ..., n = 1L){ + + check_dots_empty() + if (precision != "day") { + cli_abort("{.arg precision} must be {.val day} on SQL backends.") + } + if (n != 1) { + cli_abort("{.arg n} must be {.val 1} on SQL backends.") + } + + sql_expr(!!end - !!start) + }, get_year = function(x) { sql_expr(date_part('year', !!x)) }, diff --git a/R/backend-redshift.R b/R/backend-redshift.R index b3f35d3c5..c1ff03a21 100644 --- a/R/backend-redshift.R +++ b/R/backend-redshift.R @@ -83,6 +83,18 @@ sql_translation.RedshiftConnection <- function(con) { get_day = function(x) { sql_expr(DATE_PART('day', !!x)) }, + date_count_between = function(start, end, precision, ..., n = 1L){ + + check_dots_empty() + if (precision != "day") { + cli_abort("{.arg precision} must be {.val day} on SQL backends.") + } + if (n != 1) { + cli_abort("{.arg n} must be {.val 1} on SQL backends.") + } + + sql_expr(DATEDIFF(DAY, !!start, !!end)) + }, difftime = function(time1, time2, tz, units = "days") { diff --git a/R/backend-snowflake.R b/R/backend-snowflake.R index afb696f2d..ddd4e70dd 100644 --- a/R/backend-snowflake.R +++ b/R/backend-snowflake.R @@ -232,6 +232,18 @@ sql_translation.Snowflake <- function(con) { get_day = function(x) { sql_expr(DATE_PART(DAY, !!x)) }, + date_count_between = function(start, end, precision, ..., n = 1L){ + + check_dots_empty() + if (precision != "day") { + cli_abort("{.arg precision} must be {.val day} on SQL backends.") + } + if (n != 1) { + cli_abort("{.arg n} must be {.val 1} on SQL backends.") + } + + sql_expr(DATEDIFF(DAY, !!start, !!end)) + }, difftime = function(time1, time2, tz, units = "days") { diff --git a/R/backend-spark-sql.R b/R/backend-spark-sql.R index cabb0d1c3..c551f830a 100644 --- a/R/backend-spark-sql.R +++ b/R/backend-spark-sql.R @@ -58,6 +58,18 @@ simulate_spark_sql <- function() simulate_dbi("Spark SQL") get_day = function(x) { sql_expr(date_part('DAY', !!x)) }, + date_count_between = function(start, end, precision, ..., n = 1L){ + + check_dots_empty() + if (precision != "day") { + cli_abort("{.arg precision} must be {.val day} on SQL backends.") + } + if (n != 1) { + cli_abort("{.arg n} must be {.val 1} on SQL backends.") + } + + sql_expr(datediff(!!end, !!start)) + }, difftime = function(time1, time2, tz, units = "days") { diff --git a/tests/testthat/test-backend-mssql.R b/tests/testthat/test-backend-mssql.R index bab3508d3..a39ae258c 100644 --- a/tests/testthat/test-backend-mssql.R +++ b/tests/testthat/test-backend-mssql.R @@ -139,6 +139,10 @@ test_that("custom clock functions translated correctly", { 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`)")) + expect_equal(test_translate_sql(date_count_between(date_column_1, date_column_2, "day")), + sql("DATEDIFF(DAY, `date_column_1`, `date_column_2`)")) + expect_error(test_translate_sql(date_count_between(date_column_1, date_column_2, "year"))) + expect_error(test_translate_sql(date_count_between(date_column_1, date_column_2, "day", n = 5))) }) test_that("difftime is translated correctly", { diff --git a/tests/testthat/test-backend-postgres.R b/tests/testthat/test-backend-postgres.R index 0517f195e..e9f137398 100644 --- a/tests/testthat/test-backend-postgres.R +++ b/tests/testthat/test-backend-postgres.R @@ -98,6 +98,10 @@ test_that("custom clock functions translated correctly", { 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`)")) + expect_equal(test_translate_sql(date_count_between(date_column_1, date_column_2, "day")), + sql("`date_column_2` - `date_column_1`")) + expect_error(test_translate_sql(date_count_between(date_column_1, date_column_2, "year"))) + expect_error(test_translate_sql(date_count_between(date_column_1, date_column_2, "day", n = 5))) }) test_that("difftime is translated correctly", { diff --git a/tests/testthat/test-backend-redshift.R b/tests/testthat/test-backend-redshift.R index f2b5a9699..7f586a738 100644 --- a/tests/testthat/test-backend-redshift.R +++ b/tests/testthat/test-backend-redshift.R @@ -68,6 +68,10 @@ test_that("custom clock functions translated correctly", { 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`)")) + expect_equal(test_translate_sql(date_count_between(date_column_1, date_column_2, "day")), + sql("DATEDIFF(DAY, `date_column_1`, `date_column_2`)")) + expect_error(test_translate_sql(date_count_between(date_column_1, date_column_2, "year"))) + expect_error(test_translate_sql(date_count_between(date_column_1, date_column_2, "day", n = 5))) }) test_that("difftime is translated correctly", { diff --git a/tests/testthat/test-backend-snowflake.R b/tests/testthat/test-backend-snowflake.R index 37c50828f..ac4facc5c 100644 --- a/tests/testthat/test-backend-snowflake.R +++ b/tests/testthat/test-backend-snowflake.R @@ -112,6 +112,10 @@ test_that("custom clock functions translated correctly", { 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`)")) + expect_equal(test_translate_sql(date_count_between(date_column_1, date_column_2, "day")), + sql("DATEDIFF(DAY, `date_column_1`, `date_column_2`)")) + expect_error(test_translate_sql(date_count_between(date_column_1, date_column_2, "year"))) + expect_error(test_translate_sql(date_count_between(date_column_1, date_column_2, "day", n = 5))) }) test_that("difftime is translated correctly", { diff --git a/tests/testthat/test-backend-spark-sql.R b/tests/testthat/test-backend-spark-sql.R index e1276c7a0..5332457d3 100644 --- a/tests/testthat/test-backend-spark-sql.R +++ b/tests/testthat/test-backend-spark-sql.R @@ -8,6 +8,10 @@ test_that("custom clock functions translated correctly", { 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`)")) + expect_equal(test_translate_sql(date_count_between(date_column_1, date_column_2, "day")), + sql("DATEDIFF(`date_column_2`, `date_column_1`)")) + expect_error(test_translate_sql(date_count_between(date_column_1, date_column_2, "year"))) + expect_error(test_translate_sql(date_count_between(date_column_1, date_column_2, "day", n = 5))) }) test_that("difftime is translated correctly", {