Skip to content
Draft
Show file tree
Hide file tree
Changes from 1 commit
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
1 change: 1 addition & 0 deletions NAMESPACE
Original file line number Diff line number Diff line change
Expand Up @@ -2,6 +2,7 @@

S3method(odbcListColumns,OdbcConnection)
S3method(odbcListObjectTypes,default)
S3method(odbcListObjects,"Microsoft SQL Server")
S3method(odbcListObjects,OdbcConnection)
S3method(odbcPreviewObject,OdbcConnection)
export(databricks)
Expand Down
53 changes: 53 additions & 0 deletions R/driver-sql-server.R
Original file line number Diff line number Diff line change
Expand Up @@ -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;",
Copy link
Collaborator Author

Choose a reason for hiding this comment

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

For now, I've opted to only include synonyms whose base object is a table, and refer to that synonym as a "table" in the output. This means that synonyms (that are tables) will be previewable through the Connections pane, but also feels a bit hacky. From what I can tell, the drop-down based in the pane based on odbcListFields() also doesn't work (but doesn't cause errors/crashes).

Instead, we could opt not to include this table and return the type as synonym. This means that there would be entries in the Connections pane but no previews.

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)))
)
}
6 changes: 6 additions & 0 deletions man/SQLServer.Rd

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

33 changes: 33 additions & 0 deletions tests/testthat/test-driver-sql-server.R
Original file line number Diff line number Diff line change
Expand Up @@ -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)
})