From 154eeacd1afcc5720cc17aa31bd75a61d4aa885e Mon Sep 17 00:00:00 2001 From: Daniel Possenriede Date: Fri, 2 Apr 2021 12:28:20 +0200 Subject: [PATCH 01/14] add pqListTables() --- DESCRIPTION | 1 + NAMESPACE | 2 ++ R/PqGenerics.R | 68 +++++++++++++++++++++++++++++++++++++++++++++ man/pqListTables.Rd | 38 +++++++++++++++++++++++++ 4 files changed, 109 insertions(+) create mode 100644 R/PqGenerics.R create mode 100644 man/pqListTables.Rd diff --git a/DESCRIPTION b/DESCRIPTION index ec946efd..a0caf406 100644 --- a/DESCRIPTION +++ b/DESCRIPTION @@ -62,6 +62,7 @@ SystemRequirements: libpq >= 9.0: libpq-dev (deb) or Collate: 'PqDriver.R' 'PqConnection.R' + 'PqGenerics.R' 'PqResult.R' 'RPostgres-pkg.R' 'RcppExports.R' diff --git a/NAMESPACE b/NAMESPACE index e0098385..1b5b2671 100644 --- a/NAMESPACE +++ b/NAMESPACE @@ -7,6 +7,7 @@ export(Redshift) export(postgresDefault) export(postgresHasDefault) export(postgresWaitForNotify) +export(pqListTables) exportClasses(PqConnection) exportClasses(PqDriver) exportClasses(PqResult) @@ -51,6 +52,7 @@ exportMethods(dbUnloadDriver) exportMethods(dbUnquoteIdentifier) exportMethods(dbWithTransaction) exportMethods(dbWriteTable) +exportMethods(pqListTables) exportMethods(show) exportMethods(sqlData) import(DBI) diff --git a/R/PqGenerics.R b/R/PqGenerics.R new file mode 100644 index 00000000..18b88063 --- /dev/null +++ b/R/PqGenerics.R @@ -0,0 +1,68 @@ +# PostgreSQL-specific features and functions + +#' List remote tables +#' +#' Returns the unquoted names of remote tables and table-like objects accessible +#' through this connection. +#' This includes foreign and partitioned tables, (materialized) views, as well +#' as temporary objects. +#' +#' @inheritParams postgres-tables +#' +#' @family PqConnection generics +#' +#' @examples +#' # For running the examples on systems without PostgreSQL connection: +#' run <- postgresHasDefault() +#' +#' library(DBI) +#' if (run) con <- dbConnect(RPostgres::Postgres()) +#' if (run) dbListTables(con) +#' +#' if (run) dbWriteTable(con, "mtcars", mtcars, temporary = TRUE) +#' if (run) dbListTables(con) +#' +#' if (run) dbDisconnect(con) +#' +#' @export +setGeneric("pqListTables", + def = function(conn, ...) standardGeneric("pqListTables"), + valueClass = "character" +) + +#' @rdname pqListTables +#' @export +setMethod("pqListTables", "PqConnection", function(conn) { + major_server_version <- dbGetInfo(conn)$db.version %/% 10000 + + query <- paste0( + # pg_class docs: https://www.postgresql.org/docs/current/catalog-pg-class.html + "SELECT cl.relname AS name FROM pg_class AS cl ", + "JOIN pg_namespace AS n ON cl.relnamespace = n.oid ", + "WHERE (n.nspname = ANY (current_schemas(true))) ", + "AND (n.nspname <> 'pg_catalog') " + ) + + if (major_server_version >= 10) { + # relkind = 'p' and relispartition only supported from v10 onwards + query <- paste0( + query, + # r = ordinary table, v = view, m = materialized view, f = foreign table, p = partitioned table + "AND (cl.relkind IN ('r', 'v', 'm', 'f', 'p')) ", + "AND NOT cl.relispartition " + ) + } else { + query <- paste0( + query, + "AND (cl.relkind IN ('r', 'v', 'm', 'f')) " + ) + } + + query <- paste0( + query, + "ORDER BY name" + ) + + dbGetQuery(conn, query)[[1]] +}) + diff --git a/man/pqListTables.Rd b/man/pqListTables.Rd new file mode 100644 index 00000000..e58bf76e --- /dev/null +++ b/man/pqListTables.Rd @@ -0,0 +1,38 @@ +% Generated by roxygen2: do not edit by hand +% Please edit documentation in R/PqGenerics.R +\name{pqListTables} +\alias{pqListTables} +\alias{pqListTables,PqConnection-method} +\title{List remote tables} +\usage{ +pqListTables(conn, ...) + +\S4method{pqListTables}{PqConnection}(conn) +} +\arguments{ +\item{conn}{a \linkS4class{PqConnection} object, produced by +\code{\link[DBI:dbConnect]{DBI::dbConnect()}}} + +\item{...}{Ignored.} +} +\description{ +Returns the unquoted names of remote tables and table-like objects accessible +through this connection. +This includes foreign and partitioned tables, (materialized) views, as well +as temporary objects. +} +\examples{ +# For running the examples on systems without PostgreSQL connection: +run <- postgresHasDefault() + +library(DBI) +if (run) con <- dbConnect(RPostgres::Postgres()) +if (run) dbListTables(con) + +if (run) dbWriteTable(con, "mtcars", mtcars, temporary = TRUE) +if (run) dbListTables(con) + +if (run) dbDisconnect(con) + +} +\concept{PqConnection generics} From 96fb1b591a2db8bc16ca9f300e7a57dabbe5757c Mon Sep 17 00:00:00 2001 From: Daniel Possenriede Date: Thu, 15 Apr 2021 19:49:21 +0200 Subject: [PATCH 02/14] pqListTables: List only relations which the user may access --- R/PqGenerics.R | 11 +++++++++-- 1 file changed, 9 insertions(+), 2 deletions(-) diff --git a/R/PqGenerics.R b/R/PqGenerics.R index 18b88063..a1cb649a 100644 --- a/R/PqGenerics.R +++ b/R/PqGenerics.R @@ -40,16 +40,23 @@ setMethod("pqListTables", "PqConnection", function(conn) { "SELECT cl.relname AS name FROM pg_class AS cl ", "JOIN pg_namespace AS n ON cl.relnamespace = n.oid ", "WHERE (n.nspname = ANY (current_schemas(true))) ", - "AND (n.nspname <> 'pg_catalog') " + "AND (n.nspname <> 'pg_catalog') ", + # Return only objects (relations) which the current user may access + # https://www.postgresql.org/docs/current/functions-info.html + "AND (pg_has_role(cl.relowner, 'USAGE'::text) ", + "OR has_table_privilege(cl.oid, 'SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER'::text) ", + "OR has_any_column_privilege(cl.oid, 'SELECT, INSERT, UPDATE, REFERENCES'::text) ", + ") " ) + # which kind of objects should be returned? if (major_server_version >= 10) { # relkind = 'p' and relispartition only supported from v10 onwards query <- paste0( query, # r = ordinary table, v = view, m = materialized view, f = foreign table, p = partitioned table "AND (cl.relkind IN ('r', 'v', 'm', 'f', 'p')) ", - "AND NOT cl.relispartition " + "AND NOT cl.relispartition " # do not return partitions ) } else { query <- paste0( From 7bb9ccbcd88874e11a00ac274c03b5a904125890 Mon Sep 17 00:00:00 2001 From: Daniel Possenriede Date: Sun, 25 Apr 2021 19:42:06 +0200 Subject: [PATCH 03/14] extract list tables query and make it more general --- R/PqGenerics.R | 47 ++++++++++++++++++++++++++++++++--------------- 1 file changed, 32 insertions(+), 15 deletions(-) diff --git a/R/PqGenerics.R b/R/PqGenerics.R index a1cb649a..af0e14ef 100644 --- a/R/PqGenerics.R +++ b/R/PqGenerics.R @@ -33,20 +33,25 @@ setGeneric("pqListTables", #' @rdname pqListTables #' @export setMethod("pqListTables", "PqConnection", function(conn) { + query <- list_tables_sql(conn = conn) + + dbGetQuery(conn, query)[["relname"]] +}) + +list_tables_sql <- function(conn, where_schema = NULL) { major_server_version <- dbGetInfo(conn)$db.version %/% 10000 query <- paste0( # pg_class docs: https://www.postgresql.org/docs/current/catalog-pg-class.html - "SELECT cl.relname AS name FROM pg_class AS cl ", - "JOIN pg_namespace AS n ON cl.relnamespace = n.oid ", - "WHERE (n.nspname = ANY (current_schemas(true))) ", - "AND (n.nspname <> 'pg_catalog') ", + "SELECT n.nspname, cl.relname \n", + "FROM pg_class AS cl \n", + "JOIN pg_namespace AS n ON cl.relnamespace = n.oid \n", # Return only objects (relations) which the current user may access # https://www.postgresql.org/docs/current/functions-info.html - "AND (pg_has_role(cl.relowner, 'USAGE'::text) ", - "OR has_table_privilege(cl.oid, 'SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER'::text) ", - "OR has_any_column_privilege(cl.oid, 'SELECT, INSERT, UPDATE, REFERENCES'::text) ", - ") " + "WHERE (pg_has_role(cl.relowner, 'USAGE'::text) \n", + " OR has_table_privilege(cl.oid, 'SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER'::text) \n", + " OR has_any_column_privilege(cl.oid, 'SELECT, INSERT, UPDATE, REFERENCES'::text) \n", + ") \n" ) # which kind of objects should be returned? @@ -54,22 +59,34 @@ setMethod("pqListTables", "PqConnection", function(conn) { # relkind = 'p' and relispartition only supported from v10 onwards query <- paste0( query, - # r = ordinary table, v = view, m = materialized view, f = foreign table, p = partitioned table - "AND (cl.relkind IN ('r', 'v', 'm', 'f', 'p')) ", - "AND NOT cl.relispartition " # do not return partitions + # r = ordinary table, v = view, m = materialized view, f = foreign table, + # p = partitioned table + "AND (cl.relkind IN ('r', 'v', 'm', 'f', 'p')) \n", + "AND NOT cl.relispartition \n" # do not return partitions ) } else { query <- paste0( query, - "AND (cl.relkind IN ('r', 'v', 'm', 'f')) " + "AND (cl.relkind IN ('r', 'v', 'm', 'f')) \n" + ) + } + + if (is.null(where_schema)) { + # all schemas in the search path without implicitly-searched system schemas + # such as pg_catalog + query <- paste0( + query, + "AND (n.nspname = ANY (current_schemas(false))) \n" ) + } else { + query <- paste0(query, where_schema) } query <- paste0( query, - "ORDER BY name" + "ORDER BY cl.relkind, cl.relname" ) - dbGetQuery(conn, query)[[1]] -}) + query +} From 69b1cd5151c9f4a890d4eb0a1d3a2881d052e770 Mon Sep 17 00:00:00 2001 From: Daniel Possenriede Date: Sun, 25 Apr 2021 19:42:56 +0200 Subject: [PATCH 04/14] add pqListObjects() --- R/PqGenerics.R | 85 ++++++++++++++++++++++++++++++++++++++++++++++++++ 1 file changed, 85 insertions(+) diff --git a/R/PqGenerics.R b/R/PqGenerics.R index af0e14ef..81eb57c9 100644 --- a/R/PqGenerics.R +++ b/R/PqGenerics.R @@ -90,3 +90,88 @@ list_tables_sql <- function(conn, where_schema = NULL) { query } +#' List remote objects +#' +#' Returns the names of remote objects accessible through this connection as a +#' data frame. +#' This includes foreign and partitioned tables, (materialized) views, as well +#' as temporary tables. +#' Compared to [dbListTables()], this method also enumerates tables and views +#' in schemas, and returns fully qualified identifiers to access these objects. +#' This allows exploration of all database objects available to the current +#' user, including those that can only be accessed by giving the full namespace. +#' +#' @inheritParams postgres-tables +#' +#' @family PqConnection generics +#' +#' @examples +#' # For running the examples on systems without PostgreSQL connection: +#' run <- postgresHasDefault() +#' +#' library(DBI) +#' if (run) con <- dbConnect(RPostgres::Postgres()) +#' if (run) dbListObjects(con) +#' +#' if (run) dbWriteTable(con, "mtcars", mtcars, temporary = TRUE) +#' if (run) dbListObjects(con) +#' +#' if (run) dbDisconnect(con) +#' +#' @export +setGeneric("pqListObjects", + def = function(conn, prefix = NULL, ...) standardGeneric("pqListObjects"), + valueClass = "data.frame" +) + +#' @rdname pqListObjects +#' @export +setMethod("pqListObjects", c("PqConnection", "ANY"), function(conn, prefix = NULL, ...) { + query <- NULL + if (is.null(prefix)) { + query <- list_tables_sql(conn = conn) + query <- paste0( + "SELECT NULL AS schema, relname AS table FROM ( \n", + query, + ") as table_query \n", + "UNION ALL \n", + "SELECT schema_name AS schema, NULL AS table \n", + "FROM INFORMATION_SCHEMA.schemata;" + ) + } else { + unquoted <- dbUnquoteIdentifier(conn, prefix) + is_prefix <- vlapply(unquoted, function(x) { "schema" %in% names(x@name) && !("table" %in% names(x@name)) }) + schemas <- vcapply(unquoted[is_prefix], function(x) x@name[["schema"]]) + if (length(schemas) > 0) { # else query is NULL + schema_strings <- dbQuoteString(conn, schemas) + where_schema <- + paste0( + "AND n.nspname IN (", + paste(schema_strings, collapse = ", "), + ")" + ) + query <- list_tables_sql(conn = conn, where_schema = where_schema) + query <- paste0( + "SELECT nspname AS schema, relname AS table FROM ( \n", + query, + ") as table_query" + ) + } + } + + if (is.null(query)) { + res <- data.frame(schema = character(), table = character(), stringsAsFactors = FALSE) + } else { + res <- dbGetQuery(conn, query) + } + + is_prefix <- !is.na(res$schema) & is.na(res$table) + tables <- Map("", res$schema, res$table, f = as_table) + + ret <- data.frame( + table = I(unname(tables)), + is_prefix = is_prefix, + stringsAsFactors = FALSE + ) + ret +}) From 29f6d29b403d1ef414594e516eb706470c0b1eb3 Mon Sep 17 00:00:00 2001 From: Daniel Possenriede Date: Sat, 22 May 2021 17:07:53 +0200 Subject: [PATCH 05/14] use pq*() functions in examples --- R/PqGenerics.R | 8 ++++---- 1 file changed, 4 insertions(+), 4 deletions(-) diff --git a/R/PqGenerics.R b/R/PqGenerics.R index 81eb57c9..fb1ebc80 100644 --- a/R/PqGenerics.R +++ b/R/PqGenerics.R @@ -17,10 +17,10 @@ #' #' library(DBI) #' if (run) con <- dbConnect(RPostgres::Postgres()) -#' if (run) dbListTables(con) +#' if (run) pqListTables(con) #' #' if (run) dbWriteTable(con, "mtcars", mtcars, temporary = TRUE) -#' if (run) dbListTables(con) +#' if (run) pqListTables(con) #' #' if (run) dbDisconnect(con) #' @@ -111,10 +111,10 @@ list_tables_sql <- function(conn, where_schema = NULL) { #' #' library(DBI) #' if (run) con <- dbConnect(RPostgres::Postgres()) -#' if (run) dbListObjects(con) +#' if (run) pqListObjects(con) #' #' if (run) dbWriteTable(con, "mtcars", mtcars, temporary = TRUE) -#' if (run) dbListObjects(con) +#' if (run) pqListObjects(con) #' #' if (run) dbDisconnect(con) #' From 8f34aaad2eddf7884acf59297ee945812d7768b2 Mon Sep 17 00:00:00 2001 From: Daniel Possenriede Date: Sat, 22 May 2021 17:10:38 +0200 Subject: [PATCH 06/14] make order_by optional in list_table_sql() --- R/PqGenerics.R | 18 ++++++++++-------- 1 file changed, 10 insertions(+), 8 deletions(-) diff --git a/R/PqGenerics.R b/R/PqGenerics.R index fb1ebc80..5e99ec90 100644 --- a/R/PqGenerics.R +++ b/R/PqGenerics.R @@ -33,12 +33,12 @@ setGeneric("pqListTables", #' @rdname pqListTables #' @export setMethod("pqListTables", "PqConnection", function(conn) { - query <- list_tables_sql(conn = conn) + query <- list_tables_sql(conn = conn, order_by = "cl.relkind, cl.relname") dbGetQuery(conn, query)[["relname"]] }) -list_tables_sql <- function(conn, where_schema = NULL) { +list_tables_sql <- function(conn, where_schema = NULL, order_by = NULL) { major_server_version <- dbGetInfo(conn)$db.version %/% 10000 query <- paste0( @@ -82,10 +82,7 @@ list_tables_sql <- function(conn, where_schema = NULL) { query <- paste0(query, where_schema) } - query <- paste0( - query, - "ORDER BY cl.relkind, cl.relname" - ) + if (!is.null(order_by)) query <- paste0(query, "ORDER BY ", order_by) query } @@ -129,7 +126,7 @@ setGeneric("pqListObjects", setMethod("pqListObjects", c("PqConnection", "ANY"), function(conn, prefix = NULL, ...) { query <- NULL if (is.null(prefix)) { - query <- list_tables_sql(conn = conn) + query <- list_tables_sql(conn = conn, order_by = "cl.relkind, cl.relname") query <- paste0( "SELECT NULL AS schema, relname AS table FROM ( \n", query, @@ -150,7 +147,12 @@ setMethod("pqListObjects", c("PqConnection", "ANY"), function(conn, prefix = NUL paste(schema_strings, collapse = ", "), ")" ) - query <- list_tables_sql(conn = conn, where_schema = where_schema) + query <- + list_tables_sql( + conn = conn, + where_schema = where_schema, + order_by = "cl.relkind, cl.relname" + ) query <- paste0( "SELECT nspname AS schema, relname AS table FROM ( \n", query, From e41b2eb04b834989bfab8fa739ee6337ebfc7a09 Mon Sep 17 00:00:00 2001 From: Daniel Possenriede Date: Sat, 22 May 2021 17:12:33 +0200 Subject: [PATCH 07/14] add pqExistsTable() --- R/PqGenerics.R | 69 +++++++++++++++++++++++++++++++++++++++++++++++++- 1 file changed, 68 insertions(+), 1 deletion(-) diff --git a/R/PqGenerics.R b/R/PqGenerics.R index 5e99ec90..2f6d7536 100644 --- a/R/PqGenerics.R +++ b/R/PqGenerics.R @@ -38,7 +38,7 @@ setMethod("pqListTables", "PqConnection", function(conn) { dbGetQuery(conn, query)[["relname"]] }) -list_tables_sql <- function(conn, where_schema = NULL, order_by = NULL) { +list_tables_sql <- function(conn, where_schema = NULL, where_table = NULL, order_by = NULL) { major_server_version <- dbGetInfo(conn)$db.version %/% 10000 query <- paste0( @@ -82,10 +82,77 @@ list_tables_sql <- function(conn, where_schema = NULL, order_by = NULL) { query <- paste0(query, where_schema) } + if (!is.null(where_table)) query <- paste0(query, where_table) + if (!is.null(order_by)) query <- paste0(query, "ORDER BY ", order_by) query } +#' Does a table exist? +#' +#' Returns if a table or (materialized) view given by name exists in the +#' database. +#' +#' @inheritParams postgres-tables +#' +#' @family PqConnection generics +#' +#' @examples +#' # For running the examples on systems without PostgreSQL connection: +#' run <- postgresHasDefault() +#' +#' library(DBI) +#' if (run) con <- dbConnect(RPostgres::Postgres()) +#' if (run) pqExistsTable(con, "mtcars") +#' +#' if (run) dbWriteTable(con, "mtcars", mtcars, temporary = TRUE) +#' if (run) pqExistsTable(con, "mtcars") +#' +#' if (run) dbDisconnect(con) +#' +#' @export +setGeneric("pqExistsTable", + def = function(conn, name, ...) standardGeneric("pqExistsTable"), + valueClass = "logical" +) + +#' @rdname pqExistsTable +#' @export +setMethod("pqExistsTable", c("PqConnection", "character"), function(conn, name, ...) { + stopifnot(length(name) == 1L) + # use (Un)QuoteIdentifier roundtrip instead of Id(table = name) + # so that quoted names (possibly incl. schema) can be passed to `name` e.g. + # name = dbQuoteIdentifier(conn, Id(schema = "sname", table = "tname")) + name <- dbQuoteIdentifier(conn, name) + id <- dbUnquoteIdentifier(conn, name)[[1]] + pq_exists_table(conn, id) +}) + +#' @export +#' @rdname postgres-tables +setMethod("pqExistsTable", c("PqConnection", "Id"), function(conn, name, ...) { + pq_exists_table(conn, id = name) +}) + +pq_exists_table <- function(conn, id) { + name <- id@name + stopifnot("table" %in% names(name)) + table_name <- dbQuoteString(conn, name[["table"]]) + where_table <- paste0("AND cl.relname = ", table_name, "\n") + + if ("schema" %in% names(name)) { + schema_name <- dbQuoteString(conn, name[["schema"]]) + where_schema <- paste0("AND n.nspname = ", schema_name, "\n") + } else { + where_schema <- NULL + } + query <- paste0( + "SELECT EXISTS ( \n", + list_tables_sql(conn, where_schema = where_schema, where_table = where_table), + ")" + ) + dbGetQuery(conn, query)[[1]] +} #' List remote objects #' From c53610e04b9bd9f6ca6d7598671a6269a55db83a Mon Sep 17 00:00:00 2001 From: Daniel Possenriede Date: Fri, 28 May 2021 17:21:58 +0200 Subject: [PATCH 08/14] add pqListFields() --- R/PqGenerics.R | 65 ++++++++++++++++++++++++++++++++++++++++++++++++++ 1 file changed, 65 insertions(+) diff --git a/R/PqGenerics.R b/R/PqGenerics.R index 2f6d7536..c56d9bed 100644 --- a/R/PqGenerics.R +++ b/R/PqGenerics.R @@ -244,3 +244,68 @@ setMethod("pqListObjects", c("PqConnection", "ANY"), function(conn, prefix = NUL ) ret }) + +#' List field names of a remote table +#' +#' @inheritParams postgres-tables +#' +#' @family PqConnection generics +#' +#' @seealso [dbColumnInfo()] to get the type of the fields. +#' +#' @examples +#' # Examples only run on systems with a PostgreSQL connection: +#' run <- postgresHasDefault() +#' +#' library(DBI) +#' if (run) con <- dbConnect(RPostgres::Postgres()) +#' +#' if (run) dbWriteTable(con, "mtcars", mtcars, temporary = TRUE) +#' if (run) pqListFields(con, "mtcars") +#' +#' if (run) dbDisconnect(con) +#' +#' @export +setGeneric("pqListFields", + def = function(conn, name, ...) standardGeneric("pqListFields"), + valueClass = "character" +) + +#' @export +setMethod("pqListFields", signature("DBIConnection", "character"), + function(conn, name, ...) { + quoted <- dbQuoteIdentifier(conn, name) + id <- dbUnquoteIdentifier(conn, quoted)[[1]] + pq_list_fields(conn, id) + } +) + +#' @rdname pqListFields +#' @export +setMethod("pqListFields", signature("DBIConnection", "Id"), + function(conn, name, ...) { + pq_list_fields(conn, id = name) + } +) + +pq_list_fields <- function(conn, id) { + if (pq_exists_table(conn, id)) { + # we know from pq_exists_table() that at least id@name["table"] exists + tname_str <- na.omit(id@name[c("schema", "table")]) + tname_qstr <- dbQuoteString(conn, paste(tname_str, collapse = ".")) + # https://dba.stackexchange.com/a/75124 + # https://dba.stackexchange.com/a/22420 + query <- + paste0( + "SELECT attname \n", + "FROM pg_attribute \n", + "WHERE attrelid = ", tname_qstr, "::regclass \n", + " AND attnum > 0 \n", + " AND NOT attisdropped \n", + "ORDER BY attnum;" + ) + dbGetQuery(conn, query)[[1]] + } else { + stop("Table ", dbQuoteIdentifier(conn, id), " not found.", call. = FALSE) + } +} From 8de8d0d58bcaf2ffee4cd9b44bf94dfa56e35bad Mon Sep 17 00:00:00 2001 From: Daniel Possenriede Date: Fri, 28 May 2021 17:40:11 +0200 Subject: [PATCH 09/14] update docs --- NAMESPACE | 6 +++++ R/PqGenerics.R | 15 +++++++----- R/tables.R | 2 +- man/postgres-tables.Rd | 13 +++++++---- man/pqExistsTable.Rd | 46 +++++++++++++++++++++++++++++++++++++ man/pqListFields.Rd | 46 +++++++++++++++++++++++++++++++++++++ man/pqListObjects.Rd | 52 ++++++++++++++++++++++++++++++++++++++++++ man/pqListTables.Rd | 14 ++++++++---- 8 files changed, 178 insertions(+), 16 deletions(-) create mode 100644 man/pqExistsTable.Rd create mode 100644 man/pqListFields.Rd create mode 100644 man/pqListObjects.Rd diff --git a/NAMESPACE b/NAMESPACE index 1b5b2671..54558d60 100644 --- a/NAMESPACE +++ b/NAMESPACE @@ -7,6 +7,9 @@ export(Redshift) export(postgresDefault) export(postgresHasDefault) export(postgresWaitForNotify) +export(pqExistsTable) +export(pqListFields) +export(pqListObjects) export(pqListTables) exportClasses(PqConnection) exportClasses(PqDriver) @@ -52,6 +55,9 @@ exportMethods(dbUnloadDriver) exportMethods(dbUnquoteIdentifier) exportMethods(dbWithTransaction) exportMethods(dbWriteTable) +exportMethods(pqExistsTable) +exportMethods(pqListFields) +exportMethods(pqListObjects) exportMethods(pqListTables) exportMethods(show) exportMethods(sqlData) diff --git a/R/PqGenerics.R b/R/PqGenerics.R index c56d9bed..09cefd3f 100644 --- a/R/PqGenerics.R +++ b/R/PqGenerics.R @@ -12,7 +12,7 @@ #' @family PqConnection generics #' #' @examples -#' # For running the examples on systems without PostgreSQL connection: +#' # Examples only run on systems with a PostgreSQL connection: #' run <- postgresHasDefault() #' #' library(DBI) @@ -42,6 +42,7 @@ list_tables_sql <- function(conn, where_schema = NULL, where_table = NULL, order major_server_version <- dbGetInfo(conn)$db.version %/% 10000 query <- paste0( + # pg_class vs. information_schema: https://stackoverflow.com/a/24089729 # pg_class docs: https://www.postgresql.org/docs/current/catalog-pg-class.html "SELECT n.nspname, cl.relname \n", "FROM pg_class AS cl \n", @@ -88,17 +89,18 @@ list_tables_sql <- function(conn, where_schema = NULL, where_table = NULL, order query } -#' Does a table exist? + +#' Does a table exist (for the current user)? #' -#' Returns if a table or (materialized) view given by name exists in the -#' database. +#' Returns whether a table or (materialized) view given by `name` is accessible +#' through this connection. #' #' @inheritParams postgres-tables #' #' @family PqConnection generics #' #' @examples -#' # For running the examples on systems without PostgreSQL connection: +#' # Examples only run on systems with a PostgreSQL connection: #' run <- postgresHasDefault() #' #' library(DBI) @@ -170,7 +172,7 @@ pq_exists_table <- function(conn, id) { #' @family PqConnection generics #' #' @examples -#' # For running the examples on systems without PostgreSQL connection: +#' # Examples only run on systems with a PostgreSQL connection: #' run <- postgresHasDefault() #' #' library(DBI) @@ -191,6 +193,7 @@ setGeneric("pqListObjects", #' @rdname pqListObjects #' @export setMethod("pqListObjects", c("PqConnection", "ANY"), function(conn, prefix = NULL, ...) { + # TODO write (better) error message when schema/prefix is not available query <- NULL if (is.null(prefix)) { query <- list_tables_sql(conn = conn, order_by = "cl.relkind, cl.relname") diff --git a/R/tables.R b/R/tables.R index 0897817e..e8891d4f 100644 --- a/R/tables.R +++ b/R/tables.R @@ -7,7 +7,7 @@ #' SQL string. #' #' @param conn a [PqConnection-class] object, produced by -#' [DBI::dbConnect()] +#' [DBI::dbConnect()]. #' @param name a character string specifying a table name. Names will be #' automatically quoted so you can use any sequence of characters, not #' just any valid bare table name. diff --git a/man/postgres-tables.Rd b/man/postgres-tables.Rd index 4bea47d5..ffc2c643 100644 --- a/man/postgres-tables.Rd +++ b/man/postgres-tables.Rd @@ -1,6 +1,7 @@ % Generated by roxygen2: do not edit by hand -% Please edit documentation in R/tables.R -\name{postgres-tables} +% Please edit documentation in R/PqGenerics.R, R/tables.R +\name{pqExistsTable,PqConnection,Id-method} +\alias{pqExistsTable,PqConnection,Id-method} \alias{postgres-tables} \alias{dbWriteTable,PqConnection,character,data.frame-method} \alias{sqlData,PqConnection-method} @@ -15,6 +16,8 @@ \alias{dbListObjects,PqConnection-method} \title{Convenience functions for reading/writing DBMS tables} \usage{ +\S4method{pqExistsTable}{PqConnection,Id}(conn, name, ...) + \S4method{dbWriteTable}{PqConnection,character,data.frame}( conn, name, @@ -50,16 +53,16 @@ } \arguments{ \item{conn}{a \linkS4class{PqConnection} object, produced by -\code{\link[DBI:dbConnect]{DBI::dbConnect()}}} +\code{\link[DBI:dbConnect]{DBI::dbConnect()}}.} \item{name}{a character string specifying a table name. Names will be automatically quoted so you can use any sequence of characters, not just any valid bare table name.} -\item{value}{A data.frame to write to the database.} - \item{...}{Ignored.} +\item{value}{A data.frame to write to the database.} + \item{row.names}{Either \code{TRUE}, \code{FALSE}, \code{NA} or a string. If \code{TRUE}, always translate row names to a column called "row_names". diff --git a/man/pqExistsTable.Rd b/man/pqExistsTable.Rd new file mode 100644 index 00000000..8b7aecbc --- /dev/null +++ b/man/pqExistsTable.Rd @@ -0,0 +1,46 @@ +% Generated by roxygen2: do not edit by hand +% Please edit documentation in R/PqGenerics.R +\name{pqExistsTable} +\alias{pqExistsTable} +\alias{pqExistsTable,PqConnection,character-method} +\title{Does a table exist (for the current user)?} +\usage{ +pqExistsTable(conn, name, ...) + +\S4method{pqExistsTable}{PqConnection,character}(conn, name, ...) +} +\arguments{ +\item{conn}{a \linkS4class{PqConnection} object, produced by +\code{\link[DBI:dbConnect]{DBI::dbConnect()}}.} + +\item{name}{a character string specifying a table name. Names will be +automatically quoted so you can use any sequence of characters, not +just any valid bare table name.} + +\item{...}{Ignored.} +} +\description{ +Returns whether a table or (materialized) view given by \code{name} is accessible +through this connection. +} +\examples{ +# Examples only run on systems with a PostgreSQL connection: +run <- postgresHasDefault() + +library(DBI) +if (run) con <- dbConnect(RPostgres::Postgres()) +if (run) pqExistsTable(con, "mtcars") + +if (run) dbWriteTable(con, "mtcars", mtcars, temporary = TRUE) +if (run) pqExistsTable(con, "mtcars") + +if (run) dbDisconnect(con) + +} +\seealso{ +Other PqConnection generics: +\code{\link{pqListFields}()}, +\code{\link{pqListObjects}()}, +\code{\link{pqListTables}()} +} +\concept{PqConnection generics} diff --git a/man/pqListFields.Rd b/man/pqListFields.Rd new file mode 100644 index 00000000..4529f275 --- /dev/null +++ b/man/pqListFields.Rd @@ -0,0 +1,46 @@ +% Generated by roxygen2: do not edit by hand +% Please edit documentation in R/PqGenerics.R +\name{pqListFields} +\alias{pqListFields} +\alias{pqListFields,DBIConnection,Id-method} +\title{List field names of a remote table} +\usage{ +pqListFields(conn, name, ...) + +\S4method{pqListFields}{DBIConnection,Id}(conn, name, ...) +} +\arguments{ +\item{conn}{a \linkS4class{PqConnection} object, produced by +\code{\link[DBI:dbConnect]{DBI::dbConnect()}}.} + +\item{name}{a character string specifying a table name. Names will be +automatically quoted so you can use any sequence of characters, not +just any valid bare table name.} + +\item{...}{Ignored.} +} +\description{ +List field names of a remote table +} +\examples{ +# Examples only run on systems with a PostgreSQL connection: +run <- postgresHasDefault() + +library(DBI) +if (run) con <- dbConnect(RPostgres::Postgres()) + +if (run) dbWriteTable(con, "mtcars", mtcars, temporary = TRUE) +if (run) pqListFields(con, "mtcars") + +if (run) dbDisconnect(con) + +} +\seealso{ +\code{\link[=dbColumnInfo]{dbColumnInfo()}} to get the type of the fields. + +Other PqConnection generics: +\code{\link{pqExistsTable}()}, +\code{\link{pqListObjects}()}, +\code{\link{pqListTables}()} +} +\concept{PqConnection generics} diff --git a/man/pqListObjects.Rd b/man/pqListObjects.Rd new file mode 100644 index 00000000..207e193e --- /dev/null +++ b/man/pqListObjects.Rd @@ -0,0 +1,52 @@ +% Generated by roxygen2: do not edit by hand +% Please edit documentation in R/PqGenerics.R +\name{pqListObjects} +\alias{pqListObjects} +\alias{pqListObjects,PqConnection-method} +\title{List remote objects} +\usage{ +pqListObjects(conn, prefix = NULL, ...) + +\S4method{pqListObjects}{PqConnection}(conn, prefix = NULL, ...) +} +\arguments{ +\item{conn}{a \linkS4class{PqConnection} object, produced by +\code{\link[DBI:dbConnect]{DBI::dbConnect()}}.} + +\item{prefix}{A fully qualified path in the database's namespace, or \code{NULL}. +This argument will be processed with \code{\link[DBI:dbUnquoteIdentifier]{dbUnquoteIdentifier()}}. +If given the method will return all objects accessible through this prefix.} + +\item{...}{Ignored.} +} +\description{ +Returns the names of remote objects accessible through this connection as a +data frame. +This includes foreign and partitioned tables, (materialized) views, as well +as temporary tables. +Compared to \code{\link[=dbListTables]{dbListTables()}}, this method also enumerates tables and views +in schemas, and returns fully qualified identifiers to access these objects. +This allows exploration of all database objects available to the current +user, including those that can only be accessed by giving the full namespace. +} +\examples{ +# Examples only run on systems with a PostgreSQL connection: +run <- postgresHasDefault() + +library(DBI) +if (run) con <- dbConnect(RPostgres::Postgres()) +if (run) pqListObjects(con) + +if (run) dbWriteTable(con, "mtcars", mtcars, temporary = TRUE) +if (run) pqListObjects(con) + +if (run) dbDisconnect(con) + +} +\seealso{ +Other PqConnection generics: +\code{\link{pqExistsTable}()}, +\code{\link{pqListFields}()}, +\code{\link{pqListTables}()} +} +\concept{PqConnection generics} diff --git a/man/pqListTables.Rd b/man/pqListTables.Rd index e58bf76e..4b379996 100644 --- a/man/pqListTables.Rd +++ b/man/pqListTables.Rd @@ -11,7 +11,7 @@ pqListTables(conn, ...) } \arguments{ \item{conn}{a \linkS4class{PqConnection} object, produced by -\code{\link[DBI:dbConnect]{DBI::dbConnect()}}} +\code{\link[DBI:dbConnect]{DBI::dbConnect()}}.} \item{...}{Ignored.} } @@ -22,17 +22,23 @@ This includes foreign and partitioned tables, (materialized) views, as well as temporary objects. } \examples{ -# For running the examples on systems without PostgreSQL connection: +# Examples only run on systems with a PostgreSQL connection: run <- postgresHasDefault() library(DBI) if (run) con <- dbConnect(RPostgres::Postgres()) -if (run) dbListTables(con) +if (run) pqListTables(con) if (run) dbWriteTable(con, "mtcars", mtcars, temporary = TRUE) -if (run) dbListTables(con) +if (run) pqListTables(con) if (run) dbDisconnect(con) +} +\seealso{ +Other PqConnection generics: +\code{\link{pqExistsTable}()}, +\code{\link{pqListFields}()}, +\code{\link{pqListObjects}()} } \concept{PqConnection generics} From ca36513d67b64c927882f2d73ab1717f45985c39 Mon Sep 17 00:00:00 2001 From: Daniel Possenriede Date: Fri, 4 Jun 2021 17:14:24 +0200 Subject: [PATCH 10/14] fix list_tables_sql() re: temp tables --- R/PqGenerics.R | 30 +++++++++++++++++++----------- 1 file changed, 19 insertions(+), 11 deletions(-) diff --git a/R/PqGenerics.R b/R/PqGenerics.R index 09cefd3f..dae853d9 100644 --- a/R/PqGenerics.R +++ b/R/PqGenerics.R @@ -33,7 +33,12 @@ setGeneric("pqListTables", #' @rdname pqListTables #' @export setMethod("pqListTables", "PqConnection", function(conn) { - query <- list_tables_sql(conn = conn, order_by = "cl.relkind, cl.relname") + query <- + list_tables_sql( + conn = conn, + where_schema = "current", + order_by = "cl.relkind, cl.relname" + ) dbGetQuery(conn, query)[["relname"]] }) @@ -72,15 +77,18 @@ list_tables_sql <- function(conn, where_schema = NULL, where_table = NULL, order ) } - if (is.null(where_schema)) { - # all schemas in the search path without implicitly-searched system schemas - # such as pg_catalog - query <- paste0( - query, - "AND (n.nspname = ANY (current_schemas(false))) \n" - ) - } else { - query <- paste0(query, where_schema) + if (!is.null(where_schema)) { + if (identical(where_schema, "current")) { + # `current_schemas(true)` (not `false`) necessary to get temporary tables + query <- paste0( + query, + "AND (n.nspname = ANY(current_schemas(true))) \n", + "AND (n.nspname <> 'pg_catalog') \n" + ) + } else { + query <- paste0(query, where_schema) + + } } if (!is.null(where_table)) query <- paste0(query, where_table) @@ -146,7 +154,7 @@ pq_exists_table <- function(conn, id) { schema_name <- dbQuoteString(conn, name[["schema"]]) where_schema <- paste0("AND n.nspname = ", schema_name, "\n") } else { - where_schema <- NULL + where_schema <- "current" } query <- paste0( "SELECT EXISTS ( \n", From bf6d039fecbcd8809d23115f0fd6653be330e7b7 Mon Sep 17 00:00:00 2001 From: Daniel Possenriede Date: Fri, 4 Jun 2021 17:15:12 +0200 Subject: [PATCH 11/14] pqListTables(): add ellipsis --- R/PqGenerics.R | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/R/PqGenerics.R b/R/PqGenerics.R index dae853d9..05897956 100644 --- a/R/PqGenerics.R +++ b/R/PqGenerics.R @@ -32,7 +32,7 @@ setGeneric("pqListTables", #' @rdname pqListTables #' @export -setMethod("pqListTables", "PqConnection", function(conn) { +setMethod("pqListTables", "PqConnection", function(conn, ...) { query <- list_tables_sql( conn = conn, From 19415a8d8defff7ee54eb1787045b8d8bad54826 Mon Sep 17 00:00:00 2001 From: Daniel Possenriede Date: Fri, 4 Jun 2021 17:20:36 +0200 Subject: [PATCH 12/14] pqListObjects(): list all schemas with accessible tables, inkl. temporary also list schemas with materialized views only --- R/PqGenerics.R | 12 ++++++++---- 1 file changed, 8 insertions(+), 4 deletions(-) diff --git a/R/PqGenerics.R b/R/PqGenerics.R index 05897956..e0823cc5 100644 --- a/R/PqGenerics.R +++ b/R/PqGenerics.R @@ -204,14 +204,18 @@ setMethod("pqListObjects", c("PqConnection", "ANY"), function(conn, prefix = NUL # TODO write (better) error message when schema/prefix is not available query <- NULL if (is.null(prefix)) { - query <- list_tables_sql(conn = conn, order_by = "cl.relkind, cl.relname") query <- paste0( "SELECT NULL AS schema, relname AS table FROM ( \n", - query, + list_tables_sql( + conn = conn, + where_schema = "current", + order_by = "cl.relkind, cl.relname" + ), ") as table_query \n", "UNION ALL \n", - "SELECT schema_name AS schema, NULL AS table \n", - "FROM INFORMATION_SCHEMA.schemata;" + "SELECT DISTINCT nspname AS schema, NULL AS table FROM ( \n", + list_tables_sql(conn = conn), + ") as schema_query;" ) } else { unquoted <- dbUnquoteIdentifier(conn, prefix) From 65ca84d39eac941d3e0fd2fa050668d66ef342b2 Mon Sep 17 00:00:00 2001 From: Daniel Possenriede Date: Mon, 7 Jun 2021 12:18:55 +0200 Subject: [PATCH 13/14] namespace na.omit() --- R/PqGenerics.R | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/R/PqGenerics.R b/R/PqGenerics.R index e0823cc5..9ad2c08e 100644 --- a/R/PqGenerics.R +++ b/R/PqGenerics.R @@ -306,7 +306,7 @@ setMethod("pqListFields", signature("DBIConnection", "Id"), pq_list_fields <- function(conn, id) { if (pq_exists_table(conn, id)) { # we know from pq_exists_table() that at least id@name["table"] exists - tname_str <- na.omit(id@name[c("schema", "table")]) + tname_str <- stats::na.omit(id@name[c("schema", "table")]) tname_qstr <- dbQuoteString(conn, paste(tname_str, collapse = ".")) # https://dba.stackexchange.com/a/75124 # https://dba.stackexchange.com/a/22420 From 902e3060c9deddbfb1452d941a11eb5eac7acc75 Mon Sep 17 00:00:00 2001 From: Daniel Possenriede Date: Mon, 7 Jun 2021 12:48:29 +0200 Subject: [PATCH 14/14] fix docs --- R/PqGenerics.R | 1 + man/pqListFields.Rd | 3 +++ man/pqListTables.Rd | 2 +- 3 files changed, 5 insertions(+), 1 deletion(-) diff --git a/R/PqGenerics.R b/R/PqGenerics.R index 9ad2c08e..f926d89c 100644 --- a/R/PqGenerics.R +++ b/R/PqGenerics.R @@ -286,6 +286,7 @@ setGeneric("pqListFields", valueClass = "character" ) +#' @rdname pqListFields #' @export setMethod("pqListFields", signature("DBIConnection", "character"), function(conn, name, ...) { diff --git a/man/pqListFields.Rd b/man/pqListFields.Rd index 4529f275..20ac7763 100644 --- a/man/pqListFields.Rd +++ b/man/pqListFields.Rd @@ -2,11 +2,14 @@ % Please edit documentation in R/PqGenerics.R \name{pqListFields} \alias{pqListFields} +\alias{pqListFields,DBIConnection,character-method} \alias{pqListFields,DBIConnection,Id-method} \title{List field names of a remote table} \usage{ pqListFields(conn, name, ...) +\S4method{pqListFields}{DBIConnection,character}(conn, name, ...) + \S4method{pqListFields}{DBIConnection,Id}(conn, name, ...) } \arguments{ diff --git a/man/pqListTables.Rd b/man/pqListTables.Rd index 4b379996..c4c67f0c 100644 --- a/man/pqListTables.Rd +++ b/man/pqListTables.Rd @@ -7,7 +7,7 @@ \usage{ pqListTables(conn, ...) -\S4method{pqListTables}{PqConnection}(conn) +\S4method{pqListTables}{PqConnection}(conn, ...) } \arguments{ \item{conn}{a \linkS4class{PqConnection} object, produced by