Lists: | pgsql-bugs |
---|
From: | PG Bug reporting form <noreply(at)postgresql(dot)org> |
---|---|
To: | pgsql-bugs(at)lists(dot)postgresql(dot)org |
Cc: | kmanh999(at)gmail(dot)com |
Subject: | BUG #17439: DROP FUNCTION functionName(); drops associated generated column without using CASCADE |
Date: | 2022-03-15 15:11:17 |
Message-ID: | [email protected] |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Lists: | pgsql-bugs |
The following bug has been logged on the website:
Bug reference: 17439
Logged by: Kevin Humphreys
Email address: kmanh999(at)gmail(dot)com
PostgreSQL version: 13.3
Operating system: docker linux
Description:
We have the following DDL
create table schemaA.building
(
id integer default
nextval('layer0_data.instance_id_seq'::regclass) not null
primary key
unique,
serial_number text,
name text
not null,
geometry geometry(Geometry, 4326)
constraint geom_check
check (geometrytype(geometry) = ANY (ARRAY ['POLYGON'::text,
'MULTIPOLYGON'::text, 'POINT'::text])),
feature_id integer
unique
references route.feature
on update restrict on delete restrict,
type text
not null
references layer0_enum.building_type
on update restrict on delete restrict,
ownership text
not null
references layer0_enum.building_ownership
on update restrict on delete restrict,
height numeric default 0
not null,
length numeric default 0
not null,
width numeric default 0
not null,
import_info text,
altname text,
iversion text,
area double precision generated always as (map.area(geometry))
stored
);
If I execute `DROP FUNCTION IF EXISTS map.area(geometry)`, it should error
out saying it is depended on by building.area. However, instead it
successfully drops map.area(geometry) and also drops the building.area
column. According to the documentation, RESTRICT is the default so it should
refuse to drop instead of dropping the column unless I explicitly call DROP
using CASCADE.
From: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
---|---|
To: | kmanh999(at)gmail(dot)com |
Cc: | Peter Eisentraut <peter(dot)eisentraut(at)enterprisedb(dot)com>, pgsql-bugs(at)lists(dot)postgresql(dot)org |
Subject: | Re: BUG #17439: DROP FUNCTION functionName(); drops associated generated column without using CASCADE |
Date: | 2022-03-15 18:33:20 |
Message-ID: | [email protected] |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Lists: | pgsql-bugs |
PG Bug reporting form <noreply(at)postgresql(dot)org> writes:
> We have the following DDL
> ...
> area double precision generated always as (map.area(geometry)) stored
> If I execute `DROP FUNCTION IF EXISTS map.area(geometry)`, it should error
> out saying it is depended on by building.area. However, instead it
> successfully drops map.area(geometry) and also drops the building.area
> column.
Yeah. I think this might be intentional, but it's surely a POLA
violation. To reproduce:
regression=# create function foo(int) returns int as 'select $1+1' language sql immutable;
CREATE FUNCTION
regression=# create table bar (x int, y int generated always as (foo(x)) stored);
CREATE TABLE
regression=# select pg_describe_object(classid,objid,objsubid) as obj, pg_describe_object(refclassid,refobjid,refobjsubid) as ref, deptype from pg_depend where objid > ...;
obj | ref | deptype
-----------------------------------------+------------------------------------+---------
function foo(integer) | transform for integer language sql | n
function foo(integer) | schema public | n
type bar | table bar | i
type bar[] | type bar | i
table bar | schema public | n
default value for column y of table bar | column y of table bar | a
column y of table bar | column x of table bar | a
column y of table bar | function foo(integer) | a
(8 rows)
So the dependencies of the generation expression have been attached
to the column itself with 'a' (automatic) deptype, which explains
the behavior. But is that actually sensible? I think 'n' deptype
would provide the semantics that one would expect. Maybe there is
something in the SQL spec motivating references to other columns of
the same table to be handled this way, but surely that's not sane
for references to anything else.
It also seems dubious for the default -> column deptype to be 'a'
rather than 'i' for a GENERATED column. I see that we have some
special-case code that prevents a direct drop:
regression=# alter table bar alter column y drop default;
ERROR: column "y" of relation "bar" is a generated column
HINT: Use ALTER TABLE ... ALTER COLUMN ... DROP EXPRESSION instead.
but I don't have a lot of faith that that covers all possible
code paths. An 'i' dependency would make it much harder to
screw this up.
regards, tom lane
From: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
---|---|
To: | Peter Eisentraut <peter(dot)eisentraut(at)enterprisedb(dot)com> |
Cc: | kmanh999(at)gmail(dot)com, pgsql-bugs(at)lists(dot)postgresql(dot)org |
Subject: | Re: BUG #17439: DROP FUNCTION functionName(); drops associated generated column without using CASCADE |
Date: | 2022-03-15 20:06:17 |
Message-ID: | [email protected] |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Lists: | pgsql-bugs |
I wrote:
> So the dependencies of the generation expression have been attached
> to the column itself with 'a' (automatic) deptype, which explains
> the behavior. But is that actually sensible? I think 'n' deptype
> would provide the semantics that one would expect. Maybe there is
> something in the SQL spec motivating references to other columns of
> the same table to be handled this way, but surely that's not sane
> for references to anything else.
I looked into SQL:2021, and AFAICS the existing behavior is flat wrong,
even for cross references to other table columns. I think you read
11.23 <drop column definition> general rule 3, which seems to say to
unconditionally drop any generated column depending on the target column
... but you missed syntax rule 7f, which says
7) If RESTRICT is specified, then C shall not be referenced in any of the
following:
...
f) The generation expression of any column descriptor.
GR3 would be very strange if read in isolation anyway, because it
says to drop the generated column with CASCADE, which could cause
arbitrary stuff to go away. That is sensible if you know that 7f
prevents us from getting here unless the original drop said CASCADE,
but otherwise it's a pretty astonishing thing.
So it looks to me like the generation expression's dependencies
should be NORMAL not AUTO in all cases. I'm less sure about
whether to mess with any other aspects of the dependency linkages.
That might not be something to fool with in back branches, anyway.
regards, tom lane
From: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
---|---|
To: | Peter Eisentraut <peter(dot)eisentraut(at)enterprisedb(dot)com> |
Cc: | kmanh999(at)gmail(dot)com, pgsql-bugs(at)lists(dot)postgresql(dot)org |
Subject: | Re: BUG #17439: DROP FUNCTION functionName(); drops associated generated column without using CASCADE |
Date: | 2022-03-15 21:18:55 |
Message-ID: | [email protected] |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Lists: | pgsql-bugs |
I wrote:
> So it looks to me like the generation expression's dependencies
> should be NORMAL not AUTO in all cases. I'm less sure about
> whether to mess with any other aspects of the dependency linkages.
> That might not be something to fool with in back branches, anyway.
Ugh ... this opens a much larger can of worms than I thought.
There are two problems:
1. If these dependencies are NORMAL, then we cannot tell them apart from
the column's other dependencies -- such as the ones on its type and
collation. (The generation expression could easily have dependencies on
types and collations.) I think we really have to switch them so that
the referencing object is the pg_attrdef entry not the column itself,
just as is done for ordinary defaults. That's easy so far as
StoreAttrDefault itself is concerned, but ...
2. ALTER TABLE contains multiple assumptions about the structure of
dependencies for generation expressions, and they'll all be broken
by such a change. There's even a very explicit claim that any such
dependency could only be on another column of the same table :-(.
The regression tests reveal two or three places in tablecmds.c that
need to change, and I'm worried there may be other places that
aren't covered.
So it's looking to me like we probably can't fix this in the back
branches; it'll have to be a HEAD-only change.
regards, tom lane
From: | Kevin Humphreys <kmanh999(at)gmail(dot)com> |
---|---|
To: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
Cc: | Peter Eisentraut <peter(dot)eisentraut(at)enterprisedb(dot)com>, pgsql-bugs(at)lists(dot)postgresql(dot)org |
Subject: | Re: BUG #17439: DROP FUNCTION functionName(); drops associated generated column without using CASCADE |
Date: | 2022-03-16 01:46:35 |
Message-ID: | CADdM_H3ibA8e4sijO0XSg1tLgmvLah=8Sgu-dOUzN08NpaKbWQ@mail.gmail.com |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Lists: | pgsql-bugs |
Thanks for deep-diving into this Tom! I don't have any experience with the
internal workings of Postgres but if I am understanding correctly:
- This is definitely a bug and not intended or expected behavior and goes
against SQL specifications
- This is a non-trivial fix
- This is a fix that can not be back-ported to Postgres 13?
- This is a fix that can be made to Postgres 14?
Is there any recommendation you would have for mitigation besides not
dropping functions that may be used by generated columns?
Thanks,
Kevin Humphreys
On Tue, Mar 15, 2022 at 5:18 PM Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> wrote:
> I wrote:
> > So it looks to me like the generation expression's dependencies
> > should be NORMAL not AUTO in all cases. I'm less sure about
> > whether to mess with any other aspects of the dependency linkages.
> > That might not be something to fool with in back branches, anyway.
>
> Ugh ... this opens a much larger can of worms than I thought.
> There are two problems:
>
> 1. If these dependencies are NORMAL, then we cannot tell them apart from
> the column's other dependencies -- such as the ones on its type and
> collation. (The generation expression could easily have dependencies on
> types and collations.) I think we really have to switch them so that
> the referencing object is the pg_attrdef entry not the column itself,
> just as is done for ordinary defaults. That's easy so far as
> StoreAttrDefault itself is concerned, but ...
>
> 2. ALTER TABLE contains multiple assumptions about the structure of
> dependencies for generation expressions, and they'll all be broken
> by such a change. There's even a very explicit claim that any such
> dependency could only be on another column of the same table :-(.
>
> The regression tests reveal two or three places in tablecmds.c that
> need to change, and I'm worried there may be other places that
> aren't covered.
>
> So it's looking to me like we probably can't fix this in the back
> branches; it'll have to be a HEAD-only change.
>
> regards, tom lane
>
--
Kevin Humphreys
From: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
---|---|
To: | Kevin Humphreys <kmanh999(at)gmail(dot)com> |
Cc: | Peter Eisentraut <peter(dot)eisentraut(at)enterprisedb(dot)com>, pgsql-bugs(at)lists(dot)postgresql(dot)org |
Subject: | Re: BUG #17439: DROP FUNCTION functionName(); drops associated generated column without using CASCADE |
Date: | 2022-03-16 02:23:43 |
Message-ID: | [email protected] |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Lists: | pgsql-bugs |
Kevin Humphreys <kmanh999(at)gmail(dot)com> writes:
> Thanks for deep-diving into this Tom! I don't have any experience with the
> internal workings of Postgres but if I am understanding correctly:
> - This is definitely a bug and not intended or expected behavior and goes
> against SQL specifications
Looks like a bug to me. The aspect of this that a drop of a table
column causes silent drop of dependent generated columns is clearly
intentional, but AFAICS that's based on a misreading of the spec.
I suspect that the fact that it carries over to other dependencies
of the generation expression was just failure to consider that case.
> - This is a non-trivial fix
> - This is a fix that can not be back-ported to Postgres 13?
> - This is a fix that can be made to Postgres 14?
Yes, yes, no. I don't think we'd risk trying to change this for
any released branch, because redefining catalog contents in
existing installations carries all sorts of hazards. Given that
it's been wrong since v12 and you're the first to complain,
I judge that fixing it in released branches is not worth taking
such risks for. We should definitely endeavor to get it fixed
for v15 though.
> Is there any recommendation you would have for mitigation besides not
> dropping functions that may be used by generated columns?
I don't see any good user-level workaround :-(.
regards, tom lane
From: | "David G(dot) Johnston" <david(dot)g(dot)johnston(at)gmail(dot)com> |
---|---|
To: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
Cc: | Kevin Humphreys <kmanh999(at)gmail(dot)com>, Peter Eisentraut <peter(dot)eisentraut(at)enterprisedb(dot)com>, "pgsql-bugs(at)lists(dot)postgresql(dot)org" <pgsql-bugs(at)lists(dot)postgresql(dot)org> |
Subject: | Re: BUG #17439: DROP FUNCTION functionName(); drops associated generated column without using CASCADE |
Date: | 2022-03-16 02:28:09 |
Message-ID: | CAKFQuwa10Z27W8dm=-DPokw1_gq9TRqMbggg=_ZwdvNG=CYSRg@mail.gmail.com |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Lists: | pgsql-bugs |
On Tuesday, March 15, 2022, Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> wrote:
>
>
> > Is there any recommendation you would have for mitigation besides not
> > dropping functions that may be used by generated columns?
>
> I don't see any good user-level workaround :-(.
>
>
Create a dummy view that simply calls the function with null inputs. That
view then will at least enforce the dependency.
David J.
From: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
---|---|
To: | Peter Eisentraut <peter(dot)eisentraut(at)enterprisedb(dot)com> |
Cc: | kmanh999(at)gmail(dot)com, pgsql-bugs(at)lists(dot)postgresql(dot)org |
Subject: | Re: BUG #17439: DROP FUNCTION functionName(); drops associated generated column without using CASCADE |
Date: | 2022-03-16 17:27:56 |
Message-ID: | [email protected] |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Lists: | pgsql-bugs |
I wrote:
> Ugh ... this opens a much larger can of worms than I thought.
After some fooling around, here's a draft patch for this.
I needed functions to convert between pg_attrdef OIDs and owning
column's table OID + attnum. There was already some ad-hoc code
for that in objectaddress.c, which I extracted into standalone
functions. It seemed cleaner to put those into heap.c (beside
StoreAttrDefault) than keep them in objectaddress.c; but perhaps
someone else will see that differently. I'm about half tempted
to shove StoreAttrDefault, RemoveAttrDefault, and these new
functions into a new file catalog/pg_attrdef.c, just to make heap.c
a bit smaller. But I didn't undertake that here.
Otherwise it seems mostly straightforward, but I remain concerned
that I've missed place(s) that depend on the previous arrangement.
regards, tom lane
Attachment | Content-Type | Size |
---|---|---|
fix-generated-column-dependencies-1.patch | text/x-diff | 21.3 KB |
From: | Peter Eisentraut <peter(dot)eisentraut(at)enterprisedb(dot)com> |
---|---|
To: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
Cc: | kmanh999(at)gmail(dot)com, pgsql-bugs(at)lists(dot)postgresql(dot)org |
Subject: | Re: BUG #17439: DROP FUNCTION functionName(); drops associated generated column without using CASCADE |
Date: | 2022-03-16 19:05:48 |
Message-ID: | [email protected] |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Lists: | pgsql-bugs |
On 15.03.22 21:06, Tom Lane wrote:
> I looked into SQL:2021, and AFAICS the existing behavior is flat wrong,
> even for cross references to other table columns. I think you read
> 11.23 <drop column definition> general rule 3, which seems to say to
> unconditionally drop any generated column depending on the target column
> ... but you missed syntax rule 7f, which says
>
> 7) If RESTRICT is specified, then C shall not be referenced in any of the
> following:
> ...
> f) The generation expression of any column descriptor.
>
> GR3 would be very strange if read in isolation anyway, because it
> says to drop the generated column with CASCADE, which could cause
> arbitrary stuff to go away. That is sensible if you know that 7f
> prevents us from getting here unless the original drop said CASCADE,
> but otherwise it's a pretty astonishing thing.
The reported case is a DROP FUNCTION, but looking at <drop routine
statement>, it doesn't say anything about what to do with generation
expressions. That might be a bug in the standard, too.