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

ALTER TABLE

Name

ALTER TABLE  --  change the definition of a table

Synopsis

ALTER TABLE [ ONLY ] table [ * ]
    ADD [ COLUMN ] column type [ column_constraint [ ... ] ]
ALTER TABLE [ ONLY ] table [ * ]
    ALTER [ COLUMN ] column { SET DEFAULT value | DROP DEFAULT }
ALTER TABLE [ ONLY ] table [ * ]
    ALTER [ COLUMN ] column SET STATISTICS integer
ALTER TABLE [ ONLY ] table [ * ]
    RENAME [ COLUMN ] column TO newcolumn
ALTER TABLE table
    RENAME TO new_table
ALTER TABLE table
    ADD table_constraint_definition
ALTER TABLE [ ONLY ] table 
        DROP CONSTRAINT constraint { RESTRICT | CASCADE }
ALTER TABLE table
        OWNER TO new_owner 
  

Inputs

table

The name of an existing table to alter.

column

Name of a new or existing column.

type

Type of the new column.

newcolumn

New name for an existing column.

new_table

New name for the table.

table_constraint_definition

New table constraint for the table

new_owner

The user name of the new owner of the table.

Outputs

ALTER

Message returned from column or table renaming.

ERROR

Message returned if table or column is not available.

Description

ALTER TABLE changes the definition of an existing table. The ADD COLUMN form adds a new column to the table using the same syntax as CREATE TABLE. The ALTER COLUMN SET/DROP DEFAULT forms allow you to set or remove the default for the column. Note that defaults only apply to subsequent INSERT commands; they do not cause rows already in the table to change. The ALTER COLUMN SET STATISTICS form allows you to set the statistics-gathering target for subsequent ANALYZE operations. The RENAME clause causes the name of a table, column, index, or sequence to change without changing any of the data. The data will remain of the same type and size after the command is executed. The ADD table_constraint_definition clause adds a new constraint to the table using the same syntax as CREATE TABLE. The DROP CONSTRAINT constraint clause drops all constraints on the table (and its children) that match constraint. The OWNER clause changes the owner of the table to the user new user.

You must own the table in order to change its schema.

Notes

The keyword 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. You can use the SET DEFAULT form of ALTER TABLE to set the default later. (You may also want to update the already existing rows to the new default value, using UPDATE.)

In DROP CONSTRAINT, the RESTRICT keyword is required, although dependencies are not yet checked. The CASCADE option is unsupported. Currently DROP CONSTRAINT drops only CHECK constraints. To remove a PRIMARY or UNIQUE constraint, drop the relevant index using the DROP INDEX command. To remove FOREIGN KEY constraints you need to recreate and reload the table, using other parameters to the CREATE TABLE command.

For example, to drop all constraints on a table distributors:

CREATE TABLE temp AS SELECT * FROM distributors;
DROP TABLE distributors;
CREATE TABLE distributors AS SELECT * FROM temp;
DROP TABLE temp;
    

You must own the table in order to change it. Changing any part of the schema of a system catalog is not permitted. The PostgreSQL User's Guide has further information on inheritance.

Refer to CREATE TABLE for a further description of valid arguments.

Usage

To add a column of type varchar to a table:

ALTER TABLE distributors ADD COLUMN address VARCHAR(30);
   

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 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 RESTRICT;
   

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

SQL92

The ADD COLUMN form is compliant with the exception that it does not support defaults and NOT NULL constraints, as explained above. The ALTER COLUMN form is in full compliance.

SQL92 specifies some additional capabilities for ALTER TABLE statement which are not yet directly supported by PostgreSQL:

ALTER TABLE table DROP [ COLUMN ] column { RESTRICT | CASCADE }
      

Removes a column from a table. Currently, to remove an existing column the table must be recreated and reloaded:

CREATE TABLE temp AS SELECT did, city FROM distributors;    
DROP TABLE distributors;
CREATE TABLE distributors (
    did      DECIMAL(3)  DEFAULT 1,
    name     VARCHAR(40) NOT NULL
);
INSERT INTO distributors SELECT * FROM temp;
DROP TABLE temp;
       

The clauses to rename tables, columns, indexes, and sequences are PostgreSQL extensions from SQL92.

Comments


July 17, 2002, 2:28 a.m.

In response to the people who want to know how to drop columns but preserve foreign key relationships, here is a crude but effective solution.

1. Create a dump of the database into text file using the pg_dump command, e.g. pg_dump my_db > my_db.sql

2. In this file, find the portion in which the CREATE TABLE statement for the table you wish to drop the column from is.

3. Make a note as to what position the column is in the defintion.

4. Remove this column from the definition... its just a matter of deleting the line. If the column is the last one in the definition, make sure your parenthesis and semi-colons are still there.

5. Now go to the part of the file in which the data is copied back (it looks like COPY FROM STDIN with your table name), based on the position you wrote down in #3, delete the column value in each row being read in. Make sure there is exactly 1 tab between the two now adjacent columns.

6. Restore the database by dropping the original, recreating it, and then executing the psql command with data piped in from the text file (e.g., psql my_db < mydb.sql). You may want to experiment with a test database first to make sure you got it right.

This should solve the problem. I had to do this for a table which had over 60 foreign key references to other tables and views and it seems to work.


June 10, 2003, 10:02 a.m.

How to set NOT NULL on existing column:

BEGIN; //with caution :)

UPDATE pg_attribute SET attnotnull = TRUE
WHERE attname = \'my_column\' AND attrelid = ( SELECT oid FROM pg_class WHERE relname = \'my_table\') ;

COMMIT;


Oct. 6, 2003, 5:44 p.m.

To add a \'NOT NULL\' constraint to a table column I used the following:

1. If the column does not exist add it but do not add the \'NOT NULL\' constraint.

2. If the table contains existing rows make sure to populate the column you are adding the \'NOT NULL\' constraint to with values. If you try and add the \'NOT NULL\' constraint to a table that has existing rows and one or more of those rows are null in the column you are adding the \'NOT NULL\' constraint to then you will get an error.

3. Used this SQL statement to add the \'NOT NULL\' constraint:
\"ALTER TABLE my_table ALTER COLUMN my_not_null_column SET NOT NULL;\"
Subsitute your table name for \'my_table\' and the column name for
\'my_not_null_column\'.

Regards

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