Changes the definition of a table.
ALTER TABLE [IF EXISTS] [ONLY] <name> [ * ]
<action> [, ... ]
ALTER TABLE [IF EXISTS] [ONLY] <name> [ * ]
RENAME [COLUMN] <column_name> TO <new_column_name>
ALTER TABLE [IF EXISTS] [ ONLY ] <name> [ * ]
RENAME CONSTRAINT <constraint_name> TO <new_constraint_name>
ALTER TABLE [IF EXISTS] <name>
RENAME TO <new_name>
ALTER TABLE [IF EXISTS] <name>
SET SCHEMA <new_schema>
ALTER TABLE ALL IN TABLESPACE <name> [ OWNED BY <role_name> [, ... ] ]
SET TABLESPACE <new_tablespace> [ NOWAIT ]
ALTER TABLE [ IF EXISTS ] <name>
ATTACH PARTITION <partition_name> { FOR VALUES <partition_bound_spec> | DEFAULT }
ALTER TABLE [ IF EXISTS ] <name>
DETACH PARTITION <partition_name>
ALTER TABLE [IF EXISTS] [ONLY] <name> SET
[ WITH (reorganize={ true | false }) ]
DISTRIBUTED BY ({<column_name> [<opclass>]} [, ... ] )
| DISTRIBUTED RANDOMLY
| DISTRIBUTED REPLICATED
where <action> is one of:
ADD [COLUMN] [IF NOT EXISTS] <column_name> <data_type> [ COLLATE <collation> ] [<column_constraint> [ ... ]]
[ ENCODING ( <storage_directive> [,...] ) ]
DROP [COLUMN] [IF EXISTS] <column_name> [RESTRICT | CASCADE]
ALTER [COLUMN] <column_name> [ SET DATA ] TYPE <data_type> [COLLATE <collation>] [USING <expression>]
ALTER [COLUMN] <column_name> SET DEFAULT <expression>
ALTER [COLUMN] <column_name> DROP DEFAULT
ALTER [COLUMN] <column_name> { SET | DROP } NOT NULL
ALTER [COLUMN] <column_name> ADD GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY [ ( <sequence_options> ) ]
ALTER [COLUMN] <column_name> { SET GENERATED { ALWAYS | BY DEFAULT }
| SET <sequence_option>
| RESTART [ [ WITH ] <restart> ] } [...]
ALTER [COLUMN] <column_name> DROP IDENTITY [ IF EXISTS ]
ALTER [COLUMN] <column_name> SET STATISTICS <integer>
ALTER [COLUMN] <column_name> SET ( <attribute_option> = <value> [, ... ] )
ALTER [COLUMN] <column_name> RESET ( <attribute_option> [, ... ] )
ALTER [COLUMN] <column_name> SET STORAGE { PLAIN | EXTERNAL | EXTENDED | MAIN }
ALTER [COLUMN] <column_name> SET ENCODING ( storage_directive> [, ...] )
ADD <table_constraint> [NOT VALID]
ADD <table_constraint_using_index>
ALTER CONSTRAINT <constraint_name> [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
VALIDATE CONSTRAINT <constraint_name>
DROP CONSTRAINT [IF EXISTS] <constraint_name> [RESTRICT | CASCADE]
DISABLE ROW LEVEL SECURITY
ENABLE ROW LEVEL SECURITY
FORCE ROW LEVEL SECURITY
NO FORCE ROW LEVEL SECURITY
CLUSTER ON <index_name>
REPACK BY COLUMNS (<colum_name_1> [ASC|DESC], <column_name_2> [ASC|DESC], ...)
SET WITHOUT CLUSTER
SET WITHOUT OIDS
SET TABLESPACE <new_tablespace>
SET { LOGGED | UNLOGGED }
SET ( <storage_parameter> [= <value>] [, ...])
SET WITH (<set_with_parameter> = <value> [, ...])
SET ACCESS METHOD <access_method> [WITH ( <storage_parameter> = <value>, [, ...] )]
RESET (<storage_parameter> [, ... ])
INHERIT <parent_table>
NO INHERIT <parent_table>
OF <type_name>
NOT OF
OWNER TO { <new_owner> | CURRENT_USER | SESSION_USER }
and <partition_bound_spec> is:
IN ( <partition_bound_expr> [, ...] ) |
FROM ( { <partition_bound_expr> | MINVALUE | MAXVALUE } [, ...] )
TO ( { <partition_bound_expr> | MINVALUE | MAXVALUE } [, ...] ) |
WITH ( MODULUS <numeric_literal>, REMAINDER <numeric_literal> )
and <column_constraint> is:
[ CONSTRAINT <constraint_name>]
{ NOT NULL
| NULL
| CHECK ( <expression> ) [ NO INHERIT ]
| DEFAULT <default_expr>
| GENERATED ALWAYS AS ( <generation_expr> ) STORED
| GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY [ ( <sequence_options> ) ]
| UNIQUE <index_parameters>
| PRIMARY KEY <index_parameters>
| REFERENCES <reftable> [ ( refcolumn ) ] [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ]
[ ON DELETE <referential_action> ] [ ON UPDATE <referential_action> ] }
[ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
and <table_constraint> is:
[ CONSTRAINT <constraint_name> ]
{ CHECK ( <expression> ) [ NO INHERIT ]
| UNIQUE ( <column_name> [, ... ] ) <index_parameters>
| PRIMARY KEY ( <column_name> [, ... ] ) <index_parameters>
| EXCLUDE [ USING <index_method> ] ( <exclude_element> WITH <operator> [, ... ] )
<index_parameters> [ WHERE ( <predicate> ) ]
| FOREIGN KEY ( <column_name> [, ... ] ) REFERENCES <reftable> [ ( <refcolumn> [, ... ] ) ]
[ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ] [ ON DELETE <referential_action> ] [ ON UPDATE <referential_action> ] }
[ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
and <table_constraint_using_index> is:
[ CONSTRAINT <constraint_name> ]
{ UNIQUE | PRIMARY KEY } USING INDEX <index_name>
[ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
and <index_parameters> in UNIQUE, PRIMARY KEY, and EXCLUDE constraints are:
[ INCLUDE ( <column_name> [, ... ] ) ]
[ WITH ( <storage_parameter> [=<value>] [, ... ] ) ]
[ USING INDEX TABLESPACE <tablespace_name> ]
and <exclude_element> in an EXCLUDE constraint is:
{ <column_name> | ( <expression> ) } [ <opclass> ] [ ASC | DESC ]
[ NULLS { FIRST | LAST }
and <set_with_parameter> is:
reorganize={ true | false } |
orientation={COLUMN|ROW}
appendoptimized={ true | false } [, <storage_parameter> [, ...]]
Classic partitioning syntax elements include:
ALTER TABLE <name>
[ ALTER PARTITION { <partition_name> | FOR (<value>) } [...] ] <partition_action>
where <partition_action> is one of:
ALTER DEFAULT PARTITION
DROP DEFAULT PARTITION [IF EXISTS]
DROP PARTITION [IF EXISTS] { <partition_name> |
FOR (<value>) } [CASCADE]
TRUNCATE DEFAULT PARTITION
TRUNCATE PARTITION { <partition_name> | FOR (<value>) }
RENAME DEFAULT PARTITION TO <new_partition_name>
RENAME PARTITION { <partition_name> | FOR (<value>) } TO <new_partition_name>
ADD DEFAULT PARTITION <name> [ ( <subpartition_spec> ) ]
ADD PARTITION [<partition_name>] <partition_element>
[ ( <subpartition_spec> ) ]
EXCHANGE PARTITION { <partition_name> | FOR (<value>) } WITH TABLE <table_name>
[ WITH | WITHOUT VALIDATION ]
EXCHANGE DEFAULT PARTITION WITH TABLE <table_name>
[ WITH | WITHOUT VALIDATION ]
SET SUBPARTITION TEMPLATE (<subpartition_spec>)
SPLIT DEFAULT PARTITION
{ AT (<list_value>)
| START([<datatype>] <range_value>) [INCLUSIVE | EXCLUSIVE]
END([<datatype>] <range_value>) [INCLUSIVE | EXCLUSIVE] }
[ INTO ( PARTITION <new_partition_name>,
PARTITION <default_partition_name> ) ]
SPLIT PARTITION { <partition_name> | FOR (<value>) } AT (<value>)
[ INTO (PARTITION <partition_name>, PARTITION <partition_name>)]
and <partition_element> is:
VALUES (<list_value> [,...] )
| START ([<datatype>] '<start_value>') [INCLUSIVE | EXCLUSIVE]
[ END ([<datatype>] '<end_value>') [INCLUSIVE | EXCLUSIVE] ]
| END ([<datatype>] '<end_value>') [INCLUSIVE | EXCLUSIVE]
[ WITH ( <storage_parameter> = value> [ , ... ] ) ]
[ TABLESPACE <tablespace> ]
and <subpartition_spec> is:
<subpartition_element> [, ...]
and <subpartition_element> is:
DEFAULT SUBPARTITION <subpartition_name>
| [SUBPARTITION <subpartition_name>] VALUES (<list_value> [,...] )
| [SUBPARTITION <subpartition_name>]
START ([<datatype>] '<start_value>') [INCLUSIVE | EXCLUSIVE]
[ END ([<datatype>] '<end_value>') [INCLUSIVE | EXCLUSIVE] ]
[ EVERY ( [<number | datatype>] '<interval_value>') ]
| [SUBPARTITION <subpartition_name>]
END ([<datatype>] '<end_value>') [INCLUSIVE | EXCLUSIVE]
[ EVERY ( [<number | datatype>] '<interval_value>') ]
[ WITH ( <storage_parameter>=<value> [, ... ] ) ]
[ TABLESPACE <tablespace> ]
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 acquired unless explicitly noted. When multiple subcommands are provided, Greenplum Database acquires the strictest lock required by any subcommand.
IF NOT EXISTS
is specified and a column already exists with this name, no error is thrown.
DISTRIBUTED RANDOMLY
. Indexes and table constraints involving the column are 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 need to specify
CASCADE
if anything outside of the table depends on the column, such as views. If
IF EXISTS
is specified and the column does not exist, no error is thrown; Greenplum Database issues a notice instead.
This form changes the data type of a column of a table. Note that you cannot alter column data types that are being used as distribution or partitioning keys. 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 COLLATE
clause specifies a collation for the new column; if omitted, the collation is the default for the new column type. The optional USING
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 USING
clause must be provided if there is no implicit or assignment cast from old to new type.
NoteThe Greenplum query optimizer (GPORCA) supports collation only when all columns in the query use the same collation. If columns in the query use different collations, then Greenplum uses the Postgres-based planner.
ALTER TABLE
, see
Notes.
INSERT
or
UPDATE
commands; they do not cause rows already in the table to change.
Changes whether a column is marked to allow null values or to reject null values.
SET NOT NULL
may only be applied to a column provided none of the records in the table contain a NULL
value for the column. This is typically checked during the ALTER TABLE
by scanning the entire table; however, if a valid CHECK
constraint is found which proves no NULL
can exist, then Greenplum Database skips the table scan.
DROP NOT NULL
on a column if it is marked
NOT NULL
in the parent table. To drop the
NOT NULL
constraint from all the partitions, perform
DROP NOT NULL
on the parent table. Even if there is no
NOT NULL
constraint 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.
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.
DROP IDENTITY IF EXISTS
is specified and the column is not an identity column, no error is thrown. In this case Greenplum Database issues a notice instead.
INCREMENT BY
.
Sets the per-column statistics-gathering target for subsequent ANALYZE operations. The target can be set in the range 0 to 10000, or set to -1 to revert to using the system default statistics target (default_statistics_target. When set to 0, no statistics are collected.
SET STATISTICS
acquires a
SHARE UPDATE EXCLUSIVE
lock.
Sets or resets per-attribute options. Currently, the only defined per-attribute options are n_distinct
and n_distinct_inherited
, which override the number-of-distinct-values estimates made by subsequent ANALYZE operations. n_distinct
affects the statistics for the table itself, while n_distinct_inherited
affects the statistics gathered for the table plus its inheritance children. When set to a positive value, ANALYZE
assumes that the column contains exactly the specified number of distinct non-null values. When set to a negative value, which must be greater than or equal to -1, ANALYZE
assumes that the number of distinct non-null 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 the value 0 to revert to estimating the number of distinct values normally.
Changing per-attribute options acquires a SHARE UPDATE EXCLUSIVE
lock.
SET
to set attribute encoding options for appendoptimized, column-oriented tables. Instead, use
ALTER COLUMN ... SET ENCODING ...
.
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 most data types that support non-
PLAIN
storage. Use of
EXTERNAL
will make substring operations on very large text and bytea values run faster, at the penalty of increased storage space. Note that
SET STORAGE
doesn't itself change anything in the table, it just sets the strategy to be pursued during future table updates.
Adds a new constraint to a table using the same syntax as CREATE TABLE. The NOT VALID
option is currently allowed only for foreign key and CHECK
constraints.
Normally, this form causes a scan of the table to verify that all existing rows in the table satisfy the new constraint. If the constraint is marked NOT VALID
, Greenplum Database skips the potentially-lengthy initial check to verify that all rows in the table satisfy the constraint. 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 the VALIDATE CONSTRAINT
option. See the Notes for more information about using the NOT VALID
option.
Most forms of ADD <table_constraint>
require an ACCESS EXCLUSIVE
lock.
This form adds a new PRIMARY KEY
or UNIQUE
constraint 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 KEY
or ADD UNIQUE
command.
If PRIMARY KEY
is specified, and the index's columns are not already marked NOT NULL
, then this command attempts to ALTER COLUMN SET NOT NULL
against 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 Greenplum renames the index 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 KEY
or ADD UNIQUE
command. In particular, dropping the constraint will make the index disappear too.
This form validates a foreign key 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. The advantage of separating validation from initial creation of the constraint is that validation requires a lesser lock on the table than constraint creation does.
SHARE UPDATE EXCLUSIVE
lock.
IF EXISTS
is specified and the constraint does not exist, no error is thrown. Greenplum Database issues a notice in this case instead.
Selects the default index for future CLUSTER operations. It does not actually re-cluster the table.
SHARE UPDATE EXCLUSIVE
lock.
Physically reorders a table based on one or more columns to improve physical correlation. You specify one or more columns, and an optional column order. If not specified, the default is ASC
. The command is equivalent to the CLUSTER command, but it uses the provided column list instead of an index to determine the sorting order.
REPACK BY COLUMNS
with most other
ALTER TABLE
commands that do not require a rewrite of the table. You may use
REPACK BY COLUMNS
to add compression or change the existing compression settings of a table while physically reordering the table, which results in better compression and storage. See
Examples for more details.
Removes the most recently used CLUSTER index specification from the table. This affects future cluster operations that do not specify an index.
SHARE UPDATE EXCLUSIVE
lock.
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 TABLESPACE
commands. When applied to a partitioned table, nothing is moved, but any partitions created afterwards with CREATE TABLE ... PARTITION OF
will use that tablespace, unless the TABLESPACE
clause is used to override it.
All tables in the current database in a tablespace can be moved by using the ALL IN TABLESPACE
form, which will lock all tables to be moved first and then move each one. This form also supports OWNED BY
, which will only move tables owned by the roles specified. If the NOWAIT
option 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, use ALTER DATABASE
or explicit ALTER TABLE
invocations instead if desired. The information_schema
relations are not considered part of the system catalogs and will be moved. See also CREATE TABLESPACE.
This form changes one or more table-level options. See Storage Parameters in the CREATE TABLE
reference for details on the available parameters. Note that for heap tables, the table contents will not be modified immediately by this command; depending on the parameter, you may 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 TABLE
that forces a table rewrite, see Notes. For append-optimized column-oriented tables, changing a storage parameter always results in a table rewrite. For planner-related parameters, changes take effect from the next time the table is locked, so currently executing queries are not affected.
SHARE UPDATE EXCLUSIVE
lock when setting
fillfactor
, toast and autovacuum storage parameters, and the planner parameter
parallel_workers
.
SET
, a table rewrite might be required to update the table entirely.
You can use this form of the command to reorganize the table, or to set the table access method and also optionally set storage parameters.
Note: Although you can specify the table's access method using the appendoptimized
and orientation
storage parameters, VMware recommends that you use SET ACCESS METHOD <access_method>
instead.
Adds the target table as a new child of the specified parent table. Queries against the parent will include records of the target table. To be added as a child, the target table must already contain all of the same columns as the parent (it could have additional columns, too). The columns must have matching data types, and if they have NOT NULL
constraints in the parent then they must also have NOT NULL
constraints in the child.
CHECK
constraints of the parent, except those marked non-inheritable (that is, created with
ALTER TABLE ... ADD CONSTRAINT ... NO INHERIT
) in the parent, which are ignored; all child-table constraints matched must not be marked non-inheritable.
UNIQUE
,
PRIMARY KEY
, and
FOREIGN KEY
constraints are not currently considered.
CREATE TABLE OF
had formed it. The table's list of column names and types must precisely match that of the composite type. The table must not inherit from any other table. These restrictions ensure that
CREATE TABLE OF
would permit an equivalent table definition.
SET WITH (reorganize=true)
.
While Greenplum Database permits changing the distribution policy of a writable external table, the operation never results in physical redistribution of the external data.
This form of the modern partitioning syntax attaches an existing table (which might itself be partitioned) as a partition of the target table. The table can be attached as a partition for specific values using FOR VALUES
or as a default partition by using DEFAULT
. For each index in the target table, a corresponding one will be created in the attached table; or, if an equivalent index already exists, it will be attached to the target table's index, as if you had run ALTER INDEX ATTACH PARTITION
. Note that if the existing table is a foreign table, Greenplum does not permit attaching the table as a partition of the target table if there are UNIQUE
indexes on the target table. (See also CREATE FOREIGN TABLE.)
A partition using FOR VALUES
uses the same syntax for partition_bound_spec> as 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 of the NOT NULL
and CHECK
constraints of the target table. Currently FOREIGN KEY
constraints are not considered. UNIQUE
and PRIMARY KEY
constraints from the parent table will be created in the partition, if they don't already exist. If any of the CHECK
constraints of the table being attached are marked NO INHERIT
, the command will fail; such constraints must be recreated without the NO INHERIT
clause.
If the new partition is a regular table, Greenplum Database performs a full table scan to check that existing rows in the table do not violate the partition constraint. It is possible to avoid this scan by adding a valid CHECK
constraint to the table that allows only rows satisfying the desired partition constraint before running this command. The CHECK
constraint will be used to determine 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 accept NULL
values. If attaching a list partition that will not accept NULL
values, also add a NOT NULL
constraint 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 of the rows in the foreign table obey the partition constraint. (See the discussion in CREATE FOREIGN TABLE about constraints on the foreign table.)
When a table has a default partition, defining a new partition changes the partition constraint for the default partition. The default partition can't contain any rows that would need to be moved to the new partition, and will be scanned to verify that none are present. This scan, like the scan of the new partition, can be avoided if an appropriate CHECK
constraint is present. Also like the scan of the new partition, it is always skipped when the default partition is a foreign table.
Attaching a partition acquires a SHARE UPDATE EXCLUSIVE
lock on the parent table, in addition to the ACCESS EXCLUSIVE
locks on the table being attached and on the default partition (if any). You can run SELECT
and INSERT
queries in parallel with ATTACH PARTITION
. You can also run UPDATE
queries in parallel with ATTACH PARTITION
when the parent table is a heap table and the Global Deadlock Detector is enabled (the gp_enable_global_deadlock_detector server configuration paramer is set to on
).
CHECK
constraint as described in
Partitioning Large Tables.
NoteIf you add a partition to a table that has sub-partition encodings, the new partition inherits the storage directives for the sub-partitions. For more information about the precedence of compression settings, see Using Compression.
You can combine all forms of ALTER TABLE
that act on a single table into a list of multiple alterations to apply together, except RENAME
, SET SCHEMA
, ATTACH PARTITION
, and DETACH PARTITION
. 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. To add a column or alter a column type or use the OF
clause, you must also have USAGE
privilege on the data type. A superuser has these privileges automatically.
NoteMemory usage increases significantly when a table has many partitions, if a table has compression, or if the blocksize for a table is large. If the number of relations associated with the table is large, this condition can force an operation on the table to use more memory. For example, if the table is an append-optimized column-oriented table and has a large number of columns, each column is a relation. An operation that accesses all of the columns in the table allocates associated buffers. If the table has 40 columns and 100 partitions, and the columns are compressed and the blocksize is 2 MB (with a system factor of 3), the system attempts to allocate 24 GB, that is (40 ×100) × (2 ×3) MB or 24 GB.
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 of its descendant tables (if any) are updated. You can optionally specify *
after the table name to explicitly indicate that descendant tables are included.
NoteAdding or dropping a column, or changing a column's type, in a parent or descendant table only is not permitted. The parent table and its descendents must always have the same columns and types.
text
to
varchar
is OK, but
text
to
int
is not).
The ENCODING
clause is valid only for append-optimized, column-oriented tables.
When you add a column to an append-optimized, column-oriented table, Greenplum Database sets each data compression parameter for the column (compresstype
, compresslevel
, and blocksize
) based on the following setting, in order of preference.
ALTER TABLE
command ENCODING
clause.WITH
clause when the table was created.ENCODING
storage directives, refer to
CREATE TABLE.
CREATE TABLE
reference page for a list of parameters.
heap
to access the table as a heap-storage table,
ao_row
to access the table as an append-optimized table with row-oriented storage (AO), or
ao_column
to access the table as an append-optimized table with column-oriented storage (AO/CO).
Note: Although you can specify the table's access method using SET <storage_parameter>
, VMware recommends that you use SET ACCESS METHOD <access_method>
instead.
reorganize=true
when the hash distribution policy has not changed or when you have changed from a hash to a random distribution, and you want to redistribute the data anyway.
WITH (reorganize=<value>)
clause before the
DISTRIBUTED ...
clause.
Descriptions of additional parameters that are specific to the classic partitioning syntax follow.
ALTER PARTITION
clauses to specify which sub-partition in the hierarchy you want to alter. For each partition level in the table hierarchy that is above the target partition, specify the partition that is related to the target partition in an
ALTER PARTITION
clause.
<
parentname
>_<
level
>_prt_<
partition_name
>
.
partition_element - Using the existing partition type of the table (range or list), defines the boundaries of new partition you are adding. ADD PARTITION
acquires an ACCESS EXCLUSIVE
lock on the parent table.
name - A name for this new partition.
VALUES - For list partitions, defines the value(s) that the partition will contain.
START - For range partitions, defines the starting range value for the partition. By default, start values are INCLUSIVE
. For example, if you declared a start date of '2016-01-01
', then the partition would contain all dates greater than or equal to '2016-01-01
'. The data type of the START
expression must support a suitable +
operator, for example timestamp
or integer
(not float
or text
) if it is defined with the EXCLUSIVE
keyword. Typically the data type of the START
expression is the same type as the partition key column. If that is not the case, then you must explicitly cast to the intended data type.
END - For range partitions, defines the ending range value for the partition. By default, end values are EXCLUSIVE
. For example, if you declared an end date of '2016-02-01
', then the partition would contain all dates less than but not equal to '2016-02-01
'. The data type of the END
expression must support a suitable +
operator, for example timestamp
or integer
(not float
or text
) if it is defined with the INCLUSIVE
keyword. Typically the data type of the END
expression is the same type as the partition key column. If that is not the case, then you must explicitly cast to the intended data type.
WITH - Sets the table storage options for a partition. For example, you may want older partitions to be append-optimized tables and newer partitions to be regular heap tables. See CREATE TABLE for a description of the storage options.
TABLESPACE - The name of the tablespace in which the partition is to be created.
Exchanges another table into the partition hierarchy into the place of an existing partition. In a multi-level partition design, you can only exchange the lowest level partitions (those that contain data).
WITH TABLE table_name - The name of the table you are swapping into the partition design. You can exchange a table where the table data is stored in the database. For example, the table is created with the CREATE TABLE
command. The table must have the same number of columns, column order, column names, column types, and distribution policy as the parent table.
With the EXCHANGE PARTITION
clause, you can also exchange a readable external table (created with the CREATE EXTERNAL TABLE
command) into the partition hierarchy in the place of an existing leaf partition.
Exchanging a leaf partition with an external table is not supported if the partitioned table contains a column with a check constraint or a NOT NULL
constraint.
You cannot exchange a partition with a replicated table. Exchanging a partition with a partitioned table or a child partition of a partitioned table is not supported.
Splits a default partition. In a multi-level partition, only a range partition can be split, not a list partition, and you can only split the lowest level default partitions (those that contain data). Splitting a default partition creates a new partition containing the values specified and leaves the default partition containing any values that do not match to an existing partition.
AT - For list partitioned tables, specifies a single list value that should be used as the criteria for the split.
START - For range partitioned tables, specifies a starting value for the new partition.
END - For range partitioned tables, specifies an ending value for the new partition.
INTO
clause to split a default partition, the second partition name specified should always be that of the existing default partition. If you do not know the name of the default partition, you can look it up using the pg_partitions view.
Splits an existing partition into two partitions. In a multi-level partition, only a range partition can be split, not a list partition, and you can only split the lowest level partitions (those that contain data).
AT - Specifies a single value that should be used as the criteria for the split. The partition will be divided into two new partitions with the split value specified being the starting range for the latter partition.
FOR
matches to both a partition and one of its sub-partitions (for example, if the value is a date and the table is partitioned by month and then by day), then
FOR
will operate on the first level where a match is found (for example, the monthly partition). If your intent is to operate on a sub-partition, you must declare so as follows:
ALTER TABLE name ALTER PARTITION FOR ('2016-10-01') DROP PARTITION FOR ('2016-10-01');
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, or NULL
if no DEFAULT
clause is specified. Adding a column with a non-null default or changing the type of an existing column in an Append-Optimized, Column-Oriented table or an Append-Optimized table does not require rewriting the entire table and its indexes. See the table in this section for details on which Data Definition Language (DDL) types can skip table rewrites for various table types.
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.
Greenplum Database provides the option to specify multiple changes in a single ALTER TABLE
so that multiple table scans or rewrites can be combined into a single pass over the table.
Scanning a large table to verify a new check constraint can take a long time, and other updates to the table are locked out until the ALTER TABLE ADD CONSTRAINT
command is committed. The main purpose of the NOT VALID
constraint option is to reduce the impact of adding a constraint on concurrent updates. With NOT VALID
, the ADD CONSTRAINT
command does not scan the table and can be committed immediately. After that, a VALIDATE CONSTRAINT
command can be issued to verify that existing rows satisfy the constraint. The validation step does not need to lock out concurrent updates, since it knows that other transactions will be enforcing the constraint for rows that they insert or update; only pre-existing rows need to be checked. Hence, validation acquires only a SHARE UPDATE EXCLUSIVE
lock on the table being altered. In addition to improving concurrency, it can be useful to use NOT VALID
and VALIDATE CONSTRAINT
in cases where the table is known to contain pre-existing violations. Once the constraint is in place, no new violations can be inserted, and you can correct the existing problems until VALIDATE CONSTRAINT
finally succeeds.
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. If you drop the system oid
column, however, the table is rewritten immediately.
To force immediate reclamation of space occupied by a dropped column, you can run 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.
This table lists the ALTER TABLE
operations that require a table rewrite when performed on tables defined with the specified type of table storage.
Operation (See Note) | Append-Optimized, Column-Oriented | Append-Optimized | Heap |
---|---|---|---|
ALTER COLUMN TYPE |
No | Yes | Yes |
ADD COLUMN |
No | No | No |
ALTER COLUMN SET ENCODING |
No | N/A | N/A |
ImportantThe forms of
ALTER TABLE
that perform a table rewrite 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 MVCC Caveats for more details.
Take special care when altering or dropping columns that are part of the Greenplum Database distribution key as this can change the distribution policy for the table.
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 the same to the descendants. This ensures that the descendants always have columns matching the parent. Similarly, a CHECK
constraint cannot be renamed in the parent without also renaming it in all descendants, so that CHECK
constraints also match between the parent and its descendants. (That restriction does not apply to index-based constraints, however.) 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
(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 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
.
Greenplum Database does not currently support foreign key constraints. For a unique constraint to be enforced in Greenplum Database, the table must be hash-distributed (not DISTRIBUTED RANDOMLY
), and all of the distribution key columns must be the same as the initial columns of the unique constraint columns.
Greenplum Database does not permit changing any part of a system catalog table.
Refer to CREATE TABLE for a further description of valid parameters.
Be aware of the following when altering partitioned tables using the classic syntax:
The table name specified in the ALTER TABLE
command must be the actual table name of the partition, not the partition alias that is specified in the classic syntax.
Use the pg_partition_tree()
function to view the structure of a partitioned table. This function returns the partition hierarchy, and can help you identify the particular partitions you may want to alter.
These ALTER PARTITION
operations are supported if no data is changed on a partitioned table that contains a leaf partition that has been exchanged to use an external table. Otherwise, an error is returned.
These ALTER PARTITION
operations are not supported for a partitioned table that contains a leaf partition that has been exchanged to use an external table:
NOT NULL
constraint of column.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();
Rename an existing column:
ALTER TABLE distributors RENAME COLUMN address TO city;
Rename an existing table:
ALTER TABLE distributors RENAME TO suppliers;
To rename an existing constraint:
ALTER TABLE distributors RENAME CONSTRAINT zipchk TO zip_check;
Add a not-null constraint to a column:
ALTER TABLE distributors ALTER COLUMN street SET NOT NULL;
Rename an existing constraint:
ALTER TABLE distributors RENAME CONSTRAINT zipchk TO zip_check;
To remove a not-null constraint from a column:
ALTER TABLE distributors ALTER COLUMN street DROP NOT NULL;
Add a check constraint to a table and all of 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.)
Remove a check constraint from a table and all of its children:
ALTER TABLE distributors DROP CONSTRAINT zipchk;
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 that inherit distributors
.)
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;
Move a table to a different schema:
ALTER TABLE myschema.distributors SET SCHEMA yourschema;
Change a table's access method to ao_row
:
ALTER TABLE distributors SET ACCESS METHOD ao_row;
Change a table's blocksize
to 32768
:
ALTER TABLE distributors SET (blocksize = 32768);
Change a table's access method to ao_row
, compression type to zstd
and compression level to 4
:
ALTER TABLE sales SET ACCESS METHOD ao_row with (compresstype=zstd,compresslevel=4);
Alternatively, you can perform the same operation using SET WITH
:
ALTER TABLE sales SET WITH (appendoptimized=true, compresstype=zstd, compresslevel=4);
Change access method for all existing partitions of a table:
ALTER TABLE sales SET ACCESS METHOD ao_row;
Change all future partitions of a table to have an access method of heap
, leaving the access method of current partitions as is:
ALTER TABLE ONLY sales SET ACCESS METHOD heap;
Add a column and change the table's access method:
ALTER TABLE distributors SET ACCESS METHOD ao_row, ADD column j int;
Add a column and change table storage parameters:
ALTER TABLE distributors SET (compresslevel=7), ADD COLUMN k int;
Change the distribution policy of a table to replicated:
ALTER TABLE myschema.distributors SET DISTRIBUTED REPLICATED;
Change the distribution policy of a table to random and force a table rewrite:
ALTER TABLE distributors SET WITH (REORGANIZE=true) SET DISTRIBUTED RANDOMLY;
Set compression for a table and physically reorder the table by column i
:
ALTER TABLE distributors
REPACK BY COLUMNS (i),
SET (compresstype=zstd, compresslevel=3);
Attach a partition to a range-partitioned table:
ALTER TABLE measurement
ATTACH PARTITION measurement_y2016m07 FOR VALUES FROM ('2016-07-01') TO ('2016-08-01');
Attach a partition to a list-partitioned table:
ALTER TABLE cities
ATTACH PARTITION cities_ab FOR VALUES IN ('a', 'b');
Attach a partition to a hash-partitioned table:
ALTER TABLE orders
ATTACH PARTITION orders_p4 FOR VALUES WITH (MODULUS 4, REMAINDER 3);
Attach a default partition to a partitioned table:
ALTER TABLE cities
ATTACH PARTITION cities_partdef DEFAULT;
Detach a partition from a partitioned table:
ALTER TABLE measurement
DETACH PARTITION measurement_y2015m12;
Add a new partition to a partitioned table:
ALTER TABLE sales ADD PARTITION
START (date '2017-02-01') INCLUSIVE
END (date '2017-03-01') EXCLUSIVE;
Add a default partition to an existing partition design:
ALTER TABLE sales ADD DEFAULT PARTITION other;
Rename a partition:
ALTER TABLE sales RENAME PARTITION FOR ('2016-01-01') TO
jan08;
Exchange a table into your partition design:
ALTER TABLE sales EXCHANGE PARTITION FOR ('2016-01-01') WITH
TABLE jan08;
Split the default partition (where the existing default partition's name is other
) to add a new monthly partition for January 2017:
ALTER TABLE sales SPLIT DEFAULT PARTITION
START ('2017-01-01') INCLUSIVE
END ('2017-02-01') EXCLUSIVE
INTO (PARTITION jan09, PARTITION other);
Split a monthly partition into two with the first partition containing dates January 1-15 and the second partition containing dates January 16-31:
ALTER TABLE sales SPLIT PARTITION FOR ('2016-01-01')
AT ('2016-01-16')
INTO (PARTITION jan081to15, PARTITION jan0816to31);
For a multi-level partitioned table that consists of three levels, year, quarter, and region, exchange a leaf partition region
with the table region_new
.
ALTER TABLE sales ALTER PARTITION year_1 ALTER PARTITION quarter_4 EXCHANGE PARTITION region WITH TABLE region_new ;
In the previous command, the two ALTER PARTITION
clauses identify which region
partition to exchange. Both clauses are required to identify the specific partition to exchange.
The forms ADD
(without USING INDEX
), DROP [COLUMN]
, DROP IDENTITY
, RESTART
, SET DEFAULT
, SET DATA TYPE
(without USING
), SET GENERATED
, and SET <sequence_option>
conform with the SQL standard. The other forms are Greenplum Database extensions of the SQL standard. Also, the ability to specify more than one manipulation in a single 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.
Parent topic: SQL Commands