Thread: [postgresSQL] [bug] Two or more different types of constraints with same name creates ambiguity while drooping.
[postgresSQL] [bug] Two or more different types of constraints with same name creates ambiguity while drooping.
From
Harshal Dhumal
Date:
Hi Team,
While I was working on constraints node in pgadmin4 I came across this scenario. Please let me know if it's correct behaviour or a bug.
Scenario:
ALTER TABLE public."Test_tbl" DROP CONSTRAINT key;
If we execute above query for first time then it drops primary key first and if execute same query for second time then it drops foreign key.
Also in pgadmin3 if we right click on foreign key and try to drop it, it drops primary key and not the foreign key. We have to drop foreign key twice to actually drop the foreign key if primary key with same was there.
Note: Create foreign key first and then primary key with same name.
Note: Create foreign key first and then primary key with same name.
Regards
Re: [postgresSQL] [bug] Two or more different types of constraints with same name creates ambiguity while drooping.
From
Amit Langote
Date:
On 2016/03/30 15:16, Harshal Dhumal wrote: > Hi Team, > > While I was working on constraints node in pgadmin4 I came across this > scenario. Please let me know if it's correct behaviour or a bug. > > *Scenario:* > > If we create two different type of constrains (lets say primary key and > foreign key) on same table with same name (lets say 'key' ) then its shows > same drop query for both constrains. > e.g. > > ALTER TABLE public."Test_tbl" DROP CONSTRAINT key; > > > If we execute above query for first time then it drops primary key first > and if execute same query for second time then it drops foreign key. > > Also in pgadmin3 if we right click on foreign key and try to drop it, it > drops primary key and not the foreign key. We have to drop foreign key > twice to actually drop the foreign key if primary key with same was there. It seems that, whereas name uniqueness check occurs when creating a named FK constraint, the same does not occur when creating a named PK constraint or any index-based constraint for that matter (they are handled by different code paths - in the latter's case, name conflicts with existing relations is checked for when creating the constraint index) Maybe, we should perform the constraint name check in code paths handling the following two cases: ALTER TABLE foo ADD CONSTRAINT name PK/UNIQUE/EXCLUSION ... ALTER TABLE foo ADD CONSTRAINT name PK/UNIQUE/EXCLUSION USING INDEX ... If so, attached a patch for the same (regression tests pass). Thanks, Amit
Attachment
Re: [postgresSQL] [bug] Two or more different types of constraints with same name creates ambiguity while drooping.
From
Tom Lane
Date:
Amit Langote <Langote_Amit_f8@lab.ntt.co.jp> writes: > On 2016/03/30 15:16, Harshal Dhumal wrote: >> If we create two different type of constrains (lets say primary key and >> foreign key) on same table with same name (lets say 'key' ) then its shows >> same drop query for both constrains. I have a vague recollection that non-uniqueness of constraint names may have been intentional at some point. But yeah, the existence of the ALTER TABLE DROP CONSTRAINT syntax seems to make that a pretty bad idea. > It seems that, whereas name uniqueness check occurs when creating a named > FK constraint, the same does not occur when creating a named PK constraint > or any index-based constraint for that matter (they are handled by > different code paths - in the latter's case, name conflicts with existing > relations is checked for when creating the constraint index) I think that if we want to ensure uniqueness of constraint names, this is really approaching it the wrong way, as it still fails to provide any guarantees (consider concurrent index creation, for example). What we need is a unique index on pg_constraint. The problem with that is that pg_constraint contains both table-related and type (domain) related constraints; but it strikes me that we could probably create a unique index on (conrelid, contypid, conname). Given the convention that conrelid is zero in a type constraint and contypid is zero in a table constraint, this should work to enforce per-table or per-type constraint name uniqueness. The cost of an extra index is a bit annoying, but we could probably make it help pay for itself by speeding up assorted searches. regards, tom lane
Re: [postgresSQL] [bug] Two or more different types of constraints with same name creates ambiguity while drooping.
From
Andrew Dunstan
Date:
On 03/30/2016 10:21 AM, Tom Lane wrote: > Amit Langote <Langote_Amit_f8@lab.ntt.co.jp> writes: >> On 2016/03/30 15:16, Harshal Dhumal wrote: >>> If we create two different type of constrains (lets say primary key and >>> foreign key) on same table with same name (lets say 'key' ) then its shows >>> same drop query for both constrains. > I have a vague recollection that non-uniqueness of constraint names may > have been intentional at some point. But yeah, the existence of the > ALTER TABLE DROP CONSTRAINT syntax seems to make that a pretty bad idea. > >> It seems that, whereas name uniqueness check occurs when creating a named >> FK constraint, the same does not occur when creating a named PK constraint >> or any index-based constraint for that matter (they are handled by >> different code paths - in the latter's case, name conflicts with existing >> relations is checked for when creating the constraint index) > I think that if we want to ensure uniqueness of constraint names, this > is really approaching it the wrong way, as it still fails to provide > any guarantees (consider concurrent index creation, for example). > What we need is a unique index on pg_constraint. > > The problem with that is that pg_constraint contains both table-related > and type (domain) related constraints; but it strikes me that we could > probably create a unique index on (conrelid, contypid, conname). Given > the convention that conrelid is zero in a type constraint and contypid > is zero in a table constraint, this should work to enforce per-table > or per-type constraint name uniqueness. The cost of an extra index > is a bit annoying, but we could probably make it help pay for itself > by speeding up assorted searches. > > +1, but does that mean people will have to change constraint names to be compliant before running pg_upgrade? cheers andrew
Re: [postgresSQL] [bug] Two or more different types of constraints with same name creates ambiguity while drooping.
From
Tom Lane
Date:
Andrew Dunstan <andrew@dunslane.net> writes: > On 03/30/2016 10:21 AM, Tom Lane wrote: >> I think that if we want to ensure uniqueness of constraint names, this >> is really approaching it the wrong way, as it still fails to provide >> any guarantees (consider concurrent index creation, for example). >> What we need is a unique index on pg_constraint. > +1, but does that mean people will have to change constraint names to be > compliant before running pg_upgrade? Yeah, but I think the situation is pretty uncommon, because we already reject duplicate constraint names in most cases. As far as I could see in testing it earlier, these cases all fail already: * create index constraint when same-named index constraint exists already * create FK constraint when same-named index constraint exists already * create FK constraint when same-named FK constraint exists already * create check constraint when same-named check constraint exists already * create FK constraint when same-named check constraint exists already I think that the case Amit's patch plugged, namely create index constraint when same-named FK or check constraint exists already, may be about the only missing check. I just want a unique index to be sure we are covering all cases. Note also that because pg_dump prefers to create indexes before FK constraints (for obvious reasons), I believe that such a case would fail to dump/restore or pg_upgrade already. regards, tom lane
Re: [postgresSQL] [bug] Two or more different types of constraints with same name creates ambiguity while drooping.
From
Alvaro Herrera
Date:
Tom Lane wrote: > What we need is a unique index on pg_constraint. > > The problem with that is that pg_constraint contains both table-related > and type (domain) related constraints; but it strikes me that we could > probably create a unique index on (conrelid, contypid, conname). Weren't you proposing elsewhere to split pg_constraint in two catalogs, one for table constraint and another for domain constraints? That seems a cleaner solution to me. -- Álvaro Herrera http://www.2ndQuadrant.com/ PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
Re: [postgresSQL] [bug] Two or more different types of constraints with same name creates ambiguity while drooping.
From
Tom Lane
Date:
Alvaro Herrera <alvherre@2ndquadrant.com> writes: > Tom Lane wrote: >> What we need is a unique index on pg_constraint. >> The problem with that is that pg_constraint contains both table-related >> and type (domain) related constraints; but it strikes me that we could >> probably create a unique index on (conrelid, contypid, conname). > Weren't you proposing elsewhere to split pg_constraint in two catalogs, > one for table constraint and another for domain constraints? That seems > a cleaner solution to me. Yeah, and you'll notice how much progress we've made towards that. regards, tom lane