Skip to content

Commit ff4b0e8

Browse files
Merge pull request #413 from dpprdan/feat/refactor_list
chore: refactor `dbListTables()` et al.
2 parents d3a5569 + f789767 commit ff4b0e8

File tree

5 files changed

+109
-50
lines changed

5 files changed

+109
-50
lines changed

R/dbExistsTable_PqConnection_character.R

Lines changed: 5 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -2,10 +2,11 @@
22
#' @usage NULL
33
dbExistsTable_PqConnection_character <- function(conn, name, ...) {
44
stopifnot(length(name) == 1L)
5-
name <- dbQuoteIdentifier(conn, name)
6-
7-
# Convert to identifier
8-
id <- dbUnquoteIdentifier(conn, name)[[1]]
5+
# use (Un)QuoteIdentifier roundtrip instead of Id(table = name)
6+
# so that quoted names (possibly incl. schema) can be passed to `name` e.g.
7+
# name = dbQuoteIdentifier(conn, Id(schema = "sname", table = "tname"))
8+
quoted <- dbQuoteIdentifier(conn, name)
9+
id <- dbUnquoteIdentifier(conn, quoted)[[1]]
910
exists_table(conn, id)
1011
}
1112

R/dbListFields_PqConnection_Id.R

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,7 +1,7 @@
11
#' @rdname postgres-tables
22
#' @usage NULL
33
dbListFields_PqConnection_Id <- function(conn, name, ...) {
4-
list_fields(conn, name)
4+
list_fields(conn, id = name)
55
}
66

77
#' @rdname postgres-tables

R/dbListObjects_PqConnection_ANY.R

Lines changed: 19 additions & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -13,10 +13,13 @@ dbListObjects_PqConnection_ANY <- function(conn, prefix = NULL, ...) {
1313
null_varchar <- "NULL::text"
1414
}
1515
query <- paste0(
16-
"SELECT ", null_varchar, " AS schema, table_name AS table FROM INFORMATION_SCHEMA.tables\n",
17-
"WHERE (table_schema = ANY(current_schemas(true))) AND (table_schema <> 'pg_catalog')\n",
16+
"SELECT ", null_varchar, " AS schema, table_name AS table FROM ( \n",
17+
list_tables(conn = conn, order_by = "table_type, table_name"),
18+
") as table_query \n",
1819
"UNION ALL\n",
19-
"SELECT DISTINCT table_schema AS schema, ", null_varchar, " AS table FROM INFORMATION_SCHEMA.tables"
20+
"SELECT DISTINCT table_schema AS schema, ", null_varchar, " AS table FROM ( \n",
21+
list_tables(conn = conn, where_schema = "true"),
22+
") as schema_query;"
2023
)
2124
} else {
2225
if (!is.list(prefix)) prefix <- list(prefix)
@@ -27,10 +30,20 @@ dbListObjects_PqConnection_ANY <- function(conn, prefix = NULL, ...) {
2730
schemas <- vcapply(prefix[is_prefix], function(x) x@name[["schema"]])
2831
if (length(schemas) > 0) {
2932
schema_strings <- dbQuoteString(conn, schemas)
33+
where_schema <-
34+
paste0(
35+
"table_schema IN (",
36+
paste(schema_strings, collapse = ", "),
37+
") \n"
38+
)
3039
query <- paste0(
31-
"SELECT table_schema AS schema, table_name AS table FROM INFORMATION_SCHEMA.tables\n",
32-
"WHERE ",
33-
"(table_schema IN (", paste(schema_strings, collapse = ", "), "))"
40+
"SELECT table_schema AS schema, table_name AS table FROM ( \n",
41+
list_tables(
42+
conn = conn,
43+
where_schema = where_schema,
44+
order_by = "table_type, table_name"
45+
),
46+
") as table_query"
3447
)
3548
}
3649
}

R/dbListTables_PqConnection.R

Lines changed: 3 additions & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -1,12 +1,9 @@
11
#' @rdname postgres-tables
22
#' @usage NULL
33
dbListTables_PqConnection <- function(conn, ...) {
4-
query <- paste0(
5-
"SELECT table_name FROM INFORMATION_SCHEMA.tables ",
6-
"WHERE ",
7-
"(table_schema = ANY(current_schemas(true))) AND (table_schema <> 'pg_catalog')"
8-
)
9-
dbGetQuery(conn, query)[[1]]
4+
query <- list_tables(conn = conn, order_by = "table_type, table_name")
5+
6+
dbGetQuery(conn, query)[["table_name"]]
107
}
118

129
#' @rdname postgres-tables

R/tables.R

Lines changed: 81 additions & 33 deletions
Original file line numberDiff line numberDiff line change
@@ -120,26 +120,72 @@ db_append_table <- function(conn, name, value, copy, warn) {
120120
nrow(value)
121121
}
122122

123+
list_tables <- function(conn, where_schema = NULL, where_table = NULL, order_by = NULL) {
124+
125+
query <- paste0(
126+
# information_schema.table docs: https://www.postgresql.org/docs/current/infoschema-tables.html
127+
"SELECT table_schema, table_name \n",
128+
"FROM information_schema.tables \n",
129+
"WHERE TRUE \n" # dummy clause to be able to add additional ones with `AND`
130+
)
131+
132+
if (is.null(where_schema)) {
133+
# `true` in `current_schemas(true)` is necessary to get temporary tables
134+
query <- paste0(
135+
query,
136+
" AND (table_schema = ANY(current_schemas(true))) \n",
137+
" AND (table_schema <> 'pg_catalog') \n"
138+
)
139+
} else {
140+
query <- paste0(query, " AND ", where_schema)
141+
}
142+
143+
if (!is.null(where_table)) query <- paste0(query, " AND ", where_table)
144+
145+
if (!is.null(order_by)) query <- paste0(query, "ORDER BY ", order_by)
146+
147+
query
148+
}
149+
123150
exists_table <- function(conn, id) {
124151
name <- id@name
152+
stopifnot("table" %in% names(name))
153+
table_name <- dbQuoteString(conn, name[["table"]])
154+
where_table <- paste0("table_name = ", table_name, " \n")
125155

156+
if ("schema" %in% names(name)) {
157+
schema_name <- dbQuoteString(conn, name[["schema"]])
158+
where_schema <- paste0("table_schema = ", schema_name, " \n")
159+
} else {
160+
where_schema <- NULL
161+
}
126162
query <- paste0(
127-
"SELECT COUNT(*) FROM ",
128-
find_table(conn, name)
163+
"SELECT EXISTS ( \n",
164+
list_tables(conn, where_schema = where_schema, where_table = where_table),
165+
")"
129166
)
130-
131-
dbGetQuery(conn, query)[[1]] >= 1
167+
dbGetQuery(conn, query)[[1]]
132168
}
133169

134-
find_table <- function(conn, id, inf_table = "tables", only_first = FALSE) {
170+
list_fields <- function(conn, id) {
171+
name <- id@name
172+
135173
is_redshift <- is(conn, "RedshiftConnection")
136174

137-
if ("schema" %in% names(id)) {
175+
# get relevant schema
176+
if ("schema" %in% names(name)) {
177+
# either the user provides the schema
138178
query <- paste0(
139179
"(SELECT 1 AS nr, ",
140-
dbQuoteString(conn, id[["schema"]]), "::varchar",
180+
dbQuoteString(conn, name[["schema"]]), "::varchar",
141181
" AS table_schema) t"
142182
)
183+
184+
# only_first not necessary,
185+
# as there cannot be multiple tables with the same name in a single schema
186+
only_first <- FALSE
187+
188+
# or we have to look the table up in the schemas on the search path
143189
} else if (is_redshift) {
144190
# A variant of the Postgres version that uses CTEs and generate_series()
145191
# instead of generate_subscripts(), the latter is not supported on Redshift
@@ -158,25 +204,31 @@ find_table <- function(conn, id, inf_table = "tables", only_first = FALSE) {
158204
)
159205
only_first <- FALSE
160206
} else {
161-
# https://stackoverflow.com/a/8767450/946850
207+
# Get `current_schemas()` in search_path order
208+
# so $user and temp tables take precedence over the public schema (by default)
209+
# https://www.postgresql.org/docs/current/ddl-schemas.html#DDL-SCHEMAS-PATH
210+
# https://www.postgresql.org/docs/current/runtime-config-client.html#GUC-SEARCH-PATH
211+
# How to unnest `current_schemas(true)` array with element number (works since v9.4):
212+
# https://stackoverflow.com/a/8767450/2114932
162213
query <- paste0(
163-
"(SELECT nr, schemas[nr] AS table_schema FROM ",
164-
"(SELECT *, generate_subscripts(schemas, 1) AS nr FROM ",
165-
"(SELECT current_schemas(true) AS schemas) ",
166-
"t) ",
167-
"tt WHERE schemas[nr] <> 'pg_catalog') ",
168-
"ttt"
214+
"(",
215+
"SELECT * FROM unnest(current_schemas(true)) WITH ORDINALITY AS tbl(table_schema, nr) \n",
216+
"WHERE table_schema != 'pg_catalog'",
217+
") schemas_on_path"
169218
)
219+
only_first <- TRUE
170220
}
171221

172-
table <- dbQuoteString(conn, id[["table"]])
222+
# join columns info
223+
table <- dbQuoteString(conn, name[["table"]])
173224
query <- paste0(
174225
query, " ",
175-
"INNER JOIN INFORMATION_SCHEMA.", inf_table, " USING (table_schema) ",
226+
"INNER JOIN INFORMATION_SCHEMA.COLUMNS USING (table_schema) ",
176227
"WHERE table_name = ", table
177228
)
178229

179230
if (only_first) {
231+
# we can only detect duplicate table names after we know in which schemas they are
180232
# https://stackoverflow.com/a/31814584/946850
181233
query <- paste0(
182234
"(SELECT *, rank() OVER (ORDER BY nr) AS rnr ",
@@ -185,7 +237,19 @@ find_table <- function(conn, id, inf_table = "tables", only_first = FALSE) {
185237
)
186238
}
187239

188-
query
240+
query <- paste0(
241+
"SELECT column_name FROM ",
242+
query, " ",
243+
"ORDER BY ordinal_position"
244+
)
245+
246+
fields <- dbGetQuery(conn, query)[[1]]
247+
248+
if (length(fields) == 0) {
249+
stop("Table ", dbQuoteIdentifier(conn, id), " not found.", call. = FALSE)
250+
}
251+
252+
fields
189253
}
190254

191255
find_temp_schema <- function(conn, fail_if_missing = TRUE) {
@@ -214,19 +278,3 @@ find_temp_schema <- function(conn, fail_if_missing = TRUE) {
214278
return(connection_get_temp_schema(conn@ptr))
215279
}
216280
}
217-
218-
list_fields <- function(conn, id) {
219-
name <- id@name
220-
221-
query <- find_table(conn, name, "columns", only_first = TRUE)
222-
query <- paste0(
223-
"SELECT column_name FROM ",
224-
query, " ",
225-
"ORDER BY ordinal_position"
226-
)
227-
fields <- dbGetQuery(conn, query)[[1]]
228-
if (length(fields) == 0) {
229-
stop("Table ", dbQuoteIdentifier(conn, name), " not found.", call. = FALSE)
230-
}
231-
fields
232-
}

0 commit comments

Comments
 (0)