From e0abc4cb2b1225e1dd779092a48ef6d5b63a947d Mon Sep 17 00:00:00 2001 From: "dependabot[bot]" <49699333+dependabot[bot]@users.noreply.github.com> Date: Tue, 3 Sep 2024 22:03:29 +0000 Subject: [PATCH 01/14] Bump actions/download-artifact from 2 to 4.1.7 in /.github/workflows Bumps [actions/download-artifact](https://github.com/actions/download-artifact) from 2 to 4.1.7. - [Release notes](https://github.com/actions/download-artifact/releases) - [Commits](https://github.com/actions/download-artifact/compare/v2...v4.1.7) --- updated-dependencies: - dependency-name: actions/download-artifact dependency-type: direct:production ... Signed-off-by: dependabot[bot] --- .github/workflows/R_CMD_check_Hades.yaml | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/.github/workflows/R_CMD_check_Hades.yaml b/.github/workflows/R_CMD_check_Hades.yaml index a7da98b7..4091bc55 100644 --- a/.github/workflows/R_CMD_check_Hades.yaml +++ b/.github/workflows/R_CMD_check_Hades.yaml @@ -157,7 +157,7 @@ jobs: - name: Download package tarball if: ${{ env.new_version != '' }} - uses: actions/download-artifact@v2 + uses: actions/download-artifact@v4.1.7 with: name: package_tarball From d590230d30a86c708f45232d5f4f9ac1fce49015 Mon Sep 17 00:00:00 2001 From: Benjamin De Boe Date: Thu, 29 Feb 2024 13:21:33 +0100 Subject: [PATCH 02/14] initial support for InterSystems IRIS --- inst/csv/replacementPatterns.csv | 48 ++++++++++++++++++++++++++++ inst/csv/supportedDialects.csv | 1 + tests/testthat/test-translate-iris.R | 47 +++++++++++++++++++++++++++ 3 files changed, 96 insertions(+) create mode 100644 tests/testthat/test-translate-iris.R diff --git a/inst/csv/replacementPatterns.csv b/inst/csv/replacementPatterns.csv index 890b4d6d..ecb14b6e 100644 --- a/inst/csv/replacementPatterns.csv +++ b/inst/csv/replacementPatterns.csv @@ -1369,3 +1369,51 @@ sql server,...@([0-9]+|y)a,xxx@a sql server,DROP TABLE IF EXISTS #@table;,"IF OBJECT_ID('tempdb..#@table', 'U') IS NOT NULL DROP TABLE #@table;" sql server,DROP TABLE IF EXISTS @table;,"IF OBJECT_ID('@table', 'U') IS NOT NULL DROP TABLE @table;" sql server,CREATE TABLE IF NOT EXISTS @table (@definition);,"IF OBJECT_ID('@table', 'U') IS NULL CREATE TABLE @table (@definition);" +iris,...@([0-9]+)a,xxx@a --??? +iris,"IIF(@condition, @whentrue, @whenfalse)","CASE WHEN @condition THEN @whentrue ELSE @whenfalse END" +iris,TRY_CAST(@a),CAST(@a) +iris,+ '@a',|| '@a' +iris,'@a' +,'@a' || +iris,CAST(@a AS varchar(@b)) +,CAST(@a AS varchar(@b)) || +iris,+ CAST(@a AS varchar(@b)),|| CAST(@a AS varchar(@b)) +iris,CAST(@a AS varchar) +,CAST(@a AS varchar) || +iris,+ CAST(@a AS varchar),|| CAST(@a AS varchar) +iris,COUNT_BIG(@a),COUNT(@a) +iris,.dbo.,. +iris,CREATE TABLE #@table (@definition),CREATE GLOBAL TEMPORARY TABLE @table (@definition) +iris,"IF OBJECT_ID('@table', 'U') IS NULL CREATE TABLE @table (@definition);",CREATE TABLE IF NOT EXISTS @table (@definition); +iris,"IF OBJECT_ID('@table', 'U') IS NOT NULL DROP TABLE @table;",DROP TABLE IF EXISTS @table; +iris,"IF OBJECT_ID('tempdb..#@table', 'U') IS NOT NULL DROP TABLE #@table;",DROP TABLE IF EXISTS #@table; +iris,PRIMARY KEY NONCLUSTERED,PRIMARY KEY +iris,"AS drvd(@a)","AS drvd(@a)" +iris,"@a, @b)","@a, @b)" +iris,"","NULL AS " +iris,"FROM (VALUES @a) AS drvd(@b)","FROM (SELECT @b WHERE (0 = 1) UNION ALL VALUES @a) AS values_table" +iris,SELECT @a INTO #@b FROM @c;,CREATE GLOBAL TEMPORARY TABLE #@b AS SELECT @a FROM @c; +iris,SELECT @a INTO @b FROM @c;,CREATE TABLE @b AS SELECT @a FROM @c; +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,"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(mm, @a, @b) as "," TO_DATE(DATEADD(mm, @a, @b),'YYYY-MM-DD HH:MI:SS') as " +iris," DATEADD(d, @a, @b) as "," TO_DATE(DATEADD(d, @a, @b),'YYYY-MM-DD HH:MI:SS') as " +iris," DATEADD(yy, @a, @b) as "," TO_DATE(DATEADD(yy, @a, @b),'YYYY-MM-DD HH:MI:SS') as " +iris,"CONCAT(@a, @b,","@a || CONCAT(@b," +iris,"CONCAT(@a,@b)",@a || @b +iris,CREATE CLUSTERED INDEX @index_name ON @table (@variable);,CREATE INDEX @index_name ON @table (@variable); +iris,CREATE INDEX @index_name ON @table (@variable) WHERE @b;,CREATE INDEX @index_name ON @table (@variable); +iris,AS MIN,AS "MIN" +iris,AS MAX,AS "MAX" +iris,AS COUNT,AS "COUNT" +iris,STDEV(@a),STDDEV(@a) +iris,STDEV_POP(@a),STDDEV_POP(@a) +iris,STDEV_SAMP(@a),STDDEV_SAMP(@a) +iris,.DOMAIN ,."DOMAIN" +iris,WITH @a AS @b INSERT INTO @c SELECT @d;,INSERT INTO @c SELECT @d FROM @b AS @a; +iris,WITH @a AS @b CREATE TABLE @c AS SELECT @d FROM @a;,CREATE TABLE @c AS SELECT @d FROM (@b); +iris,WITH @a AS @b CREATE GLOBAL TEMPORARY TABLE @c AS SELECT @d FROM @a;,CREATE GLOBAL TEMPORARY TABLE @c AS SELECT @d FROM (@b); diff --git a/inst/csv/supportedDialects.csv b/inst/csv/supportedDialects.csv index 75b1d398..4cc38cbf 100644 --- a/inst/csv/supportedDialects.csv +++ b/inst/csv/supportedDialects.csv @@ -14,3 +14,4 @@ sqlite extended,SQLite Extended Syntax duckdb,DuckDB snowflake,Snowflake synapse,Azure Synapse Analytics Dedicated +iris,InterSystems IRIS diff --git a/tests/testthat/test-translate-iris.R b/tests/testthat/test-translate-iris.R new file mode 100644 index 00000000..8656e2b7 --- /dev/null +++ b/tests/testthat/test-translate-iris.R @@ -0,0 +1,47 @@ +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) +} + +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 +", { + 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 -> 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')") +}) + + + +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="")) +}) From cf168893e39175804ec61fc59501d7522bec45d2 Mon Sep 17 00:00:00 2001 From: Benjamin De Boe Date: Thu, 29 Feb 2024 13:31:45 +0100 Subject: [PATCH 03/14] adding IRIS option to documentation --- R/HelperFunctions.R | 3 ++- R/RenderSql.R | 9 ++++++--- man/translate.Rd | 3 ++- man/translateSingleStatement.Rd | 3 ++- man/translateSql.Rd | 3 ++- man/translateSqlFile.Rd | 3 ++- 6 files changed, 16 insertions(+), 8 deletions(-) diff --git a/R/HelperFunctions.R b/R/HelperFunctions.R index 40dda1b7..21988423 100644 --- a/R/HelperFunctions.R +++ b/R/HelperFunctions.R @@ -130,7 +130,8 @@ renderSqlFile <- function(sourceFile, targetFile, warnOnMissingParameters = TRUE #' @param sourceFile The source SQL file #' @param targetFile The target SQL file #' @param targetDialect The target dialect. Currently "oracle", "postgresql", "pdw", "impala", -#' "sqlite", "netezza", "bigquery", "snowflake", "synapse", "spark", and "redshift" are supported. +#' "sqlite", "netezza", "bigquery", "snowflake", "synapse", "spark", "redshift" +#' and "iris" are supported. #' @param oracleTempSchema DEPRECATED: use \code{tempEmulationSchema} instead. #' @param tempEmulationSchema Some database platforms like Oracle and Impala do not truly support #' temp tables. To emulate temp tables, provide a schema with write diff --git a/R/RenderSql.R b/R/RenderSql.R index 4b63fb67..872cc47a 100644 --- a/R/RenderSql.R +++ b/R/RenderSql.R @@ -133,7 +133,8 @@ renderSql <- function(sql = "", warnOnMissingParameters = TRUE, ...) { #' #' @param sql The SQL to be translated #' @param targetDialect The target dialect. Currently "oracle", "postgresql", "pdw", "impala", -#' "sqlite", "sqlite extended", "netezza", "bigquery", "snowflake", "synapse", "spark", and "redshift" are supported. +#' "sqlite", "sqlite extended", "netezza", "bigquery", "snowflake", "synapse", "spark", +#' "redshift", and "iris" are supported. #' Use \code{\link{listSupportedDialects}} to get the list of supported dialects. #' @param oracleTempSchema DEPRECATED: use \code{tempEmulationSchema} instead. #' @param tempEmulationSchema Some database platforms like Oracle and Impala do not truly support @@ -201,7 +202,8 @@ translate <- function(sql, #' #' @param sql The SQL to be translated #' @param targetDialect The target dialect. Currently "oracle", "postgresql", "pdw", "impala", -#' "netezza", "bigquery", "snowflake", "synapse", "spark", and "redshift" are supported +#' "netezza", "bigquery", "snowflake", "synapse", "spark", "redshift", and +#' "iris" are supported #' @param oracleTempSchema A schema that can be used to create temp tables in when using Oracle or #' Impala. #' @@ -230,7 +232,8 @@ translateSql <- function(sql = "", targetDialect, oracleTempSchema = NULL) { #' #' @param sql The SQL to be translated #' @param targetDialect The target dialect. Currently "oracle", "postgresql", "pdw", "impala", -#' "sqlite", "sqlite extended", "netezza", "bigquery", "snowflake", "synapse", "spark", and "redshift" are supported. +#' "sqlite", "sqlite extended", "netezza", "bigquery", "snowflake", "synapse", "spark", +#' "redshift", and "iris" are supported. #' @param oracleTempSchema DEPRECATED: use \code{tempEmulationSchema} instead. #' @param tempEmulationSchema Some database platforms like Oracle and Impala do not truly support #' temp tables. To emulate temp tables, provide a schema with write diff --git a/man/translate.Rd b/man/translate.Rd index 7b870c5e..e3bf3efc 100644 --- a/man/translate.Rd +++ b/man/translate.Rd @@ -15,7 +15,8 @@ translate( \item{sql}{The SQL to be translated} \item{targetDialect}{The target dialect. Currently "oracle", "postgresql", "pdw", "impala", -"sqlite", "sqlite extended", "netezza", "bigquery", "snowflake", "synapse", "spark", and "redshift" are supported. +"sqlite", "sqlite extended", "netezza", "bigquery", "snowflake", "synapse", "spark", +"redshift", and "iris" are supported. Use \code{\link{listSupportedDialects}} to get the list of supported dialects.} \item{tempEmulationSchema}{Some database platforms like Oracle and Impala do not truly support diff --git a/man/translateSingleStatement.Rd b/man/translateSingleStatement.Rd index b25411a5..47521ef3 100644 --- a/man/translateSingleStatement.Rd +++ b/man/translateSingleStatement.Rd @@ -15,7 +15,8 @@ translateSingleStatement( \item{sql}{The SQL to be translated} \item{targetDialect}{The target dialect. Currently "oracle", "postgresql", "pdw", "impala", -"sqlite", "sqlite extended", "netezza", "bigquery", "snowflake", "synapse", "spark", and "redshift" are supported.} +"sqlite", "sqlite extended", "netezza", "bigquery", "snowflake", "synapse", "spark", +"redshift", and "iris" are supported.} \item{tempEmulationSchema}{Some database platforms like Oracle and Impala do not truly support temp tables. To emulate temp tables, provide a schema with write diff --git a/man/translateSql.Rd b/man/translateSql.Rd index 90b74cef..bbf3636e 100644 --- a/man/translateSql.Rd +++ b/man/translateSql.Rd @@ -10,7 +10,8 @@ translateSql(sql = "", targetDialect, oracleTempSchema = NULL) \item{sql}{The SQL to be translated} \item{targetDialect}{The target dialect. Currently "oracle", "postgresql", "pdw", "impala", -"netezza", "bigquery", "snowflake", "synapse", "spark", and "redshift" are supported} +"netezza", "bigquery", "snowflake", "synapse", "spark", "redshift", and +"iris" are supported} \item{oracleTempSchema}{A schema that can be used to create temp tables in when using Oracle or Impala.} diff --git a/man/translateSqlFile.Rd b/man/translateSqlFile.Rd index 6e3eb5c8..b40c180f 100644 --- a/man/translateSqlFile.Rd +++ b/man/translateSqlFile.Rd @@ -18,7 +18,8 @@ translateSqlFile( \item{targetFile}{The target SQL file} \item{targetDialect}{The target dialect. Currently "oracle", "postgresql", "pdw", "impala", -"sqlite", "netezza", "bigquery", "snowflake", "synapse", "spark", and "redshift" are supported.} +"sqlite", "netezza", "bigquery", "snowflake", "synapse", "spark", "redshift" +and "iris" are supported.} \item{tempEmulationSchema}{Some database platforms like Oracle and Impala do not truly support temp tables. To emulate temp tables, provide a schema with write From 9a7f5e877174e548e0f04b56dd7b3338d9f88484 Mon Sep 17 00:00:00 2001 From: Benjamin De Boe Date: Wed, 27 Mar 2024 15:53:47 +0100 Subject: [PATCH 04/14] translate multi-CTE DML into separate statements --- inst/csv/replacementPatterns.csv | 7 ++++++- 1 file changed, 6 insertions(+), 1 deletion(-) diff --git a/inst/csv/replacementPatterns.csv b/inst/csv/replacementPatterns.csv index ecb14b6e..72efe188 100644 --- a/inst/csv/replacementPatterns.csv +++ b/inst/csv/replacementPatterns.csv @@ -1414,6 +1414,11 @@ iris,STDEV(@a),STDDEV(@a) iris,STDEV_POP(@a),STDDEV_POP(@a) iris,STDEV_SAMP(@a),STDDEV_SAMP(@a) iris,.DOMAIN ,."DOMAIN" -iris,WITH @a AS @b INSERT INTO @c SELECT @d;,INSERT INTO @c SELECT @d FROM @b AS @a; +iris,"WITH @a (@cols) AS (@b)","WITH @a AS (SELECT @cols FROM (@b))" +iris,", @a (@cols) AS (@b)",", @a AS (SELECT @cols FROM (@b))" +iris,"WITH @a AS (@b), @c CREATE TABLE @d AS @e;","CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n WITH @c CREATE TABLE @d AS @e;\n DROP TABLE IF EXISTS @a;" iris,WITH @a AS @b CREATE TABLE @c AS SELECT @d FROM @a;,CREATE TABLE @c AS SELECT @d FROM (@b); +iris,"WITH @a AS (@b), @c CREATE GLOBAL TEMPORARY TABLE @d AS @e;","CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n WITH @c CREATE GLOBAL TEMPORARY TABLE @d AS @e;\n DROP TABLE IF EXISTS @a;" iris,WITH @a AS @b CREATE GLOBAL TEMPORARY TABLE @c AS SELECT @d FROM @a;,CREATE GLOBAL TEMPORARY TABLE @c AS SELECT @d FROM (@b); +iris,"WITH @a AS (@b), @c INSERT INTO @d SELECT @e;","CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n WITH @c INSERT INTO @d SELECT @e;\n DROP TABLE IF EXISTS @a;" +iris,WITH @a AS @b INSERT INTO @c SELECT @d;,INSERT INTO @c SELECT @d FROM @b AS @a; From 666ff3ab08411caab1bb0a79041a2518a0609903 Mon Sep 17 00:00:00 2001 From: Benjamin De Boe Date: Fri, 29 Mar 2024 10:27:07 +0100 Subject: [PATCH 05/14] drop leftover temp tables before creating them --- inst/csv/replacementPatterns.csv | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/inst/csv/replacementPatterns.csv b/inst/csv/replacementPatterns.csv index 72efe188..dc56b614 100644 --- a/inst/csv/replacementPatterns.csv +++ b/inst/csv/replacementPatterns.csv @@ -1416,9 +1416,9 @@ iris,STDEV_SAMP(@a),STDDEV_SAMP(@a) iris,.DOMAIN ,."DOMAIN" iris,"WITH @a (@cols) AS (@b)","WITH @a AS (SELECT @cols FROM (@b))" iris,", @a (@cols) AS (@b)",", @a AS (SELECT @cols FROM (@b))" -iris,"WITH @a AS (@b), @c CREATE TABLE @d AS @e;","CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n WITH @c CREATE TABLE @d AS @e;\n DROP TABLE IF EXISTS @a;" +iris,"WITH @a AS (@b), @c CREATE TABLE @d AS @e;","DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n WITH @c CREATE TABLE @d AS @e;\n DROP TABLE IF EXISTS @a;" iris,WITH @a AS @b CREATE TABLE @c AS SELECT @d FROM @a;,CREATE TABLE @c AS SELECT @d FROM (@b); -iris,"WITH @a AS (@b), @c CREATE GLOBAL TEMPORARY TABLE @d AS @e;","CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n WITH @c CREATE GLOBAL TEMPORARY TABLE @d AS @e;\n DROP TABLE IF EXISTS @a;" +iris,"WITH @a AS (@b), @c CREATE GLOBAL TEMPORARY TABLE @d AS @e;","DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n WITH @c CREATE GLOBAL TEMPORARY TABLE @d AS @e;\n DROP TABLE IF EXISTS @a;" iris,WITH @a AS @b CREATE GLOBAL TEMPORARY TABLE @c AS SELECT @d FROM @a;,CREATE GLOBAL TEMPORARY TABLE @c AS SELECT @d FROM (@b); -iris,"WITH @a AS (@b), @c INSERT INTO @d SELECT @e;","CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n WITH @c INSERT INTO @d SELECT @e;\n DROP TABLE IF EXISTS @a;" +iris,"WITH @a AS (@b), @c INSERT INTO @d SELECT @e;","DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n WITH @c INSERT INTO @d SELECT @e;\n DROP TABLE IF EXISTS @a;" iris,WITH @a AS @b INSERT INTO @c SELECT @d;,INSERT INTO @c SELECT @d FROM @b AS @a; From 6cabdd6b69144db0105c2cbd93bc90e2dd4d0f35 Mon Sep 17 00:00:00 2001 From: Benjamin De Boe Date: Fri, 29 Mar 2024 11:31:32 +0100 Subject: [PATCH 06/14] fix temp table creation logic --- inst/csv/replacementPatterns.csv | 6 ++---- 1 file changed, 2 insertions(+), 4 deletions(-) diff --git a/inst/csv/replacementPatterns.csv b/inst/csv/replacementPatterns.csv index dc56b614..1fdef51c 100644 --- a/inst/csv/replacementPatterns.csv +++ b/inst/csv/replacementPatterns.csv @@ -1417,8 +1417,6 @@ iris,.DOMAIN ,."DOMAIN" iris,"WITH @a (@cols) AS (@b)","WITH @a AS (SELECT @cols FROM (@b))" iris,", @a (@cols) AS (@b)",", @a AS (SELECT @cols FROM (@b))" iris,"WITH @a AS (@b), @c CREATE TABLE @d AS @e;","DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n WITH @c CREATE TABLE @d AS @e;\n DROP TABLE IF EXISTS @a;" -iris,WITH @a AS @b CREATE TABLE @c AS SELECT @d FROM @a;,CREATE TABLE @c AS SELECT @d FROM (@b); +iris,WITH @a AS (@b) CREATE TABLE @c AS SELECT @d;,DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n CREATE TABLE @c AS SELECT @d;\n DROP TABLE IF EXISTS @a; iris,"WITH @a AS (@b), @c CREATE GLOBAL TEMPORARY TABLE @d AS @e;","DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n WITH @c CREATE GLOBAL TEMPORARY TABLE @d AS @e;\n DROP TABLE IF EXISTS @a;" -iris,WITH @a AS @b CREATE GLOBAL TEMPORARY TABLE @c AS SELECT @d FROM @a;,CREATE GLOBAL TEMPORARY TABLE @c AS SELECT @d FROM (@b); -iris,"WITH @a AS (@b), @c INSERT INTO @d SELECT @e;","DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n WITH @c INSERT INTO @d SELECT @e;\n DROP TABLE IF EXISTS @a;" -iris,WITH @a AS @b INSERT INTO @c SELECT @d;,INSERT INTO @c SELECT @d FROM @b AS @a; +iris,WITH @a AS (@b) CREATE GLOBAL TEMPORARY TABLE @c AS @d;,DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n CREATE GLOBAL TEMPORARY TABLE @c AS @d;\n DROP TABLE IF EXISTS @a; \ No newline at end of file From 266abff1e9c8d0768716de7ef6bba3d42b97a513 Mon Sep 17 00:00:00 2001 From: Benjamin De Boe Date: Fri, 29 Mar 2024 17:32:11 +0100 Subject: [PATCH 07/14] rewrite EOMONTH() to LAST_DAY() --- inst/csv/replacementPatterns.csv | 1 + 1 file changed, 1 insertion(+) diff --git a/inst/csv/replacementPatterns.csv b/inst/csv/replacementPatterns.csv index 1fdef51c..bc5c963b 100644 --- a/inst/csv/replacementPatterns.csv +++ b/inst/csv/replacementPatterns.csv @@ -1413,6 +1413,7 @@ iris,AS COUNT,AS "COUNT" iris,STDEV(@a),STDDEV(@a) iris,STDEV_POP(@a),STDDEV_POP(@a) iris,STDEV_SAMP(@a),STDDEV_SAMP(@a) +iris,EOMONTH(@date),LAST_DAY(@date) iris,.DOMAIN ,."DOMAIN" iris,"WITH @a (@cols) AS (@b)","WITH @a AS (SELECT @cols FROM (@b))" iris,", @a (@cols) AS (@b)",", @a AS (SELECT @cols FROM (@b))" From 05bf9d05f7a77479b16a7d3f2955019007dd8c27 Mon Sep 17 00:00:00 2001 From: Benjamin De Boe Date: Sun, 8 Sep 2024 21:16:53 +0200 Subject: [PATCH 08/14] refine DATEADD() rules for IRIS & other Odysseus recommendations --- inst/csv/replacementPatterns.csv | 14 ++++++++++---- 1 file changed, 10 insertions(+), 4 deletions(-) diff --git a/inst/csv/replacementPatterns.csv b/inst/csv/replacementPatterns.csv index bc5c963b..a23ac41b 100644 --- a/inst/csv/replacementPatterns.csv +++ b/inst/csv/replacementPatterns.csv @@ -1400,9 +1400,15 @@ 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(mm, @a, @b) as "," TO_DATE(DATEADD(mm, @a, @b),'YYYY-MM-DD HH:MI:SS') as " -iris," DATEADD(d, @a, @b) as "," TO_DATE(DATEADD(d, @a, @b),'YYYY-MM-DD HH:MI:SS') as " -iris," DATEADD(yy, @a, @b) as "," TO_DATE(DATEADD(yy, @a, @b),'YYYY-MM-DD HH:MI:SS') as " +iris," DATEADD(d, @a, @b) AS"," TO_DATE(DATEADD(d, @a, @b),'YYYY-MM-DD HH:MI:SS') AS" +iris," DATEADD(dd, @a, @b) AS"," TO_DATE(DATEADD(dd, @a, @b),'YYYY-MM-DD HH:MI:SS') AS" +iris," DATEADD(day, @a, @b) AS"," TO_DATE(DATEADD(day, @a, @b),'YYYY-MM-DD HH:MI:SS') AS" +iris," DATEADD(m, @a, @b) AS"," TO_DATE(DATEADD(m, @a, @b),'YYYY-MM-DD HH:MI:SS') AS" +iris," DATEADD(mm, @a, @b) AS"," TO_DATE(DATEADD(mm, @a, @b),'YYYY-MM-DD HH:MI:SS') AS" +iris," DATEADD(yy, @a, @b) AS"," TO_DATE(DATEADD(yy, @a, @b),'YYYY-MM-DD HH:MI:SS') AS" +iris," DATEADD(yyyy, @a, @b) AS"," TO_DATE(DATEADD(yyyy, @a, @b),'YYYY-MM-DD HH:MI:SS') AS" +iris," COALESCE(p.birth_datetime", COALESCE(CAST(p.birth_datetime AS DATE) +iris,"CONCAT(p.year_of_birth, @b, @c)",p.year_of_birth||'-'||@b||'-'|| @c iris,"CONCAT(@a, @b,","@a || CONCAT(@b," iris,"CONCAT(@a,@b)",@a || @b iris,CREATE CLUSTERED INDEX @index_name ON @table (@variable);,CREATE INDEX @index_name ON @table (@variable); @@ -1420,4 +1426,4 @@ iris,", @a (@cols) AS (@b)",", @a AS (SELECT @cols FROM (@b))" iris,"WITH @a AS (@b), @c CREATE TABLE @d AS @e;","DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n WITH @c CREATE TABLE @d AS @e;\n DROP TABLE IF EXISTS @a;" iris,WITH @a AS (@b) CREATE TABLE @c AS SELECT @d;,DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n CREATE TABLE @c AS SELECT @d;\n DROP TABLE IF EXISTS @a; iris,"WITH @a AS (@b), @c CREATE GLOBAL TEMPORARY TABLE @d AS @e;","DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n WITH @c CREATE GLOBAL TEMPORARY TABLE @d AS @e;\n DROP TABLE IF EXISTS @a;" -iris,WITH @a AS (@b) CREATE GLOBAL TEMPORARY TABLE @c AS @d;,DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n CREATE GLOBAL TEMPORARY TABLE @c AS @d;\n DROP TABLE IF EXISTS @a; \ No newline at end of file +iris,WITH @a AS (@b) CREATE GLOBAL TEMPORARY TABLE @c AS @d;,DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n CREATE GLOBAL TEMPORARY TABLE @c AS @d;\n DROP TABLE IF EXISTS @a; From 32a403e023900c97ee39e81090c6df6cc40e6e2c Mon Sep 17 00:00:00 2001 From: Benjamin De Boe Date: Sun, 8 Sep 2024 21:17:48 +0200 Subject: [PATCH 09/14] workaround for window function issue --- inst/csv/replacementPatterns.csv | 1 + 1 file changed, 1 insertion(+) diff --git a/inst/csv/replacementPatterns.csv b/inst/csv/replacementPatterns.csv index a23ac41b..23f282d2 100644 --- a/inst/csv/replacementPatterns.csv +++ b/inst/csv/replacementPatterns.csv @@ -1427,3 +1427,4 @@ iris,"WITH @a AS (@b), @c CREATE TABLE @d AS @e;","DROP TABLE IF EXISTS @a;\n CR iris,WITH @a AS (@b) CREATE TABLE @c AS SELECT @d;,DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n CREATE TABLE @c AS SELECT @d;\n DROP TABLE IF EXISTS @a; iris,"WITH @a AS (@b), @c CREATE GLOBAL TEMPORARY TABLE @d AS @e;","DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n WITH @c CREATE GLOBAL TEMPORARY TABLE @d AS @e;\n DROP TABLE IF EXISTS @a;" iris,WITH @a AS (@b) CREATE GLOBAL TEMPORARY TABLE @c AS @d;,DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n CREATE GLOBAL TEMPORARY TABLE @c AS @d;\n DROP TABLE IF EXISTS @a; +iris,"SELECT event_id, person_id, start_date, end_date, visit_occurrence_id FROM","SELECT event_id, person_id, start_date, end_date, visit_occurrence_id, ordinal FROM" From 70b40882d02983ae5b64c7e7de0bdc43e7c99874 Mon Sep 17 00:00:00 2001 From: Benjamin De Boe Date: Sun, 8 Sep 2024 21:19:15 +0200 Subject: [PATCH 10/14] remove workaround after server-side fixes (IRIS 2024.1.2) --- inst/csv/replacementPatterns.csv | 3 --- 1 file changed, 3 deletions(-) diff --git a/inst/csv/replacementPatterns.csv b/inst/csv/replacementPatterns.csv index 23f282d2..5fc60771 100644 --- a/inst/csv/replacementPatterns.csv +++ b/inst/csv/replacementPatterns.csv @@ -1421,10 +1421,7 @@ iris,STDEV_POP(@a),STDDEV_POP(@a) iris,STDEV_SAMP(@a),STDDEV_SAMP(@a) iris,EOMONTH(@date),LAST_DAY(@date) iris,.DOMAIN ,."DOMAIN" -iris,"WITH @a (@cols) AS (@b)","WITH @a AS (SELECT @cols FROM (@b))" -iris,", @a (@cols) AS (@b)",", @a AS (SELECT @cols FROM (@b))" iris,"WITH @a AS (@b), @c CREATE TABLE @d AS @e;","DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n WITH @c CREATE TABLE @d AS @e;\n DROP TABLE IF EXISTS @a;" iris,WITH @a AS (@b) CREATE TABLE @c AS SELECT @d;,DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n CREATE TABLE @c AS SELECT @d;\n DROP TABLE IF EXISTS @a; iris,"WITH @a AS (@b), @c CREATE GLOBAL TEMPORARY TABLE @d AS @e;","DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n WITH @c CREATE GLOBAL TEMPORARY TABLE @d AS @e;\n DROP TABLE IF EXISTS @a;" iris,WITH @a AS (@b) CREATE GLOBAL TEMPORARY TABLE @c AS @d;,DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n CREATE GLOBAL TEMPORARY TABLE @c AS @d;\n DROP TABLE IF EXISTS @a; -iris,"SELECT event_id, person_id, start_date, end_date, visit_occurrence_id FROM","SELECT event_id, person_id, start_date, end_date, visit_occurrence_id, ordinal FROM" From bf57361e4768ea9bdb8d182a0df3bfb7b6bbc30f Mon Sep 17 00:00:00 2001 From: Benjamin De Boe Date: Sun, 8 Sep 2024 21:19:35 +0200 Subject: [PATCH 11/14] extend unit tests for IRIS --- tests/testthat/test-translate-iris.R | 60 ++++++++++++++++++++++++++++ 1 file changed, 60 insertions(+) diff --git a/tests/testthat/test-translate-iris.R b/tests/testthat/test-translate-iris.R index 8656e2b7..58c88e8f 100644 --- a/tests/testthat/test-translate-iris.R +++ b/tests/testthat/test-translate-iris.R @@ -16,16 +16,26 @@ expect_equal_ignore_spaces <- function(string1, 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')") @@ -37,6 +47,7 @@ test_that("translate sql server -> InterSystems IRIS DATETIMEFROMPARTS()", { +# 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;") @@ -45,3 +56,52 @@ 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") +}) From 0bce272e351c18481c6eabb3b5d328f498fcfa5a Mon Sep 17 00:00:00 2001 From: Benjamin De Boe Date: Sun, 8 Sep 2024 21:44:46 +0200 Subject: [PATCH 12/14] adding InterSystems IRIS to misc reference pages --- DESCRIPTION | 2 +- README.md | 2 +- vignettes/UsingSqlRender.Rmd | 3 ++- 3 files changed, 4 insertions(+), 3 deletions(-) diff --git a/DESCRIPTION b/DESCRIPTION index e3eb4115..fccd7afe 100644 --- a/DESCRIPTION +++ b/DESCRIPTION @@ -11,7 +11,7 @@ Maintainer: Martijn Schuemie Description: A rendering tool for parameterized SQL that also translates into different SQL dialects. These dialects include 'Microsoft SQL Server', 'Oracle', 'PostgreSql', 'Amazon RedShift', 'Apache Impala', 'IBM Netezza', 'Google BigQuery', 'Microsoft PDW', 'Snowflake', - 'Azure Synapse Analytics Dedicated', 'Apache Spark', and 'SQLite'. + 'Azure Synapse Analytics Dedicated', 'Apache Spark', 'SQLite', and 'InterSystems IRIS'. SystemRequirements: Java (>= 8) License: Apache License 2.0 VignetteBuilder: knitr diff --git a/README.md b/README.md index dc0624e6..8c69f24b 100644 --- a/README.md +++ b/README.md @@ -17,7 +17,7 @@ Features - Supports a simple markup syntax for making SQL parameterized, and renders parameterized SQL (containing the markup syntax) to executable SQL - The syntax supports defining default parameter values - The syntax supports if-then-else structures -- Has functions for translating SQL from one dialect (Microsoft SQL Server) to other dialects (Oracle, PostgreSQL, Amazon RedShift, Impala, IBM Netezza, Google BigQuery, Microsoft PDW, Snowflake, Azure Synapse, Apache Spark and SQLite) +- Has functions for translating SQL from one dialect (Microsoft SQL Server) to other dialects (Oracle, PostgreSQL, Amazon RedShift, Impala, IBM Netezza, Google BigQuery, Microsoft PDW, Snowflake, Azure Synapse, Apache Spark, SQLite, and InterSystems IRIS) - Can be used as R package, Java library, or as stand-alone executable through a command-line interface Examples diff --git a/vignettes/UsingSqlRender.Rmd b/vignettes/UsingSqlRender.Rmd index 7161315b..eaf5e406 100644 --- a/vignettes/UsingSqlRender.Rmd +++ b/vignettes/UsingSqlRender.Rmd @@ -102,7 +102,7 @@ SQL for one platform (e.g. Microsoft SQL Server) will not always execute on othe A first limitation is that **the starting dialect has to be SQL Server**. The reason for this is that this dialect is in general the most specific. For example, the number of days between two dates in SQL Server has to be computed using the DATEDIFF function: `DATEDIFF(dd,a,b)`. In other languages one can simply subtract the two dates: `b-a`. Since you'd need to know a and b are dates, it is not possible to go from other languages to SQL Server, only the other way around. -A second limitation is that currently only these dialects are supported as targets: **Oracle**, **PostgreSQL**, **Microsoft PDW (Parallel Data Warehouse)**, **Impala**, **Netezza**, **Google BigQuery**, **Amazon Redshift**, **Snowflake**, **Azure Synapse**, **Apache Spark** and **SQLite**. +A second limitation is that currently only these dialects are supported as targets: **Oracle**, **PostgreSQL**, **Microsoft PDW (Parallel Data Warehouse)**, **Impala**, **Netezza**, **Google BigQuery**, **Amazon Redshift**, **Snowflake**, **Azure Synapse**, **Apache Spark**, **SQLite**, and **InterSystems IRIS**. A third limitation is that only a limited set of translation rules have currently been implemented, although adding them to the [list](https://github.com/OHDSI/SqlRender/blob/main/inst/csv/replacementPatterns.csv) should not be hard. @@ -130,6 +130,7 @@ The `targetDialect` parameter can have the following values: - "sqlite" - "sqlite extended" - "sql server" + - "iris" ## Functions and structures supported by translate From 51c9ab9a94e705807f92de04316fbb272705b565 Mon Sep 17 00:00:00 2001 From: Benjamin De Boe Date: Mon, 9 Sep 2024 15:16:10 +0200 Subject: [PATCH 13/14] add InterSystems IRIS to shiny app --- inst/shinyApps/SqlDeveloper/ui.R | 90 ++++++++++++++++---------------- 1 file changed, 45 insertions(+), 45 deletions(-) diff --git a/inst/shinyApps/SqlDeveloper/ui.R b/inst/shinyApps/SqlDeveloper/ui.R index 0590129e..1eedb5f9 100644 --- a/inst/shinyApps/SqlDeveloper/ui.R +++ b/inst/shinyApps/SqlDeveloper/ui.R @@ -1,45 +1,45 @@ -library(shiny) -library(shinydashboard) -source("widgets.R") - -dashboardPage( - dashboardHeader(title = "SqlRender Developer"), - dashboardSidebar( - sidebarMenu( - menuItemFileInput("open", "Open file", icon = shiny::icon("folder-open")), - menuItemDownloadLink("save", "Save", icon = shiny::icon("save")), - menuItem("Open new tab", href = "", icon = shiny::icon("plus-square")), - menuItemCopyTextAreaToClipboard("source", "Copy source to clipboard"), - menuItemCopyDivToClipboard("target", "Copy target to clipboard") - ) - ), - dashboardBody( - fluidRow( - column(width = 9, - box( - title = "Source: OHDSI SQL", width = NULL, status = "primary", - textAreaInput("source", NULL, width = "100%", height = "300px") - ), - box( - title = "Target: Rendered translation", width = NULL, - # tags$table(width = "100%", - # tags$tr( - # tags$td(align = "left", actionButton("renderTranslate", "Render and translate")), - # tags$td(align = "right", checkboxInput("continuous", "Auto render and translate")))), - pre(textOutput("target")) - ) - ), - column(width = 3, - box(background = "light-blue", - h4("Target dialect"), width = NULL, - selectInput("dialect", NULL, choices = c("BigQuery", "Impala", "Netezza", "Oracle", "PDW", "PostgreSQL", "RedShift", "SQL Server", "SQLite", "Hive", "Spark", "Snowflake", "Synapse"), selected = "SQL Server"), - h4("Temp emulation schema"), - textInput("tempEmulationSchema", NULL), - h4("Parameters"), - uiOutput("parameterInputs"), - textOutput("warnings") - ) - ) - ) - ) -) +library(shiny) +library(shinydashboard) +source("widgets.R") + +dashboardPage( + dashboardHeader(title = "SqlRender Developer"), + dashboardSidebar( + sidebarMenu( + menuItemFileInput("open", "Open file", icon = shiny::icon("folder-open")), + menuItemDownloadLink("save", "Save", icon = shiny::icon("save")), + menuItem("Open new tab", href = "", icon = shiny::icon("plus-square")), + menuItemCopyTextAreaToClipboard("source", "Copy source to clipboard"), + menuItemCopyDivToClipboard("target", "Copy target to clipboard") + ) + ), + dashboardBody( + fluidRow( + column(width = 9, + box( + title = "Source: OHDSI SQL", width = NULL, status = "primary", + textAreaInput("source", NULL, width = "100%", height = "300px") + ), + box( + title = "Target: Rendered translation", width = NULL, + # tags$table(width = "100%", + # tags$tr( + # tags$td(align = "left", actionButton("renderTranslate", "Render and translate")), + # tags$td(align = "right", checkboxInput("continuous", "Auto render and translate")))), + pre(textOutput("target")) + ) + ), + column(width = 3, + box(background = "light-blue", + h4("Target dialect"), width = NULL, + selectInput("dialect", NULL, choices = c("BigQuery", "Impala", "Netezza", "Oracle", "PDW", "PostgreSQL", "RedShift", "SQL Server", "SQLite", "Hive", "Spark", "Snowflake", "Synapse", "InterSystems IRIS" = "iris"), selected = "SQL Server"), + h4("Temp emulation schema"), + textInput("tempEmulationSchema", NULL), + h4("Parameters"), + uiOutput("parameterInputs"), + textOutput("warnings") + ) + ) + ) + ) +) From 3136e9f137566e4e96e81ce09fe5d99de4819051 Mon Sep 17 00:00:00 2001 From: Benjamin De Boe Date: Mon, 9 Sep 2024 15:35:14 +0200 Subject: [PATCH 14/14] improve temp table handling on IRIS --- inst/csv/replacementPatterns.csv | 10 +++++----- 1 file changed, 5 insertions(+), 5 deletions(-) diff --git a/inst/csv/replacementPatterns.csv b/inst/csv/replacementPatterns.csv index 5fc60771..c7da32f9 100644 --- a/inst/csv/replacementPatterns.csv +++ b/inst/csv/replacementPatterns.csv @@ -1380,7 +1380,11 @@ iris,CAST(@a AS varchar) +,CAST(@a AS varchar) || iris,+ CAST(@a AS varchar),|| CAST(@a AS varchar) iris,COUNT_BIG(@a),COUNT(@a) iris,.dbo.,. -iris,CREATE TABLE #@table (@definition),CREATE GLOBAL TEMPORARY TABLE @table (@definition) +iris,CREATE TABLE #@table (@definition),CREATE GLOBAL TEMPORARY TABLE #@table (@definition) +iris,"WITH @a AS (@b), @c CREATE TABLE @d AS @e;","DROP TABLE IF EXISTS #@a;\n CREATE GLOBAL TEMPORARY TABLE #@a AS @b;\n WITH @c CREATE TABLE @d AS @e;\n DROP TABLE IF EXISTS #@a;" +iris,WITH @a AS (@b) CREATE TABLE @c AS SELECT @d;,DROP TABLE IF EXISTS #@a;\n CREATE GLOBAL TEMPORARY TABLE #@a AS @b;\n CREATE TABLE @c AS SELECT @d;\n DROP TABLE IF EXISTS #@a; +iris,"WITH @a AS (@b), @c CREATE GLOBAL TEMPORARY TABLE @d AS @e;","DROP TABLE IF EXISTS #@a;\n CREATE GLOBAL TEMPORARY TABLE #@a AS @b;\n WITH @c CREATE GLOBAL TEMPORARY TABLE @d AS @e;\n DROP TABLE IF EXISTS #@a;" +iris,WITH @a AS (@b) CREATE GLOBAL TEMPORARY TABLE @c AS @d;,DROP TABLE IF EXISTS #@a;\n CREATE GLOBAL TEMPORARY TABLE #@a AS @b;\n CREATE GLOBAL TEMPORARY TABLE @c AS @d;\n DROP TABLE IF EXISTS #@a; iris,"IF OBJECT_ID('@table', 'U') IS NULL CREATE TABLE @table (@definition);",CREATE TABLE IF NOT EXISTS @table (@definition); iris,"IF OBJECT_ID('@table', 'U') IS NOT NULL DROP TABLE @table;",DROP TABLE IF EXISTS @table; iris,"IF OBJECT_ID('tempdb..#@table', 'U') IS NOT NULL DROP TABLE #@table;",DROP TABLE IF EXISTS #@table; @@ -1421,7 +1425,3 @@ iris,STDEV_POP(@a),STDDEV_POP(@a) iris,STDEV_SAMP(@a),STDDEV_SAMP(@a) iris,EOMONTH(@date),LAST_DAY(@date) iris,.DOMAIN ,."DOMAIN" -iris,"WITH @a AS (@b), @c CREATE TABLE @d AS @e;","DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n WITH @c CREATE TABLE @d AS @e;\n DROP TABLE IF EXISTS @a;" -iris,WITH @a AS (@b) CREATE TABLE @c AS SELECT @d;,DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n CREATE TABLE @c AS SELECT @d;\n DROP TABLE IF EXISTS @a; -iris,"WITH @a AS (@b), @c CREATE GLOBAL TEMPORARY TABLE @d AS @e;","DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n WITH @c CREATE GLOBAL TEMPORARY TABLE @d AS @e;\n DROP TABLE IF EXISTS @a;" -iris,WITH @a AS (@b) CREATE GLOBAL TEMPORARY TABLE @c AS @d;,DROP TABLE IF EXISTS @a;\n CREATE GLOBAL TEMPORARY TABLE @a AS @b;\n CREATE GLOBAL TEMPORARY TABLE @c AS @d;\n DROP TABLE IF EXISTS @a;