ALTER TABLE
ALTER TABLE
ALTER TABLE - change the definition of a table
Synopsis
ALTER TABLE [ IF EXISTS ] [ ONLY ]name[ * ]action[, ... ] ALTER TABLE [ IF EXISTS ] [ ONLY ]name[ * ] RENAME [ COLUMN ]column_nameTOnew_column_nameALTER TABLE [ IF EXISTS ] [ ONLY ]name[ * ] RENAME CONSTRAINTconstraint_nameTOnew_constraint_nameALTER TABLE [ IF EXISTS ]nameRENAME TOnew_nameALTER TABLE [ IF EXISTS ]nameSET SCHEMAnew_schemaALTER TABLE ALL IN TABLESPACEname[ OWNED BYrole_name[, ... ] ] SET TABLESPACEnew_tablespace[ NOWAIT ] ALTER TABLE [ IF EXISTS ]nameATTACH PARTITIONpartition_nameFOR VALUESpartition_bound_specALTER TABLE [ IF EXISTS ]nameDETACH PARTITIONpartition_namewhereactionis one of: ADD [ COLUMN ] [ IF NOT EXISTS ]column_namedata_type[ COLLATEcollation] [column_constraint[ ... ] ] DROP [ COLUMN ] [ IF EXISTS ]column_name[ RESTRICT | CASCADE ] ALTER [ COLUMN ]column_name[ SET DATA ] TYPEdata_type[ COLLATEcollation] [ USINGexpression] ALTER [ COLUMN ]column_nameSET DEFAULTexpressionALTER [ COLUMN ]column_nameDROP DEFAULT ALTER [ COLUMN ]column_name{ SET | DROP } NOT NULL ALTER [ COLUMN ]column_nameADD GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY [ (sequence_options) ] ALTER [ COLUMN ]column_name{ SET GENERATED { ALWAYS | BY DEFAULT } | SETsequence_option| RESTART [ [ WITH ]restart] } [...] ALTER [ COLUMN ]column_nameDROP IDENTITY [ IF EXISTS ] ALTER [ COLUMN ]column_nameSET STATISTICSintegerALTER [ COLUMN ]column_nameSET (attribute_option=value[, ... ] ) ALTER [ COLUMN ]column_nameRESET (attribute_option[, ... ] ) ALTER [ COLUMN ]column_nameSET STORAGE { PLAIN | EXTERNAL | EXTENDED | MAIN } ADDtable_constraint[ NOT VALID ] ADDtable_constraint_using_indexALTER CONSTRAINTconstraint_name[ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ] VALIDATE CONSTRAINTconstraint_nameDROP CONSTRAINT [ IF EXISTS ]constraint_name[ RESTRICT | CASCADE ] DISABLE TRIGGER [trigger_name| ALL | USER ] ENABLE TRIGGER [trigger_name| ALL | USER ] ENABLE REPLICA TRIGGERtrigger_nameENABLE ALWAYS TRIGGERtrigger_nameDISABLE RULErewrite_rule_nameENABLE RULErewrite_rule_nameENABLE REPLICA RULErewrite_rule_nameENABLE ALWAYS RULErewrite_rule_nameDISABLE ROW LEVEL SECURITY ENABLE ROW LEVEL SECURITY FORCE ROW LEVEL SECURITY NO FORCE ROW LEVEL SECURITY CLUSTER ONindex_nameSET WITHOUT CLUSTER SET WITH OIDS SET WITHOUT OIDS SET TABLESPACEnew_tablespaceSET { LOGGED | UNLOGGED } SET (storage_parameter=value[, ... ] ) RESET (storage_parameter[, ... ] ) INHERITparent_tableNO INHERITparent_tableOFtype_nameNOT OF OWNER TO {new_owner| CURRENT_USER | SESSION_USER } REPLICA IDENTITY { DEFAULT | USING INDEXindex_name| FULL | NOTHING } andtable_constraint_using_indexis: [ CONSTRAINTconstraint_name] { UNIQUE | PRIMARY KEY } USING INDEXindex_name[ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
Description
ALTER TABLE
changes the definition of an existing table.
There are several subforms described below. Note that the lock level required
may differ for each subform. An
ACCESS EXCLUSIVE
lock is held
unless explicitly noted. When multiple subcommands are listed, the lock
held will be the strictest one required from any subcommand.
-
ADD COLUMN [ IF NOT EXISTS ] -
This form adds a new column to the table, using the same syntax as CREATE TABLE . If
IF NOT EXISTSis specified and a column already exists with this name, no error is thrown. -
DROP COLUMN [ IF EXISTS ] -
This form drops a column from a table. Indexes and table constraints involving the column will be automatically dropped as well. Multivariate statistics referencing the dropped column will also be removed if the removal of the column would cause the statistics to contain data for only a single column. You will need to say
CASCADEif anything outside the table depends on the column, for example, foreign key references or views. IfIF EXISTSis specified and the column does not exist, no error is thrown. In this case a notice is issued instead. -
SET DATA TYPE -
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
COLLATEclause specifies a collation for the new column; if omitted, the collation is the default for the new column type. The optionalUSINGclause 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. AUSINGclause must be provided if there is no implicit or assignment cast from old to new type. -
SET/DROP DEFAULT -
These forms set or remove the default value for a column. Default values only apply in subsequent
INSERTorUPDATEcommands; they do not cause rows already in the table to change. -
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 NULLwhen the column contains no null values.If this table is a partition, one cannot perform
DROP NOT NULLon a column if it is markedNOT NULLin the parent table. To drop theNOT NULLconstraint from all the partitions, performDROP NOT NULLon the parent table. Even if there is noNOT NULLconstraint on the parent, such a constraint can still be added to individual partitions, if desired; that is, the children can disallow nulls even if the parent allows them, but not the other way around. -
ADD GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY
SET GENERATED { ALWAYS | BY DEFAULT }
DROP IDENTITY [ IF EXISTS ] -
These forms change whether a column is an identity column or change the generation attribute of an existing identity column. See CREATE TABLE for details.
If
DROP IDENTITY IF EXISTSis specified and the column is not an identity column, no error is thrown. In this case a notice is issued instead. -
SETsequence_option
RESTART -
These forms alter the sequence that underlies an existing identity column.
sequence_optionis an option supported by ALTER SEQUENCE such asINCREMENT BY. -
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 10000; alternatively, set it to -1 to revert to using the system default statistics target ( default_statistics_target ). For more information on the use of statistics by the PostgreSQL query planner, refer to Section 14.2 .
SET STATISTICSacquires aSHARE UPDATE EXCLUSIVElock. -
SET (attribute_option=value[, ... ] )
RESET (attribute_option[, ... ] ) -
This form sets or resets per-attribute options. Currently, the only defined per-attribute options are
n_distinctandn_distinct_inherited, which override the number-of-distinct-values estimates made by subsequent ANALYZE operations.n_distinctaffects the statistics for the table itself, whilen_distinct_inheritedaffects the statistics gathered for the table plus its inheritance children. When set to a positive value,ANALYZEwill assume that the column contains exactly the specified number of distinct nonnull values. When set to a negative value, which must be greater than or equal to -1,ANALYZEwill assume that the number of distinct nonnull values in the column is linear in the size of the table; the exact count is to be computed by multiplying the estimated table size by the absolute value of the given number. For example, a value of -1 implies that all values in the column are distinct, while a value of -0.5 implies that each value appears twice on the average. This can be useful when the size of the table changes over time, since the multiplication by the number of rows in the table is not performed until query planning time. Specify a value of 0 to revert to estimating the number of distinct values normally. For more information on the use of statistics by the PostgreSQL query planner, refer to Section 14.2 .Changing per-attribute options acquires a
SHARE UPDATE EXCLUSIVElock. -
SET STORAGE -
This form sets the storage mode for a column. This controls whether this column is held inline or in a secondary TOAST table, and whether the data should be compressed or not.
PLAINmust be used for fixed-length values such asintegerand is inline, uncompressed.MAINis for inline, compressible data.EXTERNALis for external, uncompressed data, andEXTENDEDis for external, compressed data.EXTENDEDis the default for most data types that support non-PLAINstorage. Use ofEXTERNALwill make substring operations on very largetextandbyteavalues run faster, at the penalty of increased storage space. Note thatSET STORAGEdoesn't itself change anything in the table, it just sets the strategy to be pursued during future table updates. See Section 66.2 for more information. -
ADDtable_constraint[ NOT VALID ] -
This form adds a new constraint to a table using the same syntax as CREATE TABLE , plus the option
NOT VALID, which is currently only allowed for foreign key and CHECK constraints. If the constraint is markedNOT VALID, the potentially-lengthy initial check to verify that all rows in the table satisfy the constraint is skipped. The constraint will still be enforced against subsequent inserts or updates (that is, they'll fail unless there is a matching row in the referenced table, in the case of foreign keys; and they'll fail unless the new row matches the specified check constraints). But the database will not assume that the constraint holds for all rows in the table, until it is validated by using theVALIDATE CONSTRAINToption. -
ADDtable_constraint_using_index -
This form adds a new
PRIMARY KEYorUNIQUEconstraint to a table based on an existing unique index. All the columns of the index will be included in the constraint.The index cannot have expression columns nor be a partial index. Also, it must be a b-tree index with default sort ordering. These restrictions ensure that the index is equivalent to one that would be built by a regular
ADD PRIMARY KEYorADD UNIQUEcommand.If
PRIMARY KEYis specified, and the index's columns are not already markedNOT NULL, then this command will attempt to doALTER COLUMN SET NOT NULLagainst each such column. That requires a full table scan to verify the column(s) contain no nulls. In all other cases, this is a fast operation.If a constraint name is provided then the index will be renamed to match the constraint name. Otherwise the constraint will be named the same as the index.
After this command is executed, the index is " owned " by the constraint, in the same way as if the index had been built by a regular
ADD PRIMARY KEYorADD UNIQUEcommand. In particular, dropping the constraint will make the index disappear too.Note
Adding a constraint using an existing index can be helpful in situations where a new constraint needs to be added without blocking table updates for a long time. To do that, create the index using
CREATE INDEX CONCURRENTLY, and then install it as an official constraint using this syntax. See the example below. -
ALTER CONSTRAINT -
This form alters the attributes of a constraint that was previously created. Currently only foreign key constraints may be altered.
-
VALIDATE CONSTRAINT -
This form validates a foreign key or check constraint that was previously created as
NOT VALID, by scanning the table to ensure there are no rows for which the constraint is not satisfied. Nothing happens if the constraint is already marked valid.Validation can be a long process on larger tables. The value of separating validation from initial creation is that you can defer validation to less busy times, or can be used to give additional time to correct pre-existing errors while preventing new errors. Note also that validation on its own does not prevent normal write commands against the table while it runs.
Validation acquires only a
SHARE UPDATE EXCLUSIVElock on the table being altered. If the constraint is a foreign key then aROW SHARElock is also required on the table referenced by the constraint. -
DROP CONSTRAINT [ IF EXISTS ] -
This form drops the specified constraint on a table. If
IF EXISTSis specified and the constraint does not exist, no error is thrown. In this case a notice is issued instead. -
DISABLE/ENABLE [ REPLICA | ALWAYS ] TRIGGER -
These forms configure the firing of trigger(s) belonging to the table. A disabled trigger is still known to the system, but is not executed when its triggering event occurs. For a deferred trigger, the enable status is checked when the event occurs, not when the trigger function is actually executed. One can disable or enable a single trigger specified by name, or all triggers on the table, or only user triggers (this option excludes internally generated constraint triggers such as those that are used to implement foreign key constraints or deferrable uniqueness and exclusion constraints). Disabling or enabling internally generated constraint triggers requires superuser privileges; it should be done with caution since of course the integrity of the constraint cannot be guaranteed if the triggers are not executed. The trigger firing mechanism is also affected by the configuration variable session_replication_role . Simply enabled triggers will fire when the replication role is " origin " (the default) or " local " . Triggers configured as
ENABLE REPLICAwill only fire if the session is in " replica " mode, and triggers configured asENABLE ALWAYSwill fire regardless of the current replication mode.This command acquires a
SHARE ROW EXCLUSIVElock. -
DISABLE/ENABLE [ REPLICA | ALWAYS ] RULE -
These forms configure the firing of rewrite rules belonging to the table. A disabled rule is still known to the system, but is not applied during query rewriting. The semantics are as for disabled/enabled triggers. This configuration is ignored for
ON SELECTrules, which are always applied in order to keep views working even if the current session is in a non-default replication role. -
DISABLE/ENABLE ROW LEVEL SECURITY -
These forms control the application of row security policies belonging to the table. If enabled and no policies exist for the table, then a default-deny policy is applied. Note that policies can exist for a table even if row level security is disabled - in this case, the policies will NOT be applied and the policies will be ignored. See also CREATE POLICY .
-
NO FORCE/FORCE ROW LEVEL SECURITY -
These forms control the application of row security policies belonging to the table when the user is the table owner. If enabled, row level security policies will be applied when the user is the table owner. If disabled (the default) then row level security will not be applied when the user is the table owner. See also CREATE POLICY .
-
CLUSTER ON -
This form selects the default index for future CLUSTER operations. It does not actually re-cluster the table.
Changing cluster options acquires a
SHARE UPDATE EXCLUSIVElock. -
SET WITHOUT CLUSTER -
This form removes the most recently used CLUSTER index specification from the table. This affects future cluster operations that don't specify an index.
Changing cluster options acquires a
SHARE UPDATE EXCLUSIVElock. -
SET WITH OIDS -
This form adds an
oidsystem column to the table (see Section 5.4 ). It does nothing if the table already has OIDs.Note that this is not equivalent to
ADD COLUMN oid oid; that would add a normal column that happened to be namedoid, not a system column. -
SET WITHOUT OIDS -
This form removes the
oidsystem column from the table. This is exactly equivalent toDROP COLUMN oid RESTRICT, except that it will not complain if there is already nooidcolumn. -
SET TABLESPACE -
This form changes the table's tablespace to the specified tablespace and moves the data file(s) associated with the table to the new tablespace. Indexes on the table, if any, are not moved; but they can be moved separately with additional
SET TABLESPACEcommands. All tables in the current database in a tablespace can be moved by using theALL IN TABLESPACEform, which will lock all tables to be moved first and then move each one. This form also supportsOWNED BY, which will only move tables owned by the roles specified. If theNOWAIToption is specified then the command will fail if it is unable to acquire all of the locks required immediately. Note that system catalogs are not moved by this command, useALTER DATABASEor explicitALTER TABLEinvocations instead if desired. Theinformation_schemarelations are not considered part of the system catalogs and will be moved. See also CREATE TABLESPACE . -
SET { LOGGED | UNLOGGED } -
This form changes the table from unlogged to logged or vice-versa (see
UNLOGGED). It cannot be applied to a temporary table. -
SET (storage_parameter=value[, ... ] ) -
This form changes one or more storage parameters for the table. See Storage Parameters for details on the available parameters. Note that the table contents will not be modified immediately by this command; depending on the parameter you might need to rewrite the table to get the desired effects. That can be done with VACUUM FULL , CLUSTER or one of the forms of
ALTER TABLEthat forces a table rewrite. For planner related parameters, changes will take effect from the next time the table is locked so currently executing queries will not be affected.SHARE UPDATE EXCLUSIVElock will be taken for fillfactor and autovacuum storage parameters, as well as the following planner related parameters:effective_io_concurrency,parallel_workers,seq_page_cost,random_page_cost,n_distinctandn_distinct_inherited.Note
While
CREATE TABLEallowsOIDSto be specified in theWITH (syntax,storage_parameter)ALTER TABLEdoes not treatOIDSas a storage parameter. Instead use theSET WITH OIDSandSET WITHOUT OIDSforms to change OID status. -
RESET (storage_parameter[, ... ] ) -
This form resets one or more storage parameters to their defaults. As with
SET, a table rewrite might be needed to update the table entirely. -
INHERITparent_table -
This form adds the target table as a new child of the specified parent table. Subsequently, queries against the parent will include records of the target table. To be added as a child, the target table must already contain all the same columns as the parent (it could have additional columns, too). The columns must have matching data types, and if they have
NOT NULLconstraints in the parent then they must also haveNOT NULLconstraints in the child.There must also be matching child-table constraints for all
CHECKconstraints of the parent, except those marked non-inheritable (that is, created withALTER TABLE ... ADD CONSTRAINT ... NO INHERIT) in the parent, which are ignored; all child-table constraints matched must not be marked non-inheritable. CurrentlyUNIQUE,PRIMARY KEY, andFOREIGN KEYconstraints are not considered, but this might change in the future. -
NO INHERITparent_table -
This form removes the target table from the list of children of the specified parent table. Queries against the parent table will no longer include records drawn from the target table.
-
OFtype_name -
This form links the table to a composite type as though
CREATE TABLE OFhad formed it. The table's list of column names and types must precisely match that of the composite type; the presence of anoidsystem column is permitted to differ. The table must not inherit from any other table. These restrictions ensure thatCREATE TABLE OFwould permit an equivalent table definition. -
NOT OF -
This form dissociates a typed table from its type.
-
OWNER -
This form changes the owner of the table, sequence, view, materialized view, or foreign table to the specified user.
-
REPLICA IDENTITY -
This form changes the information which is written to the write-ahead log to identify rows which are updated or deleted. This option has no effect except when logical replication is in use.
DEFAULT(the default for non-system tables) records the old values of the columns of the primary key, if any.USING INDEXrecords the old values of the columns covered by the named index, which must be unique, not partial, not deferrable, and include only columns markedNOT NULL.FULLrecords the old values of all columns in the row.NOTHINGrecords no information about the old row. (This is the default for system tables.) In all cases, no old values are logged unless at least one of the columns that would be logged differs between the old and new versions of the row. -
RENAME -
The
RENAMEforms change the name of a table (or an index, sequence, view, materialized view, or foreign table), the name of an individual column in a table, or the name of a constraint of the table. There is no effect on the stored data. -
SET SCHEMA -
This form moves the table into another schema. Associated indexes, constraints, and sequences owned by table columns are moved as well.
-
ATTACH PARTITIONpartition_nameFOR VALUESpartition_bound_spec -
This form attaches an existing table (which might itself be partitioned) as a partition of the target table using the same syntax for
partition_bound_specas CREATE TABLE . The partition bound specification must correspond to the partitioning strategy and partition key of the target table. The table to be attached must have all the same columns as the target table and no more; moreover, the column types must also match. Also, it must have all theNOT NULLandCHECKconstraints of the target table. CurrentlyUNIQUE,PRIMARY KEY, andFOREIGN KEYconstraints are not considered. If any of theCHECKconstraints of the table being attached is markedNO INHERIT, the command will fail; such a constraint must be recreated without theNO INHERITclause.If the new partition is a regular table, a full table scan is performed to check that no existing row in the table violates the partition constraint. It is possible to avoid this scan by adding a valid
CHECKconstraint to the table that would allow only the rows satisfying the desired partition constraint before running this command. It will be determined using such a constraint that the table need not be scanned to validate the partition constraint. This does not work, however, if any of the partition keys is an expression and the partition does not acceptNULLvalues. If attaching a list partition that will not acceptNULLvalues, also addNOT NULLconstraint to the partition key column, unless it's an expression.If the new partition is a foreign table, nothing is done to verify that all the rows in the foreign table obey the partition constraint. (See the discussion in CREATE FOREIGN TABLE about constraints on the foreign table.)
-
DETACH PARTITIONpartition_name -
This form detaches specified partition of the target table. The detached partition continues to exist as a standalone table, but no longer has any ties to the table from which it was detached.
All the forms of ALTER TABLE that act on a single table, except
RENAME
,
SET SCHEMA
,
ATTACH PARTITION
, and
DETACH PARTITION
can be combined into
a list of multiple alterations to be applied together. 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.
You must own the table to use
ALTER TABLE
.
To change the schema or tablespace of a table, you must also have
CREATE
privilege on the new schema or tablespace.
To add the table as a new child of a parent table, you must own the parent
table as well. Also, to attach a table as a new partition of the table,
you must own the table being attached.
To alter the owner, you must also be a direct or indirect member of the new
owning role, and that role must have
CREATE
privilege on
the table's schema. (These restrictions enforce that altering the owner
doesn't do anything you couldn't do by dropping and recreating the table.
However, a superuser can alter ownership of any table anyway.)
To add a column or alter a column type or use the
OF
clause, you must also have
USAGE
privilege on the data
type.
Parameters
-
IF EXISTS -
Do not throw an error if the table does not exist. A notice is issued in this case.
-
name -
The name (optionally schema-qualified) of an existing table to alter. If
ONLYis specified before the table name, only that table is altered. IfONLYis not specified, the table and all its descendant tables (if any) are altered. Optionally,*can be specified after the table name to explicitly indicate that descendant tables are included. -
column_name -
Name of a new or existing column.
-
new_column_name -
New name for an existing column.
-
new_name -
New name for the table.
-
data_type -
Data type of the new column, or new data type for an existing column.
-
table_constraint -
New table constraint for the table.
-
constraint_name -
Name of a new or existing constraint.
-
CASCADE -
Automatically drop objects that depend on the dropped column or constraint (for example, views referencing the column), and in turn all objects that depend on those objects (see Section 5.13 ).
-
RESTRICT -
Refuse to drop the column or constraint if there are any dependent objects. This is the default behavior.
-
trigger_name -
Name of a single trigger to disable or enable.
-
ALL -
Disable or enable all triggers belonging to the table. (This requires superuser privilege if any of the triggers are internally generated constraint triggers such as those that are used to implement foreign key constraints or deferrable uniqueness and exclusion constraints.)
-
USER -
Disable or enable all triggers belonging to the table except for internally generated constraint triggers such as those that are used to implement foreign key constraints or deferrable uniqueness and exclusion constraints.
-
index_name -
The name of an existing index.
-
storage_parameter -
The name of a table storage parameter.
-
value -
The new value for a table storage parameter. This might be a number or a word depending on the parameter.
-
parent_table -
A parent table to associate or de-associate with this table.
-
new_owner -
The user name of the new owner of the table.
-
new_tablespace -
The name of the tablespace to which the table will be moved.
-
new_schema -
The name of the schema to which the table will be moved.
-
partition_name -
The name of the table to attach as a new partition or to detach from this table.
-
partition_bound_spec -
The partition bound specification for a new partition. Refer to CREATE TABLE for more details on the syntax of the same.
Notes
The key word
COLUMN
is noise and can be omitted.
When a column is added with
ADD COLUMN
, all existing
rows in the table are initialized with the column's default value
(NULL if no
DEFAULT
clause is specified).
If there is no
DEFAULT
clause, this is merely a metadata
change and does not require any immediate update of the table's data;
the added NULL values are supplied on readout, instead.
Adding a column with a
DEFAULT
clause or changing the type of
an existing column will require the entire table and its indexes to be
rewritten. As an exception when changing the type of an existing column,
if the
USING
clause does not change the column
contents and the old type is either binary coercible to the new type or
an unconstrained domain over the new type, a table rewrite is not needed;
but any indexes on the affected columns must still be rebuilt. Adding or
removing a system
oid
column also requires rewriting the entire
table. Table and/or index rebuilds may take a significant amount of time
for a large table; and will temporarily require as much as double the disk
space.
Adding a
CHECK
or
NOT NULL
constraint requires
scanning the table to verify that existing rows meet the constraint,
but does not require a table rewrite.
Similarly, when attaching a new partition it may be scanned to verify that existing rows meet the partition constraint.
The main reason for providing the option to specify multiple changes
in a single
ALTER TABLE
is that multiple table scans or
rewrites can thereby be combined into a single pass over the table.
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. (These statements do
not apply when dropping the system
oid
column; that is done
with an immediate rewrite.)
To force immediate reclamation of space occupied by a dropped column,
you can execute one of the forms of
ALTER TABLE
that
performs a rewrite of the whole table. This results in reconstructing
each row with the dropped column replaced by a null value.
The rewriting forms of
ALTER TABLE
are not MVCC-safe.
After a table rewrite, the table will appear empty to concurrent
transactions, if they are using a snapshot taken before the rewrite
occurred. See
Section 13.5
for more details.
The
USING
option of
SET DATA TYPE
can actually
specify any expression involving the old values of the row; that is, it
can refer to other columns as well as the one being converted. This allows
very general conversions to be done with the
SET DATA TYPE
syntax. Because of this flexibility, the
USING
expression is not applied to the column's default value (if any); the
result might not be a constant expression as required for a default.
This means that when there is no implicit or assignment cast from old to
new type,
SET DATA TYPE
might fail to convert the default even
though a
USING
clause is supplied. In such cases,
drop the default with
DROP DEFAULT
, perform the
ALTER
TYPE
, and then use
SET DEFAULT
to add a suitable new
default. Similar considerations apply to indexes and constraints involving
the column.
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
same to the descendants. This ensures that the descendants always have
columns matching the parent. Similarly, a constraint cannot be renamed
in the parent without also renaming it in all descendants, so that
constraints also match between the parent and its descendants.
Also, because selecting from the parent also selects from its descendants,
a constraint on the parent cannot be marked valid unless it is also marked
valid for those descendants. In all of these cases,
ALTER TABLE
ONLY
will be rejected.
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.
A nonrecursive
DROP COLUMN
command will fail for a
partitioned table, because all partitions of a table must have the same
columns as the partitioning root.
The actions for identity columns (
ADD
GENERATED
,
SET
etc.,
DROP
IDENTITY
), as well as the actions
TRIGGER
,
CLUSTER
,
OWNER
,
and
TABLESPACE
never recurse to descendant tables;
that is, they always act as though
ONLY
were specified.
Adding a constraint recurses only for
CHECK
constraints
that are not marked
NO INHERIT
.
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 change the types of two existing columns in one operation:
ALTER TABLE distributors
ALTER COLUMN address TYPE varchar(80),
ALTER COLUMN name TYPE varchar(100);
To change an integer column containing Unix timestamps to
timestamp
with time zone
via a
USING
clause:
ALTER TABLE foo
ALTER COLUMN foo_timestamp SET DATA TYPE timestamp with time zone
USING
timestamp with time zone 'epoch' + foo_timestamp * interval '1 second';
The same, when the column has a default expression that won't automatically cast to the new data type:
ALTER TABLE foo
ALTER COLUMN foo_timestamp DROP DEFAULT,
ALTER COLUMN foo_timestamp TYPE timestamp with time zone
USING
timestamp with time zone 'epoch' + foo_timestamp * interval '1 second',
ALTER COLUMN foo_timestamp SET DEFAULT now();
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 rename an existing constraint:
ALTER TABLE distributors RENAME CONSTRAINT zipchk TO zip_check;
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 and all its children:
ALTER TABLE distributors ADD CONSTRAINT zipchk CHECK (char_length(zipcode) = 5);
To add a check constraint only to a table and not to its children:
ALTER TABLE distributors ADD CONSTRAINT zipchk CHECK (char_length(zipcode) = 5) NO INHERIT;
(The check constraint will not be inherited by future children, either.)
To remove a check constraint from a table and all its children:
ALTER TABLE distributors DROP CONSTRAINT zipchk;
To remove a check constraint from one table only:
ALTER TABLE ONLY distributors DROP CONSTRAINT zipchk;
(The check constraint remains in place for any child tables.)
To add a foreign key constraint to a table:
ALTER TABLE distributors ADD CONSTRAINT distfk FOREIGN KEY (address) REFERENCES addresses (address);
To add a foreign key constraint to a table with the least impact on other work:
ALTER TABLE distributors ADD CONSTRAINT distfk FOREIGN KEY (address) REFERENCES addresses (address) NOT VALID; ALTER TABLE distributors VALIDATE CONSTRAINT distfk;
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);
To move a table to a different tablespace:
ALTER TABLE distributors SET TABLESPACE fasttablespace;
To move a table to a different schema:
ALTER TABLE myschema.distributors SET SCHEMA yourschema;
To recreate a primary key constraint, without blocking updates while the index is rebuilt:
CREATE UNIQUE INDEX CONCURRENTLY dist_id_temp_idx ON distributors (dist_id);
ALTER TABLE distributors DROP CONSTRAINT distributors_pkey,
ADD CONSTRAINT distributors_pkey PRIMARY KEY USING INDEX dist_id_temp_idx;
Attach a partition to range partitioned table:
ALTER TABLE measurement
ATTACH PARTITION measurement_y2016m07 FOR VALUES FROM ('2016-07-01') TO ('2016-08-01');
Attach a partition to list partitioned table:
ALTER TABLE cities
ATTACH PARTITION cities_ab FOR VALUES IN ('a', 'b');
Detach a partition from partitioned table:
ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
Compatibility
The forms
ADD
(without
USING INDEX
),
DROP [COLUMN]
,
DROP IDENTITY
,
RESTART
,
SET DEFAULT
,
SET DATA TYPE
(without
USING
),
SET GENERATED
, and
SET
conform with the SQL standard. The other forms are
PostgreSQL
extensions of the SQL standard.
Also, the ability to specify more than one manipulation in a single
sequence_option
ALTER TABLE
command is an extension.
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.