Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add translations for base::difftime(), and clock functions add_days(), add_years(), date_build(), get_year(), get_month(), get_day() #1357

Merged
merged 16 commits into from
Jan 9, 2024
Merged
Show file tree
Hide file tree
Changes from 9 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
23 changes: 23 additions & 0 deletions R/backend-mssql.R
Original file line number Diff line number Diff line change
Expand Up @@ -350,6 +350,29 @@ 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))
},

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
26 changes: 25 additions & 1 deletion R/backend-oracle.R
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
23 changes: 23 additions & 0 deletions R/backend-postgres.R
Original file line number Diff line number Diff line change
Expand Up @@ -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'))
Copy link
Contributor Author

@ablack3 ablack3 Nov 10, 2023

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@mgirlich this works but is very awkward. Is there a better way to get the correct SQL here?

This is what I want to write but it is not a valid R expression

sql_expr((!!x + !!n * INTERVAL'1 year'))

The SQL should look like

(`column_name` + 2 * INTERVAL'1 year')

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@hadley is there a better way to write this expression? !!x + !!n%*INTERVAL%'1 year' seems strange but it's the only way I could come up with that worked.

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I'd probably use glue_sql2() since that's SQL expression is distant from any R equivalent.

Copy link
Contributor Author

@ablack3 ablack3 Dec 26, 2023

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Ok I tried glue_sql2() instead. Hopefully I used it correctly. I'm using sql_current_con() as the first argument.

},

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"')
Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I thought we could just support the 'days' unit to start. Keep it simple.

}

sql_expr((CAST(!!time2 %AS% DATE) - CAST(!!time1 %AS% DATE)))
},
),
sql_translator(.parent = base_agg,
cor = sql_aggregate_2("CORR"),
Expand Down
23 changes: 23 additions & 0 deletions R/backend-redshift.R
Original file line number Diff line number Diff line change
Expand Up @@ -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,
Expand Down
22 changes: 22 additions & 0 deletions R/backend-snowflake.R
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
25 changes: 24 additions & 1 deletion R/backend-spark-sql.R
Original file line number Diff line number Diff line change
Expand Up @@ -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"),
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
16 changes: 16 additions & 0 deletions tests/testthat/test-backend-mssql.R
Original file line number Diff line number Diff line change
Expand Up @@ -124,6 +124,22 @@ 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")))
})

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 @@ -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")))
})
16 changes: 16 additions & 0 deletions tests/testthat/test-backend-postgres.R
Original file line number Diff line number Diff line change
Expand Up @@ -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())

Expand Down
16 changes: 16 additions & 0 deletions tests/testthat/test-backend-redshift.R
Original file line number Diff line number Diff line change
Expand Up @@ -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")))
})
16 changes: 16 additions & 0 deletions tests/testthat/test-backend-snowflake.R
Original file line number Diff line number Diff line change
Expand Up @@ -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())

Expand Down
15 changes: 15 additions & 0 deletions tests/testthat/test-backend-spark-sql.R
Original file line number Diff line number Diff line change
@@ -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")))
})
1 change: 1 addition & 0 deletions tests/testthat/test-tidyeval.R
Original file line number Diff line number Diff line change
Expand Up @@ -38,6 +38,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", {
Expand Down
Loading