Commit 9b77f619 authored by Tom Lane's avatar Tom Lane

ALTER TABLE SET/DROP NOT NULL, from Christopher Kings-Lynne.

parent 838fe25a
<!-- <!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/alter_table.sgml,v 1.40 2002/03/06 20:42:38 momjian Exp $ $Header: /cvsroot/pgsql/doc/src/sgml/ref/alter_table.sgml,v 1.41 2002/04/01 04:35:37 tgl Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -28,6 +28,8 @@ ALTER TABLE [ ONLY ] <replaceable class="PARAMETER">table</replaceable> [ * ] ...@@ -28,6 +28,8 @@ ALTER TABLE [ ONLY ] <replaceable class="PARAMETER">table</replaceable> [ * ]
ALTER TABLE [ ONLY ] <replaceable class="PARAMETER">table</replaceable> [ * ] ALTER TABLE [ ONLY ] <replaceable class="PARAMETER">table</replaceable> [ * ]
ALTER [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> { SET DEFAULT <replaceable ALTER [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> { SET DEFAULT <replaceable
class="PARAMETER">value</replaceable> | DROP DEFAULT } class="PARAMETER">value</replaceable> | DROP DEFAULT }
ALTER TABLE [ ONLY ] <replaceable class="PARAMETER">table</replaceable> [ * ]
ALTER [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> { SET | DROP } NOT NULL
ALTER TABLE [ ONLY ] <replaceable class="PARAMETER">table</replaceable> [ * ] ALTER TABLE [ ONLY ] <replaceable class="PARAMETER">table</replaceable> [ * ]
ALTER [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> SET STATISTICS <replaceable class="PARAMETER">integer</replaceable> ALTER [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> SET STATISTICS <replaceable class="PARAMETER">integer</replaceable>
ALTER TABLE [ ONLY ] <replaceable class="PARAMETER">table</replaceable> [ * ] ALTER TABLE [ ONLY ] <replaceable class="PARAMETER">table</replaceable> [ * ]
...@@ -168,6 +170,9 @@ ALTER TABLE <replaceable class="PARAMETER">table</replaceable> ...@@ -168,6 +170,9 @@ ALTER TABLE <replaceable class="PARAMETER">table</replaceable>
allow you to set or remove the default for the column. Note that defaults allow you to set or remove the default for the column. Note that defaults
only apply to subsequent <command>INSERT</command> commands; they do not only apply to subsequent <command>INSERT</command> commands; they do not
cause rows already in the table to change. cause rows already in the table to change.
The <literal>ALTER COLUMN SET/DROP NOT NULL</literal> forms allow you to
change whether a column is marked to allow NULL values or to reject NULL
values.
The <literal>ALTER COLUMN SET STATISTICS</literal> form allows you to The <literal>ALTER COLUMN SET STATISTICS</literal> form allows you to
set the statistics-gathering target for subsequent set the statistics-gathering target for subsequent
<xref linkend="sql-analyze" endterm="sql-analyze-title"> operations. <xref linkend="sql-analyze" endterm="sql-analyze-title"> operations.
...@@ -279,6 +284,17 @@ ALTER TABLE distributors RENAME TO suppliers; ...@@ -279,6 +284,17 @@ ALTER TABLE distributors RENAME TO suppliers;
</programlisting> </programlisting>
</para> </para>
<para>
To add a NOT NULL constraint to a column:
<programlisting>
ALTER TABLE distributors ALTER COLUMN street SET NOT NULL;
</programlisting>
To remove a NOT NULL constraint from a column:
<programlisting>
ALTER TABLE distributors ALTER COLUMN street DROP NOT NULL;
</programlisting>
</para>
<para> <para>
To add a check constraint to a table: To add a check constraint to a table:
<programlisting> <programlisting>
......
<!-- <!--
$Header: /cvsroot/pgsql/doc/src/sgml/release.sgml,v 1.128 2002/03/25 21:24:08 momjian Exp $ $Header: /cvsroot/pgsql/doc/src/sgml/release.sgml,v 1.129 2002/04/01 04:35:37 tgl Exp $
--> -->
<appendix id="release"> <appendix id="release">
...@@ -24,6 +24,7 @@ CDATA means the content is "SGML-free", so you can write without ...@@ -24,6 +24,7 @@ CDATA means the content is "SGML-free", so you can write without
worries about funny characters. worries about funny characters.
--> -->
<literallayout><![CDATA[ <literallayout><![CDATA[
ALTER TABLE ALTER COLUMN SET/DROP NOT NULL
EXPLAIN output comes out as a query result, not a NOTICE message EXPLAIN output comes out as a query result, not a NOTICE message
DOMAINs (types that are constrained versions of base types) DOMAINs (types that are constrained versions of base types)
Access privileges on functions Access privileges on functions
......
This diff is collapsed.
...@@ -11,7 +11,7 @@ ...@@ -11,7 +11,7 @@
* *
* *
* IDENTIFICATION * IDENTIFICATION
* $Header: /cvsroot/pgsql/src/backend/parser/gram.y,v 2.298 2002/04/01 03:34:25 tgl Exp $ * $Header: /cvsroot/pgsql/src/backend/parser/gram.y,v 2.299 2002/04/01 04:35:38 tgl Exp $
* *
* HISTORY * HISTORY
* AUTHOR DATE MAJOR EVENT * AUTHOR DATE MAJOR EVENT
...@@ -1122,6 +1122,24 @@ AlterTableStmt: ...@@ -1122,6 +1122,24 @@ AlterTableStmt:
n->def = $7; n->def = $7;
$$ = (Node *)n; $$ = (Node *)n;
} }
/* ALTER TABLE <relation> ALTER [COLUMN] <colname> DROP NOT NULL */
| ALTER TABLE relation_expr ALTER opt_column ColId DROP NOT NULL_P
{
AlterTableStmt *n = makeNode(AlterTableStmt);
n->subtype = 'N';
n->relation = $3;
n->name = $6;
$$ = (Node *)n;
}
/* ALTER TABLE <relation> ALTER [COLUMN] <colname> SET NOT NULL */
| ALTER TABLE relation_expr ALTER opt_column ColId SET NOT NULL_P
{
AlterTableStmt *n = makeNode(AlterTableStmt);
n->subtype = 'O';
n->relation = $3;
n->name = $6;
$$ = (Node *)n;
}
/* ALTER TABLE <relation> ALTER [COLUMN] <colname> SET STATISTICS <Iconst> */ /* ALTER TABLE <relation> ALTER [COLUMN] <colname> SET STATISTICS <Iconst> */
| ALTER TABLE relation_expr ALTER opt_column ColId SET STATISTICS Iconst | ALTER TABLE relation_expr ALTER opt_column ColId SET STATISTICS Iconst
{ {
......
...@@ -10,7 +10,7 @@ ...@@ -10,7 +10,7 @@
* *
* *
* IDENTIFICATION * IDENTIFICATION
* $Header: /cvsroot/pgsql/src/backend/tcop/utility.c,v 1.144 2002/03/31 07:49:30 tgl Exp $ * $Header: /cvsroot/pgsql/src/backend/tcop/utility.c,v 1.145 2002/04/01 04:35:39 tgl Exp $
* *
*------------------------------------------------------------------------- *-------------------------------------------------------------------------
*/ */
...@@ -437,6 +437,16 @@ ProcessUtility(Node *parsetree, ...@@ -437,6 +437,16 @@ ProcessUtility(Node *parsetree,
stmt->name, stmt->name,
stmt->def); stmt->def);
break; break;
case 'N': /* ALTER COLUMN DROP NOT NULL */
AlterTableAlterColumnDropNotNull(RangeVarGetRelid(stmt->relation, false),
interpretInhOption(stmt->relation->inhOpt),
stmt->name);
break;
case 'O': /* ALTER COLUMN SET NOT NULL */
AlterTableAlterColumnSetNotNull(RangeVarGetRelid(stmt->relation, false),
interpretInhOption(stmt->relation->inhOpt),
stmt->name);
break;
case 'S': /* ALTER COLUMN STATISTICS */ case 'S': /* ALTER COLUMN STATISTICS */
case 'M': /* ALTER COLUMN STORAGE */ case 'M': /* ALTER COLUMN STORAGE */
/* /*
......
...@@ -7,7 +7,7 @@ ...@@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2001, PostgreSQL Global Development Group * Portions Copyright (c) 1996-2001, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California * Portions Copyright (c) 1994, Regents of the University of California
* *
* $Id: command.h,v 1.36 2002/03/29 19:06:21 tgl Exp $ * $Id: command.h,v 1.37 2002/04/01 04:35:39 tgl Exp $
* *
*------------------------------------------------------------------------- *-------------------------------------------------------------------------
*/ */
...@@ -45,6 +45,12 @@ extern void AlterTableAddColumn(Oid myrelid, bool inherits, ColumnDef *colDef); ...@@ -45,6 +45,12 @@ extern void AlterTableAddColumn(Oid myrelid, bool inherits, ColumnDef *colDef);
extern void AlterTableAlterColumnDefault(Oid myrelid, bool inh, extern void AlterTableAlterColumnDefault(Oid myrelid, bool inh,
const char *colName, Node *newDefault); const char *colName, Node *newDefault);
extern void AlterTableAlterColumnDropNotNull(Oid myrelid,
bool inh, const char *colName);
extern void AlterTableAlterColumnSetNotNull(Oid myrelid,
bool inh, const char *colName);
extern void AlterTableAlterColumnFlags(Oid myrelid, extern void AlterTableAlterColumnFlags(Oid myrelid,
bool inh, const char *colName, bool inh, const char *colName,
Node *flagValue, const char *flagType); Node *flagValue, const char *flagType);
......
...@@ -7,7 +7,7 @@ ...@@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2001, PostgreSQL Global Development Group * Portions Copyright (c) 1996-2001, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California * Portions Copyright (c) 1994, Regents of the University of California
* *
* $Id: parsenodes.h,v 1.166 2002/03/29 19:06:23 tgl Exp $ * $Id: parsenodes.h,v 1.167 2002/04/01 04:35:40 tgl Exp $
* *
*------------------------------------------------------------------------- *-------------------------------------------------------------------------
*/ */
...@@ -728,6 +728,8 @@ typedef struct AlterTableStmt ...@@ -728,6 +728,8 @@ typedef struct AlterTableStmt
char subtype; /*------------ char subtype; /*------------
* A = add column * A = add column
* T = alter column default * T = alter column default
* N = alter column drop not null
* O = alter column set not null
* S = alter column statistics * S = alter column statistics
* M = alter column storage * M = alter column storage
* D = drop column * D = drop column
......
...@@ -578,3 +578,74 @@ ERROR: Cannot insert a duplicate key into unique index atacc1_pkey ...@@ -578,3 +578,74 @@ ERROR: Cannot insert a duplicate key into unique index atacc1_pkey
insert into atacc1 (test2, test) values (1, NULL); insert into atacc1 (test2, test) values (1, NULL);
ERROR: ExecAppend: Fail to add null value in not null attribute test ERROR: ExecAppend: Fail to add null value in not null attribute test
drop table atacc1; drop table atacc1;
-- alter table / alter column [set/drop] not null tests
-- try altering system catalogs, should fail
alter table pg_class alter column relname drop not null;
ERROR: ALTER TABLE: relation "pg_class" is a system catalog
alter table pg_class alter relname set not null;
ERROR: ALTER TABLE: relation "pg_class" is a system catalog
-- try altering non-existent table, should fail
alter table foo alter column bar set not null;
ERROR: Relation "foo" does not exist
alter table foo alter column bar drop not null;
ERROR: Relation "foo" does not exist
-- test setting columns to null and not null and vice versa
-- test checking for null values and primary key
create table atacc1 (test int not null);
alter table atacc1 add constraint "atacc1_pkey" primary key (test);
NOTICE: ALTER TABLE / ADD PRIMARY KEY will create implicit index 'atacc1_pkey' for table 'atacc1'
alter table atacc1 alter column test drop not null;
ERROR: ALTER TABLE: Attribute "test" is in a primary key
drop index atacc1_pkey;
alter table atacc1 alter column test drop not null;
insert into atacc1 values (null);
alter table atacc1 alter test set not null;
ERROR: ALTER TABLE: Attribute "test" contains NULL values
delete from atacc1;
alter table atacc1 alter test set not null;
-- try altering a non-existent column, should fail
alter table atacc1 alter bar set not null;
ERROR: ALTER TABLE: relation "atacc1" has no column "bar"
alter table atacc1 alter bar drop not null;
ERROR: ALTER TABLE: relation "atacc1" has no column "bar"
-- try altering the oid column, should fail
alter table atacc1 alter oid set not null;
ERROR: ALTER TABLE: Cannot alter system attribute "oid"
alter table atacc1 alter oid drop not null;
ERROR: ALTER TABLE: Cannot alter system attribute "oid"
-- try creating a view and altering that, should fail
create view myview as select * from atacc1;
alter table myview alter column test drop not null;
ERROR: ALTER TABLE: relation "myview" is not a table
alter table myview alter column test set not null;
ERROR: ALTER TABLE: relation "myview" is not a table
drop view myview;
drop table atacc1;
-- test inheritance
create table parent (a int);
create table child (b varchar(255)) inherits (parent);
alter table parent alter a set not null;
insert into parent values (NULL);
ERROR: ExecAppend: Fail to add null value in not null attribute a
insert into child (a, b) values (NULL, 'foo');
ERROR: ExecAppend: Fail to add null value in not null attribute a
alter table parent alter a drop not null;
insert into parent values (NULL);
insert into child (a, b) values (NULL, 'foo');
alter table only parent alter a set not null;
ERROR: ALTER TABLE: Attribute "a" contains NULL values
alter table child alter a set not null;
ERROR: ALTER TABLE: Attribute "a" contains NULL values
delete from parent;
alter table only parent alter a set not null;
insert into parent values (NULL);
ERROR: ExecAppend: Fail to add null value in not null attribute a
alter table child alter a set not null;
insert into child (a, b) values (NULL, 'foo');
ERROR: ExecAppend: Fail to add null value in not null attribute a
delete from child;
alter table child alter a set not null;
insert into child (a, b) values (NULL, 'foo');
ERROR: ExecAppend: Fail to add null value in not null attribute a
drop table child;
drop table parent;
...@@ -452,3 +452,64 @@ insert into atacc1 (test2, test) values (3, 3); ...@@ -452,3 +452,64 @@ insert into atacc1 (test2, test) values (3, 3);
insert into atacc1 (test2, test) values (2, 3); insert into atacc1 (test2, test) values (2, 3);
insert into atacc1 (test2, test) values (1, NULL); insert into atacc1 (test2, test) values (1, NULL);
drop table atacc1; drop table atacc1;
-- alter table / alter column [set/drop] not null tests
-- try altering system catalogs, should fail
alter table pg_class alter column relname drop not null;
alter table pg_class alter relname set not null;
-- try altering non-existent table, should fail
alter table foo alter column bar set not null;
alter table foo alter column bar drop not null;
-- test setting columns to null and not null and vice versa
-- test checking for null values and primary key
create table atacc1 (test int not null);
alter table atacc1 add constraint "atacc1_pkey" primary key (test);
alter table atacc1 alter column test drop not null;
drop index atacc1_pkey;
alter table atacc1 alter column test drop not null;
insert into atacc1 values (null);
alter table atacc1 alter test set not null;
delete from atacc1;
alter table atacc1 alter test set not null;
-- try altering a non-existent column, should fail
alter table atacc1 alter bar set not null;
alter table atacc1 alter bar drop not null;
-- try altering the oid column, should fail
alter table atacc1 alter oid set not null;
alter table atacc1 alter oid drop not null;
-- try creating a view and altering that, should fail
create view myview as select * from atacc1;
alter table myview alter column test drop not null;
alter table myview alter column test set not null;
drop view myview;
drop table atacc1;
-- test inheritance
create table parent (a int);
create table child (b varchar(255)) inherits (parent);
alter table parent alter a set not null;
insert into parent values (NULL);
insert into child (a, b) values (NULL, 'foo');
alter table parent alter a drop not null;
insert into parent values (NULL);
insert into child (a, b) values (NULL, 'foo');
alter table only parent alter a set not null;
alter table child alter a set not null;
delete from parent;
alter table only parent alter a set not null;
insert into parent values (NULL);
alter table child alter a set not null;
insert into child (a, b) values (NULL, 'foo');
delete from child;
alter table child alter a set not null;
insert into child (a, b) values (NULL, 'foo');
drop table child;
drop table parent;
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