This page in other versions: 9.0 / 9.1 / 9.2 / 9.3 / 9.4  |  Development versions: devel  |  Unsupported versions: 7.1 / 7.2 / 7.3 / 7.4 / 8.0 / 8.1 / 8.2 / 8.3 / 8.4

ALTER TABLE

Name

ALTER TABLE -- change the definition of a table

Synopsis

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 CREATE TABLE.

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 ANALYZE 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.

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 CREATE TABLE.

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 CLUSTER 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 UPDATE.) 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. Chapter 5 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.

Comments


Aug. 25, 2004, 10:08 p.m.

For those who want to move table from one schema to another:

http://archives.postgresql.org/pgsql-general/2003-05/msg01252.php

But it would be nice to have such possibility using ALTER TABLE...


Oct. 1, 2004, 8:32 p.m.

To drop a constraint with a default generated constraint name, enclose the name in double quotes. Why double quotes? Beats me.

alter table foo drop constraint \"$1\";


July 25, 2005, 3:47 a.m.

To drop a primary key, drop the constraint with the appropriate name. For example:

dabc=# \d clicks_sum;
Table "public.clicks_sum"
Column | Type | Modifiers
--------+-------------------+-----------
url | character varying | not null
query | character varying | not null
count | integer |
date | date |
Indexes:
"clicks_sum_pkey" primary key, btree (url, query)
abc=# alter table clicks_sum drop constraint clicks_sum_pkey;
ALTER TABLE
abc=#


July 27, 2005, 11:32 a.m.

@Oliver Crow: double quotes are used to quote column and table names which contain characters not matching [a-z_][a-z_0-9]*


Dec. 23, 2005, 7:06 p.m.

Bruno's fears are right - there are some additional implications that must be taken into account in order to effectively move a table from one schema into another:

1. Tables have an associated pg_type that needs to be moved to the new schema as well.

2. Dependencies table pg_depend must be updated to reflect the change in schema.

The following script does the job for me:

begin;
create temp table mv_data as
select
(select n.oid from pg_namespace n where n.nspname = '$newschema') as new_schema_oid,
(select n.oid from pg_namespace n where n.nspname = '$oldschema') as old_schema_oid,
(select c.oid from pg_class c join pg_namespace n on c.relnamespace = n.oid where c.relname = '$table' and n.nspname = '$oldschema') as table_oid;

update pg_class set
relnamespace = (select new_schema_oid from mv_data)
where oid = (select table_oid from mv_data)
and relnamespace = (select old_schema_oid from mv_data);

update pg_depend set
refobjid = (select new_schema_oid from mv_data)
where objid = (select table_oid from mv_data)
and refobjid = (select old_schema_oid from mv_data);

update pg_type set
typnamespace = (select new_schema_oid from mv_data)
where typname = '$table'
and typnamespace = (select old_schema_oid from mv_data);

drop table mv_data;
commit;


Jan. 25, 2006, 6:08 p.m.

To change the data type of a column, do this:

BEGIN;
ALTER TABLE tab ADD COLUMN new_col new_data_type;
UPDATE tab SET new_col = CAST(old_col AS new_data_type);
ALTER TABLE tab DROP COLUMN old_col;
COMMIT;

You might then want to do VACUUM FULL tab to reclaim the disk space used by the expired rows.

Privacy Policy | About PostgreSQL
Copyright © 1996-2014 The PostgreSQL Global Development Group