ALTER TABLE
  SQL - Language Statements
 
 
  
   ALTER TABLE
  
  
   change the definition of a table
  
 
 
  
   1999-07-20
  
  
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 | DROP } NOT NULL
ALTER TABLE [ ONLY ] table [ * ]
    ALTER [ COLUMN ] column SET STATISTICS integer
ALTER TABLE [ ONLY ] table [ * ]
    ALTER [ COLUMN ] column SET STORAGE { PLAIN | EXTERNAL | EXTENDED | MAIN }
ALTER TABLE [ ONLY ] table [ * ]
    RENAME [ COLUMN ] column TO new_column
ALTER TABLE table
    RENAME TO new_table
ALTER TABLE table
    ADD table_constraint_definition
ALTER TABLE [ ONLY ] table 
	DROP CONSTRAINT constraint_name { RESTRICT | CASCADE }
ALTER TABLE table
	OWNER TO new_owner 
  
  
   
    1998-04-15
   
   
    Inputs
   
   
    
     
       table 
      
       
	The name (possibly schema-qualified) of an existing table to alter.
       
      
     
     
       column 
      
       
	Name of a new or existing column.
       
      
     
     
       type 
      
       
	Type of the new column.
       
      
     
     
       new_column 
      
       
	New name for an existing column.
       
      
     
     
       new_table 
      
       
	New name for the table.
       
      
     
     
       table_constraint_definition 
      
       
	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.
       
      
     
    
   
  
  
   
    1998-04-15
   
   
    Outputs
   
   
    
     
      ALTER
      
       
	Message returned from column or table renaming.
       
      
     
     
      ERROR
      
       
	Message returned if table or column is not available.
       
      
     
    
   
  
 
 
  
   1998-04-15
  
  
   Description
  
  
   ALTER TABLE changes the definition of an existing table.
   There are several sub-forms:
  
  
   
    ADD COLUMN
    
     
      This form adds a new column to the table using the same syntax as
      .
     
    
   
   
    SET/DROP DEFAULT
    
     
      These forms set or remove the default value for a column. Note
      that defaults 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 may only SET NOT NULL>
      when the table contains no NULLs in the column.
     
    
   
   
    SET STATISTICS
    
     
      This form
      sets the per-column statistics-gathering target for subsequent
       operations.
     
    
   
   
    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
      datatypes that support it.  The use of EXTERNAL will
      make substring operations on a TEXT column faster, at the penalty of
      increased storage space.
     
    
   
   
    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_definition
    
     
      This form adds a new constraint to a table using the same syntax as
      . 
     
    
   
   
    DROP CONSTRAINT
    
     
      This form drops constraints on a table (and its children).
      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.
     
    
   
  
  
   You must own the table to use ALTER TABLE>; except for
   ALTER TABLE OWNER>, which may only be executed by a superuser.
  
  
   
    1998-04-15
   
   
    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.
    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 afterwards.
    (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.
   
   
    In DROP CONSTRAINT, the RESTRICT keyword is required, although
    dependencies are not yet checked.  The CASCADE option is unsupported.  
    Currently DROP CONSTRAINT only handles CHECK constraints.
    To remove a PRIMARY or UNIQUE constraint, drop the 
    relevant index using the  command.
    To remove FOREIGN KEY constraints you need to recreate
    and reload the table, using other parameters to the
     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;
    
   
   
    Changing any  part  of  the schema of a system
    catalog is not permitted.
   
   
    Refer to CREATE TABLE for a further description
    of valid arguments.
    The PostgreSQL User's Guide has further
    information on inheritance.
   
  
 
 
  
   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 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 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
  
  
   
    1998-04-15
   
   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.