ALTER TABLE

The ALTER TABLE statement alters the definition of a table.

Invocation

This statement can be embedded in an application program or issued interactively. It is an executable statement that can be dynamically prepared.

Authorization

The privileges held by the authorization ID of the statement must include at least one of the following:

To define a foreign key, the privileges held by the authorization ID of the statement must include at least one of the following on the parent table:

If a select-statement is specified, the privileges held by the authorization ID of the statement must include at least one of the following on the tables or views specified in these clauses:

If a distinct type is referenced, the privileges held by the authorization ID of the statement must include at least one of the following:

For information on the system authorities corresponding to SQL privileges, see Corresponding System Authorities When Checking Privileges to a Table or View and Corresponding System Authorities When Checking Privileges to a Distinct Type.

Syntax

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-ALTER TABLE--table-name-------------------------------------->
 
   .-----------------------------------------------------------------------------.
   V          .-COLUMN-.                                                         |
>------+-ADD--+--------+--column-definition----------------------------------+---+-><
       |        .-COLUMN-.                                                   |
       +-ALTER--+--------+--column-alteration--------------------------------+
       |         .-COLUMN-.               .-CASCADE--.                       |
       +-DROP----+--------+--column-name--+----------+-----------------------+
       |                                  '-RESTRICT-'                       |
       +-ADD--+-unique-constraint------+-------------------------------------+
       |      +-referential-constraint-+                                     |
       |      '-check-constraint-------'                                     |
       |                                             .-CASCADE--.            |
       +-DROP--+-PRIMARY KEY----------------------+--+----------+------------+
       |       '-+-UNIQUE------+--constraint-name-'  '-RESTRICT-'            |
       |         +-FOREIGN KEY-+                                             |
       |         +-CHECK-------+                                             |
       |         '-CONSTRAINT--'                                             |
       +-ADD--partitioning-clause--------------------------------------------+
       +-DROP PARTITIONING---------------------------------------------------+
       +-ADD PARTITION--+-+----------------+--boundary-spec-+----------------+
       |                | '-partition-name-'                |                |
       |                '-integer--+-HASH PARTITIONS-+------'                |
       |                           '-HASH PARTITION--'                       |
       +-ALTER PARTITION--partition-name--boundary-spec----------------------+
       +-DROP PARTITION--partition-name--+-DELETE ROWS---+-------------------+
       |                                 '-PRESERVE ROWS-'                   |
       |        .-MATERIALIZED-.                                             |
       |      .-+--------------+--QUERY-.                                    |
       +-ADD--+-------------------------+--materialized-query-definition-----+
       |        .-MATERIALIZED-.                                             |
       +-ALTER--+--------------+--QUERY--materialized-query-table-alteration-+
       |       .-MATERIALIZED-.                                              |
       +-DROP--+--------------+--QUERY---------------------------------------+
       +-ACTIVATE--NOT LOGGED INITIALLY--+------------------+----------------+
       |                                 '-WITH EMPTY TABLE-'                |
       |                   .-CARDINALITY-.                                   |
       '-+-NOT VOLATILE-+--+-------------+-----------------------------------'
         '-VOLATILE-----'
 
Read syntax diagramSkip visual syntax diagramcolumn-definition:
 
|--column-name--+-------------------------------------+--------->
                |      .-COLUMN-.                     |
                '-FOR--+--------+--system-column-name-'
 
>--data-type---------------------------------------------------->
 
   .---------------------------------------------------------.
   V                                                         | (3)
>----+-----------------------------------------------------+-+-------|
     +-default-clause--------------------------------------+
     | .-GENERATED ALWAYS-----. (1)                        |
     +-+----------------------+-------+------------------+-+
     | '-GENERATED BY DEFAULT-'       '-identity-options-' |
     |                  (2)                                |
     +-datalink-options------------------------------------+
     +-NOT NULL--------------------------------------------+
     '-column-constraint-----------------------------------'
 
data-type:
 
|--+-built-in-type------+---------------------------------------|
   '-distinct-type-name-'
 
Notes:
  1. GENERATED can be specified only if the column has a ROWID data type (or a distinct type that is based on a ROWID data type), or the column is an identity column.
  2. The datalink-options can only be specified for DATALINKs and distinct-types sourced on DATALINKs.
  3. The same clause must not be specified more than once.
Read syntax diagramSkip visual syntax diagrambuilt-in-type:
 
|--+-+---SMALLINT---+-------------------------------------------------------------------------------------------+--|
   | +-+-INTEGER-+--+                                                                                           |
   | | '-INT-----'  |                                                                                           |
   | '---BIGINT-----'                                                                                           |
   |                  .-(5,0)------------------------.                                                          |
   +-+-+-DECIMAL-+-+--+------------------------------+----------------------------------------------------------+
   | | '-DEC-----' |  |             .-,0--------.    |                                                          |
   | '-NUMERIC-----'  '-(--integer--+-----------+--)-'                                                          |
   |                                '-, integer-'                                                               |
   |          .-(--52--)------.                                                                                 |
   +-+-FLOAT--+---------------+-+-------------------------------------------------------------------------------+
   | |        '-(--integer--)-' |                                                                               |
   | +-REAL---------------------+                                                                               |
   | |         .-PRECISION-.    |                                                                               |
   | '-DOUBLE--+-----------+----'                                                                               |
   |                    .-(--1--)-------.                                                                       |
   +-+-+-+-CHARACTER-+--+---------------+-------------------------------+--+----------------+-----------------+-+
   | | | '-CHAR------'  '-(--integer--)-'                               |  +-FOR BIT DATA---+                 | |
   | | '-+-+-CHARACTER-+--VARYING-+--(--integer--)--+-----------------+-'  +-FOR SBCS DATA--+                 | |
   | |   | '-CHAR------'          |                 '-allocate-clause-'    +-FOR MIXED DATA-+                 | |
   | |   '-VARCHAR----------------'                                        '-ccsid-clause---'                 | |
   | |                                      .-(--1M--)-------------.                                          | |
   | '---+-+-CHARACTER-+--LARGE OBJECT-+----+----------------------+--+-----------------+--+----------------+-' |
   |     | '-CHAR------'               |    '-(--integer--+---+--)-'  '-allocate-clause-'  +-FOR SBCS DATA--+   |
   |     '-CLOB------------------------'                  +-K-+                            +-FOR MIXED DATA-+   |
   |                                                      +-M-+                            '-ccsid-clause---'   |
   |                                                      '-G-'                                                 |
   |                .-(--1--)-------.                                                                           |
   +-+---GRAPHIC----+---------------+----------------------------+--+--------------+----------------------------+
   | |              '-(--integer--)-'                            |  '-ccsid-clause-'                            |
   | +-+-GRAPHIC VARYING-+--(--integer--)--+-----------------+---+                                              |
   | | '-VARGRAPHIC------'                 '-allocate-clause-'   |                                              |
   | |             .-(--1M--)-------------.                      |                                              |
   | '---DBCLOB----+----------------------+--+-----------------+-'                                              |
   |               '-(--integer--+---+--)-'  '-allocate-clause-'                                                |
   |                             +-K-+                                                                          |
   |                             +-M-+                                                                          |
   |                             '-G-'                                                                          |
   |             .-(--1--)-------.                                                                              |
   +-+-+-BINARY--+---------------+------------------------------+-----------------+-----------------------------+
   | | |         '-(--integer--)-'                              |                 |                             |
   | | '-+-BINARY VARYING-+--(--integer--)--+-----------------+-'                 |                             |
   | |   '-VARBINARY------'                 '-allocate-clause-'                   |                             |
   | |                              .-(--1M--)-------------.                      |                             |
   | '---+-BLOB----------------+----+----------------------+--+-----------------+-'                             |
   |     '-BINARY LARGE OBJECT-'    '-(--integer--+---+--)-'  '-allocate-clause-'                               |
   |                                              +-K-+                                                         |
   |                                              +-M-+                                                         |
   |                                              '-G-'                                                         |
   +-+-DATE-------------------+---------------------------------------------------------------------------------+
   | |       .-(--0--)-.      |                                                                                 |
   | +-TIME--+---------+------+                                                                                 |
   | |            .-(--6--)-. |                                                                                 |
   | '-TIMESTAMP--+---------+-'                                                                                 |
   |             .-(--200--)-----.                                                                              |
   +---DATALINK--+---------------+--+-----------------+--+--------------+---------------------------------------+
   |             '-(--integer--)-'  '-allocate-clause-'  '-ccsid-clause-'                                       |
   '---ROWID----------------------------------------------------------------------------------------------------'
 
allocate-clause:
 
|--ALLOCATE--(integer)------------------------------------------|
 
ccsid-clause:
 
                   .-NOT NORMALIZED-.
|--CCSID--integer--+----------------+---------------------------|
                   '-NORMALIZED-----'
 
Read syntax diagramSkip visual syntax diagramdefault-clause:
 
   .-WITH-.
|--+------+--DEFAULT--+-------------------------------------------------+--|
                      +-constant----------------------------------------+
                      +-USER--------------------------------------------+
                      +-NULL--------------------------------------------+
                      +-CURRENT_DATE------------------------------------+
                      +-CURRENT_TIME------------------------------------+
                      +-CURRENT_TIMESTAMP-------------------------------+
                      '-cast-function-name--(--+-constant----------+--)-'
                                               +-USER--------------+
                                               +-CURRENT_DATE------+
                                               +-CURRENT_TIME------+
                                               '-CURRENT_TIMESTAMP-'
 
identity-options:
 
|--AS IDENTITY--+-------------------------------------------------------+--|
                |    .-,-------------------------------------------.    |
                |    V               .-1----------------.     (1)  |    |
                '-(----+-START WITH--+-numeric-constant-+---+------+--)-'
                       |               .-1----------------. |
                       +-INCREMENT BY--+-numeric-constant-+-+
                       | .-NO MINVALUE----------------.     |
                       +-+-MINVALUE--numeric-constant-+-----+
                       | .-NO MAXVALUE----------------.     |
                       +-+-MAXVALUE--numeric-constant-+-----+
                       | .-NO CYCLE-.                       |
                       +-+-CYCLE----+-----------------------+
                       | .-CACHE--20------.                 |
                       +-+-NO CACHE-------+-----------------+
                       | '-CACHE--integer-'                 |
                       | .-NO ORDER-.                       |
                       '-+-ORDER----+-----------------------'
 
column-constraint:
 
|--+-----------------------------+--+-+-PRIMARY KEY-+--------------+--|
   '-CONSTRAINT--constraint-name-'  | '-UNIQUE------'              |
                                    +-references-clause------------+
                                    '-CHECK--(--check-condition--)-'
 
Notes:
  1. The same clause must not be specified more than once.
Read syntax diagramSkip visual syntax diagramdatalink-options:
 
   .-LINKTYPE URL-.  .-NO LINK CONTROL--------------------------.
|--+--------------+--+------------------------------------------+--|
                     '-FILE LINK CONTROL--+-file-link-options-+-'
                                          '-MODE DB2OPTIONS---'
 
file-link-options:
 
   .---------------------------------------.
   V                                  (1)  |
|----+-INTEGRITY ALL----------------+------+--------------------|
     +-+-READ PERMISSION FS-+-------+
     | '-READ PERMISSION DB-'       |
     +-+-WRITE PERMISSION FS------+-+
     | '-WRITE PERMISSION BLOCKED-' |
     +-RECOVERY NO------------------+
     '-+-ON UNLINK RESTORE-+--------'
       '-ON UNLINK DELETE--'
 
Notes:
  1. All five file-link-options must be specified, but they can be specified in any order.
Read syntax diagramSkip visual syntax diagramcolumn-alteration:
 
                .-----------------------------------------------------------------------------------.
                |                                  .--------------------------------------------.   |
                V                                  V                                       (2)  |   |
|--column-name----+-SET--+----------------------+----+-+-default-clause----------------+-+------+-+-+--|
                  |      '-DATA TYPE--data-type-'    | | .-GENERATED ALWAYS-----. (1)  | |        |
                  |                                  | '-+----------------------+------' |        |
                  |                                  |   '-GENERATED BY DEFAULT-'        |        |
                  |                                  '-NOT NULL--------------------------'        |
                  |       .-------------------.                                                   |
                  |       V              (2)  |                                                   |
                  +-DROP----+-DEFAULT--+------+---------------------------------------------------+
                  |         +-NOT NULL-+                                                          |
                  |         '-IDENTITY-'                                                          |
                  '-identity-alteration-----------------------------------------------------------'
 
identity-alteration:
 
   .---------------------------------------------.
   V                                             | (2)
|----+-SET--+-INCREMENT BY--numeric-constant-+-+-+--------------|
     |      +-+-NO MINVALUE----------------+-+ |
     |      | '-MINVALUE--numeric-constant-' | |
     |      +-+-NO MAXVALUE----------------+-+ |
     |      | '-MAXVALUE--numeric-constant-' | |
     |      +-+-NO CYCLE-+-------------------+ |
     |      | '-CYCLE----'                   | |
     |      +-+-NO CACHE-------+-------------+ |
     |      | '-CACHE--integer-'             | |
     |      '-+-NO ORDER-+-------------------' |
     |        '-ORDER----'                     |
     '-RESTART--+------------------------+-----'
                '-WITH--numeric-constant-'
 
Notes:
  1. GENERATED can be specified only if the column has a ROWID data type (or a distinct type that is based on a ROWID data type), or the column is an identity column.
  2. The same clause must not be specified more than once.
Read syntax diagramSkip visual syntax diagramunique-constraint:
 
|--+-----------------------------+--+-PRIMARY KEY-+--(---------->
   '-CONSTRAINT--constraint-name-'  '-UNIQUE------'
 
   .-,-----------.
   V             |
>----column-name-+--)-------------------------------------------|
 
referential-constraint:
 
|--+-----------------------------+--FOREIGN KEY----------------->
   '-CONSTRAINT--constraint-name-'
 
      .-,-----------.
      V             |
>--(----column-name-+--)--references-clause---------------------|
 
references-clause:
 
|--REFERENCES--table-name--+-----------------------+------------>
                           |    .-,-----------.    |
                           |    V             |    |
                           '-(----column-name-+--)-'
 
   .-ON DELETE NO ACTION--------.  .-ON UPDATE NO ACTION-. (1)
>--+----------------------------+--+---------------------+-------|
   '-ON DELETE--+-RESTRICT----+-'  '-ON UPDATE RESTRICT--'
                +-CASCADE-----+
                +-SET NULL----+
                '-SET DEFAULT-'
 
check-constraint:
 
|--+-----------------------------+------------------------------>
   '-CONSTRAINT--constraint-name-'
 
>--CHECK--(--check-condition--)---------------------------------|
 
Notes:
  1. The ON DELETE and ON UPDATE clauses may be specified in either order.
Read syntax diagramSkip visual syntax diagrammaterialized-query-definition:
 
|--(--select-statement--)--refreshable-table-options------------|
 
refreshable-table-options:
 
                                                   .------------------------------------.
                                                   V                                    | (1)
|--+-DATA INITIALLY DEFERRED--+--REFRESH DEFERRED----+-MAINTAINED BY USER-------------+-+-------|
   '-DATA INITIALLY IMMEDIATE-'                      '-+-ENABLE QUERY OPTIMIZATION--+-'
                                                       '-DISABLE QUERY OPTIMIZATION-'
 
materialized-query-table-alteration:
 
|--+-(--select-statement--)--+---------------------------+-+----|
   |                         '-refreshable-table-options-' |
   |      .------------------------------------.           |
   |      V                                    | (2)       |
   '-SET----+-REFRESH DEFERRED---------------+-+-----------'
            +-MAINTAINED BY USER-------------+
            '-+-ENABLE QUERY OPTIMIZATION--+-'
              '-DISABLE QUERY OPTIMIZATION-'
 
Notes:
  1. The same clause must not be specified more than once. MAINTAINED BY USER must be specified.
  2. The same clause must not be specified more than once.
Read syntax diagramSkip visual syntax diagrampartitioning-clause:
 
                   .-RANGE-.
|--PARTITION BY--+-+-------+--range-partition-spec-+------------|
                 '-HASH--hash-partition-spec-------'
 
range-partition-spec:
 
      .-,----------------------------.          .-,--------------------------------------------.
      V              .-NULLS LAST--. |          V                                              |
|--(----column-name--+-------------+-+--)--(--+---+---------------------------+--boundary-spec-+---------+--)--|
                     '-NULLS FIRST-'          |   '-PARTITION--partition-name-'                          |
                                              '-boundary-spec--EVERY--(--integer-constant--+--------+--)-'
                                                                                           +-DAY----+
                                                                                           +-DAYS---+
                                                                                           +-MONTH--+
                                                                                           +-MONTHS-+
                                                                                           +-YEAR---+
                                                                                           '-YEARS--'
 
hash-partition-spec:
 
      .-,-----------.
      V             |
|--(----column-name-+--)--INTO--integer--PARTITIONS-------------|
 
boundary-spec:
 
|--starting-clause--ending-clause-------------------------------|
 
starting-clause:
 
                            .-,------------.
             .-FROM-.       V              |       .-INCLUSIVE-.
|--STARTING--+------+--+-(----+-constant-+-+--)-+--+-----------+--|
                       |      +-MINVALUE-+      |  '-EXCLUSIVE-'
                       |      '-MAXVALUE-'      |
                       '-+-constant-+-----------'
                         +-MINVALUE-+
                         '-MAXVALUE-'
 
ending-clause:
 
                        .-,------------.
           .-AT-.       V              |       .-INCLUSIVE-.
|--ENDING--+----+--+-(----+-constant-+-+--)-+--+-----------+----|
                   |      +-MINVALUE-+      |  '-EXCLUSIVE-'
                   |      '-MAXVALUE-'      |
                   '-+-constant-+-----------'
                     +-MINVALUE-+
                     '-MAXVALUE-'
 

Description

table-name
Identifies the table you want to be altered. The table-name must identify a table that exists at the current server. It must not be a view, a catalog table, or a global temporary table. If table-name identifies a materialized query table, ADD column-definition, ALTER column-alteration, and DROP COLUMN are not allowed.

ADD COLUMN column-definition

Adds a column to the table. If the table has rows, every value of the column is set to its default value, unless the column is a ROWID column or an identity column (a column that is defined AS IDENTITY). The database manager generates default values for ROWID columns and identity columns. If the table previously had n columns, the ordinality of the new column is n+1. The value of n+1 must not exceed 8000.

A table can have only one ROWID or identity column.

A DataLink column with FILE LINK CONTROL cannot be added to a table that is a dependent in a referential constraint with a delete rule of CASCADE.

Adding a new column must not make the sum of the row buffer byte counts of the columns be greater than 32766 or, if a VARCHAR or VARGRAPHIC column is specified, 32740. Additionally, if a LOB is specified, the sum of the byte counts of the columns must not be greater than 3 758 096 383 at the time of insert or update. For information on the byte counts of columns according to data type, see Notes.

column-name
Names the column to be added to the table. Do not use the same name for more than one column of the table or for a system-column-name of the table. Do not qualify column-name.
FOR COLUMN system-column-name
Provides an i5/OS name for the column. Do not use the same name for more than one column-name or system-column-name of the table.

If the system-column-name is not specified, and the column-name is not a valid system-column-name, a system column name is generated. For more information about how system column names are generated, see Rules for Column Name Generation.

data-type
Specifies the data type of the column. The data type can be a built-in data type or a distinct type.
built-in-type
Specifies a built-in data type. See CREATE TABLE for a description of built-in types.
distinct-type-name
Specifies the data type of a column is a distinct type. The length, precision and scale of the column are respectively the length, precision, and scale of the source type of the distinct type. If a distinct type name is specified without a schema name, the distinct type name is resolved by searching the schemas on the SQL path. If the column is to be used in the definition of the foreign key of a referential constraint, the data type of the corresponding column of the parent key must have the same distinct type.
DEFAULT
Specifies a default value for the column. This clause cannot be specified more than once in the same column-definition. DEFAULT cannot be specified for a ROWID column or an identity column (a column that is defined AS IDENTITY). The database manager generates default values for ROWID columns and identity columns. If a value is not specified following the DEFAULT keyword, then:

Omission of NOT NULL and DEFAULT from a column-definition is an implicit specification of DEFAULT NULL.

constant
Specifies the constant as the default for the column. The specified constant must represent a value that could be assigned to the column in accordance with the rules of assignment as described in Assignments and comparisons. A floating-point constant must not be used for a SMALLINT, INTEGER, BIGINT, DECIMAL, or NUMERIC column. A decimal constant must not contain more digits to the right of the decimal point than the specified scale of the column.
USER
Specifies the value of the USER special register at the time of INSERT or UPDATE as the default value for the column. The data type of the column must be CHAR or VARCHAR with a length attribute that is greater than or equal to the length attribute of the USER special register. For existing rows, the value is that of the USER special register at the time the ALTER TABLE statement is processed.
NULL
Specifies null as the default for the column. If NOT NULL is specified, DEFAULT NULL must not be specified within the same column-definition.
CURRENT_DATE
Specifies the current date as the default for the column. If CURRENT_DATE is specified, the data type of the column must be DATE or a distinct type based on a DATE.
CURRENT_TIME
Specifies the current time as the default for the column. If CURRENT_TIME is specified, the data type of the column must be TIME or a distinct type based on a TIME.
CURRENT_TIMESTAMP
Specifies the current timestamp as the default for the column. If CURRENT_TIMESTAMP is specified, the data type of the column must be TIMESTAMP or a distinct type based on a TIMESTAMP.
cast-function-name
This form of a default value can only be used with columns defined as a distinct type, BINARY, VARBINARY, BLOB, CLOB, DBCLOB, DATE, TIME, or TIMESTAMP data types. The following table describes the allowed uses of these cast-functions.
Data Type Cast Function Name
Distinct type N based on a BINARY, VARBINARY, BLOB, CLOB, or DBCLOB BINARY, VARBINARY, BLOB, CLOB, or DBCLOB *
Distinct type N based on a DATE, TIME, or TIMESTAMP N (the user-defined cast function that was generated when N was created) **
or
DATE, TIME, or TIMESTAMP *
Distinct type N based on other data types N (the user-defined cast function that was generated when N was created) **
BINARY, VARBINARY, BLOB, CLOB, or DBCLOB BINARY, VARBINARY, BLOB, CLOB, or DBCLOB *
DATE, TIME, or TIMESTAMP DATE, TIME, or TIMESTAMP *
Notes:

* The name of the function must match the name of the data type (or the source type of the distinct type) with an implicit or explicit schema name of QSYS2.

** The name of the function must match the name of the distinct type for the column. If qualified with a schema name, it must be the same as the schema name for the distinct type. If not qualified, the schema name from function resolution must be the same as the schema name for the distinct type.

constant
Specifies a constant as the argument. The constant must conform to the rules of a constant for the source type of the distinct type or for the data type if not a distinct type. For BINARY, VARBINARY, BLOB, CLOB, DBCLOB, DATE, TIME, and TIMESTAMP functions, the constant must be a string constant.
USER
Specifies the value of the USER special register at the time of INSERT or UPDATE as the default value for the column. The data type of the source type of the distinct type of the column must be CHAR or VARCHAR with a length attribute that is greater than or equal to the length attribute of USER. For existing rows, the value is that of the USER special register at the time the ALTER TABLE statement is processed.
CURRENT_DATE
Specifies the current date as the default for the column. If CURRENT_DATE is specified, the data type of the source type of the distinct type of the column must be DATE.
CURRENT_TIME
Specifies the current time as the default for the column. If CURRENT_TIME is specified, the data type of the source type of the distinct type of the column must be TIME.
CURRENT_TIMESTAMP
Specifies the current timestamp as the default for the column. If CURRENT_TIMESTAMP is specified, the data type of the source type of the distinct type of the column must be TIMESTAMP.

If the value specified is not valid, an error is returned.

GENERATED
Specifies that the database manager generates values for the column. GENERATED may be specified if the column is to be considered an identity column (defined with the AS IDENTITY clause). It may also be specified if the data type of the column is a ROWID (or a distinct type that is based on a ROWID). Otherwise, it must not be specified.
ALWAYS
Specifies that the database manager will always generate a value for the column when a row is inserted into the table. ALWAYS is the recommended value.
BY DEFAULT
Specifies that the database manager will generate a value for the column when a row is inserted only if a value is not specified for the column. If a value is specified, the database manager uses that value.

For a ROWID column, the database manager uses a specified value, but it must be a valid unique row ID value that was previously generated by DB2 UDB for z/OS or DB2 UDB for iSeries.

For an identity column, the database manager inserts a specified value but does not verify that it is a unique value for the column unless the identity column has a unique constraint or a unique index that solely specifies the identity column.

AS IDENTITY
Specifies that the column is an identity column for the table. A table can have only one identity column. An identity column is not allowed in a partitioned table or distributed table. AS IDENTITY can be specified only if the data type for the column is an exact numeric type with a scale of zero (SMALLINT, INTEGER, BIGINT, DECIMAL or NUMERIC with a scale of zero, or a distinct type based on one of these data types). If a DECIMAL or NUMERIC data type is specified, the precision must not be greater than 31.

An identity column is implicitly NOT NULL. See the AS IDENTITY clause in CREATE TABLE for the descriptions of the identity attributes.

A column in a table cannot be altered to an identity column if the table is a DDS-created physical file.

datalink-options
Specifies the options associated with a DATALINK column. See CREATE TABLE for a description of datalink-options.
NOT NULL
Prevents the column from containing null values. Omission of NOT NULL implies that the column can contain null values. If NOT NULL is specified in the column definition, then DEFAULT must also be specified.
column-constraint
The column-constraint of a column-definition provides a shorthand method of defining a constraint composed of a single column. Thus, if a column-constraint is specified in the definition of column C, the effect is the same as if that constraint were specified as a unique-constraint, referential-constraint or check-constraint in which C is the only identified column.
CONSTRAINT constraint-name
Names the constraint. A constraint-name must not identify a constraint that already exists at the current server.

If the clause is not specified, a unique constraint name is generated by the database manager.

PRIMARY KEY
Provides a shorthand method of defining a primary key composed of a single column. Thus, if PRIMARY KEY is specified in the definition of column C, the effect is the same as if the PRIMARY KEY(C) clause is specified as a separate clause.

This clause must not be specified in more than one column-definition and must not be specified at all if the UNIQUE clause is specified in the column definition. The column must not be a LOB or DataLink column.

When a primary key is added, a CHECK constraint is implicitly added to enforce the rule that the NULL value is not allowed in the column that makes up the primary key.

UNIQUE
Provides a shorthand method of defining a unique constraint composed of a single column. Thus, if UNIQUE is specified in the definition of column C, the effect is the same as if the UNIQUE (C) clause is specified as a separate clause.

This clause cannot be specified more than once in a column definition and must not be specified if PRIMARY KEY is specified in the column-definition. The column must not be a LOB or DataLink column.

references-clause
The references-clause of a column-definition provides a shorthand method of defining a foreign key composed of a single column. Thus, if a references-clause is specified in the definition of column C, the effect is the same as if that references-clause were specified as part of a FOREIGN KEY clause in which C is the only identified column. A references-clause is not allowed if the table is a global temporary table, a partitioned table, or a distributed table.
CHECK(check-condition)
Provides a shorthand method of defining a check constraint whose check-condition only references a single column. Thus, if CHECK is specified in the column definition of column C, no columns other than C can be referenced in the check-condition of the check constraint. The effect is the same as if the check constraint were specified as a separate clause.

ROWID or DATALINK with FILE LINK CONTROL columns cannot be referenced in a CHECK constraint. For additional restrictions see, ADD check-constraint.

ALTER COLUMN column-alteration

Alters the definition of a column, including the attributes of an existing identity column. Only the attributes specified will be altered. Others will remain unchanged.

column-name
Identifies the column to be altered. The name must not be qualified and must identify an existing column in the table. The name must not identify a column that is being added or dropped in the same ALTER TABLE statement.
SET DATA TYPE data-type
Specifies the new data type of the column to be altered. The new data type must be compatible with the existing data type of the column. For more information about the compatibility of data types see Assignments and comparisons. However, changing a datetime data type to a character-string data type or a numeric data type to a character-string data type or a character-string data type to a numeric data type is not allowed.

The specified length, precision, and scale may be larger, smaller, or the same as the existing length, precision, and scale. However, if the new length, precision, or scale is smaller, truncation or numeric conversion errors may occur.

If the specified column has a default value and a new default value is not specified, the existing default value must represent a value that could be assigned to the column in accordance with the rules for assignment as described in Assignments and comparisons.

If the column is specified in a unique, primary, or foreign key, the new sum of the lengths of the columns of the keys must not exceed 32766-n, where n is the number of columns specified that allow nulls.

Changing the attributes will cause any existing values in the column to be converted to the new column attributes according to the rules for assignment to a column, except that string values will be truncated.

SET default-clause
Specifies the new default value of the column to be altered. The specified default value must represent a value that could be assigned to the column in accordance with the rules for assignment as described in Assignments and comparisons.
SET NOT NULL
Specifies that the column cannot contain null values. All values for this column in existing rows of the table must be not null. If the specified column has a default value and a new default value is not specified, the existing default value must not be NULL. SET NOT NULL is not allowed if the column is identified in the foreign key of a referential constraint with a DELETE rule of SET NULL and no other nullable columns exist in the foreign key.
SET GENERATED ALWAYS or GENERATED BY DEFAULT
Specifies that the database manager generates values for the column. GENERATED may be specified if the column is to be considered an identity column (defined with the AS IDENTITY clause) or the data type of the column is a ROWID (or a distinct type that is based on a ROWID). Otherwise, it must not be specified.
DROP DEFAULT
Drops the current default for the column. The specified column must have a default value and must not have NOT NULL as the null attribute. The new default value is the null value.
DROP NOT NULL
Drops the NOT NULL attribute of the column, allowing the column to have the null value. If a default value is not specified or does not already exist, the new default value is the null value. DROP NOT NULL is not allowed if the column is specified in the primary key of the table or is an identity column or ROWID.
DROP IDENTITY
Drops the identity attributes of the column, making the column a simple numeric data type column. DROP IDENTITY is not allowed if the column is not an identity column.
identity-alteration
Alters the identity attributes of the column. The column must exist in the specified table and must already be defined with the IDENTITY attribute. For a description of the attributes, see AS IDENTITY.
RESTART
Specifies the next value for an identity column. If WITH numeric-constant is not specified the sequence is restarted at the value specified implicitly or explicitly as the starting value when the identity column was originally created.
WITH numeric-constant
Specifies that numeric-constant will be used as the next value for the column. The numeric-constant must be an exact numeric constant that can be any positive or negative value that could be assigned to this column, without nonzero digits existing to the right of the decimal point.

DROP COLUMN

Drops the identified column from the table.

column-name
Identifies the column to be dropped. The column name must not be qualified. The name must identify a column of the specified table. The name must not identify a column that was already added or altered in this ALTER TABLE statement. The name must not identify the only column of a table. The name must not identify a partition key of a partitioned table or a distributed table.
CASCADE
Specifies that any views, indexes, triggers, or constraints that are dependent on the column being dropped are also dropped. 55
RESTRICT
Specifies that the column cannot be dropped if any views, indexes, triggers, or constraints are dependent on the column. 55

If all the columns referenced in a constraint are dropped in the same ALTER TABLE statement, RESTRICT does not prevent the drop.

ADD unique-constraint

CONSTRAINT constraint-name
Names the constraint. A constraint-name must not identify a constraint that already exists at the current server. The constraint-name must be unique within a schema.

If not specified, a unique constraint name is generated by the database manager.

UNIQUE (column-name,...)
Defines a unique constraint composed of the identified columns. Each column-name must be an unqualified name that identifies a column of the table. The same column must not be identified more than once. The column must not be a LOB or DATALINK column. The number of identified columns must not exceed 120, and the sum of their lengths must not exceed 32766-n, where n is the number of columns specified that allow nulls.

The set of identified columns cannot be the same as the set of columns specified in another UNIQUE constraint or PRIMARY KEY on the table. For example, UNIQUE (A,B) is not allowed if UNIQUE (B,A) or PRIMARY KEY (A,B) already exists on the table. Any existing nonnull values in the set of columns must be unique. Multiple null values are allowed.

If a unique index already exists on the identified columns, that index is designated as a unique constraint index. Otherwise, a unique index is created to support the uniqueness of the unique key. The unique index is created as part of the system physical file, not as a separate system logical file.

PRIMARY KEY (column-name,...)
Defines a primary key composed of the identified columns. Each column-name must be an unqualified name that identifies a column of the table. The same column must not be identified more than once. The column must not be a LOB or DATALINK column. The number of identified columns must not exceed 120, and the sum of their lengths must not exceed 32766. The table must not already have a primary key.

The identified columns cannot be the same as the columns specified in another UNIQUE constraint on the table. For example, PRIMARY KEY (A,B) is not allowed if UNIQUE (B,A) already exists on the table. Any existing values in the set of columns must be unique.

When a primary key is added, a CHECK constraint is implicitly added to enforce the rule that the NULL value is not allowed in any of the columns that make up the primary key.

If a unique index already exists on the identified columns, that index is designated as a primary index. Otherwise, a primary index is created to support the uniqueness of the primary key. The unique index is created as part of the system physical file, not a separate system logical file.

ADD referential-constraint

CONSTRAINT constraint-name
Names the constraint. A constraint-name must not identify a constraint that already exists at the current server.

If not specified, a unique constraint name is generated by the database manager.

FOREIGN KEY
Defines a referential constraint. FOREIGN KEY is not allowed if the table is a partitioned table.

Let T1 denote the table being altered.

(column-name,...)
The foreign key of the referential constraint is composed of the identified columns. Each column-name must be an unqualified name that identifies a column of T1. The same column must not be identified more than once. The column must not be a LOB or DATALINK column. The number of the identified columns must not exceed 120, and the sum of their lengths must not exceed 32766-n, where n is the number of columns specified that allows nulls.
REFERENCES table-name
The table-name specified in a REFERENCES clause must identify a base table that exists at the current server, but it must not identify a catalog table, a global temporary table, a partitioned table, or a distributed table. This table is referred to as the parent table in the constraint relationship.

A referential constraint is a duplicate if its foreign key, parent key, and parent table are the same as the foreign key, parent key, and parent table of an existing referential constraint on the table. Duplicate referential constraints are allowed, but not recommended.

Let T2 denote the identified parent table.

(column-name,...)
The parent key of the referential constraint is composed of the identified columns. Each column-name must be an unqualified name that identifies a column of T2. The same column must not be identified more than once. The column must not be a LOB or DATALINK column. The number of identified columns must not exceed 120, and the sum of their lengths must not exceed 32766-n, where n is the number of columns specified that allow nulls.

The list of column names must be identical to the list of column names in the primary key of T2 or a UNIQUE constraint that exists on T2. The names may be specified in any order. For example, if (A,B) is specified, a unique constraint defined as UNIQUE (B,A) would satisfy the requirement. If a column name list is not specified then T2 must have a primary key. Omission of the column name list is an implicit specification of the columns of that primary key.

The specified foreign key must have the same number of columns as the parent key of T2. The description of the nth column of the foreign key and the nth column of the parent key must have identical data types, lengths, and CCSIDs.

Unless the table is empty, the values of the foreign key must be validated before the table can be used. Values of the foreign key are validated during the execution of the ALTER TABLE statement. Therefore, every nonnull value of the foreign key must match some value of the parent key of T2.

The referential constraint specified by the FOREIGN KEY clause defines a relationship in which T2 is the parent and T1 is the dependent.

ON DELETE
Specifies what action is to take place on the dependent tables when a row of the parent table is deleted. There are five possible actions:
  • NO ACTION (default)
  • RESTRICT
  • CASCADE
  • SET NULL
  • SET DEFAULT

SET NULL must not be specified unless some column of the foreign key allows null values. SET NULL and SET DEFAULT must not be specified if T1 has an update trigger.

CASCADE must not be specified if T1 has a delete trigger.

CASCADE must not be specified if T1 contains a DataLink column with FILE LINK CONTROL.

The delete rule applies when a row of T2 is the object of a DELETE or propagated delete operation and that row has dependents in T1. Let p denote such a row of T2.

  • If RESTRICT or NO ACTION is specified, an error occurs and no rows are deleted.
  • If CASCADE is specified, the delete operation is propagated to the dependents of p in T1.
  • If SET NULL is specified, each nullable column of the foreign key of each dependent of p in T1 is set to null.
  • If SET DEFAULT is specified, each column of the foreign key of each dependent of p in T1 is set to its default value.
ON UPDATE
Specifies what action is to take place on the dependent tables when a row of the parent table is updated.

The update rule applies when a row of T2 is the object of an UPDATE or propagated update operation and that row has dependents in T1. Let p denote such a row of T2.

  • If RESTRICT or NO ACTION is specified, an error occurs and no rows are updated.

ADD check-constraint

CONSTRAINT constraint-name
Names the constraint. A constraint-name must not identify a constraint that already exists at the current server. The constraint-name must be unique within a schema.

If not specified, a unique constraint name is generated by the database manager.

CHECK(check-condition)
Defines a check constraint. The check-condition must be true or unknown for every row of the table.

The check-condition is a search-condition, except:

For more information about search-condition, see Search conditions.

DROP

PRIMARY KEY
Drops the definition of the primary key and all referential constraints in which the primary key is a parent key. The table must have a primary key.
FOREIGN KEY constraint-name
Drops the referential constraint constraint-name. The constraint-name must identify a referential constraint in which the table is a dependent.
UNIQUE constraint-name
Drops the unique constraint constraint-name and all referential constraints dependent on this unique constraint. The constraint-name must identify a unique constraint on the table. DROP UNIQUE will not drop a PRIMARY KEY unique constraint.
CHECK constraint-name
Drops the check constraint constraint-name. The constraint-name must identify a check constraint on the table.
CONSTRAINT constraint-name
Drops the constraint constraint-name. The constraint-name must identify a unique, referential, or check constraint on the table. If the constraint is a PRIMARY KEY or UNIQUE constraint, all referential constraints in which the primary key or unique key is a parent are also dropped.
CASCADE
Specifies for unique constraints that any referential constraints that are dependent on the constraint being dropped are also dropped.
RESTRICT
Specifies for unique constraints that the constraint cannot be dropped if any referential constraints are dependent on the constraint.

ADD partitioning-clause

Changes a non-partitioned table into a partitioned table. If the specified table is a distributed table or already a partitioned table, an error is returned. A table with an identity column cannot be partitioned. A DDS-created physical file cannot be partitioned. See CREATE TABLE for a description of the partitioning-clause.

Changing a non-partitioned table that contains data into a partitioned table will require data movement between the data partitions. When using range partitioning, all existing data in the table must be assignable to the specified range partitions.

DROP PARTITIONING

Changes a partitioned table into a non-partitioned table. If the specified table is already non-partitioned, an error is returned.

Changing a partitioned table that contains data into a non-partitioned table will require data movement between the data partitions.

ADD PARTITION

Adds one or more partitions to a partitioned table. If the specified table is not a partitioned table, an error is returned. The number of partitions must not exceed 256.

Changing the number of hash partitions in a partitioned table that contains data will require data movement between the data partitions.

partition-name
Names the partition. A partition-name must not identify a data partition that already exists in the table.

If the clause is not specified, a unique partition name is generated by the database manager.

boundary-spec
Specifies the boundaries of a range partition. If the specified table is not a range partitioned table, an error is returned. See CREATE TABLE for a description of the boundary-spec.

integer HASH PARTITIONS
Specifies the number of hash partitions to be added. If the specified table is not a hash partitioned table, an error is returned.

ALTER PARTITION

Alters the boundaries of a partition of a range partitioned table. If the specified table is not a range partitioned table, an error is returned.

Changing the boundaries of one or more partitions of a table that contains data may require data movement between the data partitions. All existing data in the table must be assignable to the specified range partitions.

partition-name
Specifies the name of the partition to alter. The partition-name must identify a data partition that exists in the table.
boundary-spec
Specifies the new boundaries of a range partition. See CREATE TABLE for a description of the boundary-spec.

DROP PARTITION

Drops a partition of a partitioned table. If the specified table is not a partitioned table, an error is returned. If the last remaining partition of a partitioned table is specified, an error is returned.

partition-name
Specifies the name of the partition to drop. The partition-name must identify a data partition that exists in the table.
DELETE ROWS
Specifies that any data in the specified partition will be discarded. All data stored in the partition is dropped from the table without processing any delete triggers.
PRESERVE ROWS
Specifies that any data in the specified partition will be preserved by moving it to the remaining partitions without processing any delete or insert triggers. If the specified table is a range partitioned table, PRESERVE ROWS must not be specified. Dropping a hash partition will require data movement between the remaining data partitions.

ADD MATERIALIZED QUERY materialized-query-definition

Changes a base table to a materialized query table. If the specified table is already a materialized query table or if the table is referenced in another materialized query table, an error is returned.

select-statement
Defines the query on which the table is based. The columns of the existing table must meet the following characteristics:

The select-statement for a materialized query table must not contain a reference to the table being altered, a view over the table being altered, or another materialized query table. For additional details about specifying select-statement for a materialized query table, see CREATE TABLE.

refreshable-table-options
Specifies the materialized query table options for altering a base table to a materialized query table.
DATA INITIALLY DEFERRED
Specifies that the data in the table is not validated as part of the ALTER TABLE statement. A REFRESH TABLE statement can be used to make sure the data in the materialized query table is the same as the result of the query in which the table is based.
DATA INITIALLY IMMEDIATE
Specifies that the data is inserted in the table from the result of the query as part of processing the ALTER TABLE statement.
REFRESH DEFERRED
Specifies that the data in the table can be refreshed at any time using the REFRESH TABLE statement. The data in the table only reflects the result of the query as a snapshot at the time when the REFRESH TABLE statement is processed or when it was last updated.
MAINTAINED BY USER
Specifies that the materialized query table is maintained by the user. The user can use INSERT, DELETE, UPDATE, or REFRESH TABLE statements on the table.
ENABLE QUERY OPTIMIZATION
Specifies that the materialized query table can be used for query optimization.
DISABLE QUERY OPTIMIZATION
Specifies that the materialized query table cannot be used for query optimization. The table can still be queried directly.

ALTER MATERIALIZED QUERY materialized-query-table-alteration

Changes the attributes of a materialized query table. The table-name must identify a materialized query table.

select-statement
Defines the query on which the table is based. The columns of the existing table must meet the following characteristics:

The select-statement for a materialized query table must not contain a reference to the table being altered, a view over the table being altered, or another materialized query table. For additional details about specifying select-statement for a materialized query table, see CREATE TABLE.

refreshable-table-options
Specifies the materialized query table options for altering a base table to a materialized query table.
DATA INITIALLY DEFERRED
Specifies that the data in the table is not refreshed or validated as part of the ALTER TABLE statement. A REFRESH TABLE statement can be used to make sure the data in the materialized query table is the same as the result of the query in which the table is based.
DATA INITIALLY IMMEDIATE
Specifies that the data is inserted in the table from the result of the query as part of processing the ALTER TABLE statement.
REFRESH DEFERRED
Specifies that the data in the table can be refreshed at any time using the REFRESH TABLE statement. The data in the table only reflects the result of the query as a snapshot at the time when the REFRESH TABLE statement is processed or when it was last updated.
MAINTAINED BY USER
Specifies that the materialized query table is maintained by the user. The user can use INSERT, DELETE, UPDATE, or REFRESH TABLE statements on the table.
ENABLE QUERY OPTIMIZATION or DISABLE QUERY OPTIMIZATION
Specifies whether this materialized query table can be used for query optimization.
ENABLE QUERY OPTIMIZATION
The materialized query table can be used for query optimization.
DISABLE QUERY OPTIMIZATION
The materialized query table will not be used for query optimization. The table can still be queried directly.
SET refreshable-table-alteration
Changes how the table is maintained or whether the table can be used in query optimization.
MAINTAINED BY USER
Specifies that the materialized query table is maintained by the user. The user can use INSERT, DELETE, UPDATE, or REFRESH TABLE statements on the table.
REFRESH DEFERRED
Specifies that the data in the table can be refreshed at any time using the REFRESH TABLE statement. The data in the table only reflects the result of the query as a snapshot at the time when the REFRESH TABLE statement is processed or when it was last updated.
ENABLE QUERY OPTIMIZATION or DISABLE QUERY OPTIMIZATION
Specifies whether this materialized query table can be used for query optimization.
ENABLE QUERY OPTIMIZATION
The materialized query table can be used for query optimization.
DISABLE QUERY OPTIMIZATION
The materialized query table will not be used for query optimization. The table can still be queried directly.

DROP MATERIALIZED QUERY

Changes a materialized query table into a base table. If the specified table is already a base table, an error is returned. The definition of columns and data of the table are not changed, but the table can no longer be used for query optimization and is no longer valid for use with the REFRESH TABLE statement.

ACTIVATE NOT LOGGED INITIALLY

Activates the NOT LOGGED INITIALLY attribute of the table for this current unit of work.

Any changes made to the table by INSERT, DELETE, or UPDATE statements in the same unit of work after the table is altered by this statement are not logged (journaled).

At the completion of the current unit of work, the NOT LOGGED INITIALLY attribute is deactivated and all operations that are done on the table in subsequent units of work are logged (journaled).

ACTIVATE NOT LOGGED INITIALLY is not allowed in a transaction if data change operations are pending for table-name or cursors are currently open under commit that reference table-name.

ACTIVATE NOT LOGGED INITIALLY is ignored if the table has a DATALINK column with FILE LINK CONTROL or if running with isolation level No Commit (NC).

WITH EMPTY TABLE
Causes all data currently in the table to be removed. If the unit of work in which this ALTER statement was issued is rolled back, the table data will NOT be returned to its original state. When this action is requested, no DELETE triggers defined on the affected table are fired.

WITH EMPTY TABLE cannot be specified for a materialized query table or for a parent in a referential constraint.

A DELETE statement without a WHERE clause will typically perform as well or better than ACTIVATE NOT LOGGED INITIALLY WITH EMPTY TABLE and will allow a ROLLBACK to rollback the delete of the rows in the table.

VOLATILE or NOT VOLATILE

Indicates to the optimizer whether or not the cardinality of table table-name can vary significantly at run time. Volatility applies to the number of rows in the table, not to the table itself. The default is NOT VOLATILE.

VOLATILE
Specifies that the cardinality of table-name can vary significantly at run time, from empty to large. To access the table, the optimizer will typically use an index, if possible.
NOT VOLATILE
Specifies that the cardinality of table-name is not volatile. Access plans that reference this table will be based on the cardinality of the table at the time the access plan is built. NOT VOLATILE is the default.

Notes

Column references: A column can only be referenced once in an ADD, ALTER, or DROP COLUMN clause in a single ALTER TABLE statement. However, that same column can be referenced multiple times for adding or dropping constraints in the same ALTER TABLE statement.

Order of operations: The order of operations within an ALTER TABLE statement is:

Within each of these stages, the order in which the user specifies the clauses is the order in which they are performed, with one exception. If any columns are being dropped, that operation is logically done before any column definitions are added or altered.

QTEMP considerations: Any views or logical files in another job's QTEMP that are dependent on the table being altered will be dropped as a result of an ALTER TABLE statement.

Authority checking: Authority checking is performed only on the table being altered and any object explicitly referenced in the ALTER TABLE statement (such as tables referenced in the fullselect). Other objects may be accessed by the ALTER TABLE statement, but no authority to those objects is required. For example, no authority is required on views that exist on the table being altered, nor on dependent tables that reference the table being altered through a referential constraint.

Backup recommendation: It is strongly recommended that a current backup of the table and dependent views and logical files exist prior to altering a table.

Performance considerations: The following performance considerations apply to an ALTER TABLE statement when adding, altering, or dropping columns from a table:

Altering materialized query tables: The isolation level at the time when a base table is first altered to become a materialized query table by the ALTER TABLE statement is the isolation level for the materialized query table.

Altering a table to change it to a materialized query table with query optimization enabled makes the table eligible for use in optimization. Therefore, ensure that the data in the table is accurate. The DATA INITIALLY IMMEDIATE clause can be used to refresh the data when the table is altered.

Syntax alternatives: The following syntax is supported for compatibility to prior releases. The syntax is non-standard and should not be used:

Cascaded Effects

Adding a column has no cascaded effects to SQL views or most logical files.58 For example, adding a column to a table does not cause the column to be added to any dependent views, even if those views were created with a SELECT * clause.

Dropping or altering a column may cause several cascaded effects. Table 46 lists the cascaded effects of dropping a column.

Table 46. Cascaded effects of dropping a column
Operation RESTRICT Effect CASCADE Effect
Drop of a column referenced by a view The drop of the column is not allowed. The view and all views dependent on that view are dropped.
Drop of a column referenced by a non-view logical file The drop is allowed, and the column is dropped from the logical file if:
  • The logical file shares a format with the file being altered, and
  • The dropped column is not used as a key field or in select/omit specifications, and
  • That format is not used again in the logical file with another based-on file.
Otherwise, the drop of the column is not allowed.
The drop is allowed, and the column is dropped from the logical file if:
  • The logical file shares a format with the file being altered, and
  • The dropped column is not used as a key field or in select or omit specifications, and
  • That format is not used again in the logical file with another based-on file.
Otherwise, the logical file is dropped.
Drop of a column referenced in the key of an index The drop of the index is not allowed. The index is dropped.
Drop of a column referenced in a unique constraint If all the columns referenced in the unique constraint are dropped in the same ALTER COLUMN statement and the unique constraint is not referenced by a referential constraint, the columns and the constraint are dropped. (Hence, the index used to satisfy the constraint is also dropped.) For example, if column A is dropped, and a unique constraint of UNIQUE (A) or PRIMARY KEY (A) exists and no referential constraints reference the unique constraint, the operation is allowed.

Otherwise, the drop of the column is not allowed.

The unique constraint is dropped as are any referential constraints that refer to that unique constraint. (Hence, any indexes used by those constraints are also dropped).
Drop of a column referenced in a referential constraint If all the columns referenced in the referential constraint are dropped at the same time, the columns and the constraint are dropped. (Hence, the index used by the foreign key is also dropped). For example, if column B is dropped and a referential constraint of FOREIGN KEY (A) exists, the operation is allowed.

Otherwise, the drop of the column is not allowed.

The referential constraint is dropped. (Hence, the index used by the foreign key is also dropped).
Drop of a column referenced in a trigger The drop of the column is not allowed. The trigger is dropped.
Drop of a column referenced in an MQT The drop of the column is not allowed. The MQT is dropped.

Table 47 lists the cascaded effects of altering a column. (Alter of a column in the following chart means altering a data type, precision, scale, length, or nullability characteristic.)

Table 47. Cascaded effects of altering a column
Operation Effect
Alter of a column referenced by a view The alter is allowed.

The views that are dependent on the table will be recreated. The new column attributes will be used when recreating the views.

Alter of a column referenced by a non-view logical file The alter is allowed.

The non-view logical files that are dependent on the table will be recreated. If the logical file shares a format with the file being altered, and that format is not used again in the logical file with another based-on file, the new column attributes will be used when recreating the logical file.

Otherwise, the new column attributes will not be used when recreating the logical file. Instead, the current logical file attributes are used.

Alter of a column referenced in the key of an index. The alter is allowed. (Hence, the index will usually be rebuilt.)
Alter of a column referenced in a unique constraint The alter is allowed. (Hence, the index will usually be rebuilt.)

If the unique constraint is referenced by a referential constraint, the attributes of the foreign keys no longer match the attributes of the unique constraint. The constraint will be placed in a defined and check-pending state.

Alter of a column referenced in a referential constraint The alter is allowed.
  • If the referential constraint is in the defined but check-pending state, the alter is allowed and an attempt is made to put the constraint in the enabled state. (Hence, the index used to satisfy the unique constraint will usually to be rebuilt.)
  • If the referential constraint is in the enabled state, the constraint is placed in the defined and check-pending state.
Alter of a column referenced in a trigger The trigger is preserved.
Alter of a column referenced in an MQT The MQT is recreated to include the new attributes.

Examples

Example 1: Add a new column named RATING, which is one character long, to the DEPARTMENT table.

  ALTER TABLE DEPARTMENT
    ADD RATING CHAR

Example 2: Add a new column named PICTURE_THUMBNAIL to the EMPLOYEE table. Create PICTURE_THUMBNAIL as a BLOB column with a maximum length of 1K characters.

  ALTER TABLE EMPLOYEE
    ADD PICTURE_THUMBNAIL  BLOB(1K)

Example 3: Assume a new table EQUIPMENT has been created with the following columns:

  EQUIP_NO
INT
  EQUIP_DESC
VARCHAR(50)
  LOCATION
VARCHAR(50)
  EQUIP_OWNER
CHAR(3)

Add a referential constraint to the EQUIPMENT table so that the owner (EQUIP_OWNER) must be a department number (DEPTNO) that is present in the DEPARTMENT table. If a department is removed from the DEPARTMENT table, the owner (EQUIP_OWNER) values for all equipment owned by that department should become unassigned (or set to null). Give the constraint the name DEPTQUIP.

  ALTER TABLE EQUIPMENT
    FOREIGN KEY DEPTQUIP (EQUIP_OWNER)
      REFERENCES DEPARTMENT
      ON DELETE SET NULL

Change the default value for the EQUIP_OWNER column to 'ABC'.

   ALTER TABLE EQUIPMENT
     ALTER COLUMN EQUIP_OWNER
     SET DEFAULT 'ABC'

Drop the LOCATION column. Also drop any views, indexes, or constraints that are built on that column.

   ALTER TABLE EQUIPMENT
     DROP COLUMN LOCATION CASCADE

Alter the table so that a new column called SUPPLIER is added, the existing column called LOCATION is dropped, a unique constraint over the new column SUPPLIER is added, and a primary key is built over the existing column EQUIP_NO.

   ALTER TABLE EQUIPMENT
     ADD COLUMN SUPPLIER INT
     DROP COLUMN LOCATION
     ADD UNIQUE SUPPLIER
     ADD PRIMARY KEY EQUIP_NO

Notice that the column EQUIP_DESC is a variable length column. If an allocated length of 25 was specified, the following ALTER TABLE statement would not change that allocated length.

   ALTER TABLE EQUIPMENT
     ALTER COLUMN EQUIP_DESC
     SET DATA TYPE VARCHAR(60)

Example 4: Alter the EMPLOYEE table. Add the check constraint named REVENUE defined so that each employee must make a total of salary and commission greater than $30,000.

  ALTER TABLE EMPLOYEE
    ADD CONSTRAINT REVENUE 
    CHECK (SALARY + COMM > 30000)

Example 5: Alter EMPLOYEE table. Drop the constraint REVENUE which was previously defined.

  ALTER TABLE EMPLOYEE
    DROP CONSTRAINT REVENUE 

Example 6: Alter the EMPLOYEE table. Alter the column PHONENO to accept up to 20 characters for a phone number.

  ALTER TABLE EMPLOYEE
    ALTER COLUMN PHONENO SET DATA TYPE VARCHAR (20)

Example 7: Alter the base table TRANSCOUNT to a materialized query table. The result of the select-statement must provide a set of columns that match the columns in the existing table (same number of columns and compatible attributes).

  ALTER TABLE TRANSCOUNT
    ADD MATERIALIZED QUERY
    (SELECT  ACCTID, LOCID, YEAR, COUNT(*) AS CNT
       FROM TRANS
       GROUP BY ACCTID, LOCID, YEAR )
    DATA INITIALLY DEFERRED
    REFRESH DEFERRED
    MAINTAINED BY USER 

55.
A trigger is dependent on the column if it is referenced in the UPDATE OF column list or anywhere in the triggered action.
56.
In cases where enough storage does not exist to make a complete copy, a special copy that only requires approximately 16-32 megabytes of free storage is performed.
57.
Any indexes that need to be rebuilt are rebuilt asynchronously by database server jobs.
58.
A column will also be added to a logical file that shares its physical file's format when a column is added to that physical file (unless that format is used again in the logical file with another based-on file).



[ Top of Page | Previous Page | Next Page | Contents | Index ]