ALTER TABLE Statement

Modifies a table definition.

Syntax

ALTER TABLEowner.]table-namealter-clause, ... }

Parameters

Examples

Usage

The ALTER TABLE statement changes table attributes (column definitions and constraints) in a table that was previously created. The syntax allows a list of alter clauses; however, only one table constraint or column constraint can be added, modified, or deleted in each ALTER TABLE statement.

Note:

You cannot alter local temporary tables, but you can alter global temporary tables when they are in use by only one connection.

Sybase IQ enforces REFERENCES and CHECK constraints. Table and/or column check constraints added in an ALTER TABLE statement are not evaluated as part of that alter table operation. For details about CHECK constraints, see CREATE TABLE Statement.

If SELECT * is used in a view definition and you alter a table referenced by the SELECT *, then you must run ALTER VIEW <viewname> RECOMPILE to ensure that the view definition is correct and to prevent unexpected results when querying the view.

ADD column-definition [ column-constraint ]—Add a new column to the table. The table must be empty to specify NOT NULL. The table might contain data when you add an IDENTITY or DEFAULT AUTOINCREMENT column. If the column has a default IDENTITY value, all rows of the new column are populated with sequential values. You can also add a foreign key constraint as a column constraint for a single column key. The value of the IDENTITY/DEFAULT AUTOINCREMENT column uniquely identifies every row in a table. The IDENTITY/DEFAULT AUTOINCREMENT column stores sequential numbers that are automatically generated during inserts and updates. DEFAULT AUTOINCREMENT columns are also known as IDENTITY columns. When using IDENTITY/DEFAULT AUTOINCREMENT, the column must be one of the integer data types, or an exact numeric type, with scale 0. See CREATE TABLE Statement for more about column constraints and IDENTITY/DEFAULT AUTOINCREMENT columns.

Note:

You cannot add foreign key constraints to an unenforced primary key created with Sybase IQ version 12.4.3 or earlier.

ALTER column-name column-alteration—Change the definition of a column. The permitted modifications are:

  • SET DEFAULT default-value—Change the default value of an existing column in a table. You can also use the MODIFY clause for this task, but ALTER is ISO/ANSI SQL compliant, and MODIFY is not. Modifying a default value does not change any existing values in the table.

  • DROP DEFAULT—Remove the default value of an existing column in a table. You can also use the MODIFY clause for this task, but ALTER is ISO/ANSI SQL compliant, and MODIFY is not. Dropping a default does not change any existing values in the table.

  • ADD—Add a named constraint or a CHECK condition to the column. The new constraint or condition applies only to operations on the table after its definition. The existing values in the table are not validated to confirm that they satisfy the new constraint or condition.

  • CONSTRAINT column-constraint-name—The optional column constraint name lets you modify or drop individual constraints at a later time, rather than having to modify the entire column constraint.

  • [ CONSTRAINT constraint-name ] CHECK ( condition )—Use this clause to add a CHECK constraint on the column.

  • SET COMPUTE (expression)—Change the expression associated with a computed column. The values in the column are recalculated when the statement is executed, and the statement fails if the new expression is invalid.

  • DROP COMPUTE—Change a column from being a computed column to being a noncomputed column. This statement does not change any existing values in the table.

DROP partition clause—Drop the specified partition. The rows are deleted and the partition definition is dropped. You cannot drop the last partition because dropping the last partition would transform a partitioned table to a non-partitioned table. (To merge a partitioned table, use UNPARTITION clause instead.) For example:

	CREATE TABLE foo (c1 INT, c2 INT)
		PARTITION BY RANGE (c1)
		(P1 VALUES <= (100) IN dbsp1,
		 P2 VALUES <= (200) IN dbsp2,
		 P3 VALUES <= (MAX) IN dbsp3
		) IN dbsp4);
	LOAD TABLE ….
	ALTER TABLE DROP PARTITION P1;

ADD table-constraint—Add a constraint to the table. You can also add a foreign key constraint as a table constraint for a single-column or multicolumn key. See CREATE TABLE Statement for a full explanation of table constraints.

If PRIMARY KEY is specified, the table must not already have a primary key created by the CREATE TABLE statement or another ALTER TABLE statement.

Note:

You cannot MODIFY a table or column constraint. To change a constraint, DELETE the old constraint and ADD the new constraint.

DROP column-name—Drop the column from the table. If the column is contained in any multicolumn index, uniqueness constraint, foreign key, or primary key, then the index, constraint, or key must be deleted before the column can be deleted. This does not delete CHECK constraints that refer to the column. An IDENTITY/DEFAULT AUTOINCREMENT column can only be deleted if IDENTITY_INSERT is turned off and the table is not a local temporary table.

DROP CHECK—Drop all check constraints for the table. This includes both table check constraints and column check constraints.

DROP CONSTRAINT constraint-name—Drop the named constraint for the table or specified column.

DROP UNIQUE (column-name,…)—Drop the unique constraints on the specified column(s). Any foreign keys referencing the unique constraint (rather than the primary key) are also deleted. Reports an error if there are associated foreign-key constraints. Use ALTER TABLE to delete all foreign keys that reference the primary key before you delete the primary key constraint.

DROP PRIMARY KEY—Drop the primary key. All foreign keys referencing the primary key for this table are also deleted. Reports an error if there are associated foreign key constraints. If the primary key is unenforced, DELETE returns an error if associated unenforced foreign key constraints exist.

DROP FOREIGN KEY role-name—Drop the foreign key constraint for this table with the given role name. Retains the implicitly created nonunique HG index for the foreign key constraint. Users can explicitly remove the HG index with the DROP INDEX statement.

DROP PARTITION—Delete rows in partition P1 and drop the partition definition of P1. If a new row with value 99 for column c1 is inserted, it will be placed under partition p2 in dbspace dbsp2.

RENAME new-table-name—Change the name of the table to the new-table-name. Any applications using the old table name must be modified. Also, any foreign keys that were automatically assigned the same name as the old table name do not change names.

RENAME column-name TO new-column-name—Change the name of the column to new-column-name. Any applications using the old column name must be modified.

RENAME constraint-name TO new-constraint-name—Change the name of the constraint to new-constraint-name. Any applications using the old constraint name must be modified.

ALTER TABLE is prevented whenever the statement affects a table that is currently being used by another connection. ALTER TABLE can be time consuming, and the server does not process requests referencing the same table while the statement is being processed.

ALTER Column MOVE TO—Move the specified column to the new dbspace for a non-partitioned table. The ALTER Column MOVE TO clause cannot be requested on a partitioned table. The ALTER Column MOVE PARTITION clause moves the column of the specified partition to the specified dbspace.

MOVE PARTITION—Move the specified partition to the new dbspace.

MOVE TO—Move all table objects including columns, indexes, unique constraints, primary key, foreign keys, and metadata resided in the same dbspace as the table is mapped to the new dbspace.

Each table object can reside in only one dbspace. Any type of ALTER MOVE blocks any modification to the table for the entire duration of the move.

MOVE TABLE METADATA—Move the metadata of the table to a new dbspace. For a partitioned table, the MOVE TABLE METADATA clause also moves metadata that is shared among partitions.

You must have DBA or SPACE ADMIN authority, or have CREATE privilege on the new dbspace and be the table owner or have alter permission on the table.

SPLIT PARTITION—Split the specified partition into two partitions. A partition can be split only if no data must be moved. All existing rows of the partition to be split must remain in a single partition after the split. The boundary value for partition-decl-1 must be less than the boundary value of partition-name and the boundary value for partition-decl-2 must be equal to the boundary value of partition-name. You can specify different names for the two new partitions. The old partition-name can only be used for the second partition, if a new name is not specified.

MERGE PARTITION—Merge partition-name-1 into partition-name-2. Two partitions can be merged if they are adjacent partitions and the data resides on the same dbspace. You can only merge a partition with a lower partition value into the adjacent partition with a higher partition value. Note that the server does not check CREATE permission on the dbspace into which the partition is merged. For an example of how to create adjacent partitions, see Example 3 in CREATE TABLE Statement.

UNPARTITION—Remove partitions from a partitioned table. Each column is placed in a single dbspace. Note that the server does not check CREATE permission on the dbspace to which data of all partitions is moved. ALTER TABLE UNPARTITION blocks all database activities.

PARTITION BY—Partition a non-partitioned table. A non-partitioned table can be partitioned, if all existing rows belong to the first partition. You can specify a different dbspace for the first partition than the dbspace of the column or table. But existing rows are not moved. Instead, the proper dbspace for the column/partition is kept in SYS.ISYSIQPARTITIONCOLUMN for existing columns. Only the default or max identity column(s) that are added later for the first partition are stored in the specified dbspace for the first partition.

RENAME PARTITION—Rename an existing partition name to a new partition name.

Side effects:
  • Automatic commit. The ALTER and DROP options close all cursors for the current connection. The dbisql data window is also cleared.

  • A checkpoint is carried out at the beginning of the ALTER TABLE operation.

  • Once you alter a column or table, any stored procedures, views or other items that refer to the altered column no longer work.

Standards

  • SQL—Vendor extension to ISO/ANSI SQL grammar.

  • Sybase—Some clauses are supported by Adaptive Server Enterprise.

Permissions

For MOVE syntax, one of the following must be true:
  • Have DBA or SPACE ADMIN authority

  • Have CREATE permission on the new dbspace and be the table owner

  • Have ALTER permission on the table

For syntax other than MOVE, one of the following must be true:
  • Have DBA authority

  • Have CREATE permission on the new dbspace and be the table owner

  • Have ALTER permission on the table

Requires exclusive access to the table.
Related reference
CREATE TABLE Statement
DROP Statement
IDENTITY_INSERT Option