Обсуждение: BUG #17134: pg_restore ERROR: operator does not exist: util.ltree = util.ltree

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

BUG #17134: pg_restore ERROR: operator does not exist: util.ltree = util.ltree

От
PG Bug reporting form
Дата:
The following bug has been logged on the website:

Bug reference:      17134
Logged by:          Vinay Kumar
Email address:      vnykmr36@gmail.com
PostgreSQL version: 13.3
Operating system:   AWS AMI Amazon Linux 2018.03 & RHEL 8
Description:

Hi Team,

We are trying to upgrade one of our database with pg_upgrade --link option.
While upgrade happens we are facing an issue with trigger creation which
uses ltree.

The target version is 13.3 and also some other versions in 12 as well.

[ec2-user@ip-172-31-12-154 tmp]$ psql -V
psql (PostgreSQL) 13.3

postgres=# select version();
                                                version
--------------------------------------------------------------------------------------------------------
 PostgreSQL 13.3 on x86_64-pc-linux-gnu, compiled by gcc (GCC) 7.2.1
20170915 (Red Hat 7.2.1-2), 64-bit
(1 row)

Error observed during pg_upgrade:

pg_restore: error: could not execute query: ERROR:  operator does not exist:
util.ltree = util.ltree
LINE 1: ...ma"."table" FOR EACH ROW WHEN (("new"."path" IS DISTINC...
                                                             ^
HINT:  No operator matches the given name and argument types. You might need
to add explicit type casts.
Command was: CREATE TRIGGER "path_aftr_trg" AFTER UPDATE ON "schema"."table"
FOR EACH ROW WHEN (("new"."path" IS DISTINCT FROM "old"."path")) EXECUTE
PROCEDURE "schema"."_update_path"();

Restoring the dump into another DB also results in similar error:

postgres=# CREATE TRIGGER "path_aftr_trg" AFTER UPDATE ON "schema"."table"
FOR EACH ROW WHEN (("new"."path" IS DISTINCT FROM "old"."path")) EXECUTE
PROCEDURE "schema"."_update_path"();
ERROR:  42883: operator does not exist: util.ltree = util.ltree
LINE 1: ...schema.table FOR EACH ROW WHEN ((new.path IS DISTINC...
                                                             ^
HINT:  No operator matches the given name and argument types. You might need
to add explicit type casts.
LOCATION:  op_error, parse_oper.c:731

Tested above trigger creation in version 11, 12 and 13 but all of them
resulted in failure until search path is set to schema which ends up
successful in creating the trigger.

postgres=# show search_path ;
   search_path
-----------------
 "$user", public
(1 row)

postgres=# set search_path = public, util;
SET

postgres=# show search_path ;
 search_path
--------------
 public, util
(1 row)

Successfully Created:
++++++++++++++++++

postgres=# CREATE TRIGGER "path_aftr_trg" AFTER UPDATE ON "schema"."table"
FOR EACH ROW WHEN (("new"."path" IS DISTINCT FROM "old"."path")) EXECUTE
PROCEDURE "schema"."_update_path"();
CREATE TRIGGER

postgres=# \dx ltree
                        List of installed extensions
 Name  | Version | Schema |                   Description
-------+---------+--------+-------------------------------------------------
 ltree | 1.2     | util   | data type for hierarchical tree-like
structures
(1 row)

A simple test fails as well:

postgres=# \d test
                 Table "public.test"
 Column |    Type    | Collation | Nullable | Default
--------+------------+-----------+----------+---------
 path   | util.ltree |           |          |
Indexes:
    "path_gist_idx" gist (path)
    "path_idx" btree (path)

postgres=# select * from public.test where path='Top';
ERROR:  42883: operator does not exist: util.ltree = unknown
LINE 1: select * from public.test where path='Top';
                                            ^
HINT:  No operator matches the given name and argument types. You might need
to add explicit type casts.
LOCATION:  op_error, parse_oper.c:731

postgres=# set search_path = public, util;
SET
postgres=# select * from public.test where path='Top';
 path
------
 Top
(1 row)

Type casting works but we don't want this and this requires a lot of manual
labor:

postgres=# select * from public.test where path::text='Top';
 path
------
 Top
(1 row)

Any other easy method available to fix this issue with search_path?


Re: BUG #17134: pg_restore ERROR: operator does not exist: util.ltree = util.ltree

От
"David G. Johnston"
Дата:
On Thu, Aug 5, 2021 at 1:49 AM PG Bug reporting form <noreply@postgresql.org> wrote:
Any other easy method available to fix this issue with search_path?

The direct solution here is to rewrite the expression, avoiding "IS DISTINCT FROM":

not("new"."path" operator("util".=) "old"."path") and (coalesce("new"."path", "old"."path") is not null)

This is needed because you need to schema-qualify the location of the = operator which requires using the "operator(...)" syntax.

That said, it might be easier, if less performant, to remove the WHEN condition and place an equivalent expression within the trigger function itself.  If the function is defined with a "SET search_path" clause that should ensure that the function body is evaluated with the "util" schema in the search_path and thus the "util".= operator will be found.

David J.

Re: BUG #17134: pg_restore ERROR: operator does not exist: util.ltree = util.ltree

От
vinay kumar
Дата:
Thanks David for replying back!

Adding search_path has resolved this issue. But the problem is as follows where we won't be able to set search_path:

1> When trying to restore the data into a new DB server.
2> When we do an upgrade.

But as per error message, it could be seen that the ltree type is found in util schema and the operator doesn't exist:

ERROR:  42883: operator does not exist: util.ltree = util.ltree

With in the function, we have below entry for NEW."path" where we provide schema.type:

NEW."path" = util.ltree_pathify(NEW."id"::TEXT)::ltree;

This seems to be a bug with the full path not being discovered or emitting the error even after it's discovered.

On Thu, Aug 5, 2021 at 9:04 PM David G. Johnston <david.g.johnston@gmail.com> wrote:
On Thu, Aug 5, 2021 at 1:49 AM PG Bug reporting form <noreply@postgresql.org> wrote:
Any other easy method available to fix this issue with search_path?

The direct solution here is to rewrite the expression, avoiding "IS DISTINCT FROM":

not("new"."path" operator("util".=) "old"."path") and (coalesce("new"."path", "old"."path") is not null)

This is needed because you need to schema-qualify the location of the = operator which requires using the "operator(...)" syntax.

That said, it might be easier, if less performant, to remove the WHEN condition and place an equivalent expression within the trigger function itself.  If the function is defined with a "SET search_path" clause that should ensure that the function body is evaluated with the "util" schema in the search_path and thus the "util".= operator will be found.

David J.

Re: BUG #17134: pg_restore ERROR: operator does not exist: util.ltree = util.ltree

От
"David G. Johnston"
Дата:
On Thu, Aug 5, 2021 at 9:02 AM vinay kumar <vnykmr36@gmail.com> wrote:
Thanks David for replying back!

Adding search_path has resolved this issue. But the problem is as follows where we won't be able to set search_path:

1> When trying to restore the data into a new DB server.
2> When we do an upgrade.

Right...which is why you cannot rely on setting a search_path but must instead arrange for everything, including the "=" operator, to be schema qualified.


But as per error message, it could be seen that the ltree type is found in util schema and the operator doesn't exist:

The ltree type wasn't "found" - its location is explicitly known to the system because the recorded data type for that column (in pg_attribute.atttype) includes an explicit schema location (in the related pg_type table).  So the system sees "util.ltree" as opposed to "search_path=util; ltree".

The problem here is that "IS DISTINCT FROM" doesn't have any syntax for schema qualification and so the stored representation of your expression is impossible to record in a search_path agnostic way, unlike the create table example above.  "NEW" is just a composite type of that table and thus has the same absolute references for the data types that comprise it.  Hence my ewrite suggestion that allows you to write "operator(util.=)" in the stored expression thus providing a place for the schema qualification to exist (if you just write = there the system might do the operator rewrite for you in order to account for this dynamic.


With in the function, we have below entry for NEW."path" where we provide schema.type:

NEW."path" = util.ltree_pathify(NEW."id"::TEXT)::ltree;

The cast to ltree there is unsafe, it needs to be "::util.ltree" (unless the function itself is defined with util in the search_path).


This seems to be a bug with the full path not being discovered or emitting the error even after it's discovered.

This is not a bug - it is a side-effect of a security related implementation choice.



On Thu, Aug 5, 2021 at 9:04 PM David G. Johnston <david.g.johnston@gmail.com> wrote:
On Thu, Aug 5, 2021 at 1:49 AM PG Bug reporting form <noreply@postgresql.org> wrote:

The convention on these lists is to inline reply (or bottom at least), while trimming liberally.

David J.