mirror of
https://github.com/postgres/postgres.git
synced 2025-12-10 14:22:35 +03:00
Avoid order-of-execution problems with ALTER TABLE ADD PRIMARY KEY.
Up to now, DefineIndex() was responsible for adding attnotnull constraints to the columns of a primary key, in any case where it hadn't been convenient for transformIndexConstraint() to mark those columns as is_not_null. It (or rather its minion index_check_primary_key) did this by executing an ALTER TABLE SET NOT NULL command for the target table. The trouble with this solution is that if we're creating the index due to ALTER TABLE ADD PRIMARY KEY, and the outer ALTER TABLE has additional sub-commands, the inner ALTER TABLE's operations executed at the wrong time with respect to the outer ALTER TABLE's operations. In particular, the inner ALTER would perform a validation scan at a point where the table's storage might be inconsistent with its catalog entries. (This is on the hairy edge of being a security problem, but AFAICS it isn't one because the inner scan would only be interested in the tuples' null bitmaps.) This can result in unexpected failures, such as the one seen in bug #15580 from Allison Kaptur. To fix, let's remove the attempt to do SET NOT NULL from DefineIndex(), reducing index_check_primary_key's role to verifying that the columns are already not null. (It shouldn't ever see such a case, but it seems wise to keep the check for safety.) Instead, make transformIndexConstraint() generate ALTER TABLE SET NOT NULL subcommands to be executed ahead of the ADD PRIMARY KEY operation in every case where it can't force the column to be created already-not-null. This requires only minor surgery in parse_utilcmd.c, and it makes for a much more satisfying spec for transformIndexConstraint(): it's no longer having to take it on faith that someone else will handle addition of NOT NULL constraints. To make that work, we have to move the execution of AT_SetNotNull into an ALTER pass that executes ahead of AT_PASS_ADD_INDEX. I moved it to AT_PASS_COL_ATTRS, and put that after AT_PASS_ADD_COL to avoid failure when the column is being added in the same command. This incidentally fixes a bug in the only previous usage of AT_PASS_COL_ATTRS, for AT_SetIdentity: it didn't work either for a newly-added column. Playing around with this exposed a separate bug in ALTER TABLE ONLY ... ADD PRIMARY KEY for partitioned tables. The intent of the ONLY modifier in that context is to prevent doing anything that would require holding lock for a long time --- but the implied SET NOT NULL would recurse to the child partitions, and do an expensive validation scan for any child where the column(s) were not already NOT NULL. To fix that, invent a new ALTER subcommand AT_CheckNotNull that just insists that a child column be already NOT NULL, and apply that, not AT_SetNotNull, when recursing to children in this scenario. This results in a slightly laxer definition of ALTER TABLE ONLY ... SET NOT NULL for partitioned tables, too: that command will now work as long as all children are already NOT NULL, whereas before it just threw up its hands if there were any partitions. In passing, clean up the API of generateClonedIndexStmt(): remove a useless argument, ensure that the output argument is not left undefined, update the header comment. A small side effect of this change is that no-such-column errors in ALTER TABLE ADD PRIMARY KEY now produce a different message that includes the table name, because they are now detected by the SET NOT NULL step which has historically worded its error that way. That seems fine to me, so I didn't make any effort to avoid the wording change. The basic bug #15580 is of very long standing, and these other bugs aren't new in v12 either. However, this is a pretty significant change in the way ALTER TABLE ADD PRIMARY KEY works. On balance it seems best not to back-patch, at least not till we get some more confidence that this patch has no new bugs. Patch by me, but thanks to Jie Zhang for a preliminary version. Discussion: https://postgr.es/m/15580-d1a6de5a3d65da51@postgresql.org Discussion: https://postgr.es/m/1396E95157071C4EBBA51892C5368521017F2E6E63@G08CNEXMBPEKD02.g08.fujitsu.local
This commit is contained in:
@@ -23,8 +23,7 @@ NOTICE: DDL test: type simple, tag CREATE TABLE
|
||||
CREATE TABLE part1 PARTITION OF part FOR VALUES FROM (1) to (100);
|
||||
NOTICE: DDL test: type simple, tag CREATE TABLE
|
||||
ALTER TABLE part ADD PRIMARY KEY (a);
|
||||
NOTICE: DDL test: type alter table, tag CREATE INDEX
|
||||
NOTICE: subcommand: SET NOT NULL
|
||||
NOTICE: subcommand: SET NOT NULL
|
||||
NOTICE: DDL test: type alter table, tag ALTER TABLE
|
||||
NOTICE: subcommand: SET NOT NULL
|
||||
NOTICE: subcommand: SET NOT NULL
|
||||
NOTICE: subcommand: ADD INDEX
|
||||
|
||||
@@ -85,6 +85,8 @@ CREATE TABLE employees OF employee_type (
|
||||
salary WITH OPTIONS DEFAULT 1000
|
||||
);
|
||||
NOTICE: DDL test: type simple, tag CREATE TABLE
|
||||
NOTICE: DDL test: type alter table, tag ALTER TABLE
|
||||
NOTICE: subcommand: SET NOT NULL
|
||||
NOTICE: DDL test: type simple, tag CREATE INDEX
|
||||
-- Inheritance
|
||||
CREATE TABLE person (
|
||||
|
||||
@@ -117,6 +117,9 @@ get_altertable_subcmdtypes(PG_FUNCTION_ARGS)
|
||||
case AT_SetNotNull:
|
||||
strtype = "SET NOT NULL";
|
||||
break;
|
||||
case AT_CheckNotNull:
|
||||
strtype = "CHECK NOT NULL";
|
||||
break;
|
||||
case AT_SetStatistics:
|
||||
strtype = "SET STATS";
|
||||
break;
|
||||
|
||||
@@ -978,7 +978,7 @@ drop table atacc1;
|
||||
create table atacc1 ( test int );
|
||||
-- add a primary key constraint (fails)
|
||||
alter table atacc1 add constraint atacc_test1 primary key (test1);
|
||||
ERROR: column "test1" named in key does not exist
|
||||
ERROR: column "test1" of relation "atacc1" does not exist
|
||||
drop table atacc1;
|
||||
-- adding a new column as primary key to a non-empty table.
|
||||
-- should fail unless the column has a non-null default value.
|
||||
@@ -990,6 +990,13 @@ ERROR: column "test2" contains null values
|
||||
-- now add a primary key column with a default (succeeds).
|
||||
alter table atacc1 add column test2 int default 0 primary key;
|
||||
drop table atacc1;
|
||||
-- this combination used to have order-of-execution problems (bug #15580)
|
||||
create table atacc1 (a int);
|
||||
insert into atacc1 values(1);
|
||||
alter table atacc1
|
||||
add column b float8 not null default random(),
|
||||
add primary key(a);
|
||||
drop table atacc1;
|
||||
-- something a little more complicated
|
||||
create table atacc1 ( test int, test2 int);
|
||||
-- add a primary key constraint
|
||||
@@ -1404,9 +1411,9 @@ ERROR: column "a" does not exist
|
||||
alter table atacc1 rename "........pg.dropped.1........" to x;
|
||||
ERROR: column "........pg.dropped.1........" does not exist
|
||||
alter table atacc1 add primary key(a);
|
||||
ERROR: column "a" named in key does not exist
|
||||
ERROR: column "a" of relation "atacc1" does not exist
|
||||
alter table atacc1 add primary key("........pg.dropped.1........");
|
||||
ERROR: column "........pg.dropped.1........" named in key does not exist
|
||||
ERROR: column "........pg.dropped.1........" of relation "atacc1" does not exist
|
||||
alter table atacc1 add unique(a);
|
||||
ERROR: column "a" named in key does not exist
|
||||
alter table atacc1 add unique("........pg.dropped.1........");
|
||||
@@ -3751,7 +3758,8 @@ ERROR: cannot alter inherited column "b"
|
||||
-- cannot add/drop NOT NULL or check constraints to *only* the parent, when
|
||||
-- partitions exist
|
||||
ALTER TABLE ONLY list_parted2 ALTER b SET NOT NULL;
|
||||
ERROR: cannot add constraint to only the partitioned table when partitions exist
|
||||
ERROR: constraint must be added to child tables too
|
||||
DETAIL: Column "b" of relation "part_2" is not already NOT NULL.
|
||||
HINT: Do not specify the ONLY keyword.
|
||||
ALTER TABLE ONLY list_parted2 ADD CONSTRAINT check_b CHECK (b <> 'zz');
|
||||
ERROR: constraint must be added to child tables too
|
||||
|
||||
@@ -290,6 +290,18 @@ SELECT seqtypid::regtype FROM pg_sequence WHERE seqrelid = 'itest3_a_seq'::regcl
|
||||
|
||||
ALTER TABLE itest3 ALTER COLUMN a TYPE text; -- error
|
||||
ERROR: identity column type must be smallint, integer, or bigint
|
||||
-- kinda silly to change property in the same command, but it should work
|
||||
ALTER TABLE itest3
|
||||
ADD COLUMN c int GENERATED BY DEFAULT AS IDENTITY,
|
||||
ALTER COLUMN c SET GENERATED ALWAYS;
|
||||
\d itest3
|
||||
Table "public.itest3"
|
||||
Column | Type | Collation | Nullable | Default
|
||||
--------+---------+-----------+----------+----------------------------------
|
||||
a | integer | | not null | generated by default as identity
|
||||
b | text | | |
|
||||
c | integer | | not null | generated always as identity
|
||||
|
||||
-- ALTER COLUMN ... SET
|
||||
CREATE TABLE itest6 (a int GENERATED ALWAYS AS IDENTITY, b text);
|
||||
INSERT INTO itest6 DEFAULT VALUES;
|
||||
|
||||
@@ -1098,6 +1098,21 @@ select indrelid::regclass, indexrelid::regclass, inhparent::regclass, indisvalid
|
||||
idxpart | idxpart_pkey | | t | idxpart_pkey | t | 0 | t | t
|
||||
(2 rows)
|
||||
|
||||
drop table idxpart;
|
||||
-- Related to the above scenario: ADD PRIMARY KEY on the parent mustn't
|
||||
-- automatically propagate NOT NULL to child columns.
|
||||
create table idxpart (a int) partition by range (a);
|
||||
create table idxpart0 (like idxpart);
|
||||
alter table idxpart0 add unique (a);
|
||||
alter table idxpart attach partition idxpart0 default;
|
||||
alter table only idxpart add primary key (a); -- fail, no NOT NULL constraint
|
||||
ERROR: constraint must be added to child tables too
|
||||
DETAIL: Column "a" of relation "idxpart0" is not already NOT NULL.
|
||||
HINT: Do not specify the ONLY keyword.
|
||||
alter table idxpart0 alter column a set not null;
|
||||
alter table only idxpart add primary key (a); -- now it works
|
||||
alter table idxpart0 alter column a drop not null; -- fail, pkey needs it
|
||||
ERROR: column "a" is marked NOT NULL in parent table
|
||||
drop table idxpart;
|
||||
-- if a partition has a unique index without a constraint, does not attach
|
||||
-- automatically; creates a new index instead.
|
||||
|
||||
@@ -749,6 +749,14 @@ alter table atacc1 add column test2 int primary key;
|
||||
alter table atacc1 add column test2 int default 0 primary key;
|
||||
drop table atacc1;
|
||||
|
||||
-- this combination used to have order-of-execution problems (bug #15580)
|
||||
create table atacc1 (a int);
|
||||
insert into atacc1 values(1);
|
||||
alter table atacc1
|
||||
add column b float8 not null default random(),
|
||||
add primary key(a);
|
||||
drop table atacc1;
|
||||
|
||||
-- something a little more complicated
|
||||
create table atacc1 ( test int, test2 int);
|
||||
-- add a primary key constraint
|
||||
|
||||
@@ -174,6 +174,12 @@ SELECT seqtypid::regtype FROM pg_sequence WHERE seqrelid = 'itest3_a_seq'::regcl
|
||||
|
||||
ALTER TABLE itest3 ALTER COLUMN a TYPE text; -- error
|
||||
|
||||
-- kinda silly to change property in the same command, but it should work
|
||||
ALTER TABLE itest3
|
||||
ADD COLUMN c int GENERATED BY DEFAULT AS IDENTITY,
|
||||
ALTER COLUMN c SET GENERATED ALWAYS;
|
||||
\d itest3
|
||||
|
||||
|
||||
-- ALTER COLUMN ... SET
|
||||
|
||||
|
||||
@@ -578,6 +578,18 @@ select indrelid::regclass, indexrelid::regclass, inhparent::regclass, indisvalid
|
||||
order by indexrelid::regclass::text collate "C";
|
||||
drop table idxpart;
|
||||
|
||||
-- Related to the above scenario: ADD PRIMARY KEY on the parent mustn't
|
||||
-- automatically propagate NOT NULL to child columns.
|
||||
create table idxpart (a int) partition by range (a);
|
||||
create table idxpart0 (like idxpart);
|
||||
alter table idxpart0 add unique (a);
|
||||
alter table idxpart attach partition idxpart0 default;
|
||||
alter table only idxpart add primary key (a); -- fail, no NOT NULL constraint
|
||||
alter table idxpart0 alter column a set not null;
|
||||
alter table only idxpart add primary key (a); -- now it works
|
||||
alter table idxpart0 alter column a drop not null; -- fail, pkey needs it
|
||||
drop table idxpart;
|
||||
|
||||
-- if a partition has a unique index without a constraint, does not attach
|
||||
-- automatically; creates a new index instead.
|
||||
create table idxpart (a int, b int) partition by range (a);
|
||||
|
||||
Reference in New Issue
Block a user