@@ -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+ 
123150exists_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 " conn , id ), "  not found." call.  =  FALSE )
250+   }
251+ 
252+   fields 
189253}
190254
191255find_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 " conn , name ), "  not found." call.  =  FALSE )
230-   }
231-   fields 
232- }
0 commit comments