Skip to content
Projects
Groups
Snippets
Help
Loading...
Help
Support
Keyboard shortcuts
?
Submit feedback
Contribute to GitLab
Sign in
Toggle navigation
P
Postgres FD Implementation
Project overview
Project overview
Details
Activity
Releases
Repository
Repository
Files
Commits
Branches
Tags
Contributors
Graph
Compare
Issues
0
Issues
0
List
Boards
Labels
Milestones
Merge Requests
0
Merge Requests
0
CI / CD
CI / CD
Pipelines
Jobs
Schedules
Analytics
Analytics
CI / CD
Repository
Value Stream
Wiki
Wiki
Snippets
Snippets
Members
Members
Collapse sidebar
Close sidebar
Activity
Graph
Create a new issue
Jobs
Commits
Issue Boards
Open sidebar
Abuhujair Javed
Postgres FD Implementation
Commits
9b77f619
Commit
9b77f619
authored
Apr 01, 2002
by
Tom Lane
Browse files
Options
Browse Files
Download
Email Patches
Plain Diff
ALTER TABLE SET/DROP NOT NULL, from Christopher Kings-Lynne.
parent
838fe25a
Changes
9
Expand all
Show whitespace changes
Inline
Side-by-side
Showing
9 changed files
with
506 additions
and
45 deletions
+506
-45
doc/src/sgml/ref/alter_table.sgml
doc/src/sgml/ref/alter_table.sgml
+17
-1
doc/src/sgml/release.sgml
doc/src/sgml/release.sgml
+2
-1
src/backend/commands/command.c
src/backend/commands/command.c
+315
-39
src/backend/parser/gram.y
src/backend/parser/gram.y
+19
-1
src/backend/tcop/utility.c
src/backend/tcop/utility.c
+11
-1
src/include/commands/command.h
src/include/commands/command.h
+7
-1
src/include/nodes/parsenodes.h
src/include/nodes/parsenodes.h
+3
-1
src/test/regress/expected/alter_table.out
src/test/regress/expected/alter_table.out
+71
-0
src/test/regress/sql/alter_table.sql
src/test/regress/sql/alter_table.sql
+61
-0
No files found.
doc/src/sgml/ref/alter_table.sgml
View file @
9b77f619
<!--
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/alter_table.sgml,v 1.4
0 2002/03/06 20:42:38 momjian
Exp $
$Header: /cvsroot/pgsql/doc/src/sgml/ref/alter_table.sgml,v 1.4
1 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>
...
...
doc/src/sgml/release.sgml
View file @
9b77f619
<!--
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/release.sgml,v 1.12
8 2002/03/25 21:24:08 momjian
Exp $
$Header: /cvsroot/pgsql/doc/src/sgml/release.sgml,v 1.12
9 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
...
...
src/backend/commands/command.c
View file @
9b77f619
This diff is collapsed.
Click to expand it.
src/backend/parser/gram.y
View file @
9b77f619
...
@@ -11,7 +11,7 @@
...
@@ -11,7 +11,7 @@
*
*
*
*
* IDENTIFICATION
* IDENTIFICATION
* $Header: /cvsroot/pgsql/src/backend/parser/gram.y,v 2.29
8 2002/04/01 03:34:25
tgl Exp $
* $Header: /cvsroot/pgsql/src/backend/parser/gram.y,v 2.29
9 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
{
{
...
...
src/backend/tcop/utility.c
View file @
9b77f619
...
@@ -10,7 +10,7 @@
...
@@ -10,7 +10,7 @@
*
*
*
*
* IDENTIFICATION
* IDENTIFICATION
* $Header: /cvsroot/pgsql/src/backend/tcop/utility.c,v 1.14
4 2002/03/31 07:49:30
tgl Exp $
* $Header: /cvsroot/pgsql/src/backend/tcop/utility.c,v 1.14
5 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 */
/*
/*
...
...
src/include/commands/command.h
View file @
9b77f619
...
@@ -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.3
6 2002/03/29 19:06:21
tgl Exp $
* $Id: command.h,v 1.3
7 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
);
...
...
src/include/nodes/parsenodes.h
View file @
9b77f619
...
@@ -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.16
6 2002/03/29 19:06:23
tgl Exp $
* $Id: parsenodes.h,v 1.16
7 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
...
...
src/test/regress/expected/alter_table.out
View file @
9b77f619
...
@@ -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;
src/test/regress/sql/alter_table.sql
View file @
9b77f619
...
@@ -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
;
Write
Preview
Markdown
is supported
0%
Try again
or
attach a new file
Attach a file
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Cancel
Please
register
or
sign in
to comment