Thread: postgres_fdw error
Adam Fuchs
Database Administrator
UC Berkeley - Information Services & Technology
2195 Hearst Ave., Berkeley, CA 94120
510-664-4354
If not, have you checked the search_path used when the FDW connects to the remote server?
-- Korry
I am struggling with a FDW between two 9.4.3 postgres databases.I am refering to the remote db as the source and the db with the fdw as the target.The connected user has the ability to query the source table on the source db successfully so I am assuming all the required grants are there.When querying from the target system, I get a "relation does not exist" error.The hitch is that the source table is actually a view that calls other views, which in turn contain functions. When I used a basic table on the target the fdw worked without error.config:source:select current_user;current_user--------------piction_ro(1 row)piction_ro@bampfa_domain_bampfa> select count(*) from piction.bampfa_metadata_v;count-------21309(1 row)target:List of foreign servers-[ RECORD 1 ]--------+-------------------------------------------------------------------------Name | bampfa_dev_serverOwner | postgres51Foreign-data wrapper | postgres_fdwAccess privileges |Type |Version |FDW Options | (host 'source_host', port 'XXXX', dbname 'bampfa_domain_bampfa')Description |List of user mappings-[ RECORD 1 ]--------------------------------------------Server | bampfa_dev_serverUser name | pictionFDW Options | ("user" 'piction_ro', password '***')List of foreign tables-[ RECORD 1 ]--------------------------------------------------------Schema | pictionTable | bampfa_metadata_fvServer | bampfa_dev_serverFDW Options | (schema_name 'piction', table_name 'bampfa_metadata_v')Description |piction@piction_transit> select * from piction.bampfa_metadata_fv limit 4;ERROR: relation "collectionobjects_common" does not existCONTEXT: Remote SQL command: SELECT objectcsid, idnumber, sortobjectnumber, artistcalc, artistorigin, title, datemade, site, itemclass, materials, measurement, fullbampfacreditline, copyrightcredit, photocredit, subjects, collections, periodstyles, artistdates, caption, tags, permissiontoreproduce, acquisitionsource, legalstatus, updatedat FROM piction.bampfa_metadata_vPL/pgSQL function utils.concat_artists(character varying) line 7 at SQL statementBut if we are on the source as the mapped user, we can select from the table in question:piction_ro@bampfa_domain_bampfa> select * from collectionobjects_common limit 2;-[ RECORD 1 ]------------------+---------------------------------------------------------------------------------------------------------------------------------id | 2d40e6eb-a4f7-402b-ab06-f3fb57fb6e5dassoceventnametype |ownershipcategory |fieldcollectionnote |ownershipplace |...We can also execute the function in the source view:piction_ro@bampfa_domain_bampfa> select utils.concat_artists('foo');-[ RECORD 1 ]--+-concat_artists |\df+ utils.concat_artistsList of functions-[ RECORD 1 ]-------+----------------------------------------------------------------------------------------Schema | utilsName | concat_artistsResult data type | character varyingArgument data types | csid character varyingType | normalSecurity | invokerVolatility | immutableOwner | nuxeo_bampfaLanguage | plpgsqlAny help would be much appreciated, I am thinking it could have something to do with the complexity of the base view, or perhaps fdw gets confused if the source is a view and not an actual table, but I would think the query should act just as the mapped user on the source system.Adam--Adam Fuchs
Database Administrator
UC Berkeley - Information Services & Technology
2195 Hearst Ave., Berkeley, CA 94120
510-664-4354
Are all references schema-qualified?
If not, have you checked the search_path used when the FDW connects to the remote server?
-- KorryI am struggling with a FDW between two 9.4.3 postgres databases.I am refering to the remote db as the source and the db with the fdw as the target.The connected user has the ability to query the source table on the source db successfully so I am assuming all the required grants are there.When querying from the target system, I get a "relation does not exist" error.The hitch is that the source table is actually a view that calls other views, which in turn contain functions. When I used a basic table on the target the fdw worked without error.config:source:select current_user;current_user--------------piction_ro(1 row)piction_ro@bampfa_domain_bampfa> select count(*) from piction.bampfa_metadata_v;count-------21309(1 row)target:List of foreign servers-[ RECORD 1 ]--------+-------------------------------------------------------------------------Name | bampfa_dev_serverOwner | postgres51Foreign-data wrapper | postgres_fdwAccess privileges |Type |Version |FDW Options | (host 'source_host', port 'XXXX', dbname 'bampfa_domain_bampfa')Description |List of user mappings-[ RECORD 1 ]--------------------------------------------Server | bampfa_dev_serverUser name | pictionFDW Options | ("user" 'piction_ro', password '***')List of foreign tables-[ RECORD 1 ]--------------------------------------------------------Schema | pictionTable | bampfa_metadata_fvServer | bampfa_dev_serverFDW Options | (schema_name 'piction', table_name 'bampfa_metadata_v')Description |piction@piction_transit> select * from piction.bampfa_metadata_fv limit 4;ERROR: relation "collectionobjects_common" does not existCONTEXT: Remote SQL command: SELECT objectcsid, idnumber, sortobjectnumber, artistcalc, artistorigin, title, datemade, site, itemclass, materials, measurement, fullbampfacreditline, copyrightcredit, photocredit, subjects, collections, periodstyles, artistdates, caption, tags, permissiontoreproduce, acquisitionsource, legalstatus, updatedat FROM piction.bampfa_metadata_vPL/pgSQL function utils.concat_artists(character varying) line 7 at SQL statementBut if we are on the source as the mapped user, we can select from the table in question:piction_ro@bampfa_domain_bampfa> select * from collectionobjects_common limit 2;-[ RECORD 1 ]------------------+---------------------------------------------------------------------------------------------------------------------------------id | 2d40e6eb-a4f7-402b-ab06-f3fb57fb6e5dassoceventnametype |ownershipcategory |fieldcollectionnote |ownershipplace |...We can also execute the function in the source view:piction_ro@bampfa_domain_bampfa> select utils.concat_artists('foo');-[ RECORD 1 ]--+-concat_artists |\df+ utils.concat_artistsList of functions-[ RECORD 1 ]-------+----------------------------------------------------------------------------------------Schema | utilsName | concat_artistsResult data type | character varyingArgument data types | csid character varyingType | normalSecurity | invokerVolatility | immutableOwner | nuxeo_bampfaLanguage | plpgsqlAny help would be much appreciated, I am thinking it could have something to do with the complexity of the base view, or perhaps fdw gets confused if the source is a view and not an actual table, but I would think the query should act just as the mapped user on the source system.Adam--Adam Fuchs
Database Administrator
UC Berkeley - Information Services & Technology
2195 Hearst Ave., Berkeley, CA 94120
Adam Fuchs
Database Administrator
UC Berkeley - Information Services & Technology
2195 Hearst Ave., Berkeley, CA 94120
510-664-4354
Adam FUCHS <atman@berkeley.edu> writes: > Thanks Korry, how would I check the search_path that is being used by the > FDW user? postgres_fdw always does "SET search_path = pg_catalog" when opening the connection. Probably this needs to be documented, since it's user-visible if you try to attach a foreign table to a remote view. Anyway the short answer is that you should fully schema-qualify references in functions used by such a view, or else attach "SET search_path" options to the functions. regards, tom lane
Adam FUCHS <atman@berkeley.edu> writes:
> Thanks Korry, how would I check the search_path that is being used by the
> FDW user?
postgres_fdw always does "SET search_path = pg_catalog" when opening the
connection. Probably this needs to be documented, since it's user-visible
if you try to attach a foreign table to a remote view.
Anyway the short answer is that you should fully schema-qualify references
in functions used by such a view, or else attach "SET search_path" options
to the functions.
regards, tom lane
Adam Fuchs
Database Administrator
UC Berkeley - Information Services & Technology
2195 Hearst Ave., Berkeley, CA 94120
510-664-4354
Adam FUCHS <atman@berkeley.edu> writes: > In case this breaks stuff, what is the default search_path for functions if > they are created without one set explicitly? Ordinarily a function just runs with whatever search_path is active when it's called. regards, tom lane
Adam FUCHS <atman@berkeley.edu> writes:
> In case this breaks stuff, what is the default search_path for functions if
> they are created without one set explicitly?
Ordinarily a function just runs with whatever search_path is active
when it's called.
regards, tom lane
Adam Fuchs
Database Administrator
UC Berkeley - Information Services & Technology
2195 Hearst Ave., Berkeley, CA 94120
510-664-4354