Allow ALTER TABLE ONLY on partitioned tables
There is no need to forbid ALTER TABLE ONLY on partitioned tables, when no partitions exist yet. This can be handy for users who are building up their partitioned table independently and will create actual partitions later. In addition, this is how pg_dump likes to operate in certain instances. Author: Amit Langote, with some error message word-smithing by me
This commit is contained in:
parent
5f2b48d1dd
commit
9139aa1942
@ -2944,17 +2944,23 @@ VALUES ('Albany', NULL, NULL, 'NY');
|
|||||||
Both <literal>CHECK</literal> and <literal>NOT NULL</literal>
|
Both <literal>CHECK</literal> and <literal>NOT NULL</literal>
|
||||||
constraints of a partitioned table are always inherited by all its
|
constraints of a partitioned table are always inherited by all its
|
||||||
partitions. <literal>CHECK</literal> constraints that are marked
|
partitions. <literal>CHECK</literal> constraints that are marked
|
||||||
<literal>NO INHERIT</literal> are not allowed.
|
<literal>NO INHERIT</literal> are not allowed to be created on
|
||||||
|
partitioned tables.
|
||||||
</para>
|
</para>
|
||||||
</listitem>
|
</listitem>
|
||||||
|
|
||||||
<listitem>
|
<listitem>
|
||||||
<para>
|
<para>
|
||||||
The <literal>ONLY</literal> notation used to exclude child tables
|
Using <literal>ONLY</literal> to add or drop a constraint on only the
|
||||||
will cause an error for partitioned tables in the case of
|
partitioned table is supported when there are no partitions. Once
|
||||||
schema-modifying commands such as most <literal>ALTER TABLE</literal>
|
partitions exist, using <literal>ONLY</literal> will result in an error
|
||||||
commands. For example, dropping a column from only the parent does
|
as adding or dropping constraints on only the partitioned table, when
|
||||||
not make sense for partitioned tables.
|
partitions exist, is not supported. Instead, constraints can be added
|
||||||
|
or dropped, when they are not present in the parent table, directly on
|
||||||
|
the partitions. As a partitioned table does not have any data
|
||||||
|
directly, attempts to use <command>TRUNCATE</command>
|
||||||
|
<literal>ONLY</literal> on a partitioned table will always return an
|
||||||
|
error.
|
||||||
</para>
|
</para>
|
||||||
</listitem>
|
</listitem>
|
||||||
|
|
||||||
|
@ -1259,7 +1259,8 @@ ExecuteTruncate(TruncateStmt *stmt)
|
|||||||
else if (rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE)
|
else if (rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE)
|
||||||
ereport(ERROR,
|
ereport(ERROR,
|
||||||
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
|
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
|
||||||
errmsg("must truncate child tables too")));
|
errmsg("cannot truncate only a partitioned table"),
|
||||||
|
errhint("Do not specify the ONLY keyword, or use truncate only on the partitions directly.")));
|
||||||
}
|
}
|
||||||
|
|
||||||
/*
|
/*
|
||||||
@ -5578,14 +5579,20 @@ static void
|
|||||||
ATPrepDropNotNull(Relation rel, bool recurse, bool recursing)
|
ATPrepDropNotNull(Relation rel, bool recurse, bool recursing)
|
||||||
{
|
{
|
||||||
/*
|
/*
|
||||||
* If the parent is a partitioned table, like check constraints, NOT NULL
|
* If the parent is a partitioned table, like check constraints, we do
|
||||||
* constraints must be dropped from child tables.
|
* not support removing the NOT NULL while partitions exist.
|
||||||
*/
|
*/
|
||||||
if (rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE &&
|
if (rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE)
|
||||||
!recurse && !recursing)
|
{
|
||||||
|
PartitionDesc partdesc = RelationGetPartitionDesc(rel);
|
||||||
|
|
||||||
|
Assert(partdesc != NULL);
|
||||||
|
if (partdesc->nparts > 0 && !recurse && !recursing)
|
||||||
ereport(ERROR,
|
ereport(ERROR,
|
||||||
(errcode(ERRCODE_INVALID_TABLE_DEFINITION),
|
(errcode(ERRCODE_INVALID_TABLE_DEFINITION),
|
||||||
errmsg("constraint must be dropped from child tables too")));
|
errmsg("cannot remove constraint from only the partitioned table when partitions exist"),
|
||||||
|
errhint("Do not specify the ONLY keyword.")));
|
||||||
|
}
|
||||||
}
|
}
|
||||||
static ObjectAddress
|
static ObjectAddress
|
||||||
ATExecDropNotNull(Relation rel, const char *colName, LOCKMODE lockmode)
|
ATExecDropNotNull(Relation rel, const char *colName, LOCKMODE lockmode)
|
||||||
@ -5746,13 +5753,19 @@ ATPrepSetNotNull(Relation rel, bool recurse, bool recursing)
|
|||||||
{
|
{
|
||||||
/*
|
/*
|
||||||
* If the parent is a partitioned table, like check constraints, NOT NULL
|
* If the parent is a partitioned table, like check constraints, NOT NULL
|
||||||
* constraints must be added to the child tables.
|
* constraints must be added to the child tables. Complain if requested
|
||||||
|
* otherwise and partitions exist.
|
||||||
*/
|
*/
|
||||||
if (rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE &&
|
if (rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE)
|
||||||
!recurse && !recursing)
|
{
|
||||||
|
PartitionDesc partdesc = RelationGetPartitionDesc(rel);
|
||||||
|
|
||||||
|
if (partdesc && partdesc->nparts > 0 && !recurse && !recursing)
|
||||||
ereport(ERROR,
|
ereport(ERROR,
|
||||||
(errcode(ERRCODE_INVALID_TABLE_DEFINITION),
|
(errcode(ERRCODE_INVALID_TABLE_DEFINITION),
|
||||||
errmsg("constraint must be added to child tables too")));
|
errmsg("cannot add constraint to only the partitioned table when partitions exist"),
|
||||||
|
errhint("Do not specify the ONLY keyword.")));
|
||||||
|
}
|
||||||
}
|
}
|
||||||
|
|
||||||
static ObjectAddress
|
static ObjectAddress
|
||||||
@ -6547,7 +6560,8 @@ ATExecDropColumn(List **wqueue, Relation rel, const char *colName,
|
|||||||
if (rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE && !recurse)
|
if (rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE && !recurse)
|
||||||
ereport(ERROR,
|
ereport(ERROR,
|
||||||
(errcode(ERRCODE_INVALID_TABLE_DEFINITION),
|
(errcode(ERRCODE_INVALID_TABLE_DEFINITION),
|
||||||
errmsg("column must be dropped from child tables too")));
|
errmsg("cannot drop column from only the partitioned table when partitions exist"),
|
||||||
|
errhint("Do not specify the ONLY keyword.")));
|
||||||
|
|
||||||
attr_rel = heap_open(AttributeRelationId, RowExclusiveLock);
|
attr_rel = heap_open(AttributeRelationId, RowExclusiveLock);
|
||||||
foreach(child, children)
|
foreach(child, children)
|
||||||
@ -8561,16 +8575,6 @@ ATExecDropConstraint(Relation rel, const char *constrName,
|
|||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
|
||||||
/*
|
|
||||||
* In case of a partitioned table, the constraint must be dropped from the
|
|
||||||
* partitions too. There is no such thing as NO INHERIT constraints in
|
|
||||||
* case of partitioned tables.
|
|
||||||
*/
|
|
||||||
if (!recurse && rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE)
|
|
||||||
ereport(ERROR,
|
|
||||||
(errcode(ERRCODE_INVALID_TABLE_DEFINITION),
|
|
||||||
errmsg("constraint must be dropped from child tables too")));
|
|
||||||
|
|
||||||
/*
|
/*
|
||||||
* Propagate to children as appropriate. Unlike most other ALTER
|
* Propagate to children as appropriate. Unlike most other ALTER
|
||||||
* routines, we have to do this one level of recursion at a time; we can't
|
* routines, we have to do this one level of recursion at a time; we can't
|
||||||
@ -8581,6 +8585,18 @@ ATExecDropConstraint(Relation rel, const char *constrName,
|
|||||||
else
|
else
|
||||||
children = NIL;
|
children = NIL;
|
||||||
|
|
||||||
|
/*
|
||||||
|
* For a partitioned table, if partitions exist and we are told not to
|
||||||
|
* recurse, it's a user error. It doesn't make sense to have a constraint
|
||||||
|
* be defined only on the parent, especially if it's a partitioned table.
|
||||||
|
*/
|
||||||
|
if (rel->rd_rel->relkind == RELKIND_PARTITIONED_TABLE &&
|
||||||
|
children != NIL && !recurse)
|
||||||
|
ereport(ERROR,
|
||||||
|
(errcode(ERRCODE_INVALID_TABLE_DEFINITION),
|
||||||
|
errmsg("cannot remove constraint from only the partitioned table when partitions exist"),
|
||||||
|
errhint("Do not specify the ONLY keyword.")));
|
||||||
|
|
||||||
foreach(child, children)
|
foreach(child, children)
|
||||||
{
|
{
|
||||||
Oid childrelid = lfirst_oid(child);
|
Oid childrelid = lfirst_oid(child);
|
||||||
|
@ -3295,7 +3295,8 @@ DROP TABLE part_3_4;
|
|||||||
ALTER TABLE ONLY list_parted2 ADD COLUMN c int;
|
ALTER TABLE ONLY list_parted2 ADD COLUMN c int;
|
||||||
ERROR: column must be added to child tables too
|
ERROR: column must be added to child tables too
|
||||||
ALTER TABLE ONLY list_parted2 DROP COLUMN b;
|
ALTER TABLE ONLY list_parted2 DROP COLUMN b;
|
||||||
ERROR: column must be dropped from child tables too
|
ERROR: cannot drop column from only the partitioned table when partitions exist
|
||||||
|
HINT: Do not specify the ONLY keyword.
|
||||||
-- cannot add a column to partition or drop an inherited one
|
-- cannot add a column to partition or drop an inherited one
|
||||||
ALTER TABLE part_2 ADD COLUMN c text;
|
ALTER TABLE part_2 ADD COLUMN c text;
|
||||||
ERROR: cannot add column to a partition
|
ERROR: cannot add column to a partition
|
||||||
@ -3306,24 +3307,37 @@ ALTER TABLE part_2 RENAME COLUMN b to c;
|
|||||||
ERROR: cannot rename inherited column "b"
|
ERROR: cannot rename inherited column "b"
|
||||||
ALTER TABLE part_2 ALTER COLUMN b TYPE text;
|
ALTER TABLE part_2 ALTER COLUMN b TYPE text;
|
||||||
ERROR: cannot alter inherited column "b"
|
ERROR: cannot alter inherited column "b"
|
||||||
-- cannot add NOT NULL or check constraints to *only* the parent (ie, non-inherited)
|
-- 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;
|
ALTER TABLE ONLY list_parted2 ALTER b SET NOT NULL;
|
||||||
|
ERROR: cannot add constraint to only the partitioned table when partitions exist
|
||||||
|
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
|
ERROR: constraint must be added to child tables too
|
||||||
ALTER TABLE ONLY list_parted2 add constraint check_b check (b <> 'zz');
|
ALTER TABLE list_parted2 ALTER b SET NOT NULL;
|
||||||
ERROR: constraint must be added to child tables too
|
ALTER TABLE ONLY list_parted2 ALTER b DROP NOT NULL;
|
||||||
ALTER TABLE list_parted2 add constraint check_b check (b <> 'zz') NO INHERIT;
|
ERROR: cannot remove constraint from only the partitioned table when partitions exist
|
||||||
ERROR: cannot add NO INHERIT constraint to partitioned table "list_parted2"
|
HINT: Do not specify the ONLY keyword.
|
||||||
|
ALTER TABLE list_parted2 ADD CONSTRAINT check_b CHECK (b <> 'zz');
|
||||||
|
ALTER TABLE ONLY list_parted2 DROP CONSTRAINT check_b;
|
||||||
|
ERROR: cannot remove constraint from only the partitioned table when partitions exist
|
||||||
|
HINT: Do not specify the ONLY keyword.
|
||||||
|
-- It's alright though, if no partitions are yet created
|
||||||
|
CREATE TABLE parted_no_parts (a int) PARTITION BY LIST (a);
|
||||||
|
ALTER TABLE ONLY parted_no_parts ALTER a SET NOT NULL;
|
||||||
|
ALTER TABLE ONLY parted_no_parts ADD CONSTRAINT check_a CHECK (a > 0);
|
||||||
|
ALTER TABLE ONLY parted_no_parts ALTER a DROP NOT NULL;
|
||||||
|
ALTER TABLE ONLY parted_no_parts DROP CONSTRAINT check_a;
|
||||||
|
DROP TABLE parted_no_parts;
|
||||||
-- cannot drop inherited NOT NULL or check constraints from partition
|
-- cannot drop inherited NOT NULL or check constraints from partition
|
||||||
ALTER TABLE list_parted2 ALTER b SET NOT NULL, ADD CONSTRAINT check_a2 CHECK (a > 0);
|
ALTER TABLE list_parted2 ALTER b SET NOT NULL, ADD CONSTRAINT check_a2 CHECK (a > 0);
|
||||||
ALTER TABLE part_2 ALTER b DROP NOT NULL;
|
ALTER TABLE part_2 ALTER b DROP NOT NULL;
|
||||||
ERROR: column "b" is marked NOT NULL in parent table
|
ERROR: column "b" is marked NOT NULL in parent table
|
||||||
ALTER TABLE part_2 DROP CONSTRAINT check_a2;
|
ALTER TABLE part_2 DROP CONSTRAINT check_a2;
|
||||||
ERROR: cannot drop inherited constraint "check_a2" of relation "part_2"
|
ERROR: cannot drop inherited constraint "check_a2" of relation "part_2"
|
||||||
-- cannot drop NOT NULL or check constraints from *only* the parent
|
-- Doesn't make sense to add NO INHERIT constraints on partitioned tables
|
||||||
ALTER TABLE ONLY list_parted2 ALTER a DROP NOT NULL;
|
ALTER TABLE list_parted2 add constraint check_b2 check (b <> 'zz') NO INHERIT;
|
||||||
ERROR: constraint must be dropped from child tables too
|
ERROR: cannot add NO INHERIT constraint to partitioned table "list_parted2"
|
||||||
ALTER TABLE ONLY list_parted2 DROP CONSTRAINT check_a2;
|
|
||||||
ERROR: constraint must be dropped from child tables too
|
|
||||||
-- check that a partition cannot participate in regular inheritance
|
-- check that a partition cannot participate in regular inheritance
|
||||||
CREATE TABLE inh_test () INHERITS (part_2);
|
CREATE TABLE inh_test () INHERITS (part_2);
|
||||||
ERROR: cannot inherit from partition "part_2"
|
ERROR: cannot inherit from partition "part_2"
|
||||||
|
@ -452,7 +452,15 @@ LINE 1: SELECT nextval('truncate_a_id1');
|
|||||||
^
|
^
|
||||||
-- partitioned table
|
-- partitioned table
|
||||||
CREATE TABLE truncparted (a int, b char) PARTITION BY LIST (a);
|
CREATE TABLE truncparted (a int, b char) PARTITION BY LIST (a);
|
||||||
|
-- error, can't truncate a partitioned table
|
||||||
|
TRUNCATE ONLY truncparted;
|
||||||
|
ERROR: cannot truncate only a partitioned table
|
||||||
|
HINT: Do not specify the ONLY keyword, or use truncate only on the partitions directly.
|
||||||
CREATE TABLE truncparted1 PARTITION OF truncparted FOR VALUES IN (1);
|
CREATE TABLE truncparted1 PARTITION OF truncparted FOR VALUES IN (1);
|
||||||
INSERT INTO truncparted VALUES (1, 'a');
|
INSERT INTO truncparted VALUES (1, 'a');
|
||||||
|
-- error, must truncate partitions
|
||||||
|
TRUNCATE ONLY truncparted;
|
||||||
|
ERROR: cannot truncate only a partitioned table
|
||||||
|
HINT: Do not specify the ONLY keyword, or use truncate only on the partitions directly.
|
||||||
TRUNCATE truncparted;
|
TRUNCATE truncparted;
|
||||||
DROP TABLE truncparted;
|
DROP TABLE truncparted;
|
||||||
|
@ -2173,19 +2173,31 @@ ALTER TABLE part_2 DROP COLUMN b;
|
|||||||
ALTER TABLE part_2 RENAME COLUMN b to c;
|
ALTER TABLE part_2 RENAME COLUMN b to c;
|
||||||
ALTER TABLE part_2 ALTER COLUMN b TYPE text;
|
ALTER TABLE part_2 ALTER COLUMN b TYPE text;
|
||||||
|
|
||||||
-- cannot add NOT NULL or check constraints to *only* the parent (ie, non-inherited)
|
-- 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;
|
ALTER TABLE ONLY list_parted2 ALTER b SET NOT NULL;
|
||||||
ALTER TABLE ONLY list_parted2 add constraint check_b check (b <> 'zz');
|
ALTER TABLE ONLY list_parted2 ADD CONSTRAINT check_b CHECK (b <> 'zz');
|
||||||
ALTER TABLE list_parted2 add constraint check_b check (b <> 'zz') NO INHERIT;
|
|
||||||
|
ALTER TABLE list_parted2 ALTER b SET NOT NULL;
|
||||||
|
ALTER TABLE ONLY list_parted2 ALTER b DROP NOT NULL;
|
||||||
|
ALTER TABLE list_parted2 ADD CONSTRAINT check_b CHECK (b <> 'zz');
|
||||||
|
ALTER TABLE ONLY list_parted2 DROP CONSTRAINT check_b;
|
||||||
|
|
||||||
|
-- It's alright though, if no partitions are yet created
|
||||||
|
CREATE TABLE parted_no_parts (a int) PARTITION BY LIST (a);
|
||||||
|
ALTER TABLE ONLY parted_no_parts ALTER a SET NOT NULL;
|
||||||
|
ALTER TABLE ONLY parted_no_parts ADD CONSTRAINT check_a CHECK (a > 0);
|
||||||
|
ALTER TABLE ONLY parted_no_parts ALTER a DROP NOT NULL;
|
||||||
|
ALTER TABLE ONLY parted_no_parts DROP CONSTRAINT check_a;
|
||||||
|
DROP TABLE parted_no_parts;
|
||||||
|
|
||||||
-- cannot drop inherited NOT NULL or check constraints from partition
|
-- cannot drop inherited NOT NULL or check constraints from partition
|
||||||
ALTER TABLE list_parted2 ALTER b SET NOT NULL, ADD CONSTRAINT check_a2 CHECK (a > 0);
|
ALTER TABLE list_parted2 ALTER b SET NOT NULL, ADD CONSTRAINT check_a2 CHECK (a > 0);
|
||||||
ALTER TABLE part_2 ALTER b DROP NOT NULL;
|
ALTER TABLE part_2 ALTER b DROP NOT NULL;
|
||||||
ALTER TABLE part_2 DROP CONSTRAINT check_a2;
|
ALTER TABLE part_2 DROP CONSTRAINT check_a2;
|
||||||
|
|
||||||
-- cannot drop NOT NULL or check constraints from *only* the parent
|
-- Doesn't make sense to add NO INHERIT constraints on partitioned tables
|
||||||
ALTER TABLE ONLY list_parted2 ALTER a DROP NOT NULL;
|
ALTER TABLE list_parted2 add constraint check_b2 check (b <> 'zz') NO INHERIT;
|
||||||
ALTER TABLE ONLY list_parted2 DROP CONSTRAINT check_a2;
|
|
||||||
|
|
||||||
-- check that a partition cannot participate in regular inheritance
|
-- check that a partition cannot participate in regular inheritance
|
||||||
CREATE TABLE inh_test () INHERITS (part_2);
|
CREATE TABLE inh_test () INHERITS (part_2);
|
||||||
|
@ -236,7 +236,11 @@ SELECT nextval('truncate_a_id1'); -- fail, seq should have been dropped
|
|||||||
|
|
||||||
-- partitioned table
|
-- partitioned table
|
||||||
CREATE TABLE truncparted (a int, b char) PARTITION BY LIST (a);
|
CREATE TABLE truncparted (a int, b char) PARTITION BY LIST (a);
|
||||||
|
-- error, can't truncate a partitioned table
|
||||||
|
TRUNCATE ONLY truncparted;
|
||||||
CREATE TABLE truncparted1 PARTITION OF truncparted FOR VALUES IN (1);
|
CREATE TABLE truncparted1 PARTITION OF truncparted FOR VALUES IN (1);
|
||||||
INSERT INTO truncparted VALUES (1, 'a');
|
INSERT INTO truncparted VALUES (1, 'a');
|
||||||
|
-- error, must truncate partitions
|
||||||
|
TRUNCATE ONLY truncparted;
|
||||||
TRUNCATE truncparted;
|
TRUNCATE truncparted;
|
||||||
DROP TABLE truncparted;
|
DROP TABLE truncparted;
|
||||||
|
Loading…
x
Reference in New Issue
Block a user