Commit 8c092781 authored by Bruce Momjian's avatar Bruce Momjian

ALTER TABLE ... ADD/DROPS INHERIT (actually INHERIT / NO INHERIT)

Open items:

There were a few tangentially related issues that have come up that I think
are TODOs. I'm likely to tackle one or two of these next so I'm interested in
hearing feedback on them as well.

. Constraints currently do not know anything about inheritance. Tom suggested
  adding a coninhcount and conislocal like attributes have to track their
  inheritance status.

. Foreign key constraints currently do not get copied to new children (and
  therefore my code doesn't verify them). I don't think it would be hard to
  add them and treat them like CHECK constraints.

. No constraints at all are copied to tables defined with LIKE. That makes it
  hard to use LIKE to define new partitions. The standard defines LIKE and
  specifically says it does not copy constraints. But the standard already has
  an option called INCLUDING DEFAULTS; we could always define a non-standard
  extension LIKE table INCLUDING CONSTRAINTS that gives the user the option to
  request a copy including constraints.

. Personally, I think the whole attislocal thing is bunk. The decision about
  whether to drop a column from children tables or not is something that
  should be up to the user and trying to DWIM based on whether there was ever
  a local definition or the column was acquired purely through inheritance is
  hardly ever going to match up with user expectations.

. And of course there's the whole unique and primary key constraint issue. I
  think to get any traction at all on this you have a prerequisite of a real
  partitioned table implementation where the system knows what the partition
  key is so it can recognize when it's a leading part of an index key.

Greg Stark
parent 08ccdf02
This diff is collapsed.
<!--
$PostgreSQL: pgsql/doc/src/sgml/ref/alter_table.sgml,v 1.84 2006/02/12 19:11:00 momjian Exp $
$PostgreSQL: pgsql/doc/src/sgml/ref/alter_table.sgml,v 1.85 2006/07/02 01:58:36 momjian Exp $
PostgreSQL documentation
-->
......@@ -46,6 +46,8 @@ where <replaceable class="PARAMETER">action</replaceable> is one of:
CLUSTER ON <replaceable class="PARAMETER">index_name</replaceable>
SET WITHOUT CLUSTER
SET WITHOUT OIDS
INHERIT <replaceable class="PARAMETER">parent_table</replaceable>
NO INHERIT <replaceable class="PARAMETER">parent_table</replaceable>
OWNER TO <replaceable class="PARAMETER">new_owner</replaceable>
SET TABLESPACE <replaceable class="PARAMETER">new_tablespace</replaceable>
</synopsis>
......@@ -249,6 +251,52 @@ where <replaceable class="PARAMETER">action</replaceable> is one of:
</listitem>
</varlistentry>
<varlistentry>
<term><literal>INHERIT <replaceable class="PARAMETER">parent_table</replaceable></literal></term>
<listitem>
<para>
This form adds a new parent table to the table. This won't add new
columns to the child table, instead all columns of the parent table must
already exist in the child table. They must have matching data types,
and if they have <literal>NOT NULL</literal> constraints in the parent
then they must also have <literal>NOT NULL</literal> constraints in the
child.
</para>
<para>
There must also be matching table constraints for all
<literal>CHECK</literal> table constraints of the parent. Currently
<literal>UNIQUE</literal>, <literal>PRIMARY KEY</literal>, and
<literal>FOREIGN KEY</literal> constraints are ignored however this may
change in the future.
</para>
<para>
The easiest way to create a suitable table is to create a table using
<literal>INHERITS</literal> and then remove it via <literal>NO
INHERIT</literal>. Alternatively create a table using
<literal>LIKE</literal> however note that <literal>LIKE</literal> does
not create the necessary constraints.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>NO INHERIT <replaceable class="PARAMETER">parent_table</replaceable></literal></term>
<listitem>
<para>
This form removes a parent table from the list of parents of the table.
Queries against the parent table will no longer include records drawn
from the target table.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>OWNER</literal></term>
<listitem>
......
This diff is collapsed.
......@@ -15,7 +15,7 @@
* Portions Copyright (c) 1994, Regents of the University of California
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/nodes/copyfuncs.c,v 1.338 2006/07/01 18:38:32 tgl Exp $
* $PostgreSQL: pgsql/src/backend/nodes/copyfuncs.c,v 1.339 2006/07/02 01:58:36 momjian Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -1800,6 +1800,7 @@ _copyAlterTableCmd(AlterTableCmd *from)
COPY_SCALAR_FIELD(subtype);
COPY_STRING_FIELD(name);
COPY_NODE_FIELD(def);
COPY_NODE_FIELD(parent);
COPY_NODE_FIELD(transform);
COPY_SCALAR_FIELD(behavior);
......
......@@ -11,7 +11,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/parser/gram.y,v 2.548 2006/06/27 03:43:20 momjian Exp $
* $PostgreSQL: pgsql/src/backend/parser/gram.y,v 2.549 2006/07/02 01:58:36 momjian Exp $
*
* HISTORY
* AUTHOR DATE MAJOR EVENT
......@@ -1514,6 +1514,22 @@ alter_table_cmd:
n->subtype = AT_DisableTrigUser;
$$ = (Node *)n;
}
/* ALTER TABLE <name> ALTER INHERITS ADD <parent> */
| INHERIT qualified_name
{
AlterTableCmd *n = makeNode(AlterTableCmd);
n->subtype = AT_AddInherits;
n->parent = $2;
$$ = (Node *)n;
}
/* ALTER TABLE <name> alter INHERITS DROP <parent> */
| NO INHERIT qualified_name
{
AlterTableCmd *n = makeNode(AlterTableCmd);
n->subtype = AT_DropInherits;
n->parent = $3;
$$ = (Node *)n;
}
| alter_rel_cmd
{
$$ = $1;
......
......@@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2006, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/nodes/parsenodes.h,v 1.312 2006/06/27 03:43:20 momjian Exp $
* $PostgreSQL: pgsql/src/include/nodes/parsenodes.h,v 1.313 2006/07/02 01:58:36 momjian Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -874,7 +874,9 @@ typedef enum AlterTableType
AT_EnableTrigAll, /* ENABLE TRIGGER ALL */
AT_DisableTrigAll, /* DISABLE TRIGGER ALL */
AT_EnableTrigUser, /* ENABLE TRIGGER USER */
AT_DisableTrigUser /* DISABLE TRIGGER USER */
AT_DisableTrigUser, /* DISABLE TRIGGER USER */
AT_AddInherits, /* ADD INHERITS parent */
AT_DropInherits /* DROP INHERITS parent */
} AlterTableType;
typedef struct AlterTableCmd /* one subcommand of an ALTER TABLE */
......@@ -883,6 +885,7 @@ typedef struct AlterTableCmd /* one subcommand of an ALTER TABLE */
AlterTableType subtype; /* Type of table alteration to apply */
char *name; /* column, constraint, or trigger to act on,
* or new owner or tablespace */
RangeVar *parent; /* Parent table for add/drop inherits */
Node *def; /* definition of new column, column type,
* index, or constraint */
Node *transform; /* transformation expr for ALTER TYPE */
......
......@@ -306,6 +306,56 @@ insert into atacc3 (test2) values (3);
drop table atacc3;
drop table atacc2;
drop table atacc1;
-- same things with one created with INHERIT
create table atacc1 (test int);
create table atacc2 (test2 int);
create table atacc3 (test3 int) inherits (atacc1, atacc2);
alter table atacc3 no inherit atacc2;
-- fail
alter table atacc3 no inherit atacc2;
ERROR: relation "atacc2" is not a parent of relation "atacc3"
-- make sure it really isn't a child
insert into atacc3 (test2) values (3);
select test2 from atacc2;
test2
-------
(0 rows)
-- fail due to missing constraint
alter table atacc2 add constraint foo check (test2>0);
alter table atacc3 inherit atacc2;
ERROR: child table missing constraint matching parent table constraint "foo"
-- fail due to missing column
alter table atacc3 rename test2 to testx;
alter table atacc3 inherit atacc2;
ERROR: child table missing column "test2"
-- fail due to mismatched data type
alter table atacc3 add test2 bool;
alter table atacc3 add inherit atacc2;
alter table atacc3 drop test2;
-- succeed
alter table atacc3 add test2 int;
update atacc3 set test2 = 4 where test2 is null;
alter table atacc3 add constraint foo check (test2>0);
alter table atacc3 inherit atacc2;
-- fail due to duplicates and circular inheritance
alter table atacc3 inherit atacc2;
ERROR: inherited relation "atacc2" duplicated
alter table atacc2 inherit atacc3;
ERROR: circular inheritance structure found, "atacc3" is already a child of "atacc2"
alter table atacc2 inherit atacc2;
ERROR: circular inheritance structure found, "atacc2" is already a child of "atacc2"
-- test that we really are a child now (should see 4 not 3 and cascade should go through)
select test2 from atacc2;
test2
-------
4
(1 row)
drop table atacc2 cascade;
NOTICE: drop cascades to table atacc3
NOTICE: drop cascades to constraint foo on table atacc3
drop table atacc1;
-- let's try only to add only to the parent
create table atacc1 (test int);
create table atacc2 (test2 int);
......
......@@ -336,6 +336,40 @@ drop table atacc3;
drop table atacc2;
drop table atacc1;
-- same things with one created with INHERIT
create table atacc1 (test int);
create table atacc2 (test2 int);
create table atacc3 (test3 int) inherits (atacc1, atacc2);
alter table atacc3 no inherit atacc2;
-- fail
alter table atacc3 no inherit atacc2;
-- make sure it really isn't a child
insert into atacc3 (test2) values (3);
select test2 from atacc2;
-- fail due to missing constraint
alter table atacc2 add constraint foo check (test2>0);
alter table atacc3 inherit atacc2;
-- fail due to missing column
alter table atacc3 rename test2 to testx;
alter table atacc3 inherit atacc2;
-- fail due to mismatched data type
alter table atacc3 add test2 bool;
alter table atacc3 add inherit atacc2;
alter table atacc3 drop test2;
-- succeed
alter table atacc3 add test2 int;
update atacc3 set test2 = 4 where test2 is null;
alter table atacc3 add constraint foo check (test2>0);
alter table atacc3 inherit atacc2;
-- fail due to duplicates and circular inheritance
alter table atacc3 inherit atacc2;
alter table atacc2 inherit atacc3;
alter table atacc2 inherit atacc2;
-- test that we really are a child now (should see 4 not 3 and cascade should go through)
select test2 from atacc2;
drop table atacc2 cascade;
drop table atacc1;
-- let's try only to add only to the parent
create table atacc1 (test int);
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment