mirror of https://github.com/postgres/postgres
You can not select more than 25 topics
Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
589 lines
19 KiB
589 lines
19 KiB
<!--
|
|
$PostgreSQL: pgsql/doc/src/sgml/ref/alter_table.sgml,v 1.71 2004/06/02 21:01:08 momjian Exp $
|
|
PostgreSQL documentation
|
|
-->
|
|
|
|
<refentry id="SQL-ALTERTABLE">
|
|
<refmeta>
|
|
<refentrytitle id="sql-altertable-title">ALTER TABLE</refentrytitle>
|
|
<refmiscinfo>SQL - Language Statements</refmiscinfo>
|
|
</refmeta>
|
|
|
|
<refnamediv>
|
|
<refname>ALTER TABLE</refname>
|
|
<refpurpose>change the definition of a table</refpurpose>
|
|
</refnamediv>
|
|
|
|
<indexterm zone="sql-altertable">
|
|
<primary>ALTER TABLE</primary>
|
|
</indexterm>
|
|
|
|
<refsynopsisdiv>
|
|
<synopsis>
|
|
ALTER TABLE [ ONLY ] <replaceable class="PARAMETER">name</replaceable> [ * ]
|
|
<replaceable class="PARAMETER">action</replaceable> [, ... ]
|
|
ALTER TABLE [ ONLY ] <replaceable class="PARAMETER">name</replaceable> [ * ]
|
|
RENAME [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> TO <replaceable class="PARAMETER">new_column</replaceable>
|
|
ALTER TABLE <replaceable class="PARAMETER">name</replaceable>
|
|
RENAME TO <replaceable class="PARAMETER">new_name</replaceable>
|
|
|
|
where <replaceable class="PARAMETER">action</replaceable> is one of:
|
|
|
|
ADD [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> <replaceable class="PARAMETER">type</replaceable> [ <replaceable class="PARAMETER">column_constraint</replaceable> [ ... ] ]
|
|
DROP [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> [ RESTRICT | CASCADE ]
|
|
ALTER [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> TYPE <replaceable class="PARAMETER">type</replaceable> [ USING <replaceable class="PARAMETER">expression</replaceable> ]
|
|
ALTER [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> SET DEFAULT <replaceable class="PARAMETER">expression</replaceable>
|
|
ALTER [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> DROP DEFAULT
|
|
ALTER [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> { SET | DROP } NOT NULL
|
|
ALTER [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> SET STATISTICS <replaceable class="PARAMETER">integer</replaceable>
|
|
ALTER [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> SET STORAGE { PLAIN | EXTERNAL | EXTENDED | MAIN }
|
|
ADD <replaceable class="PARAMETER">table_constraint</replaceable>
|
|
DROP CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable> [ RESTRICT | CASCADE ]
|
|
SET WITHOUT OIDS
|
|
OWNER TO <replaceable class="PARAMETER">new_owner</replaceable>
|
|
CLUSTER ON <replaceable class="PARAMETER">index_name</replaceable>
|
|
SET WITHOUT CLUSTER
|
|
</synopsis>
|
|
</refsynopsisdiv>
|
|
|
|
<refsect1>
|
|
<title>Description</title>
|
|
|
|
<para>
|
|
<command>ALTER TABLE</command> changes the definition of an existing table.
|
|
There are several subforms:
|
|
|
|
<variablelist>
|
|
<varlistentry>
|
|
<term><literal>ADD COLUMN</literal></term>
|
|
<listitem>
|
|
<para>
|
|
This form adds a new column to the table using the same syntax as
|
|
<xref linkend="SQL-CREATETABLE" endterm="SQL-CREATETABLE-TITLE">.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>DROP COLUMN</literal></term>
|
|
<listitem>
|
|
<para>
|
|
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 <literal>CASCADE</> if
|
|
anything outside the table depends on the column, for example,
|
|
foreign key references or views.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>ALTER COLUMN TYPE</literal></term>
|
|
<listitem>
|
|
<para>
|
|
This form changes the type of a column of a table. Indexes and
|
|
simple table constraints involving the column will be automatically
|
|
converted to use the new column type by reparsing the originally
|
|
supplied expression. The optional <literal>USING</literal>
|
|
clause specifies how to compute the new column value from the old;
|
|
if omitted, the default conversion is the same as an assignment
|
|
cast from old data type to new. A <literal>USING</literal>
|
|
clause must be provided if there is no implicit or assignment
|
|
cast from old to new type.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>SET</literal>/<literal>DROP DEFAULT</literal></term>
|
|
<listitem>
|
|
<para>
|
|
These forms set or remove the default value for a column.
|
|
The default values only apply to subsequent <command>INSERT</command>
|
|
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 <command>INSERT</> statements on the view before
|
|
the view's <literal>ON INSERT</literal> rule is applied.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>SET</literal>/<literal>DROP NOT NULL</literal></term>
|
|
<listitem>
|
|
<para>
|
|
These forms change whether a column is marked to allow null
|
|
values or to reject null values. You can only use <literal>SET
|
|
NOT NULL</> when the column contains no null values.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>SET STATISTICS</literal></term>
|
|
<listitem>
|
|
<para>
|
|
This form
|
|
sets the per-column statistics-gathering target for subsequent
|
|
<xref linkend="sql-analyze" endterm="sql-analyze-title"> 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. For more information on the use of statistics by the
|
|
<productname>PostgreSQL</productname> query planner, refer to
|
|
<xref linkend="planner-stats">.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<indexterm>
|
|
<primary>TOAST</primary>
|
|
<secondary>per-column storage settings</secondary>
|
|
</indexterm>
|
|
|
|
<term><literal>SET STORAGE</literal></term>
|
|
<listitem>
|
|
<para>
|
|
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. <literal>PLAIN</literal> must be used
|
|
for fixed-length values such as <type>integer</type> and is
|
|
inline, uncompressed. <literal>MAIN</literal> is for inline,
|
|
compressible data. <literal>EXTERNAL</literal> is for external,
|
|
uncompressed data, and <literal>EXTENDED</literal> is for external,
|
|
compressed data. <literal>EXTENDED</literal> is the default for all
|
|
data types that support it. The use of <literal>EXTERNAL</literal> will, for example,
|
|
make substring operations on a <type>text</type> column faster, at the penalty of
|
|
increased storage space.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>ADD <replaceable class="PARAMETER">table_constraint</replaceable></literal></term>
|
|
<listitem>
|
|
<para>
|
|
This form adds a new constraint to a table using the same syntax as
|
|
<xref linkend="SQL-CREATETABLE" endterm="SQL-CREATETABLE-TITLE">.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>DROP CONSTRAINT</literal></term>
|
|
<listitem>
|
|
<para>
|
|
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 matching constraints will be dropped.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>SET WITHOUT OIDS</literal></term>
|
|
<listitem>
|
|
<para>
|
|
This form removes the <literal>oid</literal> system column from the
|
|
table. This is exactly equivalent to
|
|
<literal>DROP COLUMN oid RESTRICT</literal>,
|
|
except that it will not complain if there is already no
|
|
<literal>oid</literal> column.
|
|
</para>
|
|
|
|
<para>
|
|
Note that there is no variant of <command>ALTER TABLE</command>
|
|
that allows OIDs to be restored to a table once they have been
|
|
removed.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>OWNER</literal></term>
|
|
<listitem>
|
|
<para>
|
|
This form changes the owner of the table, index, sequence, or view to the
|
|
specified user.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>CLUSTER</literal></term>
|
|
<listitem>
|
|
<para>
|
|
This form selects the default index for future
|
|
<xref linkend="SQL-CLUSTER" endterm="sql-cluster-title">
|
|
operations.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>SET WITHOUT CLUSTER</literal></term>
|
|
<listitem>
|
|
<para>
|
|
This form removes the most recently used
|
|
<xref linkend="SQL-CLUSTER" endterm="sql-cluster-title">
|
|
index specification from the table.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>RENAME</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The <literal>RENAME</literal> 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.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</para>
|
|
|
|
<para>
|
|
All the actions except <literal>RENAME</literal> can be combined into
|
|
a list of multiple alterations to apply in parallel. For example, it
|
|
is possible to add several columns and/or alter the type of several
|
|
columns in a single command. This is particularly useful with large
|
|
tables, since only one pass over the table need be made.
|
|
</para>
|
|
|
|
<para>
|
|
You must own the table to use <command>ALTER TABLE</>; except for
|
|
<command>ALTER TABLE OWNER</>, which may only be executed by a superuser.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Parameters</title>
|
|
|
|
<variablelist>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">name</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The name (possibly schema-qualified) of an existing table to
|
|
alter. If <literal>ONLY</> is specified, only that table is
|
|
altered. If <literal>ONLY</> is not specified, the table and all
|
|
its descendant tables (if any) are updated. <literal>*</> 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, <literal>ONLY</> was the
|
|
default behavior. The default can be altered by changing the
|
|
configuration parameter <xref linkend="guc-sql-inheritance">.)
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">column</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
Name of a new or existing column.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">type</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
Data type of the new column, or new data type for an existing
|
|
column.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">new_column</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
New name for an existing column.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">new_name</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
New name for the table.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">table_constraint</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
New table constraint for the table.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">constraint_name</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
Name of an existing constraint to drop.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">new_owner</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The user name of the new owner of the table.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="PARAMETER">index_name</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The index name on which the table should be marked for clustering.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>CASCADE</literal></term>
|
|
<listitem>
|
|
<para>
|
|
Automatically drop objects that depend on the dropped column
|
|
or constraint (for example, views referencing the column).
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>RESTRICT</literal></term>
|
|
<listitem>
|
|
<para>
|
|
Refuse to drop the column or constraint if there are any dependent
|
|
objects. This is the default behavior.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Notes</title>
|
|
|
|
<para>
|
|
The key word <literal>COLUMN</literal> is noise and can be omitted.
|
|
</para>
|
|
|
|
<para>
|
|
When a column is added with <literal>ADD COLUMN</literal>, all existing
|
|
rows in the table are initialized with the column's default value
|
|
(NULL if no <literal>DEFAULT</> clause is specified).
|
|
</para>
|
|
|
|
<para>
|
|
Adding a column with a non-null default or changing the type of an
|
|
existing column will require the entire table to be rewritten. This
|
|
may take a significant amount of time for a large table; and it will
|
|
temporarily require double the disk space.
|
|
</para>
|
|
|
|
<para>
|
|
Adding a <literal>CHECK</> or <literal>NOT NULL</> constraint requires
|
|
scanning the table to verify that existing rows meet the constraint.
|
|
</para>
|
|
|
|
<para>
|
|
The main reason for providing the option to specify multiple changes
|
|
in a single <command>ALTER TABLE</> is that multiple table scans or
|
|
rewrites can thereby be combined into a single pass over the table.
|
|
</para>
|
|
|
|
<para>
|
|
The <literal>DROP COLUMN</literal> 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.
|
|
</para>
|
|
|
|
<para>
|
|
The fact that <literal>ALTER TYPE</> requires rewriting the whole table
|
|
is sometimes an advantage, because the rewriting process eliminates
|
|
any dead space in the table. For example, to reclaim the space occupied
|
|
by a dropped column immediately, the fastest way is
|
|
<programlisting>
|
|
ALTER TABLE table ALTER COLUMN anycol TYPE anytype;
|
|
</programlisting>
|
|
where <literal>anycol</> is any remaining table column and
|
|
<literal>anytype</> is the same type that column already has.
|
|
This results in no semantically-visible change in the table,
|
|
but the command forces rewriting, which gets rid of no-longer-useful
|
|
data.
|
|
</para>
|
|
|
|
<para>
|
|
If a table has any descendant tables, it is not permitted to add,
|
|
rename, or change the type of a column in the parent table without doing
|
|
the same to the descendants. That is, <command>ALTER TABLE ONLY</command>
|
|
will be rejected. This ensures that the descendants always have
|
|
columns matching the parent.
|
|
</para>
|
|
|
|
<para>
|
|
A recursive <literal>DROP COLUMN</literal> 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 <literal>DROP
|
|
COLUMN</literal> (i.e., <command>ALTER TABLE ONLY ... DROP
|
|
COLUMN</command>) never removes any descendant columns, but
|
|
instead marks them as independently defined rather than inherited.
|
|
</para>
|
|
|
|
<para>
|
|
Changing any part of a system catalog table is not permitted.
|
|
</para>
|
|
|
|
<para>
|
|
Refer to <xref linkend="sql-createtable"
|
|
endterm="sql-createtable-title"> for a further description of valid
|
|
parameters. <xref linkend="ddl"> has further information on
|
|
inheritance.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Examples</title>
|
|
|
|
<para>
|
|
To add a column of type <type>varchar</type> to a table:
|
|
<programlisting>
|
|
ALTER TABLE distributors ADD COLUMN address varchar(30);
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
To drop a column from a table:
|
|
<programlisting>
|
|
ALTER TABLE distributors DROP COLUMN address RESTRICT;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
To change the types of two existing columns in one operation:
|
|
<programlisting>
|
|
ALTER TABLE distributors
|
|
ALTER COLUMN address TYPE varchar(80),
|
|
ALTER COLUMN name TYPE varchar(100);
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
To rename an existing column:
|
|
<programlisting>
|
|
ALTER TABLE distributors RENAME COLUMN address TO city;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
To rename an existing table:
|
|
<programlisting>
|
|
ALTER TABLE distributors RENAME TO suppliers;
|
|
</programlisting>
|
|
</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>
|
|
To add a check constraint to a table:
|
|
<programlisting>
|
|
ALTER TABLE distributors ADD CONSTRAINT zipchk CHECK (char_length(zipcode) = 5);
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
To remove a check constraint from a table and all its children:
|
|
<programlisting>
|
|
ALTER TABLE distributors DROP CONSTRAINT zipchk;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
To add a foreign key constraint to a table:
|
|
<programlisting>
|
|
ALTER TABLE distributors ADD CONSTRAINT distfk FOREIGN KEY (address) REFERENCES addresses (address) MATCH FULL;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
To add a (multicolumn) unique constraint to a table:
|
|
<programlisting>
|
|
ALTER TABLE distributors ADD CONSTRAINT dist_id_zipcode_key UNIQUE (dist_id, zipcode);
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
To add an automatically named primary key constraint to a table, noting
|
|
that a table can only ever have one primary key:
|
|
<programlisting>
|
|
ALTER TABLE distributors ADD PRIMARY KEY (dist_id);
|
|
</programlisting>
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Compatibility</title>
|
|
|
|
<para>
|
|
The <literal>ADD</literal>, <literal>DROP</>, and <literal>SET DEFAULT</>
|
|
forms conform with the SQL standard. The other forms are
|
|
<productname>PostgreSQL</productname> extensions of the SQL standard.
|
|
Also, the ability to specify more than one manipulation in a single
|
|
<command>ALTER TABLE</> command is an extension.
|
|
</para>
|
|
|
|
<para>
|
|
<command>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.
|
|
</para>
|
|
</refsect1>
|
|
</refentry>
|
|
|
|
<!-- Keep this comment at the end of the file
|
|
Local variables:
|
|
mode: sgml
|
|
sgml-omittag:nil
|
|
sgml-shorttag:t
|
|
sgml-minimize-attributes:nil
|
|
sgml-always-quote-attributes:t
|
|
sgml-indent-step:1
|
|
sgml-indent-data:t
|
|
sgml-parent-document:nil
|
|
sgml-default-dtd-file:"../reference.ced"
|
|
sgml-exposed-tags:nil
|
|
sgml-local-catalogs:"/usr/lib/sgml/catalog"
|
|
sgml-local-ecat-files:nil
|
|
End:
|
|
-->
|
|
|