SQL-J Language Reference,
Page 6 of 118


[top]
[prev]
[next]
Documentation Top
Global Index
Reference Manual
TOC Index
Grammar index
Developer's Guide
TOC Index
Tuning Cloudscape
TOC Index

ALTER TABLE statement

The ALTER TABLE statement allows you to:

  • add a column to a table
  • add a constraint to a table
  • drop an existing constraint from a table
  • add a default value for a column in a table
  • drop a default value for a column in a table by setting the default to null
  • override row-level locking for the table (or drop the override)

NEW: The ability to add or drop a default value for a column in the table and to override row-level locking for the table are new features in Version 3.0.

Syntax

ALTER TABLE TableName
{
    ADD COLUMN ColumnDefinition |
    ADD CONSTRAINT clause |
    DROP CONSTRAINT ConstraintName [ RESTRICT | CASCADE ] |
    MODIFY { ( ColumnDefault ) | ColumnDefault } |
    SET LOCKING = { TABLE | ROW }
}

ColumnDefault

ColumnName DEFAULT { ConstantExpression | NULL }

ALTER TABLE does not affect any view that references the table being altered. This includes views that have an “*” in their SELECT list. You must drop and re-create those views if you wish them to return the new columns.

Adding Columns

The syntax for the ColumnDefinition for a new column is the same as for a column in a CREATE TABLE statement. This means that a column constraint can be placed on the new column within the ALTER TABLE ADD COLUMN statement. However, a column with a NOT NULL constraint can be added to an existing table only if the table is empty; otherwise, an exception is thrown when the ALTER TABLE statement is executed.

(See “Adding Constraints” for the other limitations.) Just as in CREATE TABLE, if the column definition includes a primary key constraint, the column will be made non-nullable, so an exception is thrown if you attempt to add a primary key column to a table that is not empty.

NOTE: If a table has an UPDATE trigger without an explicit column list, adding a column to that table in effect adds that column to the implicit update column list upon which the trigger is defined, and all references to transition variables are invalidated so that they pick up the new column.

Adding Constraints

ALTER TABLE ADD CONSTRAINT adds a table-level constraint to an existing table. Any supported table-level constraint type can be added via ALTER TABLE. The following limitations exist on adding a constraint to an existing table:

  • All columns included in a primary key must be non-nullable.

NOTE: When creating a primary key in a CREATE TABLE or ALTER TABLE ADD COLUMN statement, you automatically make all columns in a primary key non-nullable. ALTER TABLE ADD CONSTRAINT does not do this, so the columns it references when defining a primary key constraint must already be NOT NULL.

  • When adding a foreign key or check constraint to an existing table, Cloudscape checks the table to make sure existing rows satisfy the constraint. If any row is invalid, Cloudscape throws a statement exception and the constraint is not added.

For information on the syntax of constraints, see “CONSTRAINT clause”. Use the syntax for table-level constraint when adding a constraint with the ADD TABLE ADD CONSTRAINT syntax.

Dropping Constraints

ALTER TABLE DROP CONSTRAINT drops a constraint on an existing table. To drop an unnamed constraint, you must specify the generated constraint name stored in SYS.SYSCONSTRAINTS as a delimited identifier.

Dropping a primary key, unique, or foreign key constraint drops its backing index.

When you drop a primary key or unique constraint and there may be foreign key constraints referencing that primary key or unique constraint, you have two options:

  • Specifying CASCADE means Cloudscape drops all referencing foreign key constraints and their backing indexes.
  • Specifying RESTRICT means that Cloudscape throws an exception if there are any foreign keys referencing the primary key that you want to drop. The constraint is not dropped. This is the default behavior.

Changing the Lock Granularity for the Table

The SET LOCKING clause allows you to override row-level locking for the specific table, if your system is set for row-level locking. (If your system is set for table-level locking, you cannot change the locking granularity to row-level locking, although Cloudscape allows you to use the SET LOCKING clause in such a situation without throwing an exception.) To override row-level locking for the specific table, set locking for the table to TABLE. If you created the table with table-level locking granularity, you can change locking back to ROW with the SET LOCKING clause in the ALTER TABLE statement. For information about why this is sometimes useful, see “About the Optimizer’s Selection of Lock Granularity” in Tuning Cloudscape.

Adding or Dropping Defaults

You can specify a default value for a column. A default value is the value that is inserted into a column if no other value is specified. If not explicitly specified, the default value of a column is NULL. If you add a default to a new column, existing rows in the table gain the default value in the new column. If you add a default to an existing column, existing rows in the table do not gain the default value in the new column.

To drop a default, set the default value to NULL. Doing so does not affect the values of the column for existing rows.

For more information about defaults, see “CREATE TABLE statement”.

Examples

-- Add a new column with a column-level constraint
-- to an existing table
-- An exception will be thrown if the table
-- contains more than 1 row
-- since the newcol will be initialized to NULL
-- in all existing rows in the table
ALTER TABLE Cities
ADD COLUMN Region VARCHAR(26)
CONSTRAINT new_constraint NOT NULL
-- Add a new unique constraint to an existing table
-- An exception will be thrown if duplicate keys are found
ALTER TABLE Countries
ADD CONSTRAINT new_unique UNIQUE(country)
-- add a new foreign key constraint to the
-- Hotels table. Each row in Hotels is checked
-- to make sure it satisfied the contraints.
-- if any rows don’t satisfy the constraint, the
-- constraint is not added
ALTER TABLE HOTELS ADD CONSTRAINT City_FK
    FOREIGN KEY (city_id) REFERENCES Cities
-- Drop a primary key constraint from a table
-- You will not be able to drop this constraint if
-- there are any foreign keys referencing it
ALTER TABLE Cities DROP CONSTRAINT Cities_PK
-- Drop a primary key constraint from a table
-- and all referencing foreign keys
ALTER TABLE Cities DROP CONSTRAINT Cities_PK CASCADE
-- add a default value to a column
-- (existing rows are not affected)
ALTER TABLE HotelAvailability
MODIFY rooms_taken DEFAULT 1
-- drop a default value for a column
ALTER TABLE HotelAvailability
MODIFY rooms_taken DEFAULT NULL

Dependency System

An ALTER TABLE statement causes all statements that are dependent on the table being altered to be recompiled before their next execution. ALTER TABLE is not allowed if there are any open cursors that reference the table being altered.

[top]
[prev]
[next]


Cloudscape Version 3.0
For technical support, go to: www.cloudscape.com and click Support.
Copyright © 1998 and 1999 Cloudscape, Inc. All rights reserved.