Обсуждение: pg_upgrade failure due to dependencies

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

pg_upgrade failure due to dependencies

От
Nikhil Shetty
Дата:
Hi Team,

I was trying an upgrade from PostgreSQL 13 and PostGIS 3.1.2 TO PostgreSQL 15 and PostGIS 3.4.2 and got below error

pg_restore: creating TABLE "table1"
pg_restore: while PROCESSING TOC:
pg_restore: from TOC entry 551; 1259 39789310 TABLE table1 db1
pg_restore: error: could not execute query: ERROR: relation "public.spatial_ref_sys" does not exist
LINE 1: ...LECT proj4text, auth_name, auth_srid, srtext FROM public.spa...
^
QUERY: SELECT proj4text, auth_name, auth_srid, srtext FROM public.spatial_ref_sys WHERE srid = 3857 LIMIT 1
Command was:


Table Structure

CREATE TABLE table1 (
"id1" numeric NOT NULL,
"geom" "public"."geometry"(Geometry,4326),
"geom_3857" "public"."geometry"(Geometry,3857) GENERATED ALWAYS AS ("public"."st_transform"("public"."st_intersection"("geom", "public"."st_transform"("public"."st_tileenvelope"(0, 0, 0), 4326)), 3857)) STORED
);

The st_transform function used in above table definition uses public.spatial_ref_sys to check the SRID but since public.spatial_ref_sys is not restored yet, the table creation for table1 fails

I checked with the PostGIS community and they suggested this needs to be fixed in pg_upgrade because it is not checking the dependencies in this particular case. Even if it restores public.spatial_ref_sys first, another problem here is that it is checking for a record in the 'public.spatial_ref_sys' table which does not exist and would be populated during the upgrade link.

I am adding this in the community to check if there is a way to fix this kind of problem during upgrade?

Thanks,
Nikhil



Re: pg_upgrade failure due to dependencies

От
Laurenz Albe
Дата:
On Tue, 2025-07-01 at 11:23 +0530, Nikhil Shetty wrote:
> I was trying an upgrade from PostgreSQL 13 and PostGIS 3.1.2 TO PostgreSQL 15 and PostGIS 3.4.2 and got below error
>
> pg_restore: creating TABLE "table1"
> pg_restore: while PROCESSING TOC:
> pg_restore: from TOC entry 551; 1259 39789310 TABLE table1 db1
> pg_restore: error: could not execute query: ERROR:  relation "public.spatial_ref_sys" does not exist
> LINE 1: ...LECT proj4text, auth_name, auth_srid, srtext FROM public.spa...
>                                                              ^
> QUERY:  SELECT proj4text, auth_name, auth_srid, srtext FROM public.spatial_ref_sys WHERE srid = 3857 LIMIT 1
> Command was:
>
>
> Table Structure
>
> CREATE TABLE table1 (
>     "id1" numeric NOT NULL,
>     "geom" "public"."geometry"(Geometry,4326),
>     "geom_3857" "public"."geometry"(Geometry,3857) GENERATED ALWAYS AS
("public"."st_transform"("public"."st_intersection"("geom","public"."st_transform"("public"."st_tileenvelope"(0, 0, 0),
4326)),3857)) STORED 
> );
>
> The st_transform function used in above table definition uses public.spatial_ref_sys to check the SRID
> but since public.spatial_ref_sys is not restored yet, the table creation for table1 fails
>
> I checked with the PostGIS community and they suggested this needs to be fixed in pg_upgrade because
> it is not checking the dependencies in this particular case. Even if it restores public.spatial_ref_sys
> first, another problem here is that it is checking for a record in the 'public.spatial_ref_sys' table
> which does not exist and would be populated during the upgrade link.
>
> I am adding this in the community to check if there is a way to fix this kind of problem during upgrade?

The PostGIS people must be misinformed.
The fault is clearly theirs for marking the function st_transform(geometry, text, integer) as IMMUTABLE:

  \sf st_transform(geometry, text, integer)

  CREATE OR REPLACE FUNCTION public.st_transform(geom geometry, from_proj text, to_srid integer)
   RETURNS geometry
   LANGUAGE sql
   IMMUTABLE PARALLEL SAFE STRICT COST 5000
  AS $function$SELECT public.postgis_transform_geometry($1, $2, proj4text, $3)
    FROM public.spatial_ref_sys WHERE srid=$3;$function$

Anything that selects from a table may not be marked IMMUTABLE, since the contents of the table
can change.  In your case, the table did not even exist.
Moreover, PostgreSQL cannot check dependencies, since the function was defined using the "old"
style for SQL functions, where the function body is just a string.  If they had used the standard
conforming new style, PostgreSQL would try to trach dependencies.  Not sure if that would have been
enough to avoid the problem, but clearly better.

Did you open a bug report on https://trac.osgeo.org/postgis ?

Yours,
Laurenz Albe



Re: pg_upgrade failure due to dependencies

От
Tom Lane
Дата:
Laurenz Albe <laurenz.albe@cybertec.at> writes:
> On Tue, 2025-07-01 at 11:23 +0530, Nikhil Shetty wrote:
>> I was trying an upgrade from PostgreSQL 13 and PostGIS 3.1.2 TO PostgreSQL 15 and PostGIS 3.4.2 and got below error
>> pg_restore: error: could not execute query: ERROR:  relation "public.spatial_ref_sys" does not exist
>> LINE 1: ...LECT proj4text, auth_name, auth_srid, srtext FROM public.spa...
>>                                                              ^
>> QUERY:  SELECT proj4text, auth_name, auth_srid, srtext FROM public.spatial_ref_sys WHERE srid = 3857 LIMIT 1

> The PostGIS people must be misinformed.
> The fault is clearly theirs for marking the function st_transform(geometry, text, integer) as IMMUTABLE:

That's clearly pretty risky, but I don't understand the context here.
pg_dump always restores extensions first.  Surely both this function
and the spatial_ref_sys table would be created by the PostGIS
extension(s)?

            regards, tom lane



Re: pg_upgrade failure due to dependencies

От
Nikhil Shetty
Дата:
Yes both the extension and function are created by the extension but when restoring, extension and associated functions or tables are created separately and in different order .

Extension (postgis)

grep -wn postgis dbdump.list 

----------------------------------------

80:7; 3079 42851433 EXTENSION - postgis 

81:7870; 0 0 COMMENT - EXTENSION "postgis" 



Function (st_transform) used by Extension


grep -wn st_transform dbdump.list

----------------------------------------

2180:984; 1255 42851770 FUNCTION public st_transform("public"."geometry", integer) postgres

2181:8593; 0 0 COMMENT public FUNCTION "st_transform"("public"."geometry", integer) postgres

2182:985; 1255 42851771 FUNCTION public st_transform("public"."geometry", "text") postgres



Table (spatial_ref_sys) used by Extension


grep -wn spatial_ref_sys dbdump.list

----------------------------------------

3373:541; 1259 42851740 TABLE public spatial_ref_sys postgres

3374:9127; 0 0 ACL public TABLE "spatial_ref_syspostgres


Table that uses the extension table 


grep -wn table1 dbdump.list

----------------------------------------

3183:516; 1259 39789310 TABLE grand table1 db1

3184:9020; 0 0 ACL grand TABLE "table1" db1


As seen above from the line number (in green), 'table1' is created earlier than table 'spatial_ref_sys' and it fails to create because of dependency.


As suggested by Jeevan in a separate thread, I tried to add this dependency in pg_depend but the restore from pg_upgrade still fails because the table 'spatial_ref_sys' will be empty.


Workaround in pg_depend:


INSERT INTO pg_depend VALUES (
'pg_catalog.pg_type'::regclass::oid, 'public.geometry'::regtype::oid, 0,
'pg_catalog.pg_class'::regclass::oid, 'public.spatial_ref_sys'::regclass::oid, 0,
'n');

Error:


pg_restore: from TOC entry 231; 1259 64892012 TABLE table1 postgres

pg_restore: error: could not execute query: ERROR:  Cannot find SRID (3857) in spatial_ref_sys



Thanks,

Nikhil


On Tue, Jul 1, 2025 at 9:00 PM Tom Lane <tgl@sss.pgh.pa.us> wrote:
Laurenz Albe <laurenz.albe@cybertec.at> writes:
> On Tue, 2025-07-01 at 11:23 +0530, Nikhil Shetty wrote:
>> I was trying an upgrade from PostgreSQL 13 and PostGIS 3.1.2 TO PostgreSQL 15 and PostGIS 3.4.2 and got below error
>> pg_restore: error: could not execute query: ERROR:  relation "public.spatial_ref_sys" does not exist
>> LINE 1: ...LECT proj4text, auth_name, auth_srid, srtext FROM public.spa...
>>                                                              ^
>> QUERY:  SELECT proj4text, auth_name, auth_srid, srtext FROM public.spatial_ref_sys WHERE srid = 3857 LIMIT 1

> The PostGIS people must be misinformed.
> The fault is clearly theirs for marking the function st_transform(geometry, text, integer) as IMMUTABLE:

That's clearly pretty risky, but I don't understand the context here.
pg_dump always restores extensions first.  Surely both this function
and the spatial_ref_sys table would be created by the PostGIS
extension(s)?

                        regards, tom lane

Re: pg_upgrade failure due to dependencies

От
Nikhil Shetty
Дата:
We have not reported a bug but we have asked this in postgis mailing list, since they suggested checking if this can be fixed in pg_upgrade, I posted here.

On Tue, Jul 1, 2025 at 3:07 PM Laurenz Albe <laurenz.albe@cybertec.at> wrote:
On Tue, 2025-07-01 at 11:23 +0530, Nikhil Shetty wrote:
> I was trying an upgrade from PostgreSQL 13 and PostGIS 3.1.2 TO PostgreSQL 15 and PostGIS 3.4.2 and got below error
>
> pg_restore: creating TABLE "table1"
> pg_restore: while PROCESSING TOC:
> pg_restore: from TOC entry 551; 1259 39789310 TABLE table1 db1
> pg_restore: error: could not execute query: ERROR:  relation "public.spatial_ref_sys" does not exist
> LINE 1: ...LECT proj4text, auth_name, auth_srid, srtext FROM public.spa...
>                                                              ^
> QUERY:  SELECT proj4text, auth_name, auth_srid, srtext FROM public.spatial_ref_sys WHERE srid = 3857 LIMIT 1
> Command was:
>
>
> Table Structure
>
> CREATE TABLE table1 (
>     "id1" numeric NOT NULL,
>     "geom" "public"."geometry"(Geometry,4326),
>     "geom_3857" "public"."geometry"(Geometry,3857) GENERATED ALWAYS AS ("public"."st_transform"("public"."st_intersection"("geom", "public"."st_transform"("public"."st_tileenvelope"(0, 0, 0), 4326)), 3857)) STORED
> );
>
> The st_transform function used in above table definition uses public.spatial_ref_sys to check the SRID
> but since public.spatial_ref_sys is not restored yet, the table creation for table1 fails
>
> I checked with the PostGIS community and they suggested this needs to be fixed in pg_upgrade because
> it is not checking the dependencies in this particular case. Even if it restores public.spatial_ref_sys
> first, another problem here is that it is checking for a record in the 'public.spatial_ref_sys' table
> which does not exist and would be populated during the upgrade link.
>
> I am adding this in the community to check if there is a way to fix this kind of problem during upgrade?

The PostGIS people must be misinformed.
The fault is clearly theirs for marking the function st_transform(geometry, text, integer) as IMMUTABLE:

  \sf st_transform(geometry, text, integer)

  CREATE OR REPLACE FUNCTION public.st_transform(geom geometry, from_proj text, to_srid integer)
   RETURNS geometry
   LANGUAGE sql
   IMMUTABLE PARALLEL SAFE STRICT COST 5000
  AS $function$SELECT public.postgis_transform_geometry($1, $2, proj4text, $3)
        FROM public.spatial_ref_sys WHERE srid=$3;$function$

Anything that selects from a table may not be marked IMMUTABLE, since the contents of the table
can change.  In your case, the table did not even exist.
Moreover, PostgreSQL cannot check dependencies, since the function was defined using the "old"
style for SQL functions, where the function body is just a string.  If they had used the standard
conforming new style, PostgreSQL would try to trach dependencies.  Not sure if that would have been
enough to avoid the problem, but clearly better.

Did you open a bug report on https://trac.osgeo.org/postgis ?

Yours,
Laurenz Albe

Re: pg_upgrade failure due to dependencies

От
Tom Lane
Дата:
Nikhil Shetty <nikhil.dba04@gmail.com> writes:
> Yes both the extension and function are created by the extension but when
> restoring, extension and associated functions or tables are created
> separately and in different order .

Ah, right, I'd momentarily forgotten that binary-upgrade mode dumps
the extensions' contents as separate objects.

I think that switching the function(s) to new-style syntax, as already
mentioned, might get you pretty far.  It'd be enough for pg_dump to get
the function-vs-spatial_ref_sys-existence ordering right at least.
What it will not do is ensure that the *contents* of spatial_ref_sys
are restored early.  But I'm not sure that that's fatal in a
binary-upgrade situation, because we're not dumping/restoring data:
the tables' disk files are just moved verbatim.  There might still be
some edge cases that fail, but I think basic scenarios ought to work.

            regards, tom lane



Re: pg_upgrade failure due to dependencies

От
Laurenz Albe
Дата:
On Tue, 2025-07-01 at 07:10 -0400, Edward J. Sabol wrote:
> On Jul 1, 2025, at 5:37 AM, Laurenz Albe <laurenz.albe@cybertec.at> wrote:
> > Moreover, PostgreSQL cannot check dependencies, since the function was defined using
> > the "old" style for SQL functions, where the function body is just a string.
> > If they had used the standard conforming new style, PostgreSQL would try to trach
> > dependencies.  Not sure if that would have been enough to avoid the problem,
> > but clearly better.
>
> Just for my edification, how would one create that PostGIS function using the
> "standard-conforming new style"?

CREATE FUNCTION public.st_transform(geom geometry, from_proj text, to_srid integer)
 RETURNS geometry
 IMMUTABLE PARALLEL SAFE STRICT COST 5000
BEGIN ATOMIC
   SELECT public.postgis_transform_geometry($1, $2, proj4text, $3)
   FROM public.spatial_ref_sys WHERE srid=$3;
END;

(The IMMUTABLE would still be a lie, though.)

> *All* of the examples in PostgeSQL's current documentation are the "old" (string)
> style at https://www.postgresql.org/docs/18/xfunc-sql.html.
>
> The only example of the new style in the PostgreSQL documentation that I could
> find is the very trivial second example at
> https://www.postgresql.org/docs/18/sql-createfunction.html. The other examples
> on that web page are all the old style.
>
> If the new style is better, perhaps someone should update the PostgreSQL
> documentation to use it more than just once. More complicated examples of
> "new style" SQL functions are needed, I feel.

That is true; we could do more there.

Yours,
Laurenz Albe