Re[2]: PG 14.5 -- Impossible to restore dump due to interaction/order of views, functions, and generated columns

From: "Nunya Business" <nb3425586(at)gmail(dot)com>
To: "Tom Lane" <tgl(at)sss(dot)pgh(dot)pa(dot)us>
Cc: pgsql-general(at)postgresql(dot)org, pgsql-bugs(at)postgresql(dot)org
Subject: Re[2]: PG 14.5 -- Impossible to restore dump due to interaction/order of views, functions, and generated columns
Date: 2022-12-06 18:19:36
Message-ID: emd5c018bd-ee54-4ca6-b61d-741ad84aa451@81da44b0.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-bugs pgsql-general

>"Nunya Business" <nb3425586(at)gmail(dot)com> writes:
>>Within my schema there is a table that has a GENERATED ALWAYS column that calls a plpgsql function. The called function has a "row type" variable declared that references a view. While the schema itself functions properly day to day, and pg_dumpall works as expected, the generated SQL fails to successfully execute. The table in question is restored with no rows, and an error is generated during the COPY stating that the type does not exist.
>
>Hmm, do you have actually circular dependencies in that? pg_dump has
>some heuristics for dealing with such cases, but maybe it needs more.
>Please create a self-contained example and submit it to pgsql-bugs.
>
> regards, tom lane

Thanks Tom. There are indeed circular references in the schema and the
whole thing sort of doesn't pass the smell test, but this is my first
look at it. The generated column on the table calls a function which
selects from a view that references the table. The production schema
where I ran into this is pretty large and complex, so the contrived
example that follows may not be the minimum working example but it's
pretty small and has the same behavior regarding the SQL generated by
pg_dumpall.

It seems that the schema is probably invalid according to the GENERATED
rules and that pg_dumpall is operating as intended, but somehow the
check in the ALTER TABLE isn't deep enough to prevent the issue, but
maybe I'm mistaken. Once this is created, if you insert a few rows and
execute pg_dumpall, the resulting SQL cannot be loaded and will fail
during the COPY, complaining that the view referenced by the function
doesn't exist.

Here is the schema. CCing pgsql-bugs as requested.

--------------------------CUT
CREATE TABLE tblA (
id serial unique not null,
dt timestamp with time zone not null default now(),
data text
);

CREATE OR REPLACE VIEW viewA as (
SELECT sum(id) FROM tblA
);

CREATE OR REPLACE FUNCTION fnA(askid INTEGER) RETURNS integer
LANGUAGE 'plpgsql' IMMUTABLE
AS $$

declare
varA viewA;
ret integer;

begin
SELECT viewA.*
INTO varA
FROM viewA;

ret = varA.sum;

return ret;
end;
$$;

ALTER TABLE tblA ADD COLUMN idsum INTEGER GENERATED ALWAYS AS (fnA(id))
STORED;

In response to

Responses

Browse pgsql-bugs by date

  From Date Subject
Next Message Tom Lane 2022-12-06 20:47:26 Re: Re[2]: PG 14.5 -- Impossible to restore dump due to interaction/order of views, functions, and generated columns
Previous Message Adrian Klaver 2022-12-06 15:51:51 Re: PG 14.5 -- Impossible to restore dump due to interaction/order of views, functions, and generated columns

Browse pgsql-general by date

  From Date Subject
Next Message vignesh C 2022-12-06 18:52:29 Re: Support logical replication of DDLs
Previous Message Jeremy Finzel 2022-12-06 16:24:34 Suboptimal GIST index?