ALTER TABLE
SQL - Language Statements
ALTER TABLE
change the definition of a table
ALTER TABLE
ALTER TABLE [ ONLY ] name [ * ]
ADD [ COLUMN ] column type [ column_constraint [ ... ] ]
ALTER TABLE [ ONLY ] name [ * ]
DROP [ COLUMN ] column [ RESTRICT | CASCADE ]
ALTER TABLE [ ONLY ] name [ * ]
ALTER [ COLUMN ] column { SET DEFAULT expression | DROP DEFAULT }
ALTER TABLE [ ONLY ] name [ * ]
ALTER [ COLUMN ] column { SET | DROP } NOT NULL
ALTER TABLE [ ONLY ] name [ * ]
ALTER [ COLUMN ] column SET STATISTICS integer
ALTER TABLE [ ONLY ] name [ * ]
ALTER [ COLUMN ] column SET STORAGE { PLAIN | EXTERNAL | EXTENDED | MAIN }
ALTER TABLE [ ONLY ] name [ * ]
SET WITHOUT OIDS
ALTER TABLE [ ONLY ] name [ * ]
RENAME [ COLUMN ] column TO new_column
ALTER TABLE name
RENAME TO new_name
ALTER TABLE [ ONLY ] name [ * ]
ADD table_constraint
ALTER TABLE [ ONLY ] name [ * ]
DROP CONSTRAINT constraint_name [ RESTRICT | CASCADE ]
ALTER TABLE name
OWNER TO new_owner
ALTER TABLE name
CLUSTER ON index_name
Description
ALTER TABLE changes the definition of an existing table.
There are several subforms:
ADD COLUMN
This form adds a new column to the table using the same syntax as
.
DROP COLUMN
This form drops a column from a table. Indexes and
table constraints involving the column will be automatically
dropped as well. You will need to say CASCADE> if
anything outside the table depends on the column, for example,
foreign key references or views.
SET/DROP DEFAULT
These forms set or remove the default value for a column.
The default values only apply to subsequent INSERT
commands; they do not cause rows already in the table to change.
Defaults may also be created for views, in which case they are
inserted into INSERT> statements on the view before
the view's ON INSERT rule is applied.
SET/DROP NOT NULL
These forms change whether a column is marked to allow null
values or to reject null values. You can only use SET
NOT NULL> when the column contains no null values.
SET STATISTICS
This form
sets the per-column statistics-gathering target for subsequent
operations.
The target can be set in the range 0 to 1000; alternatively, set it
to -1 to revert to using the system default statistics target.
SET STORAGE
This form sets the storage mode for a column. This controls whether this
column is held inline or in a supplementary table, and whether the data
should be compressed or not. PLAIN must be used
for fixed-length values such as integer and is
inline, uncompressed. MAIN is for inline,
compressible data. EXTERNAL is for external,
uncompressed data, and EXTENDED is for external,
compressed data. EXTENDED is the default for all
data types that support it. The use of EXTERNAL will, for example,
make substring operations on a text column faster, at the penalty of
increased storage space.
SET WITHOUT OIDS
This form removes the oid column from the
table. Removing OIDs from a table does not occur immediately.
The space that the OID uses will be reclaimed when the row is
updated. Without updating the row, both the space and the value
of the OID are kept indefinitely. This is semantically similar
to the DROP COLUMN process.
Note that there is no variant of ALTER TABLE
that allows OIDs to be restored to a table once they have been
removed.
RENAME
The RENAME forms change the name of a table
(or an index, sequence, or view) or the name of an individual column in
a table. There is no effect on the stored data.
ADD table_constraint
This form adds a new constraint to a table using the same syntax as
.
DROP CONSTRAINT
This form drops constraints on a table.
Currently, constraints on tables are not required to have unique
names, so there may be more than one constraint matching the specified
name. All such constraints will be dropped.
OWNER
This form changes the owner of the table, index, sequence, or view to the
specified user.
CLUSTER
This form marks a table for future
operations.
You must own the table to use ALTER TABLE>; except for
ALTER TABLE OWNER>, which may only be executed by a superuser.
Parameters
name
The name (possibly schema-qualified) of an existing table to
alter. If ONLY> is specified, only that table is
altered. If ONLY> is not specified, the table and all
its descendant tables (if any) are updated. *> can be
appended to the table name to indicate that descendant tables are
to be altered, but in the current version, this is the default
behavior. (In releases before 7.1, ONLY> was the
default behavior. The default can be altered by changing the
configuration parameter sql_inheritance.)
column
Name of a new or existing column.
type
Data type of the new column.
new_column
New name for an existing column.
new_name
New name for the table.
table_constraint
New table constraint for the table.
constraint_name
Name of an existing constraint to drop.
new_owner
The user name of the new owner of the table.
index_name
The index name on which the table should be marked for clustering.
CASCADE
Automatically drop objects that depend on the dropped column
or constraint (for example, views referencing the column).
RESTRICT
Refuse to drop the column or constraint if there are any dependent
objects. This is the default behavior.
Notes
The key word COLUMN is noise and can be omitted.
In the current implementation of ADD COLUMN,
default and NOT NULL> clauses for the new column are not supported.
The new column always comes into being with all values null.
You can use the SET DEFAULT form
of ALTER TABLE to set the default afterward.
(You may also want to update the already existing rows to the
new default value, using
.)
If you want to mark the column non-null, use the SET NOT NULL>
form after you've entered non-null values for the column in all rows.
The DROP COLUMN form does not physically remove
the column, but simply makes it invisible to SQL operations. Subsequent
insert and update operations in the table will store a null value for the column.
Thus, dropping a column is quick but it will not immediately reduce the
on-disk size of your table, as the space occupied
by the dropped column is not reclaimed. The space will be
reclaimed over time as existing rows are updated.
To reclaim the space at once, do a dummy UPDATE> of all rows
and then vacuum, as in:
UPDATE table SET col = col;
VACUUM FULL table;
If a table has any descendant tables, it is not permitted to add
or rename a column in the parent table without doing the same to
the descendants. That is, ALTER TABLE ONLY
will be rejected. This ensures that the descendants always have
columns matching the parent.
A recursive DROP COLUMN operation will remove a
descendant table's column only if the descendant does not inherit
that column from any other parents and never had an independent
definition of the column. A nonrecursive DROP
COLUMN (i.e., ALTER TABLE ONLY ... DROP
COLUMN) never removes any descendant columns, but
instead marks them as independently defined rather than inherited.
Changing any part of a system catalog table is not permitted.
Refer to CREATE TABLE for a further description
of valid parameters. has further information on
inheritance.
Examples
To add a column of type varchar to a table:
ALTER TABLE distributors ADD COLUMN address varchar(30);
To drop a column from a table:
ALTER TABLE distributors DROP COLUMN address RESTRICT;
To rename an existing column:
ALTER TABLE distributors RENAME COLUMN address TO city;
To rename an existing table:
ALTER TABLE distributors RENAME TO suppliers;
To add a not-null constraint to a column:
ALTER TABLE distributors ALTER COLUMN street SET NOT NULL;
To remove a not-null constraint from a column:
ALTER TABLE distributors ALTER COLUMN street DROP NOT NULL;
To add a check constraint to a table:
ALTER TABLE distributors ADD CONSTRAINT zipchk CHECK (char_length(zipcode) = 5);
To remove a check constraint from a table and all its children:
ALTER TABLE distributors DROP CONSTRAINT zipchk;
To add a foreign key constraint to a table:
ALTER TABLE distributors ADD CONSTRAINT distfk FOREIGN KEY (address) REFERENCES addresses (address) MATCH FULL;
To add a (multicolumn) unique constraint to a table:
ALTER TABLE distributors ADD CONSTRAINT dist_id_zipcode_key UNIQUE (dist_id, zipcode);
To add an automatically named primary key constraint to a table, noting
that a table can only ever have one primary key:
ALTER TABLE distributors ADD PRIMARY KEY (dist_id);
Compatibility
The ADD COLUMN form conforms with the SQL
standard, with the exception that it does not support defaults and
not-null constraints, as explained above. The ALTER
COLUMN form is in full conformance.
The clauses to rename tables, columns, indexes, views, and sequences are
PostgreSQL extensions of the SQL standard.
ALTER TABLE DROP COLUMN> can be used to drop the only
column of a table, leaving a zero-column table. This is an
extension of SQL, which disallows zero-column tables.