Skip to content

Commit

Permalink
MSSQL version 11+ (2012+) backend calls try_cast instead of cast
Browse files Browse the repository at this point in the history
try_cast results in a more elegant failure (returns NA) if a cast is not possible ('cast' will throw an error).
Address issue tidyverse#380
  • Loading branch information
DavidPatShuiFong committed Sep 22, 2020
1 parent 56d08a3 commit bf33069
Show file tree
Hide file tree
Showing 2 changed files with 34 additions and 2 deletions.
26 changes: 24 additions & 2 deletions R/backend-mssql.R
Expand Up @@ -47,7 +47,7 @@

#' @export
`sql_translate_env.Microsoft SQL Server` <- function(con) {
sql_variant(
mssql_scalar <-
sql_translator(.parent = base_odbc_scalar,

`!` = function(x) {
Expand Down Expand Up @@ -150,8 +150,30 @@
sql_expr(DATEPART(QUARTER, !!x))
}
},
)

),
if (sub("0.*", "", DBI::dbGetInfo(con)$db.version) >= 11) {
# version 11 equates to MSSQL 2012
# if MSSQL 2012+, use sql_try_cast, allows more graceful return of invalid values
mssql_scalar <- sql_translator(.parent = mssql_scalar,
as.logical = sql_try_cast("BIT"),

as.Date = sql_try_cast("DATE"),
as.POSIXct = sql_try_cast("TIMESTAMP"),
as.numeric = sql_try_cast("FLOAT"),
as.double = sql_try_cast("FLOAT"),
as.integer = sql_try_cast("NUMERIC"),
# in MSSQL, NUMERIC converts to integer
as.integer64 = sql_try_cast("BIGINT"),
as.character = sql_try_cast("VARCHAR(MAX)"),

as_date = sql_try_cast("DATE"),
as_datetime = sql_try_cast("DATETIME2")
)
}

sql_variant(
mssql_scalar,
sql_translator(.parent = base_odbc_agg,
sd = sql_aggregate("STDEV", "sd"),
var = sql_aggregate("VAR", "var"),
Expand Down
10 changes: 10 additions & 0 deletions R/translate-sql-helpers.R
Expand Up @@ -231,6 +231,16 @@ sql_cast <- function(type) {
}
}

#' @rdname sql_variant
#' @export
sql_try_cast <- function(type) {
type <- sql(type)
function(x) {
sql_expr(try_cast(!!x %as% !!type))
# try_cast available in MSSQL 2012+
}
}

#' @rdname sql_variant
#' @export
sql_log <- function() {
Expand Down

0 comments on commit bf33069

Please sign in to comment.