Skip to content

Commit

Permalink
Fixing unit tests broken by IRIS PR #377
Browse files Browse the repository at this point in the history
  • Loading branch information
schuemie committed Sep 30, 2024
1 parent e5463e2 commit ad43879
Show file tree
Hide file tree
Showing 5 changed files with 115 additions and 114 deletions.
2 changes: 1 addition & 1 deletion DESCRIPTION
Original file line number Diff line number Diff line change
Expand Up @@ -2,7 +2,7 @@ Package: SqlRender
Type: Package
Title: Rendering Parameterized SQL and Translation to Dialects
Version: 1.19.0
Date: 2024-09-24
Date: 2024-09-30
Authors@R: c(
person("Martijn", "Schuemie", , "[email protected]", role = c("aut", "cre")),
person("Marc", "Suchard", role = c("aut"))
Expand Down
2 changes: 2 additions & 0 deletions NEWS.md
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,8 @@ Changes:

1. When creating emulated temp tables (Oracle, Spark, BigQuery), will first attempt to drop (if exist). This is to clean up any orphan tables from a previous (unsuccesful) run.

2. Adding tentative support for InterSystems IRIS. Could still be removed.

Bugfixes:

1. On Snowflake, fixed 'This session does not have a current schema' error when translating legacy `IF OBJECT_ID('tempdb..#table', 'U') IS NOT NULL DROP TABLE #table;`
Expand Down
10 changes: 5 additions & 5 deletions inst/csv/replacementPatterns.csv
Original file line number Diff line number Diff line change
Expand Up @@ -1060,8 +1060,8 @@ spark,TRY_CAST(@a),CAST(@a)
spark,"IIF(@condition, @whentrue, @whenfalse)","CASE WHEN @condition THEN @whentrue ELSE @whenfalse END"
spark,tempdb..#@table +,%temp_prefix%%session_id% ||
spark,#@([^\s]+)table.@([^\s]+)field,%session_id%@table.@field
spark,"--HINT BUCKET(@a, @b)",
spark,"--HINT PARTITION(@a @b)",
spark,"--HINT BUCKET(@a, @b)",""
spark,"--HINT PARTITION(@a @b)",""
spark,"HINT DISTRIBUTE_ON_KEY(@key) CREATE TABLE IF NOT EXISTS @table\nUSING DELTA\nAS\n@definition;","HINT DISTRIBUTE_ON_KEY(@key)\nCREATE TABLE IF NOT EXISTS @table\nUSING DELTA\nAS\n@definition;\nOPTIMIZE @table ZORDER BY @key;"
spark,"HINT DISTRIBUTE_ON_KEY(@key) IF OBJECT_ID('@d', 'U') IS NULL WITH @a AS @b SELECT @c INTO @d FROM @e;",HINT DISTRIBUTE_ON_KEY(@key)\nCREATE TABLE IF NOT EXISTS @d\nUSING DELTA\nAS\nWITH @a AS @b SELECT\n@c\nFROM\n@e;\nOPTIMIZE @d ZORDER BY @key;
spark,"HINT DISTRIBUTE_ON_KEY(@key) IF OBJECT_ID('@b', 'U') IS NULL SELECT @a INTO @b FROM @c;",HINT DISTRIBUTE_ON_KEY(@key) \nCREATE TABLE IF NOT EXISTS @b\nUSING DELTA\nAS\nSELECT\n@a\nFROM\n@c;\nOPTIMIZE @b ZORDER BY @key;
Expand Down Expand Up @@ -1402,9 +1402,9 @@ iris,SELECT @a INTO @b;,CREATE TABLE @b AS SELECT @a;
iris,SELECT @a INTO #@b;,CREATE GLOBAL TEMPORARY TABLE #@b AS SELECT @a;
iris,#,%temp_prefix%%session_id%
iris,UPDATE STATISTICS @a;,TUNE TABLE @a;
iris,"--HINT BUCKET(@a, @b)", -- haven't looked into this yet, skip it for now
iris,"--HINT PARTITION(@a @b)", -- haven't looked into this yet, skip it for now
iris,"--HINT DISTRIBUTE_ON_KEY(@key)", -- haven't looked into this yet, skip it for now
iris,"--HINT BUCKET(@a, @b)", "-- haven't looked into this yet, skip it for now"
iris,"--HINT PARTITION(@a @b)", -- "haven't looked into this yet, skip it for now""
iris,"--HINT DISTRIBUTE_ON_KEY(@key)", -- "haven't looked into this yet, skip it for now""
iris,"DATEFROMPARTS(@year,@month,@day)","TO_DATE(TO_CHAR(@year,'FM0000')||'-'||TO_CHAR(@month,'FM00')||'-'||TO_CHAR(@day,'FM00'), 'YYYY-MM-DD')"
iris,"DATETIMEFROMPARTS(@year,@month,@day,@hour,@minute,@second,@ms)","TO_TIMESTAMP(TO_CHAR(@year,'FM0000')||'-'||TO_CHAR(@month,'FM00')||'-'||TO_CHAR(@day,'FM00')||' '||TO_CHAR(@hour,'FM00')||':'||TO_CHAR(@minute,'FM00')||':'||TO_CHAR(@second,'FM00')||'.'||TO_CHAR(@ms,'FM000'), 'YYYY-MM-DD HH24:MI:SS.FF')"
iris," DATEADD(d, @a, @b) AS"," TO_DATE(DATEADD(d, @a, @b),'YYYY-MM-DD HH:MI:SS') AS"
Expand Down
2 changes: 1 addition & 1 deletion man/SqlRender-package.Rd

Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.

213 changes: 106 additions & 107 deletions tests/testthat/test-translate-iris.R
Original file line number Diff line number Diff line change
@@ -1,107 +1,106 @@
library(testthat)
library(devtools)
library(rJava)


# For debugging: force reload of code & patterns:
# load_all()
# rJava::J('org.ohdsi.sql.SqlTranslate')$setReplacementPatterns('../../inst/csv/replacementPatterns.csv')


expect_equal_ignore_spaces <- function(string1, string2) {
string1 <- gsub("([;()'+-/|*\n])", " \\1 ", string1)
string2 <- gsub("([;()'+-/|*\n])", " \\1 ", string2)
string1 <- gsub(" +", " ", string1)
string2 <- gsub(" +", " ", string2)
expect_equivalent(string1, string2)
}

# tests wrt string concatenation
test_that("translate sql server -> InterSystems IRIS string concatenation", {
sql <- translate("SELECT CONCAT(a, 'b', c)", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT a || 'b' || c")
})
test_that("translate sql server -> InterSystems IRIS string concatenation", {
sql <- translate("SELECT CONCAT(a, 'b', c, d, e, e, f)", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT a || 'b' || c || d || e || e || f")
})
test_that("translate sql server -> InterSystems IRIS string +", {
sql <- translate("SELECT CAST(a AS VARCHAR) + CAST(b AS VARCHAR(10)) + CAST(c AS VARCHAR) + 'd'", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT CAST(a AS VARCHAR) || CAST(b AS varchar(10)) || CAST(c AS VARCHAR) || 'd'")
})
test_that("translate sql server -> InterSystem IRIS string concatenation DOB", {
sql <- translate("SELECT CONCAT(p.year_of_birth, 11, 11)", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT p.year_of_birth||'-'||11||'-'||11")
})


# build date from parts
test_that("translate sql server -> InterSystems IRIS DATEFROMPARTS()", {
sql <- translate("SELECT DATEFROMPARTS(yyyy, mm, dd)", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT TO_DATE(TO_CHAR(yyyy,'FM0000')||'-'||TO_CHAR(mm,'FM00')||'-'||TO_CHAR(dd,'FM00'), 'YYYY-MM-DD')")
})
test_that("translate sql server -> InterSystems IRIS DATETIMEFROMPARTS()", {
sql <- translate("SELECT DATETIMEFROMPARTS(yyyy, mm, dd, hh, mi, ss, ms)", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT TO_TIMESTAMP(TO_CHAR(yyyy,'FM0000')||'-'||TO_CHAR(mm,'FM00')||'-'||TO_CHAR(dd,'FM00')||' '||TO_CHAR(hh,'FM00')||':'||TO_CHAR(mi,'FM00')||':'||TO_CHAR(ss,'FM00')||'.'||TO_CHAR(ms,'FM000'), 'YYYY-MM-DD HH24:MI:SS.FF')")
})



# temp table handling
test_that("translate sql server -> InterSystems IRIS implicit CTAS", {
sql <- translate("SELECT a, b INTO t_new FROM t;", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "CREATE TABLE t_new AS SELECT a, b FROM t;")
})
test_that("translate sql server -> InterSystems IRIS implicit CTTAS", {
sql <- translate("SELECT a, b INTO #t_new FROM t;", targetDialect = "iris")
expect_equal_ignore_spaces(sql, paste("CREATE GLOBAL TEMPORARY TABLE ", getTempTablePrefix(), "t_new AS SELECT a, b FROM t;", sep=""))
})


# test DATEADD() flavours
test_that("translate sql server -> InterSystems IRIS DATEADD(d, ..)", {
sql <- translate("SELECT DATEADD(d, 1, '2007-07-28') AS dt", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT TO_DATE(DATEADD(d,1,'2007-07-28'),'YYYY-MM-DD HH:MI:SS') AS dt")
})
test_that("translate sql server -> InterSystems IRIS DATEADD(d, ..)", {
sql <- translate("SELECT DATEADD(dd, 1, '2007-07-28') AS dt", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT TO_DATE(DATEADD(dd,1,'2007-07-28'),'YYYY-MM-DD HH:MI:SS') AS dt")
})
test_that("translate sql server -> InterSystems IRIS DATEADD(d, ..)", {
sql <- translate("SELECT DATEADD(day, 1, '2007-07-28') AS dt", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT TO_DATE(DATEADD(day,1,'2007-07-28'),'YYYY-MM-DD HH:MI:SS') AS dt")
})
test_that("translate sql server -> InterSystems IRIS DATEADD(d, ..)", {
sql <- translate("SELECT DATEADD(m, 1, '2007-07-28') AS dt", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT TO_DATE(DATEADD(m,1,'2007-07-28'),'YYYY-MM-DD HH:MI:SS') AS dt")
})
test_that("translate sql server -> InterSystems IRIS DATEADD(d, ..)", {
sql <- translate("SELECT DATEADD(mm, 1, '2007-07-28') AS dt", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT TO_DATE(DATEADD(mm,1,'2007-07-28'),'YYYY-MM-DD HH:MI:SS') AS dt")
})
test_that("translate sql server -> InterSystems IRIS DATEADD(d, ..)", {
sql <- translate("SELECT DATEADD(yy, 1, '2007-07-28') AS dt", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT TO_DATE(DATEADD(yy,1,'2007-07-28'),'YYYY-MM-DD HH:MI:SS') AS dt")
})
test_that("translate sql server -> InterSystems IRIS DATEADD(d, ..)", {
sql <- translate("SELECT DATEADD(yyyy, 1, '2007-07-28') AS dt", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT TO_DATE(DATEADD(yyyy,1,'2007-07-28'),'YYYY-MM-DD HH:MI:SS') AS dt")
})


# test reserved words
test_that("translate sql server -> InterSystems IRIS reserved word DOMAIN", {
sql <- translate("SELECT t.domain, 'domain' FROM omopcdm.domain AS t", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT t.\"DOMAIN\", 'domain' FROM omopcdm.\"DOMAIN\" AS t")
})
test_that("translate sql server -> InterSystems IRIS reserved words for aggregates", {
sql <- translate("SELECT MIN(x) AS min, MAX(x) AS max, COUNT(x) as COUNT FROM t", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT MIN(x) AS \"MIN\", MAX(x) AS \"MAX\", COUNT(x) as \"COUNT\" FROM t")
})


# test function names
test_that("translate sql server -> InterSystems IRIS function names", {
sql <- translate("SELECT STDEV(x), STDEV_POP(x), STDEV_SAMP(x), EOMONTH(dt) FROM t", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT STDDEV(x), STDDEV_POP(x), STDDEV_SAMP(x), LAST_DAY(dt) FROM t")
})
library(testthat)
library(rJava)


# For debugging: force reload of code & patterns:
# load_all()
# rJava::J('org.ohdsi.sql.SqlTranslate')$setReplacementPatterns('../../inst/csv/replacementPatterns.csv')


expect_equal_ignore_spaces <- function(string1, string2) {
string1 <- gsub("([;()'+-/|*\n])", " \\1 ", string1)
string2 <- gsub("([;()'+-/|*\n])", " \\1 ", string2)
string1 <- gsub(" +", " ", string1)
string2 <- gsub(" +", " ", string2)
expect_equivalent(string1, string2)
}

# tests wrt string concatenation
test_that("translate sql server -> InterSystems IRIS string concatenation", {
sql <- translate("SELECT CONCAT(a, 'b', c)", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT a || 'b' || c")
})
test_that("translate sql server -> InterSystems IRIS string concatenation", {
sql <- translate("SELECT CONCAT(a, 'b', c, d, e, e, f)", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT a || 'b' || c || d || e || e || f")
})
test_that("translate sql server -> InterSystems IRIS string +", {
sql <- translate("SELECT CAST(a AS VARCHAR) + CAST(b AS VARCHAR(10)) + CAST(c AS VARCHAR) + 'd'", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT CAST(a AS VARCHAR) || CAST(b AS varchar(10)) || CAST(c AS VARCHAR) || 'd'")
})
test_that("translate sql server -> InterSystem IRIS string concatenation DOB", {
sql <- translate("SELECT CONCAT(p.year_of_birth, 11, 11)", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT p.year_of_birth||'-'||11||'-'||11")
})


# build date from parts
test_that("translate sql server -> InterSystems IRIS DATEFROMPARTS()", {
sql <- translate("SELECT DATEFROMPARTS(yyyy, mm, dd)", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT TO_DATE(TO_CHAR(yyyy,'FM0000')||'-'||TO_CHAR(mm,'FM00')||'-'||TO_CHAR(dd,'FM00'), 'YYYY-MM-DD')")
})
test_that("translate sql server -> InterSystems IRIS DATETIMEFROMPARTS()", {
sql <- translate("SELECT DATETIMEFROMPARTS(yyyy, mm, dd, hh, mi, ss, ms)", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT TO_TIMESTAMP(TO_CHAR(yyyy,'FM0000')||'-'||TO_CHAR(mm,'FM00')||'-'||TO_CHAR(dd,'FM00')||' '||TO_CHAR(hh,'FM00')||':'||TO_CHAR(mi,'FM00')||':'||TO_CHAR(ss,'FM00')||'.'||TO_CHAR(ms,'FM000'), 'YYYY-MM-DD HH24:MI:SS.FF')")
})



# temp table handling
test_that("translate sql server -> InterSystems IRIS implicit CTAS", {
sql <- translate("SELECT a, b INTO t_new FROM t;", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "CREATE TABLE t_new AS SELECT a, b FROM t;")
})
test_that("translate sql server -> InterSystems IRIS implicit CTTAS", {
sql <- translate("SELECT a, b INTO #t_new FROM t;", targetDialect = "iris")
expect_equal_ignore_spaces(sql, paste("CREATE GLOBAL TEMPORARY TABLE ", getTempTablePrefix(), "t_new AS SELECT a, b FROM t;", sep=""))
})


# test DATEADD() flavours
test_that("translate sql server -> InterSystems IRIS DATEADD(d, ..)", {
sql <- translate("SELECT DATEADD(d, 1, '2007-07-28') AS dt", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT TO_DATE(DATEADD(d,1,'2007-07-28'),'YYYY-MM-DD HH:MI:SS') AS dt")
})
test_that("translate sql server -> InterSystems IRIS DATEADD(d, ..)", {
sql <- translate("SELECT DATEADD(dd, 1, '2007-07-28') AS dt", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT TO_DATE(DATEADD(dd,1,'2007-07-28'),'YYYY-MM-DD HH:MI:SS') AS dt")
})
test_that("translate sql server -> InterSystems IRIS DATEADD(d, ..)", {
sql <- translate("SELECT DATEADD(day, 1, '2007-07-28') AS dt", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT TO_DATE(DATEADD(day,1,'2007-07-28'),'YYYY-MM-DD HH:MI:SS') AS dt")
})
test_that("translate sql server -> InterSystems IRIS DATEADD(d, ..)", {
sql <- translate("SELECT DATEADD(m, 1, '2007-07-28') AS dt", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT TO_DATE(DATEADD(m,1,'2007-07-28'),'YYYY-MM-DD HH:MI:SS') AS dt")
})
test_that("translate sql server -> InterSystems IRIS DATEADD(d, ..)", {
sql <- translate("SELECT DATEADD(mm, 1, '2007-07-28') AS dt", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT TO_DATE(DATEADD(mm,1,'2007-07-28'),'YYYY-MM-DD HH:MI:SS') AS dt")
})
test_that("translate sql server -> InterSystems IRIS DATEADD(d, ..)", {
sql <- translate("SELECT DATEADD(yy, 1, '2007-07-28') AS dt", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT TO_DATE(DATEADD(yy,1,'2007-07-28'),'YYYY-MM-DD HH:MI:SS') AS dt")
})
test_that("translate sql server -> InterSystems IRIS DATEADD(d, ..)", {
sql <- translate("SELECT DATEADD(yyyy, 1, '2007-07-28') AS dt", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT TO_DATE(DATEADD(yyyy,1,'2007-07-28'),'YYYY-MM-DD HH:MI:SS') AS dt")
})


# test reserved words
test_that("translate sql server -> InterSystems IRIS reserved word DOMAIN", {
sql <- translate("SELECT t.domain, 'domain' FROM omopcdm.domain AS t", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT t.\"DOMAIN\", 'domain' FROM omopcdm.\"DOMAIN\" AS t")
})
test_that("translate sql server -> InterSystems IRIS reserved words for aggregates", {
sql <- translate("SELECT MIN(x) AS min, MAX(x) AS max, COUNT(x) as COUNT FROM t", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT MIN(x) AS \"MIN\", MAX(x) AS \"MAX\", COUNT(x) AS \"COUNT\" FROM t")
})


# test function names
test_that("translate sql server -> InterSystems IRIS function names", {
sql <- translate("SELECT STDEV(x), STDEV_POP(x), STDEV_SAMP(x), EOMONTH(dt) FROM t", targetDialect = "iris")
expect_equal_ignore_spaces(sql, "SELECT STDDEV(x), STDDEV_POP(x), STDDEV_SAMP(x), LAST_DAY(dt) FROM t")
})

0 comments on commit ad43879

Please sign in to comment.