@@ -122,12 +122,21 @@ db_append_table <- function(conn, name, value, copy, warn) {
122
122
123
123
list_tables <- function (conn , where_schema = NULL , where_table = NULL , order_by = NULL ) {
124
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
- )
125
+ if (conn @ system_catalogs ) {
126
+ query <- paste0(
127
+ " SELECT table_schema, table_name \n " ,
128
+ " FROM ( " , list_tables_from_system_catalog(), " ) AS schema_tables \n " ,
129
+ " WHERE TRUE \n "
130
+ )
131
+ } else {
132
+ query <- paste0(
133
+ # information_schema.table docs:
134
+ # https://www.postgresql.org/docs/current/infoschema-tables.html
135
+ " SELECT table_schema, table_name \n " ,
136
+ " FROM information_schema.tables \n " ,
137
+ " WHERE TRUE \n " # dummy clause to be able to add additional ones with `AND`
138
+ )
139
+ }
131
140
132
141
if (is.null(where_schema )) {
133
142
# `true` in `current_schemas(true)` is necessary to get temporary tables
@@ -147,6 +156,38 @@ list_tables <- function(conn, where_schema = NULL, where_table = NULL, order_by
147
156
query
148
157
}
149
158
159
+ list_tables_from_system_catalog <- function () {
160
+ # This imitates (parts of) information_schema.tables, but includes materialized views
161
+ paste0(
162
+ # pg_class vs. information_schema: https://stackoverflow.com/a/24089729
163
+ # pg_class docs: https://www.postgresql.org/docs/current/catalog-pg-class.html
164
+ " SELECT n.nspname AS table_schema, cl.relname AS table_name, \n " ,
165
+ " CASE
166
+ WHEN (n.oid = pg_my_temp_schema()) THEN 'LOCAL TEMPORARY'
167
+ WHEN (cl.relkind IN ('r', 'p')) THEN 'BASE TABLE'
168
+ WHEN (cl.relkind = 'v') THEN 'VIEW'
169
+ WHEN (cl.relkind = 'f') THEN 'FOREIGN'
170
+ WHEN (cl.relkind = 'm') THEN 'MATVIEW'
171
+ ELSE NULL
172
+ END AS table_type \n " ,
173
+ " FROM pg_class AS cl \n " ,
174
+ " JOIN pg_namespace AS n ON cl.relnamespace = n.oid \n " ,
175
+ # include: r = ordinary table, v = view, m = materialized view,
176
+ # f = foreign table, p = partitioned table
177
+ " WHERE (cl.relkind IN ('r', 'v', 'm', 'f', 'p')) \n " ,
178
+ # do not return individual table partitions
179
+ " AND NOT cl.relispartition \n " ,
180
+ # do not return other people's temp schemas
181
+ " AND (NOT pg_is_other_temp_schema(n.oid)) \n " ,
182
+ # Return only objects (relations) which the current user may access
183
+ # https://www.postgresql.org/docs/current/functions-info.html
184
+ " AND (pg_has_role(cl.relowner, 'USAGE') \n " ,
185
+ " OR has_table_privilege(cl.oid, 'SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER') \n " ,
186
+ " OR has_any_column_privilege(cl.oid, 'SELECT, INSERT, UPDATE, REFERENCES') \n " ,
187
+ " ) \n "
188
+ )
189
+ }
190
+
150
191
exists_table <- function (conn , id ) {
151
192
name <- id @ name
152
193
stopifnot(" table" %in% names(name ))
@@ -168,6 +209,14 @@ exists_table <- function(conn, id) {
168
209
}
169
210
170
211
list_fields <- function (conn , id ) {
212
+ if (conn @ system_catalogs ) {
213
+ list_fields_from_system_catalog(conn , id )
214
+ } else {
215
+ list_fields_from_info_schema(conn , id )
216
+ }
217
+ }
218
+
219
+ list_fields_from_info_schema <- function (conn , id ) {
171
220
name <- id @ name
172
221
173
222
is_redshift <- is(conn , " RedshiftConnection" )
@@ -185,7 +234,7 @@ list_fields <- function(conn, id) {
185
234
# as there cannot be multiple tables with the same name in a single schema
186
235
only_first <- FALSE
187
236
188
- # or we have to look the table up in the schemas on the search path
237
+ # or we have to look the table up in the schemas on the search path
189
238
} else if (is_redshift ) {
190
239
# A variant of the Postgres version that uses CTEs and generate_series()
191
240
# instead of generate_subscripts(), the latter is not supported on Redshift
@@ -211,10 +260,10 @@ list_fields <- function(conn, id) {
211
260
# How to unnest `current_schemas(true)` array with element number (works since v9.4):
212
261
# https://stackoverflow.com/a/8767450/2114932
213
262
query <- paste0(
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"
263
+ " (" ,
264
+ " SELECT * FROM unnest(current_schemas(true)) WITH ORDINALITY AS tbl(table_schema, nr) \n " ,
265
+ " WHERE table_schema != 'pg_catalog'" ,
266
+ " ) schemas_on_path"
218
267
)
219
268
only_first <- TRUE
220
269
}
@@ -252,6 +301,29 @@ list_fields <- function(conn, id) {
252
301
fields
253
302
}
254
303
304
+ list_fields_from_system_catalog <- function (conn , id ) {
305
+ if (exists_table(conn , id )) {
306
+ # we know from exists_table() that id@name["table"] exists
307
+ # and the user has access priviledges
308
+ tname_str <- stats :: na.omit(id @ name [c(" schema" , " table" )])
309
+ tname_qstr <- dbQuoteString(conn , paste(tname_str , collapse = " ." ))
310
+ # cast to `regclass` resolves the table name according to the current
311
+ # `search_path` https://dba.stackexchange.com/a/75124
312
+ query <-
313
+ paste0(
314
+ " SELECT attname \n " ,
315
+ " FROM pg_attribute \n " ,
316
+ " WHERE attrelid = " , tname_qstr , " ::regclass \n " ,
317
+ " AND attnum > 0 \n " ,
318
+ " AND NOT attisdropped \n " ,
319
+ " ORDER BY attnum;"
320
+ )
321
+ dbGetQuery(conn , query )[[1 ]]
322
+ } else {
323
+ stop(" Table " , dbQuoteIdentifier(conn , id ), " not found." , call. = FALSE )
324
+ }
325
+ }
326
+
255
327
find_temp_schema <- function (conn , fail_if_missing = TRUE ) {
256
328
if (! is.na(connection_get_temp_schema(conn @ ptr )))
257
329
return (connection_get_temp_schema(conn @ ptr ))
0 commit comments