1896 lines
113 KiB
HTML
1896 lines
113 KiB
HTML
|
<?xml version="1.0" encoding="utf-8"?>
|
||
|
<!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN"
|
||
|
"http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd">
|
||
|
<html xmlns="http://www.w3.org/1999/xhtml" lang="en-US" xml:lang="en-us">
|
||
|
<head>
|
||
|
<meta http-equiv="Content-Type" content="text/html; charset=utf-8" />
|
||
|
<meta name="dc.language" scheme="rfc1766" content="en-us" />
|
||
|
<!-- All rights reserved. Licensed Materials Property of IBM -->
|
||
|
<!-- US Government Users Restricted Rights -->
|
||
|
<!-- Use, duplication or disclosure restricted by -->
|
||
|
<!-- GSA ADP Schedule Contract with IBM Corp. -->
|
||
|
<meta name="dc.date" scheme="iso8601" content="2005-09-19" />
|
||
|
<meta name="copyright" content="(C) Copyright IBM Corporation 1998, 2006" />
|
||
|
<meta name="security" content="public" />
|
||
|
<meta name="Robots" content="index,follow"/>
|
||
|
<meta http-equiv="PICS-Label" content='(PICS-1.1 "http://www.icra.org/ratingsv02.html" l gen true r (cz 1 lz 1 nz 1 oz 1 vz 1) "http://www.rsac.org/ratingsv01.html" l gen true r (n 0 s 0 v 0 l 0) "http://www.classify.org/safesurf/" l gen true r (SS~~000 1))' />
|
||
|
<meta name="keywords" content="ALTER TABLE statement, ALTER TABLE,
|
||
|
SQL statements, altering, table, in ALTER TABLE statement, table-name,
|
||
|
ADD COLUMN clause, column-name, system-column-name, FOR COLUMN clause,
|
||
|
in ALTER TABLE, data-type, data type for ALTER TABLE, CCSID clause, CHAR,
|
||
|
DOUBLE PRECISION, DECIMAL, FLOAT, BIGINT, INTEGER, NUMERIC, REAL, SMALLINT,
|
||
|
VARCHAR, VARGRAPHIC, GRAPHIC, FOR BIT DATA clause, FOR MIXED DATA clause,
|
||
|
FOR SBCS DATA clause, BINARY, VARBINARY, BLOB, CLOB, DBCLOB, ROWID,
|
||
|
distinct-type, DEFAULT clause, constant, USER clause, NULL clause, CURRENT_DATE,
|
||
|
CURRENT_TIME, CURRENT_TIMESTAMP, cast-function, GENERATED, IDENTITY,
|
||
|
datalink-options, NOT NULL clause, CONSTRAINT clause, constraint-name,
|
||
|
PRIMARY KEY clause, UNIQUE clause, REFERENCES clause, CHECK clause,
|
||
|
ALTER COLUMN clause, SET DATA TYPE clause, SET default-clause,
|
||
|
SET NOT NULL clause, SET GENERATED ALWAYS clause,
|
||
|
SET GENERATED BY DEFAULT clause, DROP DEFAULT clause, DROP NOT NULL clause,
|
||
|
DROP IDENTITY clause, INCREMENT BY clause, MAXVALUE clause, MINVALUE clause,
|
||
|
NO CACHE clause, CACHE clause, NO ORDER clause, ORDER clause, NO CYCLE clause,
|
||
|
CYCLE clause, RESTART clause, DROP COLUMN clause,
|
||
|
in DROP COLUMN of ALTER TABLE statement, CASCADE clause, RESTRICT clause,
|
||
|
ADD unique-constraint clause, key, in ADD UNIQUE clause of ALTER TABLE statement,
|
||
|
in ADD PRIMARY clause of ALTER TABLE statement, of ALTER TABLE statement,
|
||
|
referential-constraint clause, in CONSTRAINT clause of ALTER TABLE statement,
|
||
|
FOREIGN KEY clause, in FOREIGN KEY clause of ALTER TABLE statement,
|
||
|
in REFERENCES clause of ALTER TABLE statement,
|
||
|
in ON DELETE clause of ALTER TABLE statement, DELETE clause, CASCADE delete rule,
|
||
|
RESTRICT delete rule, NO ACTION delete rule, SET DEFAULT delete rule,
|
||
|
SET NULL delete rule, keyword SET NULL delete rule, NULL,
|
||
|
in ON UPDATE clause of ALTER TABLE statement, UPDATE, RESTRICT update rule,
|
||
|
NO ACTION update rule, SET DEFAULT update rule, SET NULL update rule,
|
||
|
keyword SET NULL update rule, ADD check-constraint clause, check,
|
||
|
in CHECK clause of ALTER TABLE statement, check-condition,
|
||
|
DROP PRIMARY KEY clause, in DROP FOREIGN KEY clause of ALTER TABLE statement,
|
||
|
DROP FOREIGN KEY clause, in DROP UNIQUE clause of ALTER TABLE statement,
|
||
|
DROP UNIQUE clause, in DROP CHECK clause of ALTER TABLE statement,
|
||
|
DROP CHECK clause, in DROP CONSTRAINT clause of ALTER TABLE statement,
|
||
|
DROP CONSTRAINT clause, in DROP constraint of ALTER TABLE statement,
|
||
|
partitioning clause, DROP PARTITIONING, ADD PARTITION, partition name,
|
||
|
range partitions, hash partitions, ALTER PARTITION, DROP PARTITION, DELETE ROWS,
|
||
|
PRESERVE ROWS, ADD materialized query clause, materialized query table,
|
||
|
automatic summary table, ALTER materialized query clause,
|
||
|
DROP materialized query clause, ACTIVATE NOT LOGGED INITIALLY,
|
||
|
NOT LOGGED INITIALLY, WITH EMPTY TABLE, VOLATILE, NOT VOLATILE" />
|
||
|
<title>ALTER TABLE</title>
|
||
|
<link rel="stylesheet" type="text/css" href="ibmidwb.css" />
|
||
|
<link rel="stylesheet" type="text/css" href="ic.css" />
|
||
|
</head>
|
||
|
<body>
|
||
|
<a id="Top_Of_Page" name="Top_Of_Page"></a><!-- Java sync-link -->
|
||
|
<script language = "Javascript" src = "../rzahg/synch.js" type="text/javascript"></script>
|
||
|
|
||
|
|
||
|
<a name="atabl"></a>
|
||
|
<h2 id="atabl"><a href="rbafzmst02.htm#ToC_762">ALTER TABLE</a></h2><a id="idx1331" name="idx1331"></a><a id="idx1332" name="idx1332"></a><a id="idx1333" name="idx1333"></a>
|
||
|
<a name="altabl"></a>
|
||
|
<p id="altabl">The ALTER TABLE statement alters the definition of a table.</p>
|
||
|
<a name="wq1065"></a>
|
||
|
<h3 id="wq1065"><a href="rbafzmst02.htm#ToC_763">Invocation</a></h3>
|
||
|
<p>This statement can be embedded in an application program or issued interactively.
|
||
|
It is an executable statement that can be dynamically prepared.</p>
|
||
|
<a name="wq1066"></a>
|
||
|
<h3 id="wq1066"><a href="rbafzmst02.htm#ToC_764">Authorization</a></h3>
|
||
|
<p>The privileges held by the authorization ID of the statement must include
|
||
|
at least one of the following: </p>
|
||
|
<ul>
|
||
|
<li>For the table identified in the statement,
|
||
|
<ul>
|
||
|
<li>The ALTER privilege on the table, and</li>
|
||
|
<li>The system authority *EXECUTE on the library containing the table</li></ul></li>
|
||
|
<li>Administrative authority</li></ul>
|
||
|
<p>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: </p>
|
||
|
<ul>
|
||
|
<li>The REFERENCES privilege or object management authority for the table</li>
|
||
|
<li>The REFERENCES privilege on each column of the specified parent key</li>
|
||
|
<li>Ownership of the table</li>
|
||
|
<li>Administrative authority</li></ul>
|
||
|
<p>If a <var class="pv">select-statement</var> 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: </p>
|
||
|
<ul>
|
||
|
<li>The SELECT privilege for the table or view</li>
|
||
|
<li>Ownership of the table or view</li>
|
||
|
<li>Administrative authority</li></ul>
|
||
|
<p>If a distinct type is referenced, the privileges held by the authorization ID of
|
||
|
the statement must include at least one of the following: </p>
|
||
|
<ul>
|
||
|
<li>For each distinct type identified in the statement:
|
||
|
<ul>
|
||
|
<li>The USAGE privilege on the distinct type, and</li>
|
||
|
<li>The system authority *EXECUTE on the library containing the distinct type</li></ul></li>
|
||
|
<li>Administrative authority</li></ul>
|
||
|
<p>For information on the system authorities corresponding to SQL privileges,
|
||
|
see <a href="rbafzmstgnt.htm#eqtablet">Corresponding System Authorities When Checking Privileges to a Table or View</a> and <a href="rbafzmstgntudtp.htm#eqtabled">Corresponding System Authorities When Checking Privileges to a Distinct Type</a>.</p>
|
||
|
<a name="wq1067"></a>
|
||
|
<h3 id="wq1067"><a href="rbafzmst02.htm#ToC_765">Syntax</a></h3>
|
||
|
<a href="rbafzmstatabl.htm#synsalter"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
|
||
|
<a name="wq1068"></a>
|
||
|
<div class="fignone" id="wq1068">
|
||
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn250.htm"
|
||
|
border="0" /></span><a href="#skipsyn-249"><img src="c.gif" alt="Skip visual syntax diagram"
|
||
|
border="0" /></a>>>-ALTER TABLE--<span class="italic">table-name</span>-------------------------------------->
|
||
|
|
||
|
.-----------------------------------------------------------------------------.
|
||
|
V .-COLUMN-. |
|
||
|
>------+-ADD--+--------+--<span class="italic">column-definition</span>----------------------------------+---+-><
|
||
|
| .-COLUMN-. |
|
||
|
+-ALTER--+--------+--<span class="italic">column-alteration</span>--------------------------------+
|
||
|
| .-COLUMN-. .-CASCADE--. |
|
||
|
+-DROP----+--------+--<span class="italic">column-name</span>--+----------+-----------------------+
|
||
|
| '-RESTRICT-' |
|
||
|
+-ADD--+-<span class="italic">unique-constraint</span>------+-------------------------------------+
|
||
|
| +-<span class="italic">referential-constraint</span>-+ |
|
||
|
| '-<span class="italic">check-constraint</span>-------' |
|
||
|
| .-CASCADE--. |
|
||
|
+-DROP--+-PRIMARY KEY----------------------+--+----------+------------+
|
||
|
| '-+-UNIQUE------+--<span class="italic">constraint-name</span>-' '-RESTRICT-' |
|
||
|
| +-FOREIGN KEY-+ |
|
||
|
| +-CHECK-------+ |
|
||
|
| '-CONSTRAINT--' |
|
||
|
+-ADD--<span class="italic">partitioning-clause</span>--------------------------------------------+
|
||
|
+-DROP PARTITIONING---------------------------------------------------+
|
||
|
+-ADD PARTITION--+-+----------------+--<span class="italic">boundary-spec</span>-+----------------+
|
||
|
| | '-<span class="italic">partition-name</span>-' | |
|
||
|
| '-<span class="italic">integer</span>--+-HASH PARTITIONS-+------' |
|
||
|
| '-HASH PARTITION--' |
|
||
|
+-ALTER PARTITION--<span class="italic">partition-name</span>--<span class="italic">boundary-spec</span>----------------------+
|
||
|
+-DROP PARTITION--<span class="italic">partition-name</span>--+-DELETE ROWS---+-------------------+
|
||
|
| '-PRESERVE ROWS-' |
|
||
|
| .-MATERIALIZED-. |
|
||
|
| .-+--------------+--QUERY-. |
|
||
|
+-ADD--+-------------------------+--<span class="italic">materialized-query-definition</span>-----+
|
||
|
| .-MATERIALIZED-. |
|
||
|
+-ALTER--+--------------+--QUERY--<span class="italic">materialized-query-table-alteration</span>-+
|
||
|
| .-MATERIALIZED-. |
|
||
|
+-DROP--+--------------+--QUERY---------------------------------------+
|
||
|
+-<span>ACTIVATE</span>--<span>NOT LOGGED INITIALLY</span>--+------------------+----------------+
|
||
|
| '-<span>WITH EMPTY TABLE</span>-' |
|
||
|
| .-<span>CARDINALITY</span>-. |
|
||
|
'-+-<span>NOT VOLATILE</span>-+--+-------------+-----------------------------------'
|
||
|
'-<span>VOLATILE</span>-----'
|
||
|
|
||
|
</pre>
|
||
|
<a name="skipsyn-249" id="skipsyn-249"></a></div>
|
||
|
<a name="wq1069"></a>
|
||
|
<div class="fignone" id="wq1069">
|
||
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn251.htm"
|
||
|
border="0" /></span><a href="#skipsyn-250"><img src="c.gif" alt="Skip visual syntax diagram"
|
||
|
border="0" /></a>column-definition:
|
||
|
|
||
|
|--<span class="italic">column-name</span>--+-------------------------------------+--------->
|
||
|
| .-COLUMN-. |
|
||
|
'-FOR--+--------+--<span class="italic">system-column-name</span>-'
|
||
|
|
||
|
>--<span class="italic">data-type</span>---------------------------------------------------->
|
||
|
|
||
|
.---------------------------------------------------------.
|
||
|
V | (3)
|
||
|
>----+-----------------------------------------------------+-+-------|
|
||
|
+-<span class="italic">default-clause</span>--------------------------------------+
|
||
|
| .-GENERATED ALWAYS-----. (1) |
|
||
|
+-+----------------------+-------+------------------+-+
|
||
|
| '-GENERATED BY DEFAULT-' '-<span class="italic">identity-options</span>-' |
|
||
|
| (2) |
|
||
|
+-<span class="italic">datalink-options</span>------------------------------------+
|
||
|
+-NOT NULL--------------------------------------------+
|
||
|
'-<span class="italic">column-constraint</span>-----------------------------------'
|
||
|
|
||
|
data-type:
|
||
|
|
||
|
|--+-<span class="italic">built-in-type</span>------+---------------------------------------|
|
||
|
'-<span class="italic">distinct-type-name</span>-'
|
||
|
|
||
|
</pre>
|
||
|
<a name="skipsyn-250" id="skipsyn-250"></a>
|
||
|
<a name="wq1070"></a>
|
||
|
<div class="notelisttitle" id="wq1070">Notes:</div>
|
||
|
<ol type="1">
|
||
|
<li>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.</li>
|
||
|
<li>The datalink-options can only be specified for DATALINKs and distinct-types
|
||
|
sourced on DATALINKs.</li>
|
||
|
<li>The same clause must not be specified more than once.</li>
|
||
|
</ol></div>
|
||
|
<a name="wq1072"></a>
|
||
|
<div class="fignone" id="wq1072">
|
||
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn252.htm"
|
||
|
border="0" /></span><a href="#skipsyn-251"><img src="c.gif" alt="Skip visual syntax diagram"
|
||
|
border="0" /></a>built-in-type:
|
||
|
|
||
|
|--+-+---SMALLINT---+-------------------------------------------------------------------------------------------+--|
|
||
|
| +-+-INTEGER-+--+ |
|
||
|
| | '-INT-----' | |
|
||
|
| '---BIGINT-----' |
|
||
|
| .-(5,0)------------------------. |
|
||
|
+-+-+-DECIMAL-+-+--+------------------------------+----------------------------------------------------------+
|
||
|
| | '-DEC-----' | | .-,0--------. | |
|
||
|
| '-NUMERIC-----' '-(--<span class="italic">integer</span>--+-----------+--)-' |
|
||
|
| '-<span class="italic">, integer</span>-' |
|
||
|
| .-(--52--)------. |
|
||
|
+-+-FLOAT--+---------------+-+-------------------------------------------------------------------------------+
|
||
|
| | '-(--<span class="italic">integer</span>--)-' | |
|
||
|
| +-REAL---------------------+ |
|
||
|
| | .-PRECISION-. | |
|
||
|
| '-DOUBLE--+-----------+----' |
|
||
|
| .-(--1--)-------. |
|
||
|
+-+-+-+-CHARACTER-+--+---------------+-------------------------------+--+----------------+-----------------+-+
|
||
|
| | | '-CHAR------' '-(--<span class="italic">integer</span>--)-' | +-FOR BIT DATA---+ | |
|
||
|
| | '-+-+-CHARACTER-+--VARYING-+--(--<span class="italic">integer</span>--)--+-----------------+-' +-FOR SBCS DATA--+ | |
|
||
|
| | | '-CHAR------' | '-<span class="italic">allocate-clause</span>-' +-FOR MIXED DATA-+ | |
|
||
|
| | '-VARCHAR----------------' '-<span class="italic">ccsid-clause</span>---' | |
|
||
|
| | .-(--1M--)-------------. | |
|
||
|
| '---+-+-<span>CHARACTER</span>-+--<span>LARGE OBJECT</span>-+----+----------------------+--+-----------------+--+----------------+-' |
|
||
|
| | '-<span>CHAR</span>------' | '-(--<span class="italic">integer</span>--+---+--)-' '-<span class="italic">allocate-clause</span>-' +-FOR SBCS DATA--+ |
|
||
|
| '-<span>CLOB</span>------------------------' +-K-+ +-FOR MIXED DATA-+ |
|
||
|
| +-M-+ '-<span class="italic">ccsid-clause</span>---' |
|
||
|
| '-G-' |
|
||
|
| .-(--1--)-------. |
|
||
|
+-+---GRAPHIC----+---------------+----------------------------+--+--------------+----------------------------+
|
||
|
| | '-(--<span class="italic">integer</span>--)-' | '-<span class="italic">ccsid-clause</span>-' |
|
||
|
| +-+-GRAPHIC VARYING-+--(--<span class="italic">integer</span>--)--+-----------------+---+ |
|
||
|
| | '-VARGRAPHIC------' '-<span class="italic">allocate-clause</span>-' | |
|
||
|
| | .-(--1M--)-------------. | |
|
||
|
| '---DBCLOB----+----------------------+--+-----------------+-' |
|
||
|
| '-(--<span class="italic">integer</span>--+---+--)-' '-<span class="italic">allocate-clause</span>-' |
|
||
|
| +-K-+ |
|
||
|
| +-M-+ |
|
||
|
| '-G-' |
|
||
|
| .-(--1--)-------. |
|
||
|
+-+-+-BINARY--+---------------+------------------------------+-----------------+-----------------------------+
|
||
|
| | | '-(--<span class="italic">integer</span>--)-' | | |
|
||
|
| | '-+-BINARY VARYING-+--(--<span class="italic">integer</span>--)--+-----------------+-' | |
|
||
|
| | '-VARBINARY------' '-<span class="italic">allocate-clause</span>-' | |
|
||
|
| | .-(--1M--)-------------. | |
|
||
|
| '---+-BLOB----------------+----+----------------------+--+-----------------+-' |
|
||
|
| '-BINARY LARGE OBJECT-' '-(--<span class="italic">integer</span>--+---+--)-' '-<span class="italic">allocate-clause</span>-' |
|
||
|
| +-K-+ |
|
||
|
| +-M-+ |
|
||
|
| '-G-' |
|
||
|
+-+-DATE-------------------+---------------------------------------------------------------------------------+
|
||
|
| | .-(--0--)-. | |
|
||
|
| +-TIME--+---------+------+ |
|
||
|
| | .-(--6--)-. | |
|
||
|
| '-TIMESTAMP--+---------+-' |
|
||
|
| .-(--200--)-----. |
|
||
|
+---DATALINK--+---------------+--+-----------------+--+--------------+---------------------------------------+
|
||
|
| '-(--<span class="italic">integer</span>--)-' '-<span class="italic">allocate-clause</span>-' '-<span class="italic">ccsid-clause</span>-' |
|
||
|
'---ROWID----------------------------------------------------------------------------------------------------'
|
||
|
|
||
|
allocate-clause:
|
||
|
|
||
|
|--ALLOCATE--<span class="italic">(integer)</span>------------------------------------------|
|
||
|
|
||
|
ccsid-clause:
|
||
|
|
||
|
.-NOT NORMALIZED-.
|
||
|
|--CCSID--<span class="italic">integer</span>--+----------------+---------------------------|
|
||
|
'-NORMALIZED-----'
|
||
|
|
||
|
</pre>
|
||
|
<a name="skipsyn-251" id="skipsyn-251"></a></div>
|
||
|
<a name="wq1073"></a>
|
||
|
<div class="fignone" id="wq1073">
|
||
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn253.htm"
|
||
|
border="0" /></span><a href="#skipsyn-252"><img src="c.gif" alt="Skip visual syntax diagram"
|
||
|
border="0" /></a>default-clause:
|
||
|
|
||
|
.-WITH-.
|
||
|
|--+------+--DEFAULT--+-------------------------------------------------+--|
|
||
|
+-<span class="italic">constant</span>----------------------------------------+
|
||
|
+-USER--------------------------------------------+
|
||
|
+-NULL--------------------------------------------+
|
||
|
+-CURRENT_DATE------------------------------------+
|
||
|
+-CURRENT_TIME------------------------------------+
|
||
|
+-CURRENT_TIMESTAMP-------------------------------+
|
||
|
'-<span class="italic">cast-function-name</span>--(--+-<span class="italic">constant</span>----------+--)-'
|
||
|
+-USER--------------+
|
||
|
+-CURRENT_DATE------+
|
||
|
+-CURRENT_TIME------+
|
||
|
'-CURRENT_TIMESTAMP-'
|
||
|
|
||
|
identity-options:
|
||
|
|
||
|
|--AS IDENTITY--+-------------------------------------------------------+--|
|
||
|
| .-,-------------------------------------------. |
|
||
|
| V .-<span class="italic">1</span>----------------. (1) | |
|
||
|
'-(----+-START WITH--+-<span class="italic">numeric-constant</span>-+---+------+--)-'
|
||
|
| .-<span class="italic">1</span>----------------. |
|
||
|
+-INCREMENT BY--+-<span class="italic">numeric-constant</span>-+-+
|
||
|
| .-NO MINVALUE----------------. |
|
||
|
+-+-MINVALUE--<span class="italic">numeric-constant</span>-+-----+
|
||
|
| .-NO MAXVALUE----------------. |
|
||
|
+-+-MAXVALUE--<span class="italic">numeric-constant</span>-+-----+
|
||
|
| .-NO CYCLE-. |
|
||
|
+-+-CYCLE----+-----------------------+
|
||
|
| .-CACHE--<span class="italic">20</span>------. |
|
||
|
+-+-NO CACHE-------+-----------------+
|
||
|
| '-CACHE--<span class="italic">integer</span>-' |
|
||
|
| .-NO ORDER-. |
|
||
|
'-+-ORDER----+-----------------------'
|
||
|
|
||
|
column-constraint:
|
||
|
|
||
|
|--+-----------------------------+--+-+-PRIMARY KEY-+--------------+--|
|
||
|
'-CONSTRAINT--<span class="italic">constraint-name</span>-' | '-UNIQUE------' |
|
||
|
+-<span class="italic">references-clause</span>------------+
|
||
|
'-CHECK--(--<span class="italic">check-condition</span>--)-'
|
||
|
|
||
|
</pre>
|
||
|
<a name="skipsyn-252" id="skipsyn-252"></a>
|
||
|
<a name="wq1074"></a>
|
||
|
<div class="notelisttitle" id="wq1074">Notes:</div>
|
||
|
<ol type="1">
|
||
|
<li>The same clause must not be specified more than once.</li>
|
||
|
</ol></div>
|
||
|
<a name="wq1076"></a>
|
||
|
<div class="fignone" id="wq1076">
|
||
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn254.htm"
|
||
|
border="0" /></span><a href="#skipsyn-253"><img src="c.gif" alt="Skip visual syntax diagram"
|
||
|
border="0" /></a>datalink-options:
|
||
|
|
||
|
.-LINKTYPE URL-. .-NO LINK CONTROL--------------------------.
|
||
|
|--+--------------+--+------------------------------------------+--|
|
||
|
'-FILE LINK CONTROL--+-<span class="italic">file-link-options</span>-+-'
|
||
|
'-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--'
|
||
|
|
||
|
</pre>
|
||
|
<a name="skipsyn-253" id="skipsyn-253"></a>
|
||
|
<a name="wq1077"></a>
|
||
|
<div class="notelisttitle" id="wq1077">Notes:</div>
|
||
|
<ol type="1">
|
||
|
<li>All five <var class="pv">file-link-options</var> must be specified, but they can
|
||
|
be specified in any order.</li>
|
||
|
</ol></div>
|
||
|
<a name="wq1079"></a>
|
||
|
<div class="fignone" id="wq1079">
|
||
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn255.htm"
|
||
|
border="0" /></span><a href="#skipsyn-254"><img src="c.gif" alt="Skip visual syntax diagram"
|
||
|
border="0" /></a>column-alteration:
|
||
|
|
||
|
.-----------------------------------------------------------------------------------.
|
||
|
| .--------------------------------------------. |
|
||
|
V V (2) | |
|
||
|
|--<span class="italic">column-name</span>----+-SET--+----------------------+----+-+-<span class="italic">default-clause</span>----------------+-+------+-+-+--|
|
||
|
| '-DATA TYPE--<span class="italic">data-type</span>-' | | .-GENERATED ALWAYS-----. (1) | | |
|
||
|
| | '-+----------------------+------' | |
|
||
|
| | '-GENERATED BY DEFAULT-' | |
|
||
|
| '-NOT NULL--------------------------' |
|
||
|
| .-------------------. |
|
||
|
| V (2) | |
|
||
|
+-DROP----+-DEFAULT--+------+---------------------------------------------------+
|
||
|
| +-NOT NULL-+ |
|
||
|
| '-IDENTITY-' |
|
||
|
'-<span class="italic">identity-alteration</span>-----------------------------------------------------------'
|
||
|
|
||
|
identity-alteration:
|
||
|
|
||
|
.---------------------------------------------.
|
||
|
V | (2)
|
||
|
|----+-SET--+-INCREMENT BY--<span class="italic">numeric-constant</span>-+-+-+--------------|
|
||
|
| +-+-NO MINVALUE----------------+-+ |
|
||
|
| | '-MINVALUE--<span class="italic">numeric-constant</span>-' | |
|
||
|
| +-+-NO MAXVALUE----------------+-+ |
|
||
|
| | '-MAXVALUE--<span class="italic">numeric-constant</span>-' | |
|
||
|
| +-+-NO CYCLE-+-------------------+ |
|
||
|
| | '-CYCLE----' | |
|
||
|
| +-+-NO CACHE-------+-------------+ |
|
||
|
| | '-CACHE--<span class="italic">integer</span>-' | |
|
||
|
| '-+-NO ORDER-+-------------------' |
|
||
|
| '-ORDER----' |
|
||
|
'-RESTART--+------------------------+-----'
|
||
|
'-WITH--<span class="italic">numeric-constant</span>-'
|
||
|
|
||
|
</pre>
|
||
|
<a name="skipsyn-254" id="skipsyn-254"></a>
|
||
|
<a name="wq1080"></a>
|
||
|
<div class="notelisttitle" id="wq1080">Notes:</div>
|
||
|
<ol type="1">
|
||
|
<li>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.</li>
|
||
|
<li>The same clause must not be specified more than once.</li>
|
||
|
</ol></div>
|
||
|
<a name="wq1082"></a>
|
||
|
<div class="fignone" id="wq1082">
|
||
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn256.htm"
|
||
|
border="0" /></span><a href="#skipsyn-255"><img src="c.gif" alt="Skip visual syntax diagram"
|
||
|
border="0" /></a>unique-constraint:
|
||
|
|
||
|
|--+-----------------------------+--+-PRIMARY KEY-+--(---------->
|
||
|
'-CONSTRAINT--<span class="italic">constraint-name</span>-' '-UNIQUE------'
|
||
|
|
||
|
.-,-----------.
|
||
|
V |
|
||
|
>----<span class="italic">column-name</span>-+--)-------------------------------------------|
|
||
|
|
||
|
referential-constraint:
|
||
|
|
||
|
|--+-----------------------------+--FOREIGN KEY----------------->
|
||
|
'-CONSTRAINT--<span class="italic">constraint-name</span>-'
|
||
|
|
||
|
.-,-----------.
|
||
|
V |
|
||
|
>--(----<span class="italic">column-name</span>-+--)--<span class="italic">references-clause</span>---------------------|
|
||
|
|
||
|
references-clause:
|
||
|
|
||
|
|--REFERENCES--<span class="italic">table-name</span>--+-----------------------+------------>
|
||
|
| .-,-----------. |
|
||
|
| V | |
|
||
|
'-(----<span class="italic">column-name</span>-+--)-'
|
||
|
|
||
|
.-ON DELETE NO ACTION--------. .-ON UPDATE NO ACTION-. (1)
|
||
|
>--+----------------------------+--+---------------------+-------|
|
||
|
'-ON DELETE--+-RESTRICT----+-' '-ON UPDATE RESTRICT--'
|
||
|
+-CASCADE-----+
|
||
|
+-SET NULL----+
|
||
|
'-SET DEFAULT-'
|
||
|
|
||
|
check-constraint:
|
||
|
|
||
|
|--+-----------------------------+------------------------------>
|
||
|
'-CONSTRAINT--<span class="italic">constraint-name</span>-'
|
||
|
|
||
|
>--CHECK--(--<span class="italic">check-condition</span>--)---------------------------------|
|
||
|
|
||
|
</pre>
|
||
|
<a name="skipsyn-255" id="skipsyn-255"></a>
|
||
|
<a name="wq1083"></a>
|
||
|
<div class="notelisttitle" id="wq1083">Notes:</div>
|
||
|
<ol type="1">
|
||
|
<li>The ON DELETE and ON UPDATE clauses may be specified in either order.</li>
|
||
|
</ol></div>
|
||
|
<a name="wq1085"></a>
|
||
|
<div class="fignone" id="wq1085">
|
||
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn257.htm"
|
||
|
border="0" /></span><a href="#skipsyn-256"><img src="c.gif" alt="Skip visual syntax diagram"
|
||
|
border="0" /></a>materialized-query-definition:
|
||
|
|
||
|
|--(--<span class="italic">select-statement</span>--)--<span class="italic">refreshable-table-options</span>------------|
|
||
|
|
||
|
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:
|
||
|
|
||
|
|--+-(--<span class="italic">select-statement</span>--)--+---------------------------+-+----|
|
||
|
| '-<span class="italic">refreshable-table-options</span>-' |
|
||
|
| .------------------------------------. |
|
||
|
| V | (2) |
|
||
|
'-SET----+-REFRESH DEFERRED---------------+-+-----------'
|
||
|
+-MAINTAINED BY USER-------------+
|
||
|
'-+-ENABLE QUERY OPTIMIZATION--+-'
|
||
|
'-DISABLE QUERY OPTIMIZATION-'
|
||
|
|
||
|
</pre>
|
||
|
<a name="skipsyn-256" id="skipsyn-256"></a>
|
||
|
<a name="wq1086"></a>
|
||
|
<div class="notelisttitle" id="wq1086">Notes:</div>
|
||
|
<ol type="1">
|
||
|
<li>The same clause must not be specified more than once. MAINTAINED
|
||
|
BY USER must be specified.</li>
|
||
|
<li>The same clause must not be specified more than once.</li>
|
||
|
</ol></div>
|
||
|
<a name="wq1088"></a>
|
||
|
<div class="fignone" id="wq1088">
|
||
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn258.htm"
|
||
|
border="0" /></span><a href="#skipsyn-257"><img src="c.gif" alt="Skip visual syntax diagram"
|
||
|
border="0" /></a>partitioning-clause:
|
||
|
|
||
|
.-RANGE-.
|
||
|
|--PARTITION BY--+-+-------+--<span class="italic">range-partition-spec</span>-+------------|
|
||
|
'-HASH--<span class="italic">hash-partition-spec</span>-------'
|
||
|
|
||
|
range-partition-spec:
|
||
|
|
||
|
.-,----------------------------. .-,--------------------------------------------.
|
||
|
V .-NULLS LAST--. | V |
|
||
|
|--(----<span class="italic">column-name</span>--+-------------+-+--)--(--+---+---------------------------+--<span class="italic">boundary-spec</span>-+---------+--)--|
|
||
|
'-NULLS FIRST-' | '-PARTITION--<span class="italic">partition-name</span>-' |
|
||
|
'-<span class="italic">boundary-spec</span>--EVERY--(--<span class="italic">integer-constant</span>--+--------+--)-'
|
||
|
+-DAY----+
|
||
|
+-DAYS---+
|
||
|
+-MONTH--+
|
||
|
+-MONTHS-+
|
||
|
+-YEAR---+
|
||
|
'-YEARS--'
|
||
|
|
||
|
hash-partition-spec:
|
||
|
|
||
|
.-,-----------.
|
||
|
V |
|
||
|
|--(----<span class="italic">column-name</span>-+--)--INTO--<span class="italic">integer</span>--PARTITIONS-------------|
|
||
|
|
||
|
boundary-spec:
|
||
|
|
||
|
|--<span class="italic">starting-clause</span>--<span class="italic">ending-clause</span>-------------------------------|
|
||
|
|
||
|
starting-clause:
|
||
|
|
||
|
.-,------------.
|
||
|
.-FROM-. V | .-INCLUSIVE-.
|
||
|
|--STARTING--+------+--+-(----+-<span class="italic">constant</span>-+-+--)-+--+-----------+--|
|
||
|
| +-MINVALUE-+ | '-EXCLUSIVE-'
|
||
|
| '-MAXVALUE-' |
|
||
|
'-+-<span class="italic">constant</span>-+-----------'
|
||
|
+-MINVALUE-+
|
||
|
'-MAXVALUE-'
|
||
|
|
||
|
ending-clause:
|
||
|
|
||
|
.-,------------.
|
||
|
.-AT-. V | .-INCLUSIVE-.
|
||
|
|--ENDING--+----+--+-(----+-<span class="italic">constant</span>-+-+--)-+--+-----------+----|
|
||
|
| +-MINVALUE-+ | '-EXCLUSIVE-'
|
||
|
| '-MAXVALUE-' |
|
||
|
'-+-<span class="italic">constant</span>-+-----------'
|
||
|
+-MINVALUE-+
|
||
|
'-MAXVALUE-'
|
||
|
|
||
|
</pre>
|
||
|
<a name="skipsyn-257" id="skipsyn-257"></a></div>
|
||
|
<a name="synsalter"></a>
|
||
|
<h3 id="synsalter"><a href="rbafzmst02.htm#ToC_766">Description</a></h3>
|
||
|
<dl class="parml">
|
||
|
<dt class="bold"><var class="pv">table-name</var></dt>
|
||
|
<dd>Identifies the table you want to be altered. The <span class="italic">table-name</span> <a id="idx1334" name="idx1334"></a> 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 <span class="italic">table-name</span> identifies a materialized query table,
|
||
|
ADD <var class="pv">column-definition</var>, ALTER <var class="pv">column-alteration</var>, and DROP
|
||
|
COLUMN are not allowed.
|
||
|
</dd>
|
||
|
</dl>
|
||
|
<a name="wq1089"></a>
|
||
|
<h3 id="wq1089"><a href="rbafzmst02.htm#ToC_767">ADD COLUMN <span><var class="pv">column-definition</var></span></a></h3>
|
||
|
<p>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 <span class="italic">n</span> columns, the ordinality of the new column is <span class="italic">n</span>+1. The value of <span class="italic">n</span>+1 must not exceed 8000.</p><a id="idx1335" name="idx1335"></a>
|
||
|
<p>A table can have only one ROWID or identity column.</p>
|
||
|
<p>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.</p>
|
||
|
<p>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 <a href="rbafzmsthctabl.htm#unctabl">Notes</a>.</p>
|
||
|
<dl class="parml">
|
||
|
<dt class="bold"><var class="pv">column-name</var> </dt><a id="idx1336" name="idx1336"></a>
|
||
|
<dd>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 <var class="pv">column-name</var>.
|
||
|
</dd>
|
||
|
<dt class="bold">FOR COLUMN <var class="pv">system-column-name</var> </dt><a id="idx1337" name="idx1337"></a><a id="idx1338" name="idx1338"></a>
|
||
|
<dd>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.
|
||
|
<p>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 <a href="rbafzmsthctabl.htm#cnamrul">Rules for Column Name Generation</a>.</p>
|
||
|
</dd>
|
||
|
<dt class="bold"><var class="pv">data-type</var></dt><a id="idx1339" name="idx1339"></a><a id="idx1340" name="idx1340"></a><a id="idx1341" name="idx1341"></a><a id="idx1342" name="idx1342"></a><a id="idx1343" name="idx1343"></a><a id="idx1344" name="idx1344"></a><a id="idx1345" name="idx1345"></a><a id="idx1346" name="idx1346"></a><a id="idx1347" name="idx1347"></a><a id="idx1348" name="idx1348"></a><a id="idx1349" name="idx1349"></a><a id="idx1350" name="idx1350"></a><a id="idx1351" name="idx1351"></a><a id="idx1352" name="idx1352"></a><a id="idx1353" name="idx1353"></a><a id="idx1354" name="idx1354"></a><a id="idx1355" name="idx1355"></a><a id="idx1356" name="idx1356"></a><a id="idx1357" name="idx1357"></a><a id="idx1358" name="idx1358"></a><a id="idx1359" name="idx1359"></a><a id="idx1360" name="idx1360"></a><a id="idx1361" name="idx1361"></a><a id="idx1362" name="idx1362"></a>
|
||
|
<dd>Specifies the data type of the column. The data type can be a built-in
|
||
|
data type or a distinct type.
|
||
|
<dl class="parml">
|
||
|
<dt class="bold"><var class="pv">built-in-type</var> </dt><a id="idx1363" name="idx1363"></a>
|
||
|
<dd>Specifies a built-in data type. See <a href="rbafzmsthctabl.htm#hctabl">CREATE TABLE</a> for a description
|
||
|
of built-in types.
|
||
|
</dd>
|
||
|
<dt class="bold"><var class="pv">distinct-type-name</var></dt>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
</dl>
|
||
|
</dd>
|
||
|
<dt class="bold">DEFAULT </dt><a id="idx1364" name="idx1364"></a>
|
||
|
<dd>Specifies a default value for the column. This clause cannot be specified
|
||
|
more than once in the same <var class="pv">column-definition</var>. 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:
|
||
|
<ul>
|
||
|
<li>if the column is nullable, the default value is the null value.</li>
|
||
|
<li>if the column is not nullable, the default depends on the data type of
|
||
|
the column:
|
||
|
<dl>
|
||
|
<dt class="bold">Data type</dt>
|
||
|
<dd class="bold">Default value</dd>
|
||
|
<dt class="bold">Numeric</dt>
|
||
|
<dd>0
|
||
|
</dd>
|
||
|
<dt class="bold">Fixed-length character or graphic string</dt>
|
||
|
<dd>Blanks
|
||
|
</dd>
|
||
|
<dt class="bold">Fixed-length binary string</dt>
|
||
|
<dd>Hexadecimal zeros
|
||
|
</dd>
|
||
|
<dt class="bold">Varying-length string</dt>
|
||
|
<dd>A string length of 0
|
||
|
</dd>
|
||
|
<dt class="bold">Date</dt>
|
||
|
<dd>For existing rows, a date corresponding to 1 January 0001. For added
|
||
|
rows, the current date.
|
||
|
</dd>
|
||
|
<dt class="bold">Time</dt>
|
||
|
<dd>For existing rows, a time corresponding to 0 hours, 0 minutes, and 0
|
||
|
seconds. For added rows, the current time.
|
||
|
</dd>
|
||
|
<dt class="bold">Timestamp</dt>
|
||
|
<dd>For existing rows, a date corresponding to 1 January 0001 and a time
|
||
|
corresponding to 0 hours, 0 minutes, 0 seconds, and 0 microseconds. For added
|
||
|
rows, the current timestamp.
|
||
|
</dd>
|
||
|
<dt class="bold">Datalink</dt>
|
||
|
<dd>A value corresponding to DLVALUE('','URL','').
|
||
|
</dd>
|
||
|
<dt class="bold">Distinct type</dt>
|
||
|
<dd>The default value of the corresponding source type of the distinct type.
|
||
|
</dd>
|
||
|
</dl></li></ul>
|
||
|
<p>Omission of NOT NULL and DEFAULT from a <var class="pv">column-definition</var> is
|
||
|
an implicit specification of DEFAULT NULL. </p>
|
||
|
<dl class="parml">
|
||
|
<dt class="bold"><span class="italic">constant</span> </dt><a id="idx1365" name="idx1365"></a>
|
||
|
<dd>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 <a href="rbafzmstch2bas.htm#ch2bas">Assignments and comparisons</a>.
|
||
|
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.
|
||
|
</dd>
|
||
|
<dt class="bold"><span class="bold">USER</span></dt><a id="idx1366" name="idx1366"></a>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold"><span class="bold">NULL</span> </dt><a id="idx1367" name="idx1367"></a>
|
||
|
<dd>Specifies null as the default for the column. If NOT NULL is specified,
|
||
|
DEFAULT NULL must not be specified within the same <var class="pv">column-definition</var>.
|
||
|
</dd>
|
||
|
<dt class="bold"><span class="bold">CURRENT_DATE</span> </dt><a id="idx1368" name="idx1368"></a>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold"><span class="bold">CURRENT_TIME</span> </dt><a id="idx1369" name="idx1369"></a>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold"><span class="bold">CURRENT_TIMESTAMP</span> </dt><a id="idx1370" name="idx1370"></a>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold"><span class="bold"><var class="pv">cast-function-name</var></span> <a id="idx1371" name="idx1371"></a></dt>
|
||
|
<dd>This form of a default value can only be used with columns defined as
|
||
|
a distinct type, <span>BINARY, VARBINARY,</span> BLOB, CLOB, DBCLOB, DATE, TIME,
|
||
|
or TIMESTAMP data types. The following table describes the allowed uses of
|
||
|
these <var class="pv">cast-functions</var>.
|
||
|
<a name="wq1090"></a>
|
||
|
<table id="wq1090" width="100%" summary="" border="1" frame="border" rules="none">
|
||
|
<thead valign="bottom">
|
||
|
<tr>
|
||
|
<th id="wq1091" width="47%" align="left" valign="top">Data Type</th>
|
||
|
<th id="wq1092" width="52%" align="left" valign="top">Cast Function Name</th>
|
||
|
</tr>
|
||
|
</thead>
|
||
|
<tbody valign="top">
|
||
|
<tr>
|
||
|
<td align="left" valign="top" headers="wq1091">Distinct type N based on a BINARY, VARBINARY,
|
||
|
BLOB, CLOB, or DBCLOB</td>
|
||
|
<td align="left" valign="top" headers="wq1092">BINARY, VARBINARY, BLOB, CLOB, or DBCLOB *</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td align="left" valign="top" headers="wq1091">Distinct type N based on a DATE, TIME, or
|
||
|
TIMESTAMP</td>
|
||
|
<td align="left" valign="top" headers="wq1092">N (the user-defined cast function that was
|
||
|
generated when N was created) **
|
||
|
<div class="lines">or<br />
|
||
|
DATE, TIME, or TIMESTAMP *<br />
|
||
|
</div></td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td align="left" valign="top" headers="wq1091">Distinct type N based on other data types</td>
|
||
|
<td align="left" valign="top" headers="wq1092">N (the user-defined cast function that was
|
||
|
generated when N was created) **</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td align="left" valign="top" headers="wq1091">BINARY, VARBINARY, BLOB, CLOB, or DBCLOB</td>
|
||
|
<td align="left" valign="top" headers="wq1092">BINARY, VARBINARY, BLOB, CLOB, or DBCLOB *</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td align="left" valign="top" headers="wq1091">DATE, TIME, or TIMESTAMP</td>
|
||
|
<td align="left" valign="top" headers="wq1092">DATE, TIME, or TIMESTAMP *</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td colspan="2" align="left" valign="top" headers="wq1091 wq1092">
|
||
|
<a name="wq1093"></a>
|
||
|
<div class="notetitle" id="wq1093">Notes:</div>
|
||
|
<div class="notebody">
|
||
|
<p>* 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.</p>
|
||
|
<p>**
|
||
|
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.</p></div></td>
|
||
|
</tr>
|
||
|
</tbody>
|
||
|
</table>
|
||
|
<dl class="parml">
|
||
|
<dt class="bold"><var class="pv">constant</var> </dt><a id="idx1372" name="idx1372"></a>
|
||
|
<dd>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 <span>BINARY, VARBINARY,</span> BLOB, CLOB, DBCLOB,
|
||
|
DATE, TIME, and TIMESTAMP functions, the constant must be a string constant.
|
||
|
</dd>
|
||
|
<dt class="bold"><span class="bold">USER</span></dt><a id="idx1373" name="idx1373"></a>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold"><span class="bold">CURRENT_DATE</span> </dt><a id="idx1374" name="idx1374"></a>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold"><span class="bold">CURRENT_TIME</span> </dt><a id="idx1375" name="idx1375"></a>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold"><span class="bold">CURRENT_TIMESTAMP</span> </dt><a id="idx1376" name="idx1376"></a>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
</dl>
|
||
|
</dd>
|
||
|
</dl>
|
||
|
<p>If the value specified is not valid, an error is returned.</p>
|
||
|
</dd>
|
||
|
<dt class="bold">GENERATED <a id="idx1377" name="idx1377"></a></dt>
|
||
|
<dd>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.
|
||
|
<dl class="parml">
|
||
|
<dt class="bold">ALWAYS</dt>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold">BY DEFAULT</dt>
|
||
|
<dd>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.
|
||
|
<p>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.</p>
|
||
|
<p>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.</p>
|
||
|
</dd>
|
||
|
</dl>
|
||
|
</dd>
|
||
|
<dt class="bold"><a id="idattr" name="idattr"></a>AS IDENTITY <a id="idx1378" name="idx1378"></a></dt>
|
||
|
<dd>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 <span>partitioned table or</span> 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.
|
||
|
<p>An identity
|
||
|
column is implicitly NOT NULL. See the AS IDENTITY clause in <a href="rbafzmsthctabl.htm#hctabl">CREATE TABLE</a> for
|
||
|
the descriptions of the identity attributes.</p>
|
||
|
<p>A column in
|
||
|
a table cannot be altered to an identity column if the table is a DDS-created
|
||
|
physical file.</p>
|
||
|
</dd>
|
||
|
<dt class="bold"><var class="pv">datalink-options</var> <a id="idx1379" name="idx1379"></a></dt>
|
||
|
<dd>Specifies the options associated with a DATALINK column. See <a href="rbafzmsthctabl.htm#hctabl">CREATE TABLE</a> for
|
||
|
a description of <span class="italic">datalink-options</span>.
|
||
|
</dd>
|
||
|
<dt class="bold">NOT NULL </dt><a id="idx1380" name="idx1380"></a>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold"><var class="pv">column-constraint</var></dt>
|
||
|
<dd>The <var class="pv">column-constraint</var> of a <var class="pv">column-definition</var> provides
|
||
|
a shorthand method of defining a constraint composed of a single column.
|
||
|
Thus, if a <var class="pv">column-constraint</var> is specified in the definition of column
|
||
|
C, the effect is the same as if that constraint were specified as a <var class="pv">unique-constraint</var>, <var class="pv">referential-constraint</var> or <var class="pv">check-constraint</var> in which C is the only identified column.
|
||
|
<dl class="parml">
|
||
|
<dt class="bold"><span class="bold">CONSTRAINT</span> <var class="pv">constraint-name</var> <a id="idx1381" name="idx1381"></a><a id="idx1382" name="idx1382"></a></dt>
|
||
|
<dd>Names the constraint. A constraint-name must not identify a constraint
|
||
|
that already exists at the current server.
|
||
|
<p>If the clause is not specified,
|
||
|
a unique constraint name is generated by the database manager.</p>
|
||
|
</dd>
|
||
|
<dt class="bold"><span class="bold">PRIMARY KEY</span> </dt><a id="idx1383" name="idx1383"></a>
|
||
|
<dd>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.
|
||
|
<p>This clause must not be specified in more than one <var class="pv"> column-definition</var> 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.</p>
|
||
|
<p>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.</p>
|
||
|
</dd>
|
||
|
<dt class="bold"><span class="bold">UNIQUE</span> </dt><a id="idx1384" name="idx1384"></a>
|
||
|
<dd>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.
|
||
|
<p>This clause cannot be specified more than once in a column definition
|
||
|
and must not be specified if PRIMARY KEY is specified in the <var class="pv"> column-definition</var>. The column must not be a LOB or DataLink column.</p>
|
||
|
</dd>
|
||
|
<dt class="bold"><span class="italic">references-clause</span> <a id="idx1385" name="idx1385"></a></dt>
|
||
|
<dd>The <var class="pv">references-clause</var> of a column-definition provides a shorthand
|
||
|
method of defining a foreign key composed of a single column. Thus, if a <var class="pv">references-clause</var> 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 <var class="pv">references-clause</var> is not allowed if the table <span>is a global temporary table,
|
||
|
a partitioned table, or a distributed table.</span>
|
||
|
</dd>
|
||
|
<dt class="bold"><span class="bold">CHECK(</span><var class="pv">check-condition</var><span class="bold">)</span></dt><a id="idx1386" name="idx1386"></a>
|
||
|
<dd>Provides a shorthand method of defining a check constraint whose <var class="pv">check-condition</var> 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 <var class="pv">check-condition</var> of the check constraint. The effect is the
|
||
|
same as if the check constraint were specified as a separate clause.
|
||
|
<p>ROWID
|
||
|
or DATALINK with FILE LINK CONTROL columns cannot be referenced in a CHECK
|
||
|
constraint. For additional restrictions see, <a href="rbafzmstatabl.htm#atcheckcst">ADD check-constraint</a>.</p>
|
||
|
</dd>
|
||
|
</dl>
|
||
|
</dd>
|
||
|
</dl>
|
||
|
<a name="wq1094"></a>
|
||
|
<h3 id="wq1094"><a href="rbafzmst02.htm#ToC_768">ALTER COLUMN <span><var class="pv">column-alteration</var></span></a></h3><a id="idx1387" name="idx1387"></a><a id="idx1388" name="idx1388"></a>
|
||
|
<p>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. </p>
|
||
|
<dl class="parml">
|
||
|
<dt class="bold"><var class="pv">column-name</var> </dt>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold">SET DATA TYPE <var class="pv">data-type</var> </dt><a id="idx1389" name="idx1389"></a><a id="idx1390" name="idx1390"></a>
|
||
|
<dd>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 <a href="rbafzmstch2bas.htm#ch2bas">Assignments and comparisons</a>. 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.
|
||
|
<p>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.</p>
|
||
|
<p>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 <a href="rbafzmstch2bas.htm#ch2bas">Assignments and comparisons</a>.</p>
|
||
|
<p>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-<span class="italic">n</span>, where <span class="italic">n</span> is the number
|
||
|
of columns specified that allow nulls.</p>
|
||
|
<p>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.</p>
|
||
|
</dd>
|
||
|
<dt class="bold">SET <var class="pv">default-clause</var> </dt><a id="idx1391" name="idx1391"></a>
|
||
|
<dd>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 <a href="rbafzmstch2bas.htm#ch2bas">Assignments and comparisons</a>.
|
||
|
</dd>
|
||
|
<dt class="bold">SET NOT NULL </dt><a id="idx1392" name="idx1392"></a>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold">SET GENERATED ALWAYS or GENERATED BY DEFAULT</dt><a id="idx1393" name="idx1393"></a><a id="idx1394" name="idx1394"></a>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold">DROP DEFAULT </dt><a id="idx1395" name="idx1395"></a>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold">DROP NOT NULL </dt><a id="idx1396" name="idx1396"></a>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold">DROP IDENTITY </dt><a id="idx1397" name="idx1397"></a>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold"><var class="pv">identity-alteration</var></dt><a id="idx1398" name="idx1398"></a><a id="idx1399" name="idx1399"></a><a id="idx1400" name="idx1400"></a><a id="idx1401" name="idx1401"></a><a id="idx1402" name="idx1402"></a><a id="idx1403" name="idx1403"></a><a id="idx1404" name="idx1404"></a><a id="idx1405" name="idx1405"></a><a id="idx1406" name="idx1406"></a><a id="idx1407" name="idx1407"></a><a id="idx1408" name="idx1408"></a>
|
||
|
<dd>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 <a href="rbafzmstatabl.htm#idattr">AS IDENTITY</a>.
|
||
|
<dl class="parml">
|
||
|
<dt class="bold">RESTART</dt>
|
||
|
<dd>Specifies the next value for an identity column. If WITH <var class="pv">numeric-constant</var> 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.
|
||
|
<dl class="parml">
|
||
|
<dt class="bold">WITH <var class="pv">numeric-constant</var></dt>
|
||
|
<dd>Specifies that <var class="pv">numeric-constant</var> will be used as
|
||
|
the next value for the column. The <var class="pv">numeric-constant</var> 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.
|
||
|
</dd>
|
||
|
</dl>
|
||
|
</dd>
|
||
|
</dl>
|
||
|
</dd>
|
||
|
</dl>
|
||
|
<a name="wq1095"></a>
|
||
|
<h3 id="wq1095"><a href="rbafzmst02.htm#ToC_769">DROP COLUMN</a></h3><a id="idx1409" name="idx1409"></a>
|
||
|
<p>Drops the identified column from the table. </p>
|
||
|
<dl class="parml">
|
||
|
<dt class="bold"><var class="pv">column-name</var> </dt><a id="idx1410" name="idx1410"></a>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold">CASCADE </dt><a id="idx1411" name="idx1411"></a>
|
||
|
<dd>Specifies that any views, indexes, triggers, or constraints that are
|
||
|
dependent on the column being dropped are also dropped. <sup class="fn"><a href="rbafzmstatabl.htm#trgdep">55</a></sup>
|
||
|
</dd>
|
||
|
<dt class="bold">RESTRICT </dt><a id="idx1412" name="idx1412"></a>
|
||
|
<dd>Specifies that the column cannot be dropped if any views, indexes, triggers,
|
||
|
or constraints are dependent on the column. <sup class="fn"><a href="rbafzmstatabl.htm#trgdep">55</a></sup>
|
||
|
<p>If all the
|
||
|
columns referenced in a constraint are dropped in the same ALTER TABLE statement,
|
||
|
RESTRICT does not prevent the drop.</p>
|
||
|
</dd>
|
||
|
</dl>
|
||
|
<a name="wq1096"></a>
|
||
|
<h3 id="wq1096"><a href="rbafzmst02.htm#ToC_770">ADD unique-constraint</a></h3><a id="idx1413" name="idx1413"></a><a id="idx1414" name="idx1414"></a><a id="idx1415" name="idx1415"></a>
|
||
|
<dl class="parml">
|
||
|
<dt class="bold">CONSTRAINT <var class="pv">constraint-name</var></dt>
|
||
|
<dd>Names the constraint. A <var class="pv">constraint-name</var> must not identify a
|
||
|
constraint that already exists at the current server. The <var class="pv">constraint-name</var> must be unique within a schema.
|
||
|
<p>If not specified, a unique constraint
|
||
|
name is generated by the database manager.</p>
|
||
|
</dd>
|
||
|
<dt class="bold">UNIQUE (<var class="pv">column-name</var>,...) </dt><a id="idx1416" name="idx1416"></a><a id="idx1417" name="idx1417"></a><a id="idx1418" name="idx1418"></a>
|
||
|
<dd>Defines a unique constraint composed of the identified columns.
|
||
|
Each <var class="pv">column-name</var> 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-<span class="italic">n</span>, where <span class="italic">n</span> is the number of columns specified
|
||
|
that allow nulls.
|
||
|
<p>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.</p>
|
||
|
<p>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.</p>
|
||
|
</dd>
|
||
|
<dt class="bold">PRIMARY KEY (<var class="pv">column-name</var>,...) </dt><a id="idx1419" name="idx1419"></a><a id="idx1420" name="idx1420"></a><a id="idx1421" name="idx1421"></a>
|
||
|
<dd>Defines a primary key composed of the identified columns.
|
||
|
Each <var class="pv">column-name</var> 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.
|
||
|
<p>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.</p>
|
||
|
<p>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.</p>
|
||
|
<p>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.</p>
|
||
|
</dd>
|
||
|
</dl>
|
||
|
<a name="wq1097"></a>
|
||
|
<h3 id="wq1097"><a href="rbafzmst02.htm#ToC_771">ADD referential-constraint</a></h3><a id="idx1422" name="idx1422"></a><a id="idx1423" name="idx1423"></a><a id="idx1424" name="idx1424"></a>
|
||
|
<dl class="parml">
|
||
|
<dt class="bold">CONSTRAINT <var class="pv">constraint-name</var> </dt>
|
||
|
<dd>Names the constraint. A <var class="pv">constraint-name</var> must not identify a
|
||
|
constraint that already exists at the current server.
|
||
|
<p>If not specified,
|
||
|
a unique constraint name is generated by the database manager.</p>
|
||
|
</dd>
|
||
|
<dt class="bold">FOREIGN KEY</dt><a id="idx1425" name="idx1425"></a>
|
||
|
<dd>Defines a referential constraint. <span>FOREIGN KEY is not allowed if
|
||
|
the table is a partitioned table.</span>
|
||
|
<p>Let T1 denote the table being altered. </p>
|
||
|
<dl class="parml">
|
||
|
<dt class="bold">(<var class="pv">column-name</var>,...) </dt><a id="idx1426" name="idx1426"></a>
|
||
|
<dd>The foreign key of the referential constraint is composed
|
||
|
of the identified columns. Each <var class="pv">column-name</var> 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-<span class="italic">n</span>, where <span class="italic">n</span> is the number of columns specified that allows nulls.
|
||
|
</dd>
|
||
|
<dt class="bold">REFERENCES <var class="pv">table-name</var> </dt><a id="idx1427" name="idx1427"></a><a id="idx1428" name="idx1428"></a>
|
||
|
<dd>The <span class="italic">table-name</span> specified in a REFERENCES clause
|
||
|
must identify a base table that exists at the current server, but it <span>must not identify a catalog table, a global temporary table, a partitioned
|
||
|
table, or a distributed table.</span> This table is referred to as the parent
|
||
|
table in the constraint relationship.
|
||
|
<p>A referential constraint is a <var class="pv">duplicate</var> 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.</p>
|
||
|
</dd>
|
||
|
</dl>
|
||
|
<p>Let T2 denote the identified parent table. </p>
|
||
|
<dl class="parml">
|
||
|
<dt class="bold">(<var class="pv">column-name,</var>...) </dt><a id="idx1429" name="idx1429"></a>
|
||
|
<dd>The parent key of the referential constraint is composed
|
||
|
of the identified columns. Each <var class="pv">column-name</var> 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-<span class="italic">n</span>, where <span class="italic">n</span> is
|
||
|
the number of columns specified that allow nulls.
|
||
|
<p>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.</p>
|
||
|
<p>The specified foreign
|
||
|
key must have the same number of columns as the parent key of T2. The description
|
||
|
of the <span class="italic">n</span>th column of the foreign key and the <span class="italic">n</span>th column of the parent key must have identical data types, lengths,
|
||
|
and CCSIDs.</p>
|
||
|
</dd>
|
||
|
</dl>
|
||
|
<p>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.</p>
|
||
|
<p>The referential constraint specified by the FOREIGN KEY clause defines
|
||
|
a relationship in which T2 is the parent and T1 is the dependent. </p>
|
||
|
<dl class="parml">
|
||
|
<dt class="bold">ON DELETE </dt><a id="idx1430" name="idx1430"></a><a id="idx1431" name="idx1431"></a><a id="idx1432" name="idx1432"></a><a id="idx1433" name="idx1433"></a><a id="idx1434" name="idx1434"></a><a id="idx1435" name="idx1435"></a><a id="idx1436" name="idx1436"></a>
|
||
|
<dd>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:
|
||
|
<ul>
|
||
|
<li>NO ACTION (default)</li>
|
||
|
<li>RESTRICT</li>
|
||
|
<li>CASCADE</li>
|
||
|
<li>SET NULL</li>
|
||
|
<li>SET DEFAULT</li></ul>
|
||
|
<p>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.</p>
|
||
|
<p>CASCADE must not be specified if T1 has a delete
|
||
|
trigger.</p>
|
||
|
<p>CASCADE must not be specified if T1 contains a DataLink column
|
||
|
with FILE LINK CONTROL.</p>
|
||
|
<p>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 <span class="italic">p</span> denote such a row of T2. </p>
|
||
|
<ul>
|
||
|
<li>If RESTRICT or NO ACTION is specified, an error occurs and no rows are
|
||
|
deleted.</li>
|
||
|
<li>If CASCADE is specified, the delete operation is propagated to the dependents
|
||
|
of <span class="italic">p</span> in T1.</li>
|
||
|
<li>If SET NULL is specified, each nullable column of the foreign key of each
|
||
|
dependent of <span class="italic">p</span> in T1 is set to null.</li>
|
||
|
<li>If SET DEFAULT is specified, each column of the foreign key of each dependent
|
||
|
of <span class="italic">p</span> in T1 is set to its default value.</li></ul>
|
||
|
</dd>
|
||
|
<dt class="bold">ON UPDATE </dt><a id="idx1437" name="idx1437"></a><a id="idx1438" name="idx1438"></a><a id="idx1439" name="idx1439"></a><a id="idx1440" name="idx1440"></a><a id="idx1441" name="idx1441"></a><a id="idx1442" name="idx1442"></a>
|
||
|
<dd>Specifies what action is to take place on the dependent tables when
|
||
|
a row of the parent table is updated.
|
||
|
<p>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 <span class="italic">p</span> denote such a row of T2. </p>
|
||
|
<ul>
|
||
|
<li>If RESTRICT or NO ACTION is specified, an error occurs and no rows are
|
||
|
updated.</li></ul>
|
||
|
</dd>
|
||
|
</dl>
|
||
|
</dd>
|
||
|
</dl>
|
||
|
<a name="atcheckcst"></a>
|
||
|
<h3 id="atcheckcst"><a href="rbafzmst02.htm#ToC_772">ADD check-constraint</a></h3>
|
||
|
<dl class="parml"><a id="idx1443" name="idx1443"></a><a id="idx1444" name="idx1444"></a><a id="idx1445" name="idx1445"></a>
|
||
|
<dt class="bold">CONSTRAINT <var class="pv">constraint-name</var></dt>
|
||
|
<dd>Names the constraint. A <var class="pv">constraint-name</var> must not identify a
|
||
|
constraint that already exists at the current server. The <var class="pv">constraint-name</var> must be unique within a schema.
|
||
|
<p>If not specified, a unique constraint
|
||
|
name is generated by the database manager.</p>
|
||
|
</dd>
|
||
|
<dt class="bold">CHECK(<var class="pv">check-condition</var>)</dt><a id="idx1446" name="idx1446"></a><a id="idx1447" name="idx1447"></a><a id="idx1448" name="idx1448"></a>
|
||
|
<dd>Defines a check constraint. The <var class="pv">check-condition</var> must be true
|
||
|
or unknown for every row of the table.
|
||
|
<p>The <var class="pv">check-condition</var> is a <var class="pv">search-condition</var>, except:</p>
|
||
|
<ul>
|
||
|
<li>It can only refer to columns of the table and the column names must not
|
||
|
be qualified.</li>
|
||
|
<li>It cannot reference ROWID or DATALINK with FILE LINK CONTROL columns.</li>
|
||
|
<li>It must not contain any of the following:
|
||
|
<ul>
|
||
|
<li>Subqueries</li>
|
||
|
<li>Aggregate functions</li>
|
||
|
<li>Variables</li>
|
||
|
<li>Parameter markers</li>
|
||
|
<li>Complex expressions that contain LOBs (such as concatenation)</li>
|
||
|
<li>CURRENT DEBUG MODE, CURRENT DEGREE, CURRENT SCHEMA, CURRENT
|
||
|
SERVER, CURRENT PATH, SESSION_USER, SYSTEM_USER, and USER special registers</li>
|
||
|
<li>CURRENT DATE, CURRENT TIME, CURRENT TIMESTAMP, and CURRENT TIMEZONE special
|
||
|
registers</li>
|
||
|
<li>User-defined functions other than functions that were implicitly generated
|
||
|
with the creation of a distinct type</li>
|
||
|
<li>NOW, CURDATE, and CURTIME scalar functions</li>
|
||
|
<li>DBPARTITIONNAME scalar function</li>
|
||
|
<li>ATAN2, DIFFERENCE, RAND, RADIANS, and SOUNDEX scalar functions</li>
|
||
|
<li>DLVALUE, DLURLPATH, DLURLPATHONLY, DLURLSERVER, or DLURLSCHEME scalar
|
||
|
functions</li>
|
||
|
<li>DLURLCOMPLETE scalar function (for DataLinks with an attribute of FILE
|
||
|
LINK CONTROL and READ PERMISSION DB)</li>
|
||
|
<li>DECRYPT_BIT, DECRYPT_BINARY, DECRYPT_CHAR, DECRYPT_DB, ENCRYPT_RC2,
|
||
|
ENCRYPT_TDES, and GETHINT</li>
|
||
|
<li>DAYNAME, MONTHNAME, NEXT_DAY, and VARCHAR_FORMAT</li>
|
||
|
<li>INSERT, REPEAT, and REPLACE</li>
|
||
|
<li>GENERATE_UNIQUE and RAISE_ERROR</li></ul></li></ul>
|
||
|
</dd>
|
||
|
</dl>
|
||
|
<p>For more information about search-condition, see <a href="rbafzmstch2srch.htm#ch2srch">Search conditions</a>.</p>
|
||
|
<a name="wq1098"></a>
|
||
|
<h3 id="wq1098"><a href="rbafzmst02.htm#ToC_773">DROP</a></h3>
|
||
|
<dl class="parml">
|
||
|
<dt class="bold">PRIMARY KEY </dt><a id="idx1449" name="idx1449"></a>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold">FOREIGN KEY <var class="pv">constraint-name</var> </dt><a id="idx1450" name="idx1450"></a><a id="idx1451" name="idx1451"></a>
|
||
|
<dd>Drops the referential constraint <var class="pv">constraint-name</var>. The <var class="pv">constraint-name</var> must identify a referential constraint in which the table
|
||
|
is a dependent.
|
||
|
</dd>
|
||
|
<dt class="bold">UNIQUE <var class="pv">constraint-name</var> </dt><a id="idx1452" name="idx1452"></a><a id="idx1453" name="idx1453"></a>
|
||
|
<dd>Drops the unique constraint <span class="italic">constraint-name</span> and
|
||
|
all referential constraints dependent on this unique constraint. The <span class="italic">constraint-name</span> must identify a unique constraint on the table. DROP
|
||
|
UNIQUE will not drop a PRIMARY KEY unique constraint.
|
||
|
</dd>
|
||
|
<dt class="bold">CHECK <var class="pv">constraint-name</var></dt><a id="idx1454" name="idx1454"></a><a id="idx1455" name="idx1455"></a>
|
||
|
<dd>Drops the check constraint <span class="italic">constraint-name</span>.
|
||
|
The <var class="pv">constraint-name</var> must identify a check constraint
|
||
|
on the table.
|
||
|
</dd>
|
||
|
<dt class="bold">CONSTRAINT <var class="pv">constraint-name</var> </dt><a id="idx1456" name="idx1456"></a><a id="idx1457" name="idx1457"></a>
|
||
|
<dd>Drops the constraint <var class="pv">constraint-name</var>. The <var class="pv">constraint-name</var> 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.
|
||
|
</dd>
|
||
|
<dt class="bold">CASCADE </dt><a id="idx1458" name="idx1458"></a>
|
||
|
<dd>Specifies for unique constraints that any referential constraints that
|
||
|
are dependent on the constraint being dropped are also dropped.
|
||
|
</dd>
|
||
|
<dt class="bold">RESTRICT </dt><a id="idx1459" name="idx1459"></a>
|
||
|
<dd>Specifies for unique constraints that the constraint cannot be dropped
|
||
|
if any referential constraints are dependent on the constraint.
|
||
|
</dd>
|
||
|
</dl>
|
||
|
<a name="wq1099"></a>
|
||
|
<h3 id="wq1099"><a href="rbafzmst02.htm#ToC_774">ADD partitioning-clause</a></h3><a id="idx1460" name="idx1460"></a>
|
||
|
<p>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 <a href="rbafzmsthctabl.htm#hctabl">CREATE TABLE</a> for
|
||
|
a description of the <var class="pv">partitioning-clause</var>.</p>
|
||
|
<p>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.</p>
|
||
|
<a name="wq1100"></a>
|
||
|
<h3 id="wq1100"><a href="rbafzmst02.htm#ToC_775">DROP PARTITIONING</a></h3><a id="idx1461" name="idx1461"></a>
|
||
|
<p>Changes a partitioned table into a non-partitioned table. If the specified
|
||
|
table is already non-partitioned, an error is returned.</p>
|
||
|
<p>Changing a partitioned table that contains data into a non-partitioned
|
||
|
table will require data movement between the data partitions.</p>
|
||
|
<a name="wq1101"></a>
|
||
|
<h3 id="wq1101"><a href="rbafzmst02.htm#ToC_776">ADD PARTITION</a></h3><a id="idx1462" name="idx1462"></a>
|
||
|
<p>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.</p>
|
||
|
<p>Changing the number of hash partitions in a partitioned table that contains
|
||
|
data will require data movement between the data partitions.</p>
|
||
|
<p></p>
|
||
|
<dl class="parml">
|
||
|
<dt class="bold"><var class="pv">partition-name</var></dt><a id="idx1463" name="idx1463"></a>
|
||
|
<dd>Names the partition. A <var class="pv">partition-name</var> must not identify a data
|
||
|
partition that already exists in the table.
|
||
|
<p>If the clause is not specified,
|
||
|
a unique partition name is generated by the database manager.</p>
|
||
|
</dd>
|
||
|
<dt class="bold"><var class="pv">boundary-spec</var> </dt><a id="idx1464" name="idx1464"></a>
|
||
|
<dd>Specifies the boundaries of a range partition. If the specified table
|
||
|
is not a range partitioned table, an error is returned. See <a href="rbafzmsthctabl.htm#hctabl">CREATE TABLE</a> for
|
||
|
a description of the <var class="pv">boundary-spec</var>.
|
||
|
</dd>
|
||
|
</dl>
|
||
|
<p></p>
|
||
|
<dl class="parml">
|
||
|
<dt class="bold"><var class="pv">integer</var> HASH PARTITIONS</dt><a id="idx1465" name="idx1465"></a>
|
||
|
<dd>Specifies the number of hash partitions to be added. If the specified
|
||
|
table is not a hash partitioned table, an error is returned.
|
||
|
</dd>
|
||
|
</dl>
|
||
|
<a name="wq1102"></a>
|
||
|
<h3 id="wq1102"><a href="rbafzmst02.htm#ToC_777">ALTER PARTITION</a></h3><a id="idx1466" name="idx1466"></a>
|
||
|
<p>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.</p>
|
||
|
<p>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.</p>
|
||
|
<dl class="parml">
|
||
|
<dt class="bold"><var class="pv">partition-name</var></dt><a id="idx1467" name="idx1467"></a>
|
||
|
<dd>Specifies the name of the partition to alter. The <var class="pv">partition-name</var> must identify a data partition that exists in the table.
|
||
|
</dd>
|
||
|
<dt class="bold"><var class="pv">boundary-spec</var> </dt><a id="idx1468" name="idx1468"></a>
|
||
|
<dd>Specifies the new boundaries of a range partition. See <a href="rbafzmsthctabl.htm#hctabl">CREATE TABLE</a> for
|
||
|
a description of the <var class="pv">boundary-spec</var>.
|
||
|
</dd>
|
||
|
</dl>
|
||
|
<a name="wq1103"></a>
|
||
|
<h3 id="wq1103"><a href="rbafzmst02.htm#ToC_778">DROP PARTITION</a></h3><a id="idx1469" name="idx1469"></a>
|
||
|
<p>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.</p>
|
||
|
<p></p>
|
||
|
<dl class="parml">
|
||
|
<dt class="bold"><var class="pv">partition-name</var></dt><a id="idx1470" name="idx1470"></a>
|
||
|
<dd>Specifies the name of the partition to drop. The <var class="pv">partition-name</var> must identify a data partition that exists in the table.
|
||
|
</dd>
|
||
|
<dt class="bold">DELETE ROWS</dt><a id="idx1471" name="idx1471"></a>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold">PRESERVE ROWS</dt><a id="idx1472" name="idx1472"></a>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
</dl>
|
||
|
<a name="wq1104"></a>
|
||
|
<h3 id="wq1104"><a href="rbafzmst02.htm#ToC_779">ADD MATERIALIZED QUERY materialized-query-definition</a></h3><a id="idx1473" name="idx1473"></a>
|
||
|
<p>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. </p>
|
||
|
<dl class="parml">
|
||
|
<dt class="bold"><var class="pv">select-statement</var> </dt>
|
||
|
<dd>Defines the query on which the table is based. The columns of the existing
|
||
|
table must meet the following characteristics:
|
||
|
<ul>
|
||
|
<li>The number of columns in the table must be the same as the number of result
|
||
|
columns in the <var class="pv">select-statement</var>.</li>
|
||
|
<li>The column attributes of each column of the table must be compatible to
|
||
|
the column attributes of the corresponding result column in the <var class="pv">select-statement</var>.</li></ul>
|
||
|
<p>The <var class="pv">select-statement</var> 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 <var class="pv">select-statement</var> for a materialized query table,
|
||
|
see <a href="rbafzmsthctabl.htm#hctabl">CREATE TABLE</a>.</p>
|
||
|
</dd>
|
||
|
<dt class="bold">refreshable-table-options</dt><a id="idx1474" name="idx1474"></a><a id="idx1475" name="idx1475"></a>
|
||
|
<dd>Specifies the materialized query table options for altering a base table
|
||
|
to a materialized query table.
|
||
|
<dl class="parml">
|
||
|
<dt class="bold">DATA INITIALLY DEFERRED</dt>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold">DATA INITIALLY IMMEDIATE</dt>
|
||
|
<dd>Specifies that the data is inserted in the table from the result of
|
||
|
the query as part of processing the ALTER TABLE statement.
|
||
|
</dd>
|
||
|
<dt class="bold">REFRESH DEFERRED</dt>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold">MAINTAINED BY USER</dt>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold">ENABLE QUERY OPTIMIZATION</dt>
|
||
|
<dd>Specifies that the materialized query table can be used for
|
||
|
query optimization.
|
||
|
</dd>
|
||
|
<dt class="bold">DISABLE QUERY OPTIMIZATION</dt>
|
||
|
<dd>Specifies that the materialized query table cannot be used for query
|
||
|
optimization. The table can still be queried directly.
|
||
|
</dd>
|
||
|
</dl>
|
||
|
</dd>
|
||
|
</dl>
|
||
|
<a name="wq1105"></a>
|
||
|
<h3 id="wq1105"><a href="rbafzmst02.htm#ToC_780">ALTER MATERIALIZED QUERY materialized-query-table-alteration</a></h3><a id="idx1476" name="idx1476"></a>
|
||
|
<p>Changes the attributes of a materialized query table. The <var class="pv">table-name</var> must identify a materialized query table.</p>
|
||
|
<dl class="parml">
|
||
|
<dt class="bold"><var class="pv">select-statement</var> </dt>
|
||
|
<dd>Defines the query on which the table is based. The columns of the existing
|
||
|
table must meet the following characteristics:
|
||
|
<ul>
|
||
|
<li>The number of columns in the table must be the same as the number of result
|
||
|
columns in the <var class="pv">select-statement</var>.</li>
|
||
|
<li>The column attributes of each column of the table must be compatible to
|
||
|
the column attributes of the corresponding result column in the <var class="pv">select-statement</var>.</li></ul>
|
||
|
<p>The <var class="pv">select-statement</var> 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 <var class="pv">select-statement</var> for a materialized query table,
|
||
|
see <a href="rbafzmsthctabl.htm#hctabl">CREATE TABLE</a>.</p>
|
||
|
</dd>
|
||
|
<dt class="bold"><var class="pv">refreshable-table-options</var></dt><a id="idx1477" name="idx1477"></a><a id="idx1478" name="idx1478"></a>
|
||
|
<dd>Specifies the materialized query table options for altering a base table
|
||
|
to a materialized query table.
|
||
|
<dl class="parml">
|
||
|
<dt class="bold">DATA INITIALLY DEFERRED</dt>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold">DATA INITIALLY IMMEDIATE</dt>
|
||
|
<dd>Specifies that the data is inserted in the table from the result of
|
||
|
the query as part of processing the ALTER TABLE statement.
|
||
|
</dd>
|
||
|
<dt class="bold">REFRESH DEFERRED</dt>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold">MAINTAINED BY USER</dt>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold">ENABLE QUERY OPTIMIZATION <span class="base">or</span> DISABLE
|
||
|
QUERY OPTIMIZATION</dt>
|
||
|
<dd>Specifies whether this materialized query table can be used for query
|
||
|
optimization.
|
||
|
<dl class="parml">
|
||
|
<dt class="bold">ENABLE QUERY OPTIMIZATION</dt>
|
||
|
<dd>The materialized query table can be used for query optimization.
|
||
|
</dd>
|
||
|
<dt class="bold">DISABLE QUERY OPTIMIZATION</dt>
|
||
|
<dd>The materialized query table will not be used for query optimization.
|
||
|
The table can still be queried directly.
|
||
|
</dd>
|
||
|
</dl>
|
||
|
</dd>
|
||
|
</dl>
|
||
|
</dd>
|
||
|
<dt class="bold">SET <var class="pv">refreshable-table-alteration</var></dt>
|
||
|
<dd>Changes how the table is maintained or whether the table can be used
|
||
|
in query optimization.
|
||
|
<dl class="parml">
|
||
|
<dt class="bold">MAINTAINED BY USER</dt>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold">REFRESH DEFERRED</dt>
|
||
|
<dd>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.
|
||
|
</dd>
|
||
|
<dt class="bold">ENABLE QUERY OPTIMIZATION <span class="base">or</span> DISABLE
|
||
|
QUERY OPTIMIZATION</dt>
|
||
|
<dd>Specifies whether this materialized query table can be used for query
|
||
|
optimization.
|
||
|
<dl class="parml">
|
||
|
<dt class="bold">ENABLE QUERY OPTIMIZATION</dt>
|
||
|
<dd>The materialized query table can be used for query optimization.
|
||
|
</dd>
|
||
|
<dt class="bold">DISABLE QUERY OPTIMIZATION</dt>
|
||
|
<dd>The materialized query table will not be used for query optimization.
|
||
|
The table can still be queried directly.
|
||
|
</dd>
|
||
|
</dl>
|
||
|
</dd>
|
||
|
</dl>
|
||
|
</dd>
|
||
|
</dl>
|
||
|
<a name="wq1106"></a>
|
||
|
<h3 id="wq1106"><a href="rbafzmst02.htm#ToC_781">DROP MATERIALIZED QUERY</a></h3><a id="idx1479" name="idx1479"></a>
|
||
|
<p>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.</p>
|
||
|
<a name="wq1107"></a>
|
||
|
<h3 id="wq1107"><a href="rbafzmst02.htm#ToC_782">ACTIVATE NOT LOGGED INITIALLY</a></h3><a id="idx1480" name="idx1480"></a><a id="idx1481" name="idx1481"></a>
|
||
|
<p>Activates the NOT LOGGED INITIALLY attribute of the table for this current
|
||
|
unit of work.</p>
|
||
|
<p>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).</p>
|
||
|
<p>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).</p>
|
||
|
<p>ACTIVATE NOT LOGGED INITIALLY is not allowed in a transaction if data change
|
||
|
operations are pending for <var class="pv">table-name</var> or cursors are currently open
|
||
|
under commit that reference <var class="pv">table-name</var>.</p>
|
||
|
<p>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).</p>
|
||
|
<p></p>
|
||
|
<dl class="parml">
|
||
|
<dt class="bold">WITH EMPTY TABLE</dt><a id="idx1482" name="idx1482"></a>
|
||
|
<dd>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.
|
||
|
<p>WITH EMPTY TABLE cannot be specified for a materialized query table
|
||
|
or for a parent in a referential constraint.</p>
|
||
|
<p>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.</p>
|
||
|
</dd>
|
||
|
</dl>
|
||
|
<a name="wq1108"></a>
|
||
|
<h3 id="wq1108"><a href="rbafzmst02.htm#ToC_783">VOLATILE or NOT VOLATILE</a></h3>
|
||
|
<p>Indicates to the optimizer whether or not the cardinality of table <var class="pv">table-name</var> 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.</p>
|
||
|
<dl class="parml">
|
||
|
<dt class="bold">VOLATILE</dt><a id="idx1483" name="idx1483"></a>
|
||
|
<dd>Specifies that the cardinality of <var class="pv">table-name</var> can vary significantly
|
||
|
at run time, from empty to large. To access the table, the optimizer will
|
||
|
typically use an index, if possible.
|
||
|
</dd>
|
||
|
<dt class="bold">NOT VOLATILE</dt><a id="idx1484" name="idx1484"></a>
|
||
|
<dd>Specifies that the cardinality of <var class="pv">table-name</var> 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.
|
||
|
</dd>
|
||
|
</dl>
|
||
|
<a name="wq1109"></a>
|
||
|
<h3 id="wq1109"><a href="rbafzmst02.htm#ToC_784">Notes</a></h3>
|
||
|
<p><span class="bold">Column references:</span> A column can only be referenced <span class="italic">once</span> 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.</p>
|
||
|
<p><span class="bold">Order of operations:</span> The order of operations within
|
||
|
an ALTER TABLE statement is: </p>
|
||
|
<ul>
|
||
|
<li>drop constraints</li>
|
||
|
<li>drop materialized query table</li>
|
||
|
<li>drop partition</li>
|
||
|
<li>drop partitioning</li>
|
||
|
<li>drop columns for which the RESTRICT option was specified</li>
|
||
|
<li>alter all other column definitions
|
||
|
<ul>
|
||
|
<li>drop columns for which the CASCADE option was specified</li>
|
||
|
<li>alter column drop attributes (for example, DROP DEFAULT)</li>
|
||
|
<li>alter column alter attributes</li>
|
||
|
<li>alter column add attributes</li>
|
||
|
<li>add columns</li></ul></li>
|
||
|
<li>alter partition</li>
|
||
|
<li>add or alter materialized query table</li>
|
||
|
<li>add partition or add partitioning</li>
|
||
|
<li>add constraints</li></ul>
|
||
|
<p>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.</p>
|
||
|
<p><span class="bold">QTEMP considerations:</span> 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.</p>
|
||
|
<p><span class="bold">Authority checking:</span> 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.</p>
|
||
|
<p><span class="bold">Backup recommendation:</span> It is strongly recommended
|
||
|
that a current backup of the table and dependent views and logical files exist
|
||
|
prior to altering a table.</p>
|
||
|
<p><span class="bold">Performance considerations:</span> The following performance
|
||
|
considerations apply to an ALTER TABLE statement when adding, altering, or
|
||
|
dropping columns from a table: </p>
|
||
|
<ul>
|
||
|
<li>The data in the table may be copied.<sup class="fn"><a id="wq1110" name="wq1110" href="rbafzmstatabl.htm#wq1111">56</a></sup>
|
||
|
<p>Adding
|
||
|
and dropping columns require the data to be copied.</p>
|
||
|
<p>Altering a column
|
||
|
usually requires the data to be copied. The data does not need to be copied,
|
||
|
however, if the alter only includes the following changes:</p>
|
||
|
<ul>
|
||
|
<li>The length attribute of a VARCHAR column is increasing and the current
|
||
|
length attribute is greater than 20.</li>
|
||
|
<li>The length attribute of a VARGRAPHIC column is increasing and the current
|
||
|
length attribute is greater than 10.</li>
|
||
|
<li>The allocated length of a VARCHAR column is changing and the current and
|
||
|
new allocated lengths are both less than or equal to 20.</li>
|
||
|
<li>The allocated length of a VARGRAPHIC column is changing and the current
|
||
|
and new allocated lengths are both less than or equal to 10.</li>
|
||
|
<li>The CCSID of a column is changing but no conversion is necessary between
|
||
|
the old and new CCSID. For example, if one CCSID is 65535, no data conversion
|
||
|
is necessary.</li>
|
||
|
<li>The default value is changing, and the length of the default value is
|
||
|
not greater than the current allocated length.</li>
|
||
|
<li>DROP DEFAULT is specified.</li>
|
||
|
<li>DROP NOT NULL is specified, but at least one nullable column will still
|
||
|
exist in the table after the alter table is complete.</li></ul></li>
|
||
|
<li>Indexes may need to be rebuilt.<sup class="fn"><a id="wq1112" name="wq1112" href="rbafzmstatabl.htm#wq1113">57</a></sup>
|
||
|
<p>An index does not
|
||
|
need to be rebuilt when columns are added to a table or when columns are dropped
|
||
|
or altered and those columns are not referenced in the index key.</p>
|
||
|
<p>Altering
|
||
|
a column that is used in the key of an index or constraint usually requires
|
||
|
the index to be rebuilt. The index does not need to be rebuilt, however, in
|
||
|
the following cases:</p>
|
||
|
<p></p>
|
||
|
<ul>
|
||
|
<li>The length attribute of a VARCHAR or VARGRAPHIC key is increasing.</li>
|
||
|
<li>The CCSID of a column is changing but no conversion is necessary between
|
||
|
the old and new CCSID. For example, if one CCSID is 65535.</li></ul></li></ul>
|
||
|
<p><span class="bold">Altering materialized query tables:</span> 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.</p>
|
||
|
<p>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.</p>
|
||
|
<p><span class="bold">Syntax alternatives:</span> The following syntax is supported
|
||
|
for compatibility to prior releases. The syntax is non-standard and should
|
||
|
not be used:</p>
|
||
|
<ul>
|
||
|
<li>If an ADD constraint is the first clause of the ALTER TABLE
|
||
|
statement, the ADD keyword is optional, but strongly recommended. Otherwise,
|
||
|
it is required.</li>
|
||
|
<li><var class="pv">constraint-name</var> (without the CONSTRAINT keyword) may be specified
|
||
|
following the FOREIGN KEY keywords in a <var class="pv">referential-constraint</var>.</li>
|
||
|
<li>PART is a synonym for PARTITION.</li>
|
||
|
<li>PARTITION <var class="pv">partition-number</var> may be specified instead of PARTITION <var class="pv">partition-name</var>. A <var class="pv">partition-number</var> must not identify an existing
|
||
|
partition of the table or a partition that was previously specified in the
|
||
|
ALTER TABLE statement.
|
||
|
<p>If a <var class="pv">partition-number</var> is not specified,
|
||
|
a unique partition number is generated by the database manager.</p></li>
|
||
|
<li>VALUES is a synonym for ENDING AT.</li>
|
||
|
<li>SET MATERIALIZED QUERY AS DEFINITION ONLY is a synonym for DROP MATERIALIZED
|
||
|
QUERY.</li>
|
||
|
<li>SET SUMMARY AS DEFINITION ONLY is a synonym for DROP MATERIALIZED QUERY</li>
|
||
|
<li>SET MATERIALIZED QUERY AS (<var class="pv">select-statement</var>) is a synonym for
|
||
|
ADD MATERIALIZED QUERY (<var class="pv">select-statement</var>)</li>
|
||
|
<li>SET SUMMARY AS (<var class="pv">select-statement</var>) is a synonym for ADD MATERIALIZED
|
||
|
QUERY (<var class="pv">select-statement</var>)</li></ul>
|
||
|
<a name="wq1114"></a>
|
||
|
<h3 id="wq1114"><a href="rbafzmst02.htm#ToC_785">Cascaded Effects</a></h3>
|
||
|
<p>Adding a column has no cascaded effects to SQL views or most logical
|
||
|
files.<sup class="fn"><a href="rbafzmstatabl.htm#fn23">58</a></sup> 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.</p>
|
||
|
<p>Dropping or altering a column may cause several cascaded effects. <a href="rbafzmstatabl.htm#dropcas">Table 46</a> lists the cascaded effects of dropping a column.</p>
|
||
|
<a name="dropcas"></a>
|
||
|
<table id="dropcas" width="100%" summary="" border="1" frame="border" rules="all">
|
||
|
<caption>Table 46. Cascaded effects of dropping a column</caption>
|
||
|
<thead valign="bottom">
|
||
|
<tr>
|
||
|
<th id="wq1115" width="20%" align="left" valign="bottom">Operation</th>
|
||
|
<th id="wq1116" width="39%" align="left" valign="bottom">RESTRICT Effect</th>
|
||
|
<th id="wq1117" width="40%" align="left" valign="bottom">CASCADE Effect</th>
|
||
|
</tr>
|
||
|
</thead>
|
||
|
<tbody valign="top">
|
||
|
<tr>
|
||
|
<td align="left" valign="top" headers="wq1115">Drop of a column referenced by a view</td>
|
||
|
<td align="left" valign="top" headers="wq1116">The drop of the column is not allowed.</td>
|
||
|
<td align="left" valign="top" headers="wq1117">The view and all views dependent on that
|
||
|
view are dropped.</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td align="left" valign="top" headers="wq1115">Drop of a column referenced by a non-view
|
||
|
logical file</td>
|
||
|
<td align="left" valign="top" headers="wq1116">The drop is allowed, and the column is dropped
|
||
|
from the logical file if:
|
||
|
<ul>
|
||
|
<li>The logical file shares a format with the file being altered, and</li>
|
||
|
<li>The dropped column is not used as a key field or in select/omit specifications,
|
||
|
and</li>
|
||
|
<li>That format is not used again in the logical file with another based-on
|
||
|
file.</li></ul>Otherwise, the drop of the column is not allowed.</td>
|
||
|
<td align="left" valign="top" headers="wq1117">The drop is allowed, and the column is dropped
|
||
|
from the logical file if:
|
||
|
<ul>
|
||
|
<li>The logical file shares a format with the file being altered, and</li>
|
||
|
<li>The dropped column is not used as a key field or in select or omit specifications,
|
||
|
and</li>
|
||
|
<li>That format is not used again in the logical file with another based-on
|
||
|
file.</li></ul>Otherwise, the logical file is dropped.</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td align="left" valign="top" headers="wq1115">Drop of a column referenced in the key of
|
||
|
an index</td>
|
||
|
<td align="left" valign="top" headers="wq1116">The drop of the index is not allowed.</td>
|
||
|
<td align="left" valign="top" headers="wq1117">The index is dropped.</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td align="left" valign="top" headers="wq1115">Drop of a column referenced in a unique constraint</td>
|
||
|
<td align="left" valign="top" headers="wq1116">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.
|
||
|
<p>Otherwise, the drop of the column
|
||
|
is not allowed.</p></td>
|
||
|
<td align="left" valign="top" headers="wq1117">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).</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td align="left" valign="top" headers="wq1115">Drop of a column referenced in a referential
|
||
|
constraint</td>
|
||
|
<td align="left" valign="top" headers="wq1116">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.
|
||
|
<p>Otherwise, the drop of the column is not allowed.</p></td>
|
||
|
<td align="left" valign="top" headers="wq1117">The referential constraint is dropped. (Hence,
|
||
|
the index used by the foreign key is also dropped).</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td align="left" valign="top" headers="wq1115">Drop of a column referenced in a trigger</td>
|
||
|
<td align="left" valign="top" headers="wq1116">The drop of the column is not allowed.</td>
|
||
|
<td align="left" valign="top" headers="wq1117">The trigger is dropped.</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td align="left" valign="top" headers="wq1115">Drop of a column referenced in an MQT</td>
|
||
|
<td align="left" valign="top" headers="wq1116">The drop of the column is not allowed.</td>
|
||
|
<td align="left" valign="top" headers="wq1117">The MQT is dropped.</td>
|
||
|
</tr>
|
||
|
</tbody>
|
||
|
</table>
|
||
|
<p><a href="rbafzmstatabl.htm#alterca">Table 47</a> 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.)</p>
|
||
|
<a name="alterca"></a>
|
||
|
<table id="alterca" width="100%" summary="" border="1" frame="border" rules="all">
|
||
|
<caption>Table 47. Cascaded effects of altering a column</caption>
|
||
|
<thead valign="bottom">
|
||
|
<tr>
|
||
|
<th id="wq1118" width="20%" align="left" valign="bottom">Operation</th>
|
||
|
<th id="wq1119" width="80%" align="left" valign="bottom">Effect</th>
|
||
|
</tr>
|
||
|
</thead>
|
||
|
<tbody valign="top">
|
||
|
<tr>
|
||
|
<td align="left" valign="top" headers="wq1118">Alter of a column referenced by a view</td>
|
||
|
<td align="left" valign="top" headers="wq1119">The alter is allowed.
|
||
|
<p>The views that are
|
||
|
dependent on the table will be recreated. The new column attributes will be
|
||
|
used when recreating the views.</p></td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td align="left" valign="top" headers="wq1118">Alter of a column referenced by a non-view
|
||
|
logical file</td>
|
||
|
<td align="left" valign="top" headers="wq1119">The alter is allowed.
|
||
|
<p>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.</p>
|
||
|
<p>Otherwise, the new column
|
||
|
attributes will not be used when recreating the logical file. Instead, the
|
||
|
current logical file attributes are used.</p></td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td align="left" valign="top" headers="wq1118">Alter of a column referenced in the key of
|
||
|
an index.</td>
|
||
|
<td align="left" valign="top" headers="wq1119">The alter is allowed. (Hence, the index will
|
||
|
usually be rebuilt.)</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td align="left" valign="top" headers="wq1118">Alter of a column referenced in a unique
|
||
|
constraint</td>
|
||
|
<td align="left" valign="top" headers="wq1119">The alter is allowed. (Hence, the index will
|
||
|
usually be rebuilt.)
|
||
|
<p>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.</p></td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td align="left" valign="top" headers="wq1118">Alter of a column referenced in a referential
|
||
|
constraint</td>
|
||
|
<td align="left" valign="top" headers="wq1119">The alter is allowed.
|
||
|
<ul>
|
||
|
<li>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.)</li>
|
||
|
<li>If the referential constraint is in the enabled state, the constraint
|
||
|
is placed in the defined and check-pending state.</li></ul></td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td align="left" valign="top" headers="wq1118">Alter of a column referenced in a trigger</td>
|
||
|
<td align="left" valign="top" headers="wq1119">The trigger is preserved.</td>
|
||
|
</tr>
|
||
|
<tr>
|
||
|
<td align="left" valign="top" headers="wq1118">Alter of a column referenced in an MQT</td>
|
||
|
<td align="left" valign="top" headers="wq1119">The MQT is recreated to include the new attributes.</td>
|
||
|
</tr>
|
||
|
</tbody>
|
||
|
</table>
|
||
|
<a name="wq1120"></a>
|
||
|
<h3 id="wq1120"><a href="rbafzmst02.htm#ToC_786">Examples</a></h3>
|
||
|
<p><span class="italic">Example 1:</span> Add a new column named RATING, which
|
||
|
is one character long, to the DEPARTMENT table. </p>
|
||
|
<pre class="xmp"> <span class="bold">ALTER TABLE</span> DEPARTMENT
|
||
|
<span class="bold">ADD</span> RATING <span class="bold">CHAR</span></pre>
|
||
|
<p><span class="italic">Example 2:</span> 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.</p>
|
||
|
<pre class="xmp"> <span class="bold">ALTER TABLE</span> EMPLOYEE
|
||
|
<span class="bold">ADD</span> PICTURE_THUMBNAIL <span class="bold"> BLOB(</span>1K<span class="bold">)</span></pre>
|
||
|
<p><span class="italic">Example 3:</span> Assume a new table EQUIPMENT has been
|
||
|
created with the following columns: </p>
|
||
|
<dl>
|
||
|
<dt class="bold"> EQUIP_NO </dt>
|
||
|
<dd>INT
|
||
|
</dd>
|
||
|
<dt class="bold"> EQUIP_DESC </dt>
|
||
|
<dd>VARCHAR(50)
|
||
|
</dd>
|
||
|
<dt class="bold"> LOCATION </dt>
|
||
|
<dd>VARCHAR(50)
|
||
|
</dd>
|
||
|
<dt class="bold"> EQUIP_OWNER </dt>
|
||
|
<dd>CHAR(3)
|
||
|
</dd>
|
||
|
</dl><p class="indatacontent"> 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. </p>
|
||
|
<pre class="xmp"> <span class="bold">ALTER TABLE</span> EQUIPMENT
|
||
|
<span class="bold">FOREIGN KEY</span> DEPTQUIP <span class="bold">(</span>EQUIP_OWNER<span class="bold">)
|
||
|
REFERENCES</span> DEPARTMENT
|
||
|
<span class="bold"> ON DELETE SET NULL</span></pre><p class="indatacontent">Change the default value
|
||
|
for the EQUIP_OWNER column to 'ABC'. </p>
|
||
|
<pre class="xmp"> <span class="bold">ALTER TABLE</span> EQUIPMENT
|
||
|
<span class="bold">ALTER COLUMN</span> EQUIP_OWNER
|
||
|
<span class="bold">SET DEFAULT</span> 'ABC'</pre><p class="indatacontent">Drop the LOCATION column.
|
||
|
Also drop any views, indexes, or constraints that are built on that column. </p>
|
||
|
<pre class="xmp"> <span class="bold">ALTER TABLE</span> EQUIPMENT
|
||
|
<span class="bold">DROP COLUMN</span> LOCATION <span class="bold">CASCADE</span></pre><p class="indatacontent">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. </p>
|
||
|
<pre class="xmp"> <span class="bold">ALTER TABLE</span> EQUIPMENT
|
||
|
<span class="bold">ADD COLUMN</span> SUPPLIER INT
|
||
|
<span class="bold">DROP COLUMN</span> LOCATION
|
||
|
<span class="bold">ADD UNIQUE</span> SUPPLIER
|
||
|
<span class="bold">ADD PRIMARY KEY</span> EQUIP_NO</pre><p class="indatacontent">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. </p>
|
||
|
<pre class="xmp"> <span class="bold">ALTER TABLE</span> EQUIPMENT
|
||
|
<span class="bold">ALTER COLUMN</span> EQUIP_DESC
|
||
|
<span class="bold">SET DATA TYPE</span> VARCHAR(60)</pre>
|
||
|
<p><span class="italic">Example 4:</span> 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. </p>
|
||
|
<pre class="xmp"> <span class="bold">ALTER TABLE</span> EMPLOYEE
|
||
|
<span class="bold">ADD CONSTRAINT</span> REVENUE
|
||
|
<span class="bold">CHECK</span> (SALARY + COMM > 30000)</pre>
|
||
|
<p><span class="italic">Example 5:</span> Alter EMPLOYEE table. Drop the constraint
|
||
|
REVENUE which was previously defined. </p>
|
||
|
<pre class="xmp"> <span class="bold">ALTER TABLE</span> EMPLOYEE
|
||
|
<span class="bold">DROP CONSTRAINT</span> REVENUE </pre>
|
||
|
<p><span class="italic">Example 6:</span> Alter the EMPLOYEE table. Alter the
|
||
|
column PHONENO to accept up to 20 characters for a phone number. </p>
|
||
|
<pre class="xmp"> <span class="bold">ALTER TABLE</span> EMPLOYEE
|
||
|
<span class="bold">ALTER COLUMN</span> PHONENO <span class="bold">SET DATA TYPE VARCHAR (20)</span></pre>
|
||
|
<p><span class="italic">Example 7:</span> Alter the base table TRANSCOUNT to
|
||
|
a materialized query table. The result of the <var class="pv">select-statement</var> must
|
||
|
provide a set of columns that match the columns in the existing table (same
|
||
|
number of columns and compatible attributes).</p>
|
||
|
<pre class="xmp"> <span class="bold">ALTER TABLE</span> TRANSCOUNT
|
||
|
<span class="bold">ADD MATERIALIZED QUERY</span>
|
||
|
<span class="bold">(SELECT</span> ACCTID, LOCID, YEAR, <span class="bold">COUNT(*) AS</span> CNT
|
||
|
<span class="bold">FROM</span> TRANS
|
||
|
<span class="bold">GROUP BY</span> ACCTID, LOCID, YEAR <span class="bold">)</span>
|
||
|
<span class="bold">DATA INITIALLY DEFERRED</span>
|
||
|
<span class="bold">REFRESH DEFERRED</span>
|
||
|
<span class="bold">MAINTAINED BY USER</span> </pre><a id="idx1485" name="idx1485"></a><a id="idx1486" name="idx1486"></a>
|
||
|
<hr /><div class="fnnum"><a id="trgdep" name="trgdep">55</a>.</div>
|
||
|
<div class="fntext">A trigger is dependent on the column if it is referenced in the
|
||
|
UPDATE OF column list or anywhere in the triggered action.</div><div class="fnnum"><a id="wq1111" name="wq1111" href="rbafzmstatabl.htm#wq1110">56</a>.</div>
|
||
|
<div class="fntext">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.</div><div class="fnnum"><a id="wq1113" name="wq1113" href="rbafzmstatabl.htm#wq1112">57</a>.</div>
|
||
|
<div class="fntext">Any indexes that need to be rebuilt
|
||
|
are rebuilt asynchronously by database server jobs.</div><div class="fnnum"><a id="fn23" name="fn23">58</a>.</div>
|
||
|
<div class="fntext">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).</div>
|
||
|
<br />
|
||
|
<hr /><br />
|
||
|
[ <a href="#Top_Of_Page">Top of Page</a> | <a href="rbafzmstasequence.htm">Previous Page</a> | <a href="rbafzmstbegdcl.htm">Next Page</a> | <a href="rbafzmst02.htm#wq1">Contents</a> |
|
||
|
<a href="rbafzmstindex.htm#index">Index</a> ]
|
||
|
|
||
|
<a id="Bot_Of_Page" name="Bot_Of_Page"></a>
|
||
|
</body>
|
||
|
</html>
|