Обсуждение: pg_restore & search_path, COPY failed for table "mytable": ERROR: function myinnerfunction(integer) does not exist

Поиск
Список
Период
Сортировка
Hi,

The following steps reproduce an error with pg_restore:

DROP TABLE IF EXISTS myTable;
DROP FUNCTION IF EXISTS myInnerFunction(INTEGER);
DROP FUNCTION IF EXISTS myOuterFunction(INTEGER);
DROP SCHEMA IF EXISTS myOtherSchema;

CREATE SCHEMA myOtherSchema;

SET search_path = myPrimarySchema, myOtherSchema, public;

CREATE OR REPLACE FUNCTION myOtherSchema.myInnerFunction(INTEGER) RETURNS
boolean   LANGUAGE sql IMMUTABLE STRICT   AS $$SELECT TRUE;
$$;

CREATE OR REPLACE FUNCTION myOuterFunction(INTEGER) RETURNS boolean   LANGUAGE sql IMMUTABLE STRICT   AS $$SELECT
myInnerFunction($1);
$$;

CREATE TABLE myTable( mycol INTEGER, CONSTRAINT MyConstraint CHECK (myOuterFunction(mycol))
);

INSERT INTO myTable VALUES (1);


Do a pg_dump of myTable.

Doing a pg_restore, throws:
COPY failed for table "mytable": ERROR:  function myinnerfunction(integer)
does not exist
LINE 2:  SELECT myInnerFunction($1);               ^
HINT:  No function matches the given name and argument types. You might
need to add explicit type casts.
QUERY:SELECT myInnerFunction($1);
CONTEXT:  SQL function "myouterfunction" during inlining


Using pg_dump plain on myTable shows that search_path is set to
myPrimarySchema, pg_catalog, so is missing myOtherSchema.

I'm puzzled as to how search_path should be used,.
Should all references be schema qualified inside functions body ?
Or is search_path safe except in the body of functions used in index or
constraints ?

That's with version 9.5.3 & 9.6 beta 3.

Thanks,
Jean-Pierre Pelletier



On Thu, Jul 21, 2016 at 1:57 PM, Jean-Pierre Pelletier <jppelletier@e-djuster.com> wrote:

I'm puzzled as to how search_path should be used,.
Should all references be schema qualified inside functions body ?

​Pretty much...you can also do:

CREATE FUNCTION funcname()
SET search_path TO 'other_schemas_needed_by_this_function'
AS $$
[...]
$$​

​You don't have to specify the schema the function is going to reside in...but there is exposure if you don't.​

Or is search_path safe except in the body of functions used in index or
constraints ?

​pg_dump/pg_restore tends to be very conservative in setting search_path.  I'd say you are safe if you can successfully dump/restore and unsafe if you cannot.

​Cross-schema dependencies can be problematic and if you are not willing to test that your omissions are immaterial I'd say you should take the paranoid route an schema-prefix everything - either explicitly or by taking advantage of attribute setting options for functions.

Views, materialized and otherwise, are other areas commonly affected by lax schema specifications.

David J.