From 356c188b0ce442c42d05004771326fa4f404a04e Mon Sep 17 00:00:00 2001 From: simonpcouch Date: Thu, 7 Mar 2024 16:33:18 -0600 Subject: [PATCH 01/13] include synonyms in `odbcListObjects()` output --- NAMESPACE | 1 + R/driver-sql-server.R | 53 +++++++++++++++++++++++++ man/SQLServer.Rd | 6 +++ tests/testthat/test-driver-sql-server.R | 33 +++++++++++++++ 4 files changed, 93 insertions(+) diff --git a/NAMESPACE b/NAMESPACE index 62093127..6130e177 100644 --- a/NAMESPACE +++ b/NAMESPACE @@ -2,6 +2,7 @@ S3method(odbcListColumns,OdbcConnection) S3method(odbcListObjectTypes,default) +S3method(odbcListObjects,"Microsoft SQL Server") S3method(odbcListObjects,OdbcConnection) S3method(odbcPreviewObject,OdbcConnection) export(databricks) diff --git a/R/driver-sql-server.R b/R/driver-sql-server.R index 2d0efcf1..7769e703 100644 --- a/R/driver-sql-server.R +++ b/R/driver-sql-server.R @@ -204,3 +204,56 @@ setMethod("odbcDataType", "Microsoft SQL Server", ) } ) + +#' @rdname SQLServer +#' @description +#' ## `odbcListObjects()` +#' +#' This method makes tables that are synonyms visible in the Connections pane. +# See (#221). +#' @usage NULL +#' @export +`odbcListObjects.Microsoft SQL Server` <- function(connection, + catalog = NULL, + schema = NULL, + name = NULL, + type = NULL, + ...) { + objects <- NextMethod( + object = connection, + catalog = catalog, + schema = schema, + name = name, + type = type, + ... + ) + + if (is.null(catalog) | is.null(schema)) { + return(objects) + } + + synonyms <- dbGetQuery( + connection, + "SELECT + catalog = DB.name, + [schema] = Sch.name, + name = Syn.name + FROM sys.synonyms AS Syn + INNER JOIN sys.schemas AS Sch + ON Sch.schema_id = Syn.schema_id + INNER JOIN sys.databases AS DB + ON Sch.principal_id = DB.database_id + WHERE DB.name = ? AND Sch.name = ? + AND OBJECTPROPERTY(Object_ID(Syn.base_object_name), 'IsTable') = 1;", + params = list(catalog, schema) + ) + + if (!is.null(name)) { + synonyms <- synonyms[synonyms$name == name, , drop = FALSE] + } + + rbind( + objects, + data.frame(name = synonyms$name, type = rep("table", length(synonyms$name))) + ) +} diff --git a/man/SQLServer.Rd b/man/SQLServer.Rd index 6c9397ec..1cfcc19b 100644 --- a/man/SQLServer.Rd +++ b/man/SQLServer.Rd @@ -12,6 +12,7 @@ \alias{dbExistsTable,Microsoft SQL Server,SQL-method} \alias{odbcConnectionSchemas,Microsoft SQL Server-method} \alias{sqlCreateTable,Microsoft SQL Server-method} +\alias{odbcListObjects.Microsoft SQL Server} \title{SQL Server} \description{ Details of SQL Server methods for odbc and DBI generics. @@ -58,5 +59,10 @@ sure we list the schemas in the appropriate database/catalog. Warns if \code{temporary = TRUE} but the \code{name} does not conform to temp table naming conventions (i.e. it doesn't start with \verb{#}). } + +\subsection{\code{odbcListObjects()}}{ + +This method makes tables that are synonyms visible in the Connections pane. +} } \keyword{internal} diff --git a/tests/testthat/test-driver-sql-server.R b/tests/testthat/test-driver-sql-server.R index 259f8fbb..23f3b36d 100644 --- a/tests/testthat/test-driver-sql-server.R +++ b/tests/testthat/test-driver-sql-server.R @@ -337,3 +337,36 @@ test_that("captures multiline errors message", { } ) }) + +test_that("odbcListObjects shows synonyms (#221)", { + con <- test_con("SQLSERVER") + db <- dbGetQuery(con, "SELECT db_name()")[1,1] + dbExecute(con, "CREATE SCHEMA testSchema") + dbExecute(con, "CREATE SCHEMA testSchema2") + + on.exit({ + dbExecute(con, "DROP TABLE IF EXISTS testSchema.tbl") + dbExecute(con, "DROP SYNONYM IF EXISTS testSchema.tbl2") + dbExecute(con, "DROP SYNONYM IF EXISTS testSchema2.tbl2") + dbExecute(con, "DROP SCHEMA IF EXISTS testSchema") + dbExecute(con, "DROP SCHEMA IF EXISTS testSchema2") + }) + + dbExecute(con, "CREATE TABLE testSchema.tbl (x int)") + expect_equal(nrow(odbcListObjects(con, catalog = db, schema = "testSchema")), 1) + + dbExecute(con, "CREATE SYNONYM testSchema.tbl2 for testSchema.tbl") + expect_equal(nrow(odbcListObjects(con, catalog = db, schema = "testSchema")), 2) + expect_equal( + nrow(odbcListObjects(con, catalog = db, schema = "testSchema", name = "tbl")), + 1 + ) + expect_false("tbl2" %in% odbcListObjects(con)) + dbExecute(con, "DROP SYNONYM testSchema.tbl2") + + # ensure query filters out synonyms in schemas other than the one + # where the base object lives effectively + dbExecute(con, "CREATE SYNONYM testSchema2.tbl2 for testSchema.tbl") + expect_equal(nrow(odbcListObjects(con, catalog = db, schema = "testSchema")), 1) + expect_equal(nrow(odbcListObjects(con, catalog = db, schema = "testSchema2")), 1) +}) From 98d9df59a186bfe65d9e15826f56869e0fc2675a Mon Sep 17 00:00:00 2001 From: simonpcouch Date: Thu, 7 Mar 2024 16:40:48 -0600 Subject: [PATCH 02/13] note change in NEWS --- NEWS.md | 3 +++ 1 file changed, 3 insertions(+) diff --git a/NEWS.md b/NEWS.md index 85e171de..3390fe19 100644 --- a/NEWS.md +++ b/NEWS.md @@ -10,6 +10,9 @@ * The `"OdbcConnection"` method for `dbQuoteIdentifier()` will no longer pass `x` to `encodeString()` before returning, for consistency with the default implementation in DBI (@simonpcouch, #765). + +* The Connections pane will now include synonyms when displaying objects with + Microsoft SQL Server (@simonpcouch, #773). # odbc 1.4.2 From 30f592beba26fa9788b3bae5212f0c1be5676b3d Mon Sep 17 00:00:00 2001 From: simonpcouch Date: Tue, 26 Mar 2024 14:19:35 -0500 Subject: [PATCH 03/13] support synonyms in `dbListTables()` --- R/driver-sql-server.R | 37 +++++++++++++++++++++++++------------ 1 file changed, 25 insertions(+), 12 deletions(-) diff --git a/R/driver-sql-server.R b/R/driver-sql-server.R index 7769e703..0dd26611 100644 --- a/R/driver-sql-server.R +++ b/R/driver-sql-server.R @@ -107,7 +107,17 @@ setMethod("dbListTables", "Microsoft SQL Server", res <- c(res, res_temp) } - res + if (is.null(catalog_name) | is.null(schema_name)) { + return(res) + } + + synonyms <- dbGetQuery( + conn, + synonyms_query, + params = list(catalog_name, schema_name) + ) + + c(res, synonyms$name) } ) @@ -234,17 +244,7 @@ setMethod("odbcDataType", "Microsoft SQL Server", synonyms <- dbGetQuery( connection, - "SELECT - catalog = DB.name, - [schema] = Sch.name, - name = Syn.name - FROM sys.synonyms AS Syn - INNER JOIN sys.schemas AS Sch - ON Sch.schema_id = Syn.schema_id - INNER JOIN sys.databases AS DB - ON Sch.principal_id = DB.database_id - WHERE DB.name = ? AND Sch.name = ? - AND OBJECTPROPERTY(Object_ID(Syn.base_object_name), 'IsTable') = 1;", + synonyms_query, params = list(catalog, schema) ) @@ -257,3 +257,16 @@ setMethod("odbcDataType", "Microsoft SQL Server", data.frame(name = synonyms$name, type = rep("table", length(synonyms$name))) ) } + +synonyms_query <- + "SELECT + catalog = DB.name, + [schema] = Sch.name, + name = Syn.name + FROM sys.synonyms AS Syn + INNER JOIN sys.schemas AS Sch + ON Sch.schema_id = Syn.schema_id + INNER JOIN sys.databases AS DB + ON Sch.principal_id = DB.database_id + WHERE DB.name = ? AND Sch.name = ? + AND OBJECTPROPERTY(Object_ID(Syn.base_object_name), 'IsTable') = 1;" From 124c7b9a23e399c517538fb465dc5473c8cf567e Mon Sep 17 00:00:00 2001 From: simonpcouch Date: Wed, 27 Mar 2024 09:17:19 -0500 Subject: [PATCH 04/13] transition query to handle NULLs had issues passing these as parameters using something like `WHERE (? IS NULL OR DB.name = ?) AND (? IS NULL OR Sch.name = ?)` --- R/driver-sql-server.R | 61 ++++++++++++++++++++++--------------------- 1 file changed, 31 insertions(+), 30 deletions(-) diff --git a/R/driver-sql-server.R b/R/driver-sql-server.R index 0dd26611..4bea34dc 100644 --- a/R/driver-sql-server.R +++ b/R/driver-sql-server.R @@ -107,15 +107,7 @@ setMethod("dbListTables", "Microsoft SQL Server", res <- c(res, res_temp) } - if (is.null(catalog_name) | is.null(schema_name)) { - return(res) - } - - synonyms <- dbGetQuery( - conn, - synonyms_query, - params = list(catalog_name, schema_name) - ) + synonyms <- dbGetQuery(conn, synonyms_query(conn, catalog_name, schema_name)) c(res, synonyms$name) } @@ -238,15 +230,7 @@ setMethod("odbcDataType", "Microsoft SQL Server", ... ) - if (is.null(catalog) | is.null(schema)) { - return(objects) - } - - synonyms <- dbGetQuery( - connection, - synonyms_query, - params = list(catalog, schema) - ) + synonyms <- dbGetQuery(connection, synonyms_query(connection, catalog, schema)) if (!is.null(name)) { synonyms <- synonyms[synonyms$name == name, , drop = FALSE] @@ -258,15 +242,32 @@ setMethod("odbcDataType", "Microsoft SQL Server", ) } -synonyms_query <- - "SELECT - catalog = DB.name, - [schema] = Sch.name, - name = Syn.name - FROM sys.synonyms AS Syn - INNER JOIN sys.schemas AS Sch - ON Sch.schema_id = Syn.schema_id - INNER JOIN sys.databases AS DB - ON Sch.principal_id = DB.database_id - WHERE DB.name = ? AND Sch.name = ? - AND OBJECTPROPERTY(Object_ID(Syn.base_object_name), 'IsTable') = 1;" +synonyms_query <- function(conn, catalog_name = NULL, schema_name = NULL) { + res <- "SELECT + catalog = DB.name, + [schema] = Sch.name, + name = Syn.name + FROM sys.synonyms AS Syn + INNER JOIN sys.schemas AS Sch + ON Sch.schema_id = Syn.schema_id + INNER JOIN sys.databases AS DB + ON Sch.principal_id = DB.database_id" + + has_catalog <- !is.null(catalog_name) + has_schema <- !is.null(schema_name) + if (!has_catalog & !has_schema) { + return(paste0(res, filter_is_table)) + } + + if (has_catalog & has_schema) { + res <- paste0(res, " WHERE DB.name = '", catalog_name, "' AND Sch.name = '", schema_name, "'") + } else if (has_catalog) { + res <- paste0(res, " WHERE DB.name = '", catalog_name, "'") + } else if (has_schema) { + res <- paste0(res, " WHERE Sch.name = '", schema_name, "'") + } + + paste0(res, filter_is_table) +} + +filter_is_table <- " AND OBJECTPROPERTY(Object_ID(Syn.base_object_name), 'IsTable') = 1;" From e268bf88cf68b75dad17d2c2830fc902e1825b56 Mon Sep 17 00:00:00 2001 From: simonpcouch Date: Wed, 27 Mar 2024 09:32:50 -0500 Subject: [PATCH 05/13] support synonyms in `dbExistsTable()` --- R/driver-sql-server.R | 8 ++++---- 1 file changed, 4 insertions(+), 4 deletions(-) diff --git a/R/driver-sql-server.R b/R/driver-sql-server.R index 4bea34dc..5b399437 100644 --- a/R/driver-sql-server.R +++ b/R/driver-sql-server.R @@ -73,11 +73,11 @@ setMethod("dbExistsTable", c("Microsoft SQL Server", "character"), stopifnot(length(name) == 1) if (isTempTable(conn, name, ...)) { query <- paste0("SELECT OBJECT_ID('tempdb..", name, "')") - !is.na(dbGetQuery(conn, query)[[1]]) - } else { - df <- odbcConnectionTables(conn, name = name, ...) - NROW(df) > 0 + return(!is.na(dbGetQuery(conn, query)[[1]])) } + df <- odbcConnectionTables(conn, name = name, ...) + synonyms <- dbGetQuery(conn, synonyms_query(conn, ...)) + NROW(df) > 0 || name %in% synonyms$name } ) From f12dd24f736bd6b58b3fd10fb59f9ab8952b0e45 Mon Sep 17 00:00:00 2001 From: simonpcouch Date: Wed, 27 Mar 2024 09:33:09 -0500 Subject: [PATCH 06/13] test support for `dbListTables()` and `dbExistsTable()` --- tests/testthat/test-driver-sql-server.R | 11 +++++++++++ 1 file changed, 11 insertions(+) diff --git a/tests/testthat/test-driver-sql-server.R b/tests/testthat/test-driver-sql-server.R index 23f3b36d..2b324060 100644 --- a/tests/testthat/test-driver-sql-server.R +++ b/tests/testthat/test-driver-sql-server.R @@ -357,16 +357,27 @@ test_that("odbcListObjects shows synonyms (#221)", { dbExecute(con, "CREATE SYNONYM testSchema.tbl2 for testSchema.tbl") expect_equal(nrow(odbcListObjects(con, catalog = db, schema = "testSchema")), 2) + expect_length(dbListTables(con, catalog_name = db, schema_name = "testSchema"), 2) expect_equal( nrow(odbcListObjects(con, catalog = db, schema = "testSchema", name = "tbl")), 1 ) expect_false("tbl2" %in% odbcListObjects(con)) + expect_true( + dbExistsTable(con, name = "tbl2", catalog_name = db, schema_name = "testSchema") + ) + expect_true(dbExistsTable(con, name = Id(db, "testSchema", "tbl2"))) dbExecute(con, "DROP SYNONYM testSchema.tbl2") + expect_false(dbExistsTable(con, name = Id(db, "testSchema", "tbl2"))) # ensure query filters out synonyms in schemas other than the one # where the base object lives effectively dbExecute(con, "CREATE SYNONYM testSchema2.tbl2 for testSchema.tbl") expect_equal(nrow(odbcListObjects(con, catalog = db, schema = "testSchema")), 1) expect_equal(nrow(odbcListObjects(con, catalog = db, schema = "testSchema2")), 1) + expect_length(dbListTables(con, catalog_name = db, schema_name = "testSchema2"), 1) + expect_true( + dbExistsTable(con, name = "tbl2", catalog_name = db, schema_name = "testSchema2") + ) + expect_true(dbExistsTable(con, name = Id(db, "testSchema2", "tbl2"))) }) From 80a7b43d66f1d30465382a9ab64dea15f2ce44fc Mon Sep 17 00:00:00 2001 From: simonpcouch Date: Wed, 27 Mar 2024 09:35:46 -0500 Subject: [PATCH 07/13] update verbiage in NEWS --- NEWS.md | 5 +++-- 1 file changed, 3 insertions(+), 2 deletions(-) diff --git a/NEWS.md b/NEWS.md index 3390fe19..072a8436 100644 --- a/NEWS.md +++ b/NEWS.md @@ -11,8 +11,9 @@ pass `x` to `encodeString()` before returning, for consistency with the default implementation in DBI (@simonpcouch, #765). -* The Connections pane will now include synonyms when displaying objects with - Microsoft SQL Server (@simonpcouch, #773). +* `dbListTables()`, `dbExistsTable()`, and `odbcListObjects()` now support + synonyms with Microsoft SQL Server. This also means that users can now + interact with synonyms using the Connections pane (@simonpcouch, #773). # odbc 1.4.2 From 1a8170e017840042370e49f8d41b229a09c1cc98 Mon Sep 17 00:00:00 2001 From: simonpcouch Date: Mon, 8 Apr 2024 13:28:55 -0500 Subject: [PATCH 08/13] address review comments edits to `dbExistsTable()` should resolve possible slowdown when the non-synonym table does exist --- R/driver-sql-server.R | 13 ++++++------- 1 file changed, 6 insertions(+), 7 deletions(-) diff --git a/R/driver-sql-server.R b/R/driver-sql-server.R index 5b399437..29c1c991 100644 --- a/R/driver-sql-server.R +++ b/R/driver-sql-server.R @@ -76,8 +76,12 @@ setMethod("dbExistsTable", c("Microsoft SQL Server", "character"), return(!is.na(dbGetQuery(conn, query)[[1]])) } df <- odbcConnectionTables(conn, name = name, ...) + if (NROW(df) > 0) { + return(TRUE) + } + synonyms <- dbGetQuery(conn, synonyms_query(conn, ...)) - NROW(df) > 0 || name %in% synonyms$name + name %in% synonyms$name } ) @@ -255,9 +259,6 @@ synonyms_query <- function(conn, catalog_name = NULL, schema_name = NULL) { has_catalog <- !is.null(catalog_name) has_schema <- !is.null(schema_name) - if (!has_catalog & !has_schema) { - return(paste0(res, filter_is_table)) - } if (has_catalog & has_schema) { res <- paste0(res, " WHERE DB.name = '", catalog_name, "' AND Sch.name = '", schema_name, "'") @@ -267,7 +268,5 @@ synonyms_query <- function(conn, catalog_name = NULL, schema_name = NULL) { res <- paste0(res, " WHERE Sch.name = '", schema_name, "'") } - paste0(res, filter_is_table) + paste0(res, " AND OBJECTPROPERTY(Object_ID(Syn.base_object_name), 'IsTable') = 1;") } - -filter_is_table <- " AND OBJECTPROPERTY(Object_ID(Syn.base_object_name), 'IsTable') = 1;" From da86cc41b3c741d68b2de0846e47a385a73b37cd Mon Sep 17 00:00:00 2001 From: simonpcouch Date: Thu, 11 Apr 2024 08:38:51 -0500 Subject: [PATCH 09/13] restore table filter edge case --- R/driver-sql-server.R | 8 +++++++- tests/testthat/test-driver-sql-server.R | 3 +++ 2 files changed, 10 insertions(+), 1 deletion(-) diff --git a/R/driver-sql-server.R b/R/driver-sql-server.R index 29c1c991..57d2efed 100644 --- a/R/driver-sql-server.R +++ b/R/driver-sql-server.R @@ -260,6 +260,10 @@ synonyms_query <- function(conn, catalog_name = NULL, schema_name = NULL) { has_catalog <- !is.null(catalog_name) has_schema <- !is.null(schema_name) + if (!has_catalog & !has_schema) { + return(paste0(res, " WHERE ", filter_is_table)) + } + if (has_catalog & has_schema) { res <- paste0(res, " WHERE DB.name = '", catalog_name, "' AND Sch.name = '", schema_name, "'") } else if (has_catalog) { @@ -268,5 +272,7 @@ synonyms_query <- function(conn, catalog_name = NULL, schema_name = NULL) { res <- paste0(res, " WHERE Sch.name = '", schema_name, "'") } - paste0(res, " AND OBJECTPROPERTY(Object_ID(Syn.base_object_name), 'IsTable') = 1;") + paste0(res, " AND ", filter_is_table) } + +filter_is_table <- "OBJECTPROPERTY(Object_ID(Syn.base_object_name), 'IsTable') = 1;" diff --git a/tests/testthat/test-driver-sql-server.R b/tests/testthat/test-driver-sql-server.R index 2b324060..423e9ed9 100644 --- a/tests/testthat/test-driver-sql-server.R +++ b/tests/testthat/test-driver-sql-server.R @@ -367,6 +367,9 @@ test_that("odbcListObjects shows synonyms (#221)", { dbExistsTable(con, name = "tbl2", catalog_name = db, schema_name = "testSchema") ) expect_true(dbExistsTable(con, name = Id(db, "testSchema", "tbl2"))) + expect_true(dbExistsTable(con, name = Id("testSchema", "tbl2"))) + expect_true(dbExistsTable(con, name = Id("tbl2"))) + expect_true(dbExistsTable(con, name = "tbl2")) dbExecute(con, "DROP SYNONYM testSchema.tbl2") expect_false(dbExistsTable(con, name = Id(db, "testSchema", "tbl2"))) From 503f45f0630ee118caf5cba4834ae50c05518c0c Mon Sep 17 00:00:00 2001 From: simonpcouch Date: Thu, 11 Apr 2024 09:14:43 -0500 Subject: [PATCH 10/13] correct test for appropriate object type --- tests/testthat/test-driver-sql-server.R | 3 ++- 1 file changed, 2 insertions(+), 1 deletion(-) diff --git a/tests/testthat/test-driver-sql-server.R b/tests/testthat/test-driver-sql-server.R index 423e9ed9..f00d295a 100644 --- a/tests/testthat/test-driver-sql-server.R +++ b/tests/testthat/test-driver-sql-server.R @@ -362,7 +362,8 @@ test_that("odbcListObjects shows synonyms (#221)", { nrow(odbcListObjects(con, catalog = db, schema = "testSchema", name = "tbl")), 1 ) - expect_false("tbl2" %in% odbcListObjects(con)) + expect_false("tbl2" %in% odbcListObjects(con)$name) + expect_false("tbl2" %in% odbcListObjects(con, catalog = db)$name) expect_true( dbExistsTable(con, name = "tbl2", catalog_name = db, schema_name = "testSchema") ) From 779f0b22677709b0a2b6d33dbd10d665575e48e7 Mon Sep 17 00:00:00 2001 From: simonpcouch Date: Thu, 11 Apr 2024 09:15:02 -0500 Subject: [PATCH 11/13] only return synonyms when listing tables --- R/driver-sql-server.R | 4 ++++ 1 file changed, 4 insertions(+) diff --git a/R/driver-sql-server.R b/R/driver-sql-server.R index 57d2efed..117c7230 100644 --- a/R/driver-sql-server.R +++ b/R/driver-sql-server.R @@ -234,6 +234,10 @@ setMethod("odbcDataType", "Microsoft SQL Server", ... ) + if (!any(objects$type == "table")) { + return(objects) + } + synonyms <- dbGetQuery(connection, synonyms_query(connection, catalog, schema)) if (!is.null(name)) { From 1cbc62da9bba9307324b2754cf0f966242284720 Mon Sep 17 00:00:00 2001 From: simonpcouch Date: Thu, 11 Apr 2024 09:43:54 -0500 Subject: [PATCH 12/13] fix bug when a schema consists only of synonyms --- R/driver-sql-server.R | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/R/driver-sql-server.R b/R/driver-sql-server.R index 117c7230..847c0686 100644 --- a/R/driver-sql-server.R +++ b/R/driver-sql-server.R @@ -234,7 +234,7 @@ setMethod("odbcDataType", "Microsoft SQL Server", ... ) - if (!any(objects$type == "table")) { + if (!any(objects$type == "table") && nrow(objects) > 0) { return(objects) } From 79b2c8dd7532144be79c1e6ba8df0bb47c995a5f Mon Sep 17 00:00:00 2001 From: simonpcouch Date: Thu, 11 Apr 2024 13:55:47 -0500 Subject: [PATCH 13/13] simplify `synonyms_query()` since each `sys.synonyms` references only the synonyms that live inside of the database/catalog it's inside of, only query the (fully qualified, if not the one from the active database) `sys.synonyms` in the `catalog_name`. if not `catalog_name` is specified, respect the active database. --- R/driver-sql-server.R | 45 +++++++++++++++++-------------------------- 1 file changed, 18 insertions(+), 27 deletions(-) diff --git a/R/driver-sql-server.R b/R/driver-sql-server.R index 847c0686..7067f203 100644 --- a/R/driver-sql-server.R +++ b/R/driver-sql-server.R @@ -80,7 +80,7 @@ setMethod("dbExistsTable", c("Microsoft SQL Server", "character"), return(TRUE) } - synonyms <- dbGetQuery(conn, synonyms_query(conn, ...)) + synonyms <- dbGetQuery(conn, synonyms_query(...)) name %in% synonyms$name } ) @@ -111,7 +111,7 @@ setMethod("dbListTables", "Microsoft SQL Server", res <- c(res, res_temp) } - synonyms <- dbGetQuery(conn, synonyms_query(conn, catalog_name, schema_name)) + synonyms <- dbGetQuery(conn, synonyms_query(catalog_name, schema_name)) c(res, synonyms$name) } @@ -238,7 +238,7 @@ setMethod("odbcDataType", "Microsoft SQL Server", return(objects) } - synonyms <- dbGetQuery(connection, synonyms_query(connection, catalog, schema)) + synonyms <- dbGetQuery(connection, synonyms_query(catalog, schema)) if (!is.null(name)) { synonyms <- synonyms[synonyms$name == name, , drop = FALSE] @@ -250,33 +250,24 @@ setMethod("odbcDataType", "Microsoft SQL Server", ) } -synonyms_query <- function(conn, catalog_name = NULL, schema_name = NULL) { - res <- "SELECT - catalog = DB.name, - [schema] = Sch.name, - name = Syn.name - FROM sys.synonyms AS Syn - INNER JOIN sys.schemas AS Sch - ON Sch.schema_id = Syn.schema_id - INNER JOIN sys.databases AS DB - ON Sch.principal_id = DB.database_id" - - has_catalog <- !is.null(catalog_name) - has_schema <- !is.null(schema_name) - - if (!has_catalog & !has_schema) { - return(paste0(res, " WHERE ", filter_is_table)) - } +synonyms_query <- function(catalog_name = NULL, schema_name = NULL) { + sys_synonyms <- paste0(c(catalog_name, "sys.synonyms"), collapse = ".") + + res <- paste0("IF DB_ID(", sQuote(catalog_name, "'"), ") IS NOT NULL + SELECT + [schema] = SCHEMA_NAME(Syn.schema_id), + name = Syn.name + FROM ", sys_synonyms, " AS Syn") - if (has_catalog & has_schema) { - res <- paste0(res, " WHERE DB.name = '", catalog_name, "' AND Sch.name = '", schema_name, "'") - } else if (has_catalog) { - res <- paste0(res, " WHERE DB.name = '", catalog_name, "'") - } else if (has_schema) { - res <- paste0(res, " WHERE Sch.name = '", schema_name, "'") + if (is.null(schema_name)) { + return(paste0(res, " WHERE ", filter_is_table)) } - paste0(res, " AND ", filter_is_table) + paste0( + res, + " WHERE SCHEMA_NAME(Syn.schema_id) = '", schema_name, "' AND ", + filter_is_table + ) } filter_is_table <- "OBJECTPROPERTY(Object_ID(Syn.base_object_name), 'IsTable') = 1;"