2447 lines
140 KiB
HTML
2447 lines
140 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="CREATE TABLE statement, CREATE TABLE,
|
|
SQL statements, creating, table, in CREATE TABLE statement, table-name,
|
|
column-name, system-column-name, FOR COLUMN clause, system column name,
|
|
description, data type, in CREATE TABLE, data-type, built-in-type,
|
|
data type for CREATE TABLE, SMALLINT, INTEGER, BIGINT, DECIMAL, NUMERIC, FLOAT,
|
|
REAL, DOUBLE PRECISION, CHAR, VARCHAR, CLOB, GRAPHIC, VARGRAPHIC, DBCLOB, BINARY,
|
|
VARBINARY, BLOB, DATE, TIME, TIMESTAMP, DATALINK, ROWID, distinct-type,
|
|
ALLOCATE clause, FOR BIT DATA clause, FOR SBCS DATA clause,
|
|
FOR MIXED DATA clause, CCSID clause, normalization, combining characters,
|
|
WITH DEFAULT clause, DEFAULT clause, CURRENT_DATE, CURRENT_TIME,
|
|
CURRENT_TIMESTAMP, cast-function, constant, USER clause, GENERATED, IDENTITY,
|
|
datalink-options, NOT NULL clause, CONSTRAINT clause, constraint-name,
|
|
PRIMARY KEY clause, UNIQUE clause, REFERENCES clause, CHECK clause, LIKE clause,
|
|
AS subquery clause, materialized query table, automatic summary table,
|
|
INCLUDING clause, EXCLUDING clause, USING clause, key, of CREATE TABLE statement,
|
|
referential-constraint clause, FOREIGN KEY clause,
|
|
in ON DELETE clause of CREATE TABLE statement, DELETE clause,
|
|
RESTRICT delete rule, CASCADE delete rule, SET NULL delete rule,
|
|
keyword SET NULL delete rule, NULL, NO ACTION delete rule,
|
|
SET DEFAULT delete rule, in ON UPDATE clause of CREATE TABLE statement, UPDATE,
|
|
RESTRICT update rule, NO ACTION update rule, NOT LOGGED INITIALLY, VOLATILE,
|
|
NOT VOLATILE, nodegroup, syntax, distributed tables, partitioning key,
|
|
partition by range, NULLS LAST, NULLS FIRST, partition name, partition by hash,
|
|
number of hash partitions, LONG VARCHAR, LONG VARGRAPHIC, system name generation,
|
|
rules, table name generation" />
|
|
<title>CREATE 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="hctabl"></a>
|
|
<h2 id="hctabl"><a href="rbafzmst02.htm#ToC_925">CREATE TABLE</a></h2><a id="idx2046" name="idx2046"></a><a id="idx2047" name="idx2047"></a><a id="idx2048" name="idx2048"></a>
|
|
<a name="ctabl"></a>
|
|
<p id="ctabl">The CREATE TABLE statement defines a table at the current server.
|
|
The definition must include its name and the names and attributes of its columns.
|
|
The definition may include other attributes of the table such as primary key.</p>
|
|
<a name="wq1300"></a>
|
|
<h3 id="wq1300"><a href="rbafzmst02.htm#ToC_926">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="wq1301"></a>
|
|
<h3 id="wq1301"><a href="rbafzmst02.htm#ToC_927">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>The privilege to create in the schema. For more information, see <a href="rbafzmstauthown.htm#createin">Privileges necessary to create in a schema</a>.</li>
|
|
<li>Administrative authority</li></ul>
|
|
<p>The privileges held by the authorization ID of the statement must include
|
|
at least one of the following: </p>
|
|
<ul>
|
|
<li>The following system authorities:
|
|
<ul>
|
|
<li>*USE to the Create Physical File (CRTPF) command</li>
|
|
<li>*CHANGE to the data dictionary if the library into which the table is
|
|
created is an SQL schema with a data dictionary</li></ul></li>
|
|
<li>Administrative authority</li></ul>
|
|
<p>If SQL names are specified and a user profile exists that has the same
|
|
name as the library into which the table is created, and that name is different
|
|
from the authorization ID of the statement, then the privileges held by the
|
|
authorization ID of the statement must include at least one of the following: </p>
|
|
<ul>
|
|
<li>The system authority *ADD to the user profile with that name</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 the LIKE clause or <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="cr8tbl"></a>
|
|
<h3 id="cr8tbl"><a href="rbafzmst02.htm#ToC_928">Syntax</a></h3>
|
|
<a href="rbafzmsthctabl.htm#ctbldes"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
|
|
<a name="wq1302"></a>
|
|
<div class="fignone" id="wq1302">
|
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn303.htm"
|
|
border="0" /></span><a href="#skipsyn-302"><img src="c.gif" alt="Skip visual syntax diagram"
|
|
border="0" /></a> .-,------------------------------------------.
|
|
V |
|
|
>>-CREATE TABLE--<span class="italic">table-name</span>--+-(----+-<span class="italic">column-definition</span>----------------------+-+--)-+-->
|
|
| +-LIKE--+-<span class="italic">table-name</span>-+--+--------------+-+ |
|
|
| | '-<span class="italic">view-name</span>--' '-<span class="italic">copy-options</span>-' | |
|
|
| +-<span class="italic">unique-constraint</span>----------------------+ |
|
|
| +-<span class="italic">referential-constraint</span>-----------------+ |
|
|
| '-<span class="italic">check-constraint</span>-----------------------' |
|
|
+-LIKE--+-<span class="italic">table-name</span>-+--+--------------+---------------+
|
|
| '-<span class="italic">view-name</span>--' '-<span class="italic">copy-options</span>-' |
|
|
'-<span class="italic">as-subquery-clause</span>-----------------------------------'
|
|
|
|
>--+----------------------+------------------------------------->
|
|
'-<span>NOT LOGGED INITIALLY</span>-'
|
|
|
|
.-<span>CARDINALITY</span>-.
|
|
.-<span>NOT VOLATILE</span>--+-------------+-.
|
|
>--+-------------------------------+--+---------------------+--><
|
|
| .-<span>CARDINALITY</span>-. | +-<span class="italic">distribution-clause</span>-+
|
|
'-<span>VOLATILE</span>--+-------------+-----' '-<span class="italic">partitioning-clause</span>-'
|
|
|
|
</pre>
|
|
<a name="skipsyn-302" id="skipsyn-302"></a></div>
|
|
<a name="wq1303"></a>
|
|
<div class="fignone" id="wq1303">
|
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn304.htm"
|
|
border="0" /></span><a href="#skipsyn-303"><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-303" id="skipsyn-303"></a>
|
|
<a name="wq1304"></a>
|
|
<div class="notelisttitle" id="wq1304">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="wq1306"></a>
|
|
<div class="fignone" id="wq1306">
|
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn305.htm"
|
|
border="0" /></span><a href="#skipsyn-304"><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>-' |
|
|
| .-(--53--)------. |
|
|
+-+-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-304" id="skipsyn-304"></a></div>
|
|
<a name="wq1307"></a>
|
|
<div class="fignone" id="wq1307">
|
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn306.htm"
|
|
border="0" /></span><a href="#skipsyn-305"><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------------------------------------+
|
|
| (1) |
|
|
'-<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>----------------. (2) | |
|
|
'-(----+-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-305" id="skipsyn-305"></a>
|
|
<a name="wq1308"></a>
|
|
<div class="notelisttitle" id="wq1308">Notes:</div>
|
|
<ol type="1">
|
|
<li>This form of the DEFAULT value can only be used with columns that
|
|
are defined as a distinct type.</li>
|
|
<li>The same clause must not be specified more than once.</li>
|
|
</ol></div>
|
|
<a name="wq1310"></a>
|
|
<div class="fignone" id="wq1310">
|
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn307.htm"
|
|
border="0" /></span><a href="#skipsyn-306"><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-306" id="skipsyn-306"></a>
|
|
<a name="wq1311"></a>
|
|
<div class="notelisttitle" id="wq1311">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="wq1313"></a>
|
|
<div class="fignone" id="wq1313">
|
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn308.htm"
|
|
border="0" /></span><a href="#skipsyn-307"><img src="c.gif" alt="Skip visual syntax diagram"
|
|
border="0" /></a>as-subquery-clause:
|
|
|
|
|--+------------------------------------------------------------+-->
|
|
'-(--<span class="italic">column-name</span>--+-------------------------------------+--)-'
|
|
| .-COLUMN-. |
|
|
'-FOR--+--------+--<span class="italic">system-column-name</span>-'
|
|
|
|
>--AS--(--<span class="italic">select-statement</span>--)--+-+-WITH NO DATA-+--+--------------+-+--|
|
|
| '-WITH DATA----' '-<span class="italic">copy-options</span>-' |
|
|
'-<span class="italic">refreshable-table-options</span>----------'
|
|
|
|
copy-options:
|
|
|
|
.-<span>COLUMN ATTRIBUTES</span>-. .-<span>COLUMN</span>-. (1)
|
|
|----+-<span>EXCLUDING IDENTITY</span>--+-------------------+-+--+-<span>EXCLUDING</span>--+--------+--<span>DEFAULTS</span>-+---------|
|
|
| .-<span>COLUMN ATTRIBUTES</span>-. | | .-<span>COLUMN</span>-. |
|
|
'-<span>INCLUDING IDENTITY</span>--+-------------------+-' +-<span>INCLUDING</span>--+--------+--<span>DEFAULTS</span>-+
|
|
'-<span>USING TYPE DEFAULTS</span>-------------'
|
|
|
|
refreshable-table-options:
|
|
|
|
.-----------------------------------------.
|
|
V (2) |
|
|
|--+-DATA INITIALLY DEFERRED--+--REFRESH DEFERRED---------+-MAINTAINED BY USER-------------+-+--|
|
|
'-DATA INITIALLY IMMEDIATE-' | .-ENABLE QUERY OPTIMIZATION--. |
|
|
'-+-DISABLE QUERY OPTIMIZATION-+-'
|
|
|
|
</pre>
|
|
<a name="skipsyn-307" id="skipsyn-307"></a>
|
|
<a name="wq1314"></a>
|
|
<div class="notelisttitle" id="wq1314">Notes:</div>
|
|
<ol type="1">
|
|
<li>The clauses can be specified in any order.</li>
|
|
<li>The same clause must not be specified more than once. MAINTAINED
|
|
BY USER must be specified.</li>
|
|
</ol></div>
|
|
<a name="wq1316"></a>
|
|
<div class="fignone" id="wq1316">
|
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn309.htm"
|
|
border="0" /></span><a href="#skipsyn-308"><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>--)---------------------------------|
|
|
|
|
distribution-clause:
|
|
|
|
|--IN----<span class="italic">nodegroup-name</span>----+-------------------------------------------+--|
|
|
| .-,-----------. |
|
|
| V | |
|
|
'-DISTRIBUTE BY HASH--(----<span class="italic">column-name</span>-+--)-'
|
|
|
|
</pre>
|
|
<a name="skipsyn-308" id="skipsyn-308"></a>
|
|
<a name="wq1317"></a>
|
|
<div class="notelisttitle" id="wq1317">Notes:</div>
|
|
<ol type="1">
|
|
<li>The ON DELETE and ON UPDATE clauses may be specified in either order.</li>
|
|
</ol></div>
|
|
<a name="wq1319"></a>
|
|
<div class="fignone" id="wq1319">
|
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn310.htm"
|
|
border="0" /></span><a href="#skipsyn-309"><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-309" id="skipsyn-309"></a></div>
|
|
<a name="ctbldes"></a>
|
|
<h3 id="ctbldes"><a href="rbafzmst02.htm#ToC_929">Description</a></h3>
|
|
<dl class="parml">
|
|
<dt class="bold"><var class="pv">table-name</var></dt>
|
|
<dd>Names the table. <a id="idx2049" name="idx2049"></a> The name, including the implicit or explicit
|
|
qualifier, must not identify an alias, file, index, table, or view that already
|
|
exists at the current server.
|
|
<p>If SQL names were specified, the table will
|
|
be created in the schema specified by the implicit or explicit qualifier.</p>
|
|
<p>If system names were specified, the table will be created in the schema
|
|
that is specified by the qualifier. If not qualified:</p>
|
|
<ul>
|
|
<li>If the value of the CURRENT SCHEMA special register is *LIBL, the table
|
|
will be created in the current library (*CURLIB).</li>
|
|
<li>Otherwise, the table will be created in the current schema.</li></ul>
|
|
</dd>
|
|
</dl>
|
|
<a name="wq1320"></a>
|
|
<h3 id="wq1320"><a href="rbafzmst02.htm#ToC_930">column-definition</a></h3>
|
|
<p>Defines the attributes of a column. There must be at least one column definition
|
|
and no more than 8000 column definitions.</p>
|
|
<p>The sum of the row buffer byte counts of the columns must not be greater
|
|
than 32766 or, if a VARCHAR or VARGRAPHIC column is specified, 32740. Additionally,
|
|
if a LOB is specified, the sum of the row data 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="idx2050" name="idx2050"></a>
|
|
<dd>Names a column of the table. Do not qualify <var class="pv">column-name</var> and
|
|
do not use the same name for more than one column of the table or for a <var class="pv">system-column-name</var> of the table.
|
|
</dd>
|
|
<dt class="bold">FOR COLUMN <var class="pv">system-column-name</var> </dt><a id="idx2051" name="idx2051"></a><a id="idx2052" name="idx2052"></a>
|
|
<dd>Provides an i5/OS name for the column. Do not use the same name for
|
|
more than one column of the table or for a column-name of the table. <a id="idx2053" name="idx2053"></a>
|
|
<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="idx2054" name="idx2054"></a><a id="idx2055" name="idx2055"></a>
|
|
<dd>Specifies the data type of the column.
|
|
</dd>
|
|
<dt class="bold"><var class="pv">built-in-type</var> </dt><a id="idx2056" name="idx2056"></a><a id="idx2057" name="idx2057"></a>
|
|
<dd>For <var class="pv">built-in-types</var>, use:
|
|
<dl class="parml">
|
|
<dt class="bold">SMALLINT </dt><a id="idx2058" name="idx2058"></a>
|
|
<dd>For a small integer.
|
|
</dd>
|
|
<dt class="bold">INTEGER <span class="base">or</span> INT </dt><a id="idx2059" name="idx2059"></a>
|
|
<dd>For a large integer.
|
|
</dd>
|
|
<dt class="bold">BIGINT </dt><a id="idx2060" name="idx2060"></a>
|
|
<dd>For a big integer.
|
|
</dd>
|
|
<dt class="bold">DECIMAL(<var class="pv">integer</var>,<var class="pv">integer</var>) <span class="base">or</span> DEC(<var class="pv">integer</var>,<var class="pv">integer</var>)</dt>
|
|
<dt class="bold">DECIMAL(<var class="pv">integer</var>) <span class="base">or</span> DEC(<var class="pv">integer</var>)</dt>
|
|
<dt class="bold">DECIMAL <span class="base">or</span> DEC</dt><a id="idx2061" name="idx2061"></a>
|
|
<dd>For a packed decimal number. The first integer is the precision of the
|
|
number; that is, the total number of digits; it can range from 1 to 63. The
|
|
second integer is the scale of the number (the number of digits to the right
|
|
of the decimal point). It can range from 0 to the precision of the number.
|
|
<p>You can use DECIMAL(<var class="pv">p</var>) for DECIMAL(<var class="pv">p</var>,0), and DECIMAL for
|
|
DECIMAL(5,0).</p>
|
|
</dd>
|
|
<dt class="bold">NUMERIC(<var class="pv">integer</var>,<var class="pv">integer</var>)</dt>
|
|
<dt class="bold">NUMERIC(<var class="pv">integer</var>)</dt>
|
|
<dt class="bold">NUMERIC </dt><a id="idx2062" name="idx2062"></a>
|
|
<dd>For a zoned decimal number. The first integer is the precision of the
|
|
number, that is, the total number of digits; it may range from 1 to 63. The
|
|
second integer is the scale of the number, (the number of digits to the right
|
|
of the decimal point). It may range from 0 to the precision of the number.
|
|
<p>You can use NUMERIC(<var class="pv">p</var>) for NUMERIC(<var class="pv">p</var>,0), and NUMERIC for
|
|
NUMERIC(5,0).</p>
|
|
</dd>
|
|
<dt class="bold">FLOAT </dt><a id="idx2063" name="idx2063"></a>
|
|
<dd>For a double-precision floating-point number.
|
|
</dd>
|
|
<dt class="bold">FLOAT(<var class="pv">integer</var>) </dt><a id="idx2064" name="idx2064"></a>
|
|
<dd>For a single- or double-precision floating-point number, depending on
|
|
the value of integer. The value of integer must be in the range 1 through
|
|
53. The values 1 through 24 indicate single-precision, the values 25 through
|
|
53 indicate double-precision. The default is 53.
|
|
</dd>
|
|
<dt class="bold">REAL </dt><a id="idx2065" name="idx2065"></a>
|
|
<dd>For single-precision floating point.
|
|
</dd>
|
|
<dt class="bold">DOUBLE PRECISION <span class="base">or</span> DOUBLE </dt><a id="idx2066" name="idx2066"></a>
|
|
<dd>For double-precision floating point.
|
|
</dd>
|
|
<dt class="bold">CHARACTER(<var class="pv">integer</var>) <span class="base">or</span> CHAR(<var class="pv">integer</var>) </dt>
|
|
<dt class="bold">CHARACTER <span class="base">or</span> CHAR</dt><a id="idx2067" name="idx2067"></a>
|
|
<dd>For a fixed-length character string of length <var class="pv">integer</var>. The
|
|
integer can range from 1 through 32766 (32765 if null capable). If FOR MIXED
|
|
DATA or a mixed data CCSID is specified, the range is 4 through 32766 (32765
|
|
if null capable). If the length specification is omitted, a length of 1 character
|
|
is assumed.
|
|
</dd>
|
|
<dt class="bold">CHARACTER VARYING (<var class="pv">integer</var>) <span class="base">or</span> CHAR
|
|
VARYING (<var class="pv">integer</var>) <span class="base">or</span>
|
|
<span class="term">VARCHAR(<var class="pv">integer</var>)</span></dt><a id="idx2068" name="idx2068"></a>
|
|
<dd>For a varying-length character string of maximum length <span class="italic">integer</span>, which can range from 1 through 32740 (32739 if null capable).
|
|
If FOR MIXED DATA or a mixed data CCSID is specified, the range is 4 through
|
|
32740 (32739 if null capable).
|
|
</dd>
|
|
<dt class="bold">CLOB(<var class="pv">integer</var>[K|M|G]) <span class="base">or</span> CHAR LARGE
|
|
OBJECT(<var class="pv">integer</var>[K|M|G]) <span class="base">or</span> CHARACTER LARGE OBJECT(<var class="pv">integer</var>[K|M|G]) </dt>
|
|
<dt class="bold">CLOB <span class="base">or</span> CHAR LARGE
|
|
OBJECT <span class="base">or</span> CHARACTER LARGE OBJECT</dt><a id="idx2069" name="idx2069"></a>
|
|
<dd>For a character large object string of the specified maximum length.
|
|
The maximum length must be in the range of 1 through 2 147 483 647. If FOR
|
|
MIXED DATA or a mixed data CCSID is specified, the range is 4 through 2 147
|
|
483 647. If the length specification is omitted, a length of 1 megabyte is
|
|
assumed. A CLOB is not allowed in a distributed table.
|
|
<dl class="parml">
|
|
<dt class="bold"><var class="pv">integer</var></dt>
|
|
<dd>The maximum value for integer is 2 147 483 647. The maximum length of
|
|
the string is <var class="pv">integer</var>.
|
|
</dd>
|
|
<dt class="bold"><var class="pv">integer</var> K</dt>
|
|
<dd>The maximum value for integer is 2 097 152. The maximum length of the
|
|
string is 1024 times <var class="pv">integer</var>.
|
|
</dd>
|
|
<dt class="bold"><var class="pv">integer</var> M</dt>
|
|
<dd>The maximum value for integer is 2 048. The maximum length of the string
|
|
is 1 048 576 times <var class="pv">integer</var>.
|
|
</dd>
|
|
<dt class="bold"><var class="pv">integer</var> G</dt>
|
|
<dd>The maximum value for integer is 2. The maximum length of the string
|
|
is 1 073 741 824 times <var class="pv">integer</var>.
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold">GRAPHIC(<var class="pv">integer</var>)</dt>
|
|
<dt class="bold">GRAPHIC </dt><a id="idx2070" name="idx2070"></a>
|
|
<dd>For a fixed-length graphic string of length <var class="pv">integer</var>, which
|
|
can range from 1 through 16383 (16382 if null capable). If the length specification
|
|
is omitted, a length of 1 character is assumed.
|
|
</dd>
|
|
<dt class="bold">VARGRAPHIC(<var class="pv">integer</var>) <span class="base">or</span> GRAPHIC
|
|
VARYING(<var class="pv">integer</var>) <a id="idx2071" name="idx2071"></a></dt>
|
|
<dd>For a varying-length graphic string of maximum length <var class="pv">integer</var>,
|
|
which can range from 1 through 16370 (16369 if null capable).
|
|
</dd>
|
|
<dt class="bold">DBCLOB(<var class="pv">integer</var>[K|M|G]) </dt>
|
|
<dt class="bold">DBCLOB</dt><a id="idx2072" name="idx2072"></a>
|
|
<dd>For a double-byte character large object string of the specified maximum
|
|
length.
|
|
<p>The maximum length must be in the range of 1 through 1 073 741
|
|
823. If the length specification is omitted, a length of 1 megabyte is assumed.
|
|
A DBCLOB is not allowed in a distributed table.</p>
|
|
<dl class="parml">
|
|
<dt class="bold"><var class="pv">integer</var></dt>
|
|
<dd>The maximum value for integer is 1 073 741 823. The maximum length of
|
|
the string is <var class="pv">integer</var>.
|
|
</dd>
|
|
<dt class="bold"><var class="pv">integer</var> K</dt>
|
|
<dd>The maximum value for integer is 1 028 576. The maximum length of the
|
|
string is 1024 times <var class="pv">integer</var>.
|
|
</dd>
|
|
<dt class="bold"><var class="pv">integer</var> M</dt>
|
|
<dd>The maximum value for integer is 1 024. The maximum length of the string
|
|
is 1 048 576 times <var class="pv">integer</var>.
|
|
</dd>
|
|
<dt class="bold"><var class="pv">integer</var> G</dt>
|
|
<dd>The maximum value for integer is 1. The maximum length of the string
|
|
is 1 073 741 824 times <var class="pv">integer</var>.
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold">BINARY(<var class="pv">integer</var>)</dt>
|
|
<dt class="bold">BINARY</dt><a id="idx2073" name="idx2073"></a>
|
|
<dd>For a fixed-length binary string of length <var class="pv">integer</var>. The integer
|
|
can range from 1 through 32766 (32765 if null capable). If the length specification
|
|
is omitted, a length of 1 character is assumed.
|
|
</dd>
|
|
<dt class="bold">BINARY VARYING (<var class="pv">integer</var>) <span class="base">or</span>
|
|
<span class="term">VARBINARY(<var class="pv">integer</var>)</span></dt><a id="idx2074" name="idx2074"></a>
|
|
<dd>For a varying-length binary string of maximum length <span class="italic">integer</span>, which can range from 1 through 32740 (32739 if null capable).
|
|
</dd>
|
|
<dt class="bold">BLOB<span class="base">(</span><var class="pv">integer</var><span class="base">[</span>K|M|G<span class="base">])</span> <span class="base">or</span> BINARY LARGE OBJECT(<var class="pv">integer</var>[K|M|G])<a id="idx2075" name="idx2075"></a></dt>
|
|
<dt class="bold">BLOB <span class="base">or</span> BINARY
|
|
LARGE OBJECT</dt>
|
|
<dd>For a binary large object string of the specified maximum length. The
|
|
maximum length must be in the range of 1 through 2 147 483 647. If the length
|
|
specification is omitted, a length of 1 megabyte is assumed. A BLOB is not
|
|
allowed in a distributed table.
|
|
<dl class="parml">
|
|
<dt class="bold"><var class="pv">integer</var></dt>
|
|
<dd>The maximum value for integer is 2 147 483 647. The maximum length of
|
|
the string is <var class="pv">integer</var>.
|
|
</dd>
|
|
<dt class="bold"><var class="pv">integer</var> K</dt>
|
|
<dd>The maximum value for integer is 2 097 152. The maximum length of the
|
|
string is 1024 times <var class="pv">integer</var>.
|
|
</dd>
|
|
<dt class="bold"><var class="pv">integer</var> M</dt>
|
|
<dd>The maximum value for integer is 2 048. The maximum length of the string
|
|
is 1 048 576 times <var class="pv">integer</var>.
|
|
</dd>
|
|
<dt class="bold"><var class="pv">integer</var> G</dt>
|
|
<dd>The maximum value for integer is 2. The maximum length of the string
|
|
is 1 073 741 824 times <var class="pv">integer</var>.
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold">DATE </dt><a id="idx2076" name="idx2076"></a>
|
|
<dd>For a date.
|
|
</dd>
|
|
<dt class="bold">TIME </dt><a id="idx2077" name="idx2077"></a>
|
|
<dd>For a time.
|
|
</dd>
|
|
<dt class="bold">TIMESTAMP </dt><a id="idx2078" name="idx2078"></a>
|
|
<dd>For a timestamp.
|
|
</dd>
|
|
<dt class="bold">
|
|
<span class="term">DATALINK(<var class="pv">integer</var>)<span class="base"> or </span></span>
|
|
<span class="term">DATALINK</span></dt><a id="idx2079" name="idx2079"></a>
|
|
<dd>For a DataLink of the specified maximum length. The maximum length must
|
|
be in the range of 1 through 32717. If FOR MIXED DATA or a mixed data CCSID
|
|
is specified, the range is 4 through 32717. The specified length must be sufficient
|
|
to contain both the largest expected URL and any DataLink comment. If the
|
|
length specification is omitted, a length of 200 is assumed. A DATALINK is
|
|
not allowed in a distributed table.
|
|
<p>A DATALINK value is an encapsulated
|
|
value with a set of built-in scalar functions. The DLVALUE function creates
|
|
a DATALINK value. The following functions can be used to extract attributes
|
|
from a DATALINK value. </p>
|
|
<ul>
|
|
<li>DLCOMMENT</li>
|
|
<li>DLLINKTYPE</li>
|
|
<li>DLURLCOMPLETE</li>
|
|
<li>DLURLPATH</li>
|
|
<li>DLURLPATHONLY</li>
|
|
<li>DLURLSCHEME</li>
|
|
<li>DLURLSERVER</li></ul>
|
|
<p>A DataLink cannot be part of any index. Therefore, it cannot be
|
|
included as a column of a primary key, foreign key, or unique constraint.</p>
|
|
</dd>
|
|
<dt class="bold">ROWID</dt><a id="idx2080" name="idx2080"></a>
|
|
<dd>For a row ID. Only one ROWID column is allowed in a table.
|
|
A ROWID is not allowed in a partitioned table.
|
|
</dd>
|
|
<dt class="bold"><var class="pv">distinct-type-name</var> </dt><a id="idx2081" name="idx2081"></a>
|
|
<dd>Specifies that the data type of the column is a distinct type (a user-defined
|
|
data 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.
|
|
</dd>
|
|
<dt class="bold">ALLOCATE(<var class="pv">integer</var>)</dt><a id="idx2082" name="idx2082"></a>
|
|
<dd>Specifies for VARCHAR, VARGRAPHIC, VARBINARY, and LOB types the space
|
|
to be reserved for the column in each row. Column values with lengths less
|
|
than or equal to the allocated value are stored in the fixed-length portion
|
|
of the row. Column values with lengths greater than the allocated value are
|
|
stored in the variable-length portion of the row and require additional input/output
|
|
operations to retrieve. The allocated value may range from 1 to maximum length
|
|
of the string, subject to the maximum row buffer size limit. For information
|
|
on the maximum row buffer size, see <a href="rbafzmsthctabl.htm#maxrcd">Maximum row sizes</a>. If FOR MIXED DATA
|
|
or a mixed data CCSID is specified, the range is 4 to the maximum length of
|
|
the string. If the allocated length specification is omitted, an allocated
|
|
length of 0 is assumed. For VARGRAPHIC, the integer is the number of DBCS,
|
|
UTF-16, or UCS-2 characters. If a constant is specified for the default value
|
|
and the ALLOCATE length is less than the length of the default value, the
|
|
ALLOCATE length is assumed to be the length of the default value.
|
|
</dd>
|
|
<dt class="bold">FOR BIT DATA </dt><a id="idx2083" name="idx2083"></a>
|
|
<dd>Specifies that the values of the column are not associated with a coded
|
|
character set and are never converted. FOR BIT DATA is only valid for CHARACTER
|
|
or VARCHAR columns. The CCSID of a FOR BIT DATA column is 65535. FOR BIT DATA
|
|
is not allowed for CLOB columns.
|
|
</dd>
|
|
<dt class="bold">FOR SBCS DATA </dt><a id="idx2084" name="idx2084"></a>
|
|
<dd>Specifies that the values of the column contain SBCS (single-byte character
|
|
set) data. FOR SBCS DATA is the default for CHAR, VARCHAR, and CLOB columns
|
|
if the default CCSID at the current server at the time the table is created
|
|
is not DBCS-capable or if the length of the column is less than 4. FOR SBCS
|
|
DATA is only valid for CHARACTER, VARCHAR, or CLOB columns. The CCSID of FOR
|
|
SBCS DATA is determined by the default CCSID at the current server at the
|
|
time the table is created.
|
|
</dd>
|
|
<dt class="bold">FOR MIXED DATA </dt><a id="idx2085" name="idx2085"></a><a id="idx2086" name="idx2086"></a>
|
|
<dd>Specifies that the values of the column contain both SBCS data and DBCS
|
|
data. FOR MIXED DATA is the default for CHAR, VARCHAR, and CLOB columns if
|
|
the default CCSID at the current server at the time the table is created is
|
|
DBCS-capable and the length of the column is greater than 3. Every FOR MIXED
|
|
DATA column is a DBCS-open database field. FOR MIXED DATA is only valid for
|
|
CHARACTER, VARCHAR, or CLOB columns. The CCSID of FOR MIXED DATA is determined
|
|
by the default CCSID at the current server at the time the table is created.
|
|
</dd>
|
|
<dt class="bold">CCSID integer </dt><a id="idx2087" name="idx2087"></a><a id="idx2088" name="idx2088"></a><a id="idx2089" name="idx2089"></a>
|
|
<dd>Specifies that the values of the column contain data of CCSID integer.
|
|
If the integer is an SBCS CCSID, the column is SBCS data. If the integer is
|
|
a mixed data CCSID, the column is mixed data and the length of the column
|
|
must be greater than 3. For character columns, the CCSID must be an SBCS CCSID
|
|
or a mixed data CCSID. For graphic columns, the CCSID must be a DBCS, UTF-16,
|
|
or UCS-2 CCSID. If a CCSID is not specified for a graphic column, the CCSID
|
|
is determined by the default CCSID at the current server at the time the table
|
|
is created. For a list of valid CCSIDs, see <a href="rbafzmstsidvals.htm#sidvals">Appendix E. CCSID values</a>.
|
|
<p>CCSID
|
|
1208 (UTF-8) or 1200 (UTF-16) data can contain <var class="pv">combining characters</var>.
|
|
Combining character support allows a resulting character to be comprised of
|
|
more than one character. After the first character, up to 300 different non-spacing
|
|
accent characters (umlauts, accent, etc.) can follow in the data string.
|
|
If the resulting character is one that is already defined in the character
|
|
set, that character has more than one representation. <var class="pv">Normalization</var> replaces
|
|
the string of combining characters with the hex value of the defined character.
|
|
This ensures that the same character is represented in a single consistent
|
|
way. If normalization is not performed, two strings that look identical will
|
|
not compare equal.</p>
|
|
<dl class="parml">
|
|
<dt class="bold">NOT NORMALIZED</dt>
|
|
<dd>The data should not be normalized when passed from the application.
|
|
</dd>
|
|
<dt class="bold">NORMALIZED</dt>
|
|
<dd>The data should be normalized when passed from the application.
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold"><a id="crtdft" name="crtdft"></a>DEFAULT </dt><a id="idx2090" name="idx2090"></a><a id="idx2091" name="idx2091"></a>
|
|
<dd>Specifies a default value for the column. This clause cannot be specified
|
|
more than once in a <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:
|
|
<a name="wq1321"></a>
|
|
<table id="wq1321" width="90%" summary="" border="1" frame="border" rules="all">
|
|
<thead valign="bottom">
|
|
<tr>
|
|
<th id="wq1322" width="40%" align="left" valign="top">Data type</th>
|
|
<th id="wq1323" width="59%" align="left" valign="top">Default value</th>
|
|
</tr>
|
|
</thead>
|
|
<tbody valign="top">
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1322">Numeric</td>
|
|
<td align="left" valign="top" headers="wq1323">0</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1322">Fixed-length character or graphic string</td>
|
|
<td align="left" valign="top" headers="wq1323">Blanks</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1322">Fixed-length binary string</td>
|
|
<td align="left" valign="top" headers="wq1323">Hexadecimal zeros</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1322">Varying-length string</td>
|
|
<td align="left" valign="top" headers="wq1323">A string length of 0</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1322">Date</td>
|
|
<td align="left" valign="top" headers="wq1323">The current date at the time of INSERT</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1322">Time</td>
|
|
<td align="left" valign="top" headers="wq1323">The current time at the time of INSERT</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1322">Timestamp</td>
|
|
<td align="left" valign="top" headers="wq1323">The current timestamp at the time of INSERT</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1322">Datalink</td>
|
|
<td align="left" valign="top" headers="wq1323">A value corresponding to DLVALUE('','URL','')</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1322"><var class="pv">distinct-type</var></td>
|
|
<td align="left" valign="top" headers="wq1323">The default value of the corresponding source
|
|
type of the distinct type.</td>
|
|
</tr>
|
|
</tbody>
|
|
</table></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>
|
|
<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, 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>
|
|
<dd>Specifies the value of the USER special register at the time of INSERT
|
|
or UPDATE as the default value of 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.
|
|
</dd>
|
|
<dt class="bold"><span class="bold">NULL</span></dt>
|
|
<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>.
|
|
<p>NULL is the only default value allowed for a datalink column.</p>
|
|
</dd>
|
|
<dt class="bold"><span class="bold">CURRENT_DATE</span> </dt><a id="idx2092" name="idx2092"></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="idx2093" name="idx2093"></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> <a id="idx2094" name="idx2094"></a></dt>
|
|
<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"><var class="pv">cast-function-name</var> </dt><a id="idx2095" name="idx2095"></a>
|
|
<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="wq1324"></a>
|
|
<table id="wq1324" width="100%" summary="" border="1" frame="border" rules="none">
|
|
<thead valign="bottom">
|
|
<tr>
|
|
<th id="wq1325" width="47%" align="left" valign="top">Data Type</th>
|
|
<th id="wq1326" width="52%" align="left" valign="top">Cast Function Name</th>
|
|
</tr>
|
|
</thead>
|
|
<tbody valign="top">
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1325">Distinct type N based on a BINARY, VARBINARY,
|
|
BLOB, CLOB, or DBCLOB</td>
|
|
<td align="left" valign="top" headers="wq1326">BINARY, VARBINARY, BLOB, CLOB, or DBCLOB *</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1325">Distinct type N based on a DATE, TIME, or
|
|
TIMESTAMP</td>
|
|
<td align="left" valign="top" headers="wq1326">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="wq1325">Distinct type N based on other data types</td>
|
|
<td align="left" valign="top" headers="wq1326">N (the user-defined cast function that was
|
|
generated when N was created) **</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1325">BINARY, VARBINARY, BLOB, CLOB, or DBCLOB</td>
|
|
<td align="left" valign="top" headers="wq1326">BINARY, VARBINARY, BLOB, CLOB, or DBCLOB *</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1325">DATE, TIME, or TIMESTAMP</td>
|
|
<td align="left" valign="top" headers="wq1326">DATE, TIME, or TIMESTAMP *</td>
|
|
</tr>
|
|
<tr>
|
|
<td colspan="2" align="left" valign="top" headers="wq1325 wq1326">
|
|
<a name="wq1327"></a>
|
|
<div class="notetitle" id="wq1327">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="idx2096" name="idx2096"></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="idx2097" name="idx2097"></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 greater than or equal to the length attribute of the USER special
|
|
register.
|
|
</dd>
|
|
<dt class="bold"><span class="bold">CURRENT_DATE</span> </dt><a id="idx2098" name="idx2098"></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="idx2099" name="idx2099"></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="idx2100" name="idx2100"></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"><span class="bold">GENERATED</span> </dt><a id="idx2101" name="idx2101"></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). 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"><span class="bold">ALWAYS</span></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"><span class="bold">BY DEFAULT</span></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"><span class="bold">AS IDENTITY</span> </dt><a id="idx2102" name="idx2102"></a>
|
|
<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.</p>
|
|
<dl class="parml">
|
|
<dt class="bold"><span class="bold">START WITH </span><var class="pv">numeric-constant</var></dt>
|
|
<dd>Specifies the first value that is generated for the identity column.
|
|
The value can be any positive or negative value that could be assigned to
|
|
the column without non-zero digits existing to the right of the decimal point.
|
|
<p>If a value is not explicitly specified when the identity column is defined,
|
|
the default is the MINVALUE for an ascending sequence and the MAXVALUE for
|
|
a descending sequence. This value is not necessarily the value that a sequence
|
|
would cycle to after reaching the maximum or minimum value of the sequence.
|
|
The START WITH clause can be used to start a sequence outside the range that
|
|
is used for cycles. The range used for cycles is defined by MINVALUE and MAXVALUE.</p>
|
|
</dd>
|
|
<dt class="bold"><span class="bold">INCREMENT BY </span><var class="pv">numeric-constant</var></dt>
|
|
<dd>Specifies the interval between consecutive values of the identity column.
|
|
The value must not exceed the value of a large integer constant without any
|
|
non-zero digits existing to the right of the decimal point. The value must
|
|
be assignable to the column. The default is 1.
|
|
<p>If the value is zero or positive,
|
|
the sequence of values for the identity column ascends. If the value is negative,
|
|
the sequence of values descends.</p>
|
|
</dd>
|
|
<dt class="bold"><span class="bold">MAXVALUE </span> <var class="pv">numeric-constant</var></dt>
|
|
<dd>Specifies the numeric constant that is the maximum value that is generated
|
|
for this identity column. This value can be any positive or negative value
|
|
that could be assigned to this column, but the value must be greater than
|
|
the minimum value.
|
|
<p>If a value is not explicitly specified when the identity
|
|
column is defined, this is the maximum value of the data type for an ascending
|
|
sequence; or the START WITH value, or -1 if START WITH was not specified,
|
|
for a descending sequence.</p>
|
|
</dd>
|
|
<dt class="bold"><span class="bold">MINVALUE </span><var class="pv">numeric-constant</var></dt>
|
|
<dd>Specifies the numeric constant that is the minimum value that is generated
|
|
for this identity column. This value can be any positive or negative value
|
|
that could be assigned to this column, but the value must be less than the
|
|
maximum value.
|
|
<p>If a value is not explicitly specified when the identity
|
|
column is defined, this is the START WITH value, or 1 if START WITH was not
|
|
specified, for an ascending sequence; or the minimum value of the data type
|
|
(and precision, if DECIMAL) for a descending sequence.</p>
|
|
</dd>
|
|
<dt class="bold"><span class="bold">CACHE</span> or <span class="bold">NO CACHE</span></dt>
|
|
<dd>Specifies whether to keep some preallocated values in memory. Preallocating
|
|
and storing values in the cache improves the performance of inserting rows
|
|
into a table.
|
|
<dl class="parml">
|
|
<dt class="bold"><span class="bold">CACHE</span> <var class="pv">integer</var></dt>
|
|
<dd>Specifies the number of values of the identity column sequence that the database manager preallocates
|
|
and keeps in memory. The minimum value that can be specified is 2, and the
|
|
maximum is the largest value that can be represented as an integer. The default
|
|
is 20.
|
|
<p>In certain situations, such as system failure, all cached
|
|
identity column values that have not been used in committed statements are
|
|
lost, and thus, will never be used. The value specified for the CACHE option
|
|
is the maximum number of identity column values that could be lost in these
|
|
situations.</p>
|
|
</dd>
|
|
<dt class="bold"><span class="bold">NO CACHE</span> </dt>
|
|
<dd>Specifies that values for the identity column are not preallocated.
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold"><span class="bold">CYCLE</span> or <span class="bold">NO CYCLE</span></dt>
|
|
<dd>Specifies whether this identity column should continue to generate values
|
|
after reaching either the maximum or minimum value of the sequence.
|
|
<dl class="parml">
|
|
<dt class="bold"><span class="bold">CYCLE</span></dt>
|
|
<dd>Specifies that values continue to be generated for this column after
|
|
the maximum or minimum value has been reached. If this option is used, after
|
|
an ascending sequence reaches the maximum value of the sequence, it generates
|
|
its minimum value. After a descending sequence reaches its minimum value of
|
|
the sequence, it generates its maximum value. The maximum and minimum values
|
|
for the column determine the range that is used for cycling.
|
|
<p>When CYCLE
|
|
is in effect, duplicate values can be generated by the database manager for an identity
|
|
column. If a unique constraint or unique index exists on the identity column,
|
|
and a non-unique value is generated for it, an error occurs.</p>
|
|
</dd>
|
|
<dt class="bold"><span class="bold">NO CYCLE</span></dt>
|
|
<dd>Specifies that values will not be generated for the identity column
|
|
once the maximum or minimum value for the sequence has been reached. This
|
|
is the default.
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold"><span class="bold">ORDER</span> or <span class="bold">NO ORDER</span></dt>
|
|
<dd>Specifies whether the identity values must be generated in order of
|
|
request.
|
|
<dl class="parml">
|
|
<dt class="bold"><span class="bold">ORDER</span></dt>
|
|
<dd>Specifies that the values are generated in order of request.
|
|
</dd>
|
|
<dt class="bold"><span class="bold">NO ORDER</span></dt>
|
|
<dd>Specifies that the values do not need to be generated in order of request.
|
|
This is the default.
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold"><var class="pv">datalink-options</var> </dt><a id="idx2103" name="idx2103"></a>
|
|
<dd>Specifies the options associated with a DATALINK data type.
|
|
<dl class="parml">
|
|
<dt class="bold">LINKTYPE URL</dt>
|
|
<dd>Defines the type of link as a Uniform Resource Locator (URL).
|
|
</dd>
|
|
<dt class="bold">NO LINK CONTROL</dt>
|
|
<dd>Specifies that there will not be any check made to determine that the
|
|
linked files exist. Only the syntax of the URL will be checked. There is no
|
|
database manager control over the linked files.
|
|
</dd>
|
|
<dt class="bold">FILE LINK CONTROL</dt>
|
|
<dd>Specifies that a check should be made for the existence of the linked
|
|
files. Additional options may be used to give the database manager further
|
|
control over the linked files.
|
|
<p>If FILE LINK CONTROL is specified, each file
|
|
can only be linked once. That is, its URL can only be specified in a single
|
|
FILE LINK CONTROL column in a single table.</p>
|
|
</dd>
|
|
<dt class="bold"><var class="pv">file-link-options</var></dt>
|
|
<dd>Additional options to define the level of database manager control of
|
|
the linked files.
|
|
<dl class="parml">
|
|
<dt class="bold">INTEGRITY</dt>
|
|
<dd>Specifies the level of integrity of the link between a DATALINK value
|
|
and the actual file.
|
|
<dl class="parml">
|
|
<dt class="bold">ALL</dt>
|
|
<dd>Any file specified as a DATALINK value is under the control of the database
|
|
manager and may NOT be deleted or renamed using standard file system programming
|
|
interfaces.
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold">READ PERMISSION</dt>
|
|
<dd>Specifies how permission to read the file specified in a DATALINK value
|
|
is determined.
|
|
<dl class="parml">
|
|
<dt class="bold">FS</dt>
|
|
<dd>The read access permission is determined by the file system permissions.
|
|
Such files can be accessed without retrieving the file name from the column.
|
|
</dd>
|
|
<dt class="bold">DB</dt>
|
|
<dd>The read access permission is determined by the database. Access to
|
|
the file will only be allowed by passing a valid file access token, returned
|
|
on retrieval of the DATALINK value from the table, in the open operation.
|
|
If READ PERMISSION DB is specified, WRITE PERMISSION BLOCKED must be specified.
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold">WRITE PERMISSION</dt>
|
|
<dd>Specifies how permission to write to the file specified in a DATALINK
|
|
value is determined.
|
|
<dl class="parml">
|
|
<dt class="bold">FS</dt>
|
|
<dd>The write access permission is determined by the file system permissions.
|
|
Such files can be accessed without retrieving the file name from the column.
|
|
</dd>
|
|
<dt class="bold">BLOCKED</dt>
|
|
<dd>Write access is blocked. The file cannot be directly updated through
|
|
any interface. An alternative mechanism must be used to perform updates to
|
|
the information. For example, the file is copied, the copy updated, and then
|
|
the DATALINK value updated to point to the new copy of the file.
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold">RECOVERY</dt>
|
|
<dd>Specifies whether or not the database manager will support point in time recovery
|
|
of files referenced by values in this column.
|
|
<dl class="parml">
|
|
<dt class="bold">NO</dt>
|
|
<dd>Specifies that point in time recovery will not be supported.
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold">ON UNLINK</dt>
|
|
<dd>Specifies the action taken on a file when a DATALINK value is changed
|
|
or deleted (unlinked). Note that this is not applicable when WRITE PERMISSION
|
|
FS is used.
|
|
<dl class="parml">
|
|
<dt class="bold">RESTORE</dt>
|
|
<dd>Specifies that when a file is unlinked, the DataLink File Manager will
|
|
attempt to return the file to the owner with the permissions that existed
|
|
at the time the file was linked. In the case where the user is no longer registered
|
|
with the file server, the result depends on the file system that contains
|
|
the files. If the files are in the AIX® file system, the owner is "dfmunknown".
|
|
If the files are in IFS, the owner is QDLFM. This can only be specified when
|
|
INTEGRITY ALL and WRITE PERMISSION BLOCKED are also specified.
|
|
</dd>
|
|
<dt class="bold">DELETE</dt>
|
|
<dd>Specifies that the file will be deleted when it is unlinked. This can
|
|
only be specified when READ PERMISSION DB and WRITE PERMISSION BLOCKED are
|
|
also specified.
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold">MODE DB2OPTIONS</dt>
|
|
<dd>This mode defines a set of default file link options. The defaults defined
|
|
by DB2OPTIONS are:
|
|
<ul>
|
|
<li>INTEGRITY ALL</li>
|
|
<li>READ PERMISSION FS</li>
|
|
<li>WRITE PERMISSION FS</li>
|
|
<li>RECOVERY NO</li></ul>
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold">NOT NULL </dt><a id="idx2104" name="idx2104"></a>
|
|
<dd>Prevents the column from containing null values. Omission of NOT NULL
|
|
implies that the column can be null.
|
|
</dd>
|
|
<dt class="bold"><var class="pv">column-constraint</var></dt>
|
|
<dd>
|
|
<dl class="parml">
|
|
<dt class="bold">CONSTRAINT <var class="pv">constraint-name</var> </dt><a id="idx2105" name="idx2105"></a><a id="idx2106" name="idx2106"></a>
|
|
<dd>Names the constraint. A <var class="pv">constraint-name</var> must not identify a
|
|
constraint that was previously specified in the CREATE TABLE statement and
|
|
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="idx2107" name="idx2107"></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 column
|
|
definition and must not be specified at all if the UNIQUE clause is specified
|
|
in the column definition. The column must not be a LOB or DATALINK column.</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="idx2108" name="idx2108"></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 column definition.
|
|
The column must not be a LOB or DATALINK column.</p>
|
|
</dd>
|
|
<dt class="bold"><span class="italic">references-clause</span> </dt><a id="idx2109" name="idx2109"></a>
|
|
<dd>The <var class="pv">references-clause</var> of a <var class="pv">column-definition</var> provides
|
|
a shorthand method of defining a foreign key composed of a single column.
|
|
Thus, if a references-clause is specified in the definition of column C, the
|
|
effect is the same as if that references-clause were specified as part of
|
|
a FOREIGN KEY clause in which C is the only identified column. The <var class="pv">references-clause</var> is not allowed if the table <span>is 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="idx2110" name="idx2110"></a>
|
|
<dd>The CHECK(<var class="pv">check-condition</var>) of a <var class="pv">column-definition</var> 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="rbafzmsthctabl.htm#ctcheckcst">check-constraint</a>.</p>
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
</dl>
|
|
<a name="wq1328"></a>
|
|
<h3 id="wq1328"><a href="rbafzmst02.htm#ToC_931">LIKE</a></h3><a id="idx2111" name="idx2111"></a>
|
|
<dl class="parml">
|
|
<dt class="bold"><var class="pv">table-name</var> <span class="base">or</span> <var class="pv">view-name</var> </dt>
|
|
<dd>Specifies that the columns of the table have exactly the same name and
|
|
description as the columns of the identified table (<var class="pv">table-name</var>) or
|
|
view (<var class="pv">view-name</var>). The name must identify a table or view that exists
|
|
at the current server.
|
|
<p>The use of LIKE is an implicit definition of n
|
|
columns, where n is the number of columns in the identified table or view.
|
|
The implicit definition includes the following attributes of the n columns
|
|
(if applicable to the data type):</p>
|
|
<ul>
|
|
<li>Column name (and system column name)</li>
|
|
<li>Data type, length, precision, and scale</li>
|
|
<li>CCSID</li></ul>
|
|
<p>If the LIKE clause is specified immediately following the <var class="pv">table-name</var> and not enclosed in parenthesis, the following column attributes
|
|
are also included, otherwise they are not included (the default value and
|
|
identity attributes can also be controlled by using the <var class="pv">copy-options</var>):</p>
|
|
<ul>
|
|
<li>Default value, if a <var class="pv">table-name</var> is specified (<var class="pv">view-name</var> is
|
|
not specified)</li>
|
|
<li>Nullability</li>
|
|
<li>Identity attributes</li>
|
|
<li>Column heading and text (see <a href="rbafzmstlabelon.htm#labelon">LABEL</a>)</li></ul>
|
|
<p>The implicit definition does not include any other optional attributes
|
|
of the identified table or view. For example, the new table does not automatically
|
|
include primary keys, foreign keys, or triggers. The new table has these and
|
|
other optional attributes only if the optional clauses are explicitly specified.</p>
|
|
<p>If the specified table or view is a non-SQL created physical file or
|
|
logical file, any non-SQL attributes are removed. For example, the date and
|
|
time format will be changed to ISO.</p>
|
|
</dd>
|
|
</dl>
|
|
<a name="wq1329"></a>
|
|
<h3 id="wq1329"><a href="rbafzmst02.htm#ToC_932">as-subquery-clause</a></h3><a id="idx2112" name="idx2112"></a>
|
|
<dl class="parml">
|
|
<dt class="bold"><var class="pv">column-name</var> </dt>
|
|
<dd>Names a column in the table. If a list of column names is
|
|
specified, it must consist of as many names as there are columns in the result
|
|
table of the <var class="pv">select-statement</var>. Each <var class="pv">column-name</var> must be
|
|
unique and unqualified. If a list of column names is not specified, the
|
|
columns of the table inherit the names of the columns of the result table
|
|
of the <var class="pv">select-statement</var>.
|
|
<p>A list of column names must be specified
|
|
if the result table of the <var class="pv">select-statement</var> has duplicate
|
|
column names or an unnamed column. An unnamed column is a column derived
|
|
from a constant, function, expression, or set operation (UNION or INTERSECT)
|
|
that is not named using the AS clause of the select list.</p>
|
|
</dd>
|
|
<dt class="bold">FOR COLUMN <var class="pv">system-column-name</var> </dt>
|
|
<dd>Provides an i5/OS name for the column. Do not use the same name for
|
|
more than one column of the table or for a column-name of the table.
|
|
<p>If
|
|
the <var class="pv">system-column-name</var> is not specified, and the column-name is not
|
|
a valid <var class="pv">system-column-name</var>, 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">select-statement</var> </dt>
|
|
<dd>Specifies that the columns of the table have the same name and description
|
|
as the columns that would appear in the derived result table of the <var class="pv">select-statement</var> if the <var class="pv">select-statement</var> were to be executed. The use of AS <var class="pv">(select-statement)</var> is an implicit definition of <var class="pv">n</var> columns for
|
|
the table, where <var class="pv">n</var> is the number of columns that would result from
|
|
the <var class="pv">select-statement</var>.
|
|
<p>The implicit definition includes the following
|
|
attributes of the n columns (if applicable to the data type):</p>
|
|
<ul>
|
|
<li>Column name (and system column name)</li>
|
|
<li>Data type, length, precision, and scale</li>
|
|
<li>CCSID</li>
|
|
<li>Nullability</li>
|
|
<li>Column heading and text (see <a href="rbafzmstlabelon.htm#labelon">LABEL</a>)</li></ul>
|
|
<p>The following attributes are not included (the default value and
|
|
identity attributes may be included by using the <var class="pv">copy-options</var>):</p>
|
|
<ul>
|
|
<li>Default value</li>
|
|
<li>Identity attributes</li></ul>
|
|
<p>The implicit definition does not include any other optional attributes
|
|
of the identified table or view. For example, the new table does not automatically
|
|
include a primary key or foreign key from a table. The new table has these
|
|
and other optional attributes only if the optional clauses are explicitly
|
|
specified.</p>
|
|
<p>The <var class="pv">select-statement</var> must not refer to variables
|
|
or include parameter markers.</p>
|
|
<p>The <var class="pv">select-statement</var> must
|
|
not contain a PREVIOUS VALUE or a NEXT VALUE expression. The UPDATE, READ
|
|
ONLY, and OPTIMIZE clauses may not be specified.</p>
|
|
</dd>
|
|
<dt class="bold">WITH DATA</dt>
|
|
<dd>Specifies that the <var class="pv">select-statement</var> is executed. After the
|
|
table is created, the result table rows of the <var class="pv">select-statement</var> are
|
|
automatically inserted into the table.
|
|
</dd>
|
|
<dt class="bold">WITH NO DATA</dt>
|
|
<dd>Specifies that the <var class="pv">select-statement</var> is used only to define
|
|
the attributes of the new a table. The table is not populated using the results
|
|
of the <var class="pv">select-statement</var>.
|
|
</dd>
|
|
<dt class="bold">refreshable-table-options</dt><a id="idx2113" name="idx2113"></a><a id="idx2114" name="idx2114"></a>
|
|
<dd>Specifies that the table is a <var class="pv">materialized query table</var> and
|
|
the REFRESH TABLE statement can be used to populate the table with the results
|
|
of the <var class="pv">select-statement</var>.
|
|
<p>A materialized query table whose <var class="pv">select-statement</var> contains a GROUP BY clause is summarizing data from
|
|
the tables referenced in the <var class="pv">select-statement</var>. Such a materialized
|
|
query table is also known as a <var class="pv">summary table</var>. A summary table is
|
|
a specialized type of materialized query table.</p>
|
|
<p>When a materialized
|
|
query table is defined, the following <var class="pv">select-statement</var> restrictions
|
|
apply:</p>
|
|
<ul>
|
|
<li>The <var class="pv">select-statement</var> cannot contain a reference to another materialized
|
|
query table or to a view that refers to a materialized query table.</li>
|
|
<li>The <var class="pv">select-statement</var> cannot contain a reference to a declared
|
|
global temporary table, a table in QTEMP, a program-described file, or a non-SQL
|
|
logical file in the FROM clause.</li>
|
|
<li>The <var class="pv">select-statement</var> cannot contain a reference to
|
|
a view that references another materialized query table or a declared global
|
|
temporary table. When a materialized query table is defined with ENABLE QUERY
|
|
OPTIMIZATION, the <var class="pv">select-statement</var> cannot contain a reference to
|
|
a view that contains one of the restrictions from the following paragraph.</li>
|
|
<li>The <var class="pv">select-statement</var> cannot contain an expression with a DataLink
|
|
or a distinct type based on a DataLink where the DataLink is FILE LINK CONTROL.</li>
|
|
<li>The <var class="pv">select-statement</var> cannot contain a result column that is a
|
|
not an SQL data type, such as binary with precision, DBCS-ONLY, or DBCS-EITHER.</li></ul>
|
|
<p>When a materialized query table is defined with ENABLE QUERY OPTIMIZATION,
|
|
the following additional <var class="pv">select-statement</var> restrictions apply:</p>
|
|
<ul>
|
|
<li>Must not include any special registers.</li>
|
|
<li>Must not include any non-deterministic functions.</li>
|
|
<li>The ORDER BY clause is allowed, but is only used by REFRESH. It may improve
|
|
locality of reference of data in the materialized query table.</li>
|
|
<li>If the subselect references a view, the <var class="pv">select-statement</var> in the view definition must satisfy the preceding restrictions.</li></ul>
|
|
<dl class="parml">
|
|
<dt class="bold">DATA INITIALLY DEFERRED</dt>
|
|
<dd>Specifies that the data is not inserted into the materialized query
|
|
table when it is created. Use the REFRESH TABLE statement to populate the
|
|
materialized query table, or use the INSERT statement to insert data into
|
|
a materialized query table.
|
|
</dd>
|
|
<dt class="bold">DATA INITIALLY IMMEDIATE</dt>
|
|
<dd>Specifies that the data is inserted into the materialized query table
|
|
when it is created.
|
|
</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>or</span> DISABLE
|
|
QUERY OPTIMIZATION</dt>
|
|
<dd>Specifies whether this materialized query table can be used for optimization.
|
|
The default is ENABLE QUERY OPTIMIZATION.
|
|
<dl class="parml">
|
|
<dt class="bold">ENABLE QUERY OPTIMIZATION</dt>
|
|
<dd>Specifies that the materialized query table can be used for query optimization.
|
|
If the <var class="pv">select-statement</var> specified does not satisfy the restrictions
|
|
for query optimization, an error is returned.
|
|
</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>
|
|
</dd>
|
|
</dl>
|
|
<a name="wq1330"></a>
|
|
<h3 id="wq1330"><a href="rbafzmst02.htm#ToC_933">copy-options</a></h3><a id="idx2115" name="idx2115"></a><a id="idx2116" name="idx2116"></a><a id="idx2117" name="idx2117"></a>
|
|
<dl class="parml">
|
|
<dt class="bold">INCLUDING IDENTITY COLUMN ATTRIBUTES <span>or</span> EXCLUDING IDENTITY COLUMN ATTRIBUTES</dt>
|
|
<dd>Specifies whether identity column attributes are inherited.
|
|
<dl class="parml">
|
|
<dt class="bold">INCLUDING IDENTITY COLUMN ATTRIBUTES</dt>
|
|
<dd>Specifies that the table inherits the identity attribute, if any, of
|
|
the columns resulting from <var class="pv">select-statement</var>, <var class="pv">table-name</var>,
|
|
or <var class="pv">view-name</var>. In general, the identity attribute is copied if the
|
|
element of the corresponding column in the table, view, or <var class="pv">select-statement</var> is the name of a table column or the name of a view column that directly
|
|
or indirectly maps to the name of a base table column with the identity attribute.
|
|
If the INCLUDING IDENTITY COLUMN ATTRIBUTES clause is specified with the AS <var class="pv">select-statement</var> clause, the columns of the new table do not inherit
|
|
the identity attribute in the following cases:
|
|
<ul>
|
|
<li>The select list of the <var class="pv">select-statement</var> includes multiple instances
|
|
of an identity column name (that is, selecting the same column more than once).</li>
|
|
<li>The select list of the <var class="pv">select-statement</var> includes multiple identity
|
|
columns (that is, it involves a join).</li>
|
|
<li>The identity column is included in an expression in the select list.</li>
|
|
<li>The <var class="pv">select-statement</var> includes a set operation (UNION or INTERSECT).</li></ul>
|
|
<p>If INCLUDING IDENTITY is not specified, the table will not have an
|
|
identity column.</p>
|
|
</dd>
|
|
<dt class="bold">EXCLUDING IDENTITY COLUMN ATTRIBUTES</dt>
|
|
<dd>Specifies that the table does not inherit the identity attribute, if
|
|
any, of the columns resulting from the <var class="pv">fullselect</var>, <var class="pv">table-name</var>, or <var class="pv">view-name</var>.
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold">EXCLUDING COLUMN DEFAULTS <span>or</span> INCLUDING
|
|
COLUMN DEFAULTS <span>or</span> USING TYPE DEFAULTS</dt>
|
|
<dd>Specifies whether column defaults are inherited.
|
|
<dl class="parml">
|
|
<dt class="bold">EXCLUDING COLUMN DEFAULTS</dt>
|
|
<dd>Specifies that the column defaults are not inherited from the definition
|
|
of the source table. The default values of the column of the new table are
|
|
either null or there are no default values. If the column can be null, the
|
|
default is the null value. If the column cannot be null, there is no default
|
|
value, and an error occurs if a value is not provided for a column on INSERT
|
|
for the new table.
|
|
</dd>
|
|
<dt class="bold">INCLUDING COLUMN DEFAULTS</dt>
|
|
<dd>Specifies that the table inherits the default values of the columns
|
|
resulting from the <var class="pv">select-statement</var>, <var class="pv">table-name</var>, or <var class="pv">view-name</var>. A default value is the value assigned to a column when a value
|
|
is not specified on an INSERT.
|
|
<p>Do not specify INCLUDING COLUMN DEFAULTS,
|
|
if you specify USING TYPE DEFAULTS.</p>
|
|
<p>If INCLUDING COLUMN DEFAULTS is
|
|
not specified, the default values are not inherited.</p>
|
|
</dd>
|
|
<dt class="bold">USING TYPE DEFAULTS</dt>
|
|
<dd>Specifies that the default values for the table depend on the data type
|
|
of the columns that result from the <var class="pv">select-statement</var>, <var class="pv">table-name</var>, or <var class="pv">view-name</var>. If the column is nullable, then the default
|
|
value is the null value. Otherwise, the default value is as follows:
|
|
<a name="wq1331"></a>
|
|
<table id="wq1331" width="100%" summary="" border="1" frame="border" rules="all">
|
|
<thead valign="bottom">
|
|
<tr>
|
|
<th id="wq1332" width="40%" align="left" valign="top">Data type</th>
|
|
<th id="wq1333" width="59%" align="left" valign="top">Default value</th>
|
|
</tr>
|
|
</thead>
|
|
<tbody valign="top">
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1332">Numeric</td>
|
|
<td align="left" valign="top" headers="wq1333">0</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1332">Fixed-length character or graphic string</td>
|
|
<td align="left" valign="top" headers="wq1333">Blanks</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1332">Fixed-length binary string</td>
|
|
<td align="left" valign="top" headers="wq1333">Hexadecimal zeros</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1332">Varying-length string</td>
|
|
<td align="left" valign="top" headers="wq1333">A string length of 0</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1332">Date</td>
|
|
<td align="left" valign="top" headers="wq1333">The current date at the time of INSERT</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1332">Time</td>
|
|
<td align="left" valign="top" headers="wq1333">The current time at the time of INSERT</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1332">Timestamp</td>
|
|
<td align="left" valign="top" headers="wq1333">The current timestamp at the time of INSERT</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1332">Datalink</td>
|
|
<td align="left" valign="top" headers="wq1333">A value corresponding to DLVALUE('','URL','')</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1332"><var class="pv">distinct-type</var></td>
|
|
<td align="left" valign="top" headers="wq1333">The default value of the corresponding source
|
|
type of the distinct type.</td>
|
|
</tr>
|
|
</tbody>
|
|
</table>
|
|
<p>Do not specify USING TYPE DEFAULTS if INCLUDING COLUMN
|
|
DEFAULTS is specified.</p>
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
</dl>
|
|
<a name="wq1334"></a>
|
|
<h3 id="wq1334"><a href="rbafzmst02.htm#ToC_934">unique-constraint</a></h3><a id="idx2118" name="idx2118"></a><a id="idx2119" name="idx2119"></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 was previously specified in the CREATE TABLE statement and
|
|
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">PRIMARY KEY(<var class="pv">column-name</var>,...) </dt><a id="idx2120" name="idx2120"></a><a id="idx2121" name="idx2121"></a><a id="idx2122" name="idx2122"></a>
|
|
<dd>Defines a primary key composed of the identified columns. A table can
|
|
only have one primary key. Thus, this clause cannot be specified more than
|
|
once and cannot be specified at all if the shorthand form has been used to
|
|
define a primary key for the table. The identified columns cannot be the same
|
|
as the columns specified in another UNIQUE constraint specified earlier in
|
|
the CREATE TABLE statement. For example, PRIMARY KEY(A,B) would not be allowed
|
|
if UNIQUE (B,A) had already been specified.
|
|
<p>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 byte counts must not exceed 32766-<span class="italic">n</span>, where <span class="italic">n</span> is the number of columns specified
|
|
that allow nulls. For information on byte-counts see <a href="rbafzmsthctabl.htm#bytecount">Table 52</a>.</p>
|
|
<p>The unique index is created as part of the system physical file, not
|
|
a separate system logical file. 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>
|
|
</dd>
|
|
<dt class="bold">UNIQUE (<var class="pv">column-name</var>,...) </dt><a id="idx2123" name="idx2123"></a><a id="idx2124" name="idx2124"></a>
|
|
<dd>Defines a unique constraint composed of the identified columns. The
|
|
UNIQUE clause can be specified more than once. The identified columns cannot
|
|
be the same as the columns specified in another UNIQUE constraint or PRIMARY
|
|
KEY that was specified earlier in the CREATE TABLE statement. For determining
|
|
if a unique constraint is the same as another constraint specification, the
|
|
column lists are compared. For example, UNIQUE (A,B) is the same as UNIQUE
|
|
(B,A).
|
|
<p>Each column-name must be an unqualified name that identifies
|
|
a column of the table. The same column must not be identified more than once.
|
|
The column must not be a LOB or DATALINK column. The number of identified
|
|
columns must not exceed 120, and the sum of their byte counts must not exceed
|
|
32766-<span class="italic">n</span>, where <span class="italic">n</span> is the number
|
|
of columns specified that allows nulls. For information on byte-counts see <a href="rbafzmsthctabl.htm#bytecount">Table 52</a>.</p>
|
|
<p>A unique index on the identified column is created
|
|
during the execution of the CREATE TABLE statement. The unique index is created
|
|
as part of the system physical file, not as a separate system logical file.</p>
|
|
</dd>
|
|
</dl>
|
|
<a name="wq1335"></a>
|
|
<h3 id="wq1335"><a href="rbafzmst02.htm#ToC_935">referential-constraint</a></h3><a id="idx2125" name="idx2125"></a><a id="idx2126" name="idx2126"></a><a id="idx2127" name="idx2127"></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 was previously specified in the CREATE TABLE statement and
|
|
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">FOREIGN KEY </dt><a id="idx2128" name="idx2128"></a>
|
|
<dd>Each specification of the FOREIGN KEY clause defines a referential constraint. <span>FOREIGN KEY is not allowed if the table is a partitioned table.</span>
|
|
<dl class="parml">
|
|
<dt class="bold">(<var class="pv">column-name</var>,...) </dt><a id="idx2129" name="idx2129"></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 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.
|
|
</dd>
|
|
<dt class="bold">REFERENCES <var class="pv">table-name</var> </dt><a id="idx2130" name="idx2130"></a><a id="idx2131" name="idx2131"></a>
|
|
<dd>The <var class="pv">table-name</var> specified in a REFERENCES clause must identify
|
|
the table being created or a base table that already exists at the application server,
|
|
but it <span>must not identify a catalog table, a global temporary
|
|
table, a partitioned table, or a distributed table.</span>
|
|
<p>A referential constraint
|
|
is a <span class="italic">duplicate</span> if its foreign key, parent key, and
|
|
parent table are the same as the foreign key, parent key, and parent table
|
|
of a previously specified referential constraint. Duplicate referential constraints
|
|
are allowed, but not recommended.</p>
|
|
<p>Let T2 denote the identified parent
|
|
table and let T1 denote the table being created.</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 description
|
|
of the <span class="italic">n</span>th column of that parent key must have identical
|
|
data types, lengths, and CCSIDs. </p>
|
|
<dl class="parml">
|
|
<dt class="bold">(<var class="pv">column-name,</var>...) </dt><a id="idx2132" name="idx2132"></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 byte counts
|
|
must not exceed 32766-<span class="italic">n</span>, where <span class="italic">n</span> is the number of columns specified that allow nulls. For information
|
|
on byte-counts see <a href="rbafzmsthctabl.htm#bytecount">Table 52</a>.
|
|
<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 need not be specified in the same
|
|
order as in the primary key; however, they must be specified in corresponding
|
|
order to the list of columns in the <var class="pv">foreign key</var> clause. 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>
|
|
</dd>
|
|
</dl>
|
|
<p>The referential constraint specified by a FOREIGN KEY clause
|
|
defines a relationship in which T2 is the parent and T1 is the dependent.</p>
|
|
</dd><a id="idx2133" name="idx2133"></a><a id="idx2134" name="idx2134"></a><a id="idx2135" name="idx2135"></a><a id="idx2136" name="idx2136"></a><a id="idx2137" name="idx2137"></a><a id="idx2138" name="idx2138"></a><a id="idx2139" name="idx2139"></a>
|
|
<dt class="bold">ON DELETE </dt>
|
|
<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.</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><a id="idx2140" name="idx2140"></a><a id="idx2141" name="idx2141"></a><a id="idx2142" name="idx2142"></a>
|
|
<dt class="bold">ON UPDATE </dt>
|
|
<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="ctcheckcst"></a>
|
|
<h3 id="ctcheckcst"><a href="rbafzmst02.htm#ToC_936">check-constraint</a></h3><a id="idx2143" name="idx2143"></a><a id="idx2144" name="idx2144"></a>
|
|
<dl class="parml">
|
|
<dt class="bold">CONSTRAINT <var class="pv">constraint-name</var></dt>
|
|
<dd>Names the check constraint. A <var class="pv">constraint-name</var> must not identify
|
|
a constraint that was previously specified in the CREATE TABLE statement and
|
|
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">CHECK (<var class="pv">check-condition</var>)</dt><a id="idx2145" name="idx2145"></a>
|
|
<dd>Defines a check constraint. At any time, 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</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_DEGREE, CURRENT SCHEMA, CURRENT SERVER, CURRENT PATH,
|
|
CURRENT DEBUG MODE, SESSION_USER, SYSTEM_USER, and USER special registers</li>
|
|
<li>CURRENT DATE, CURRENT TIME, and CURRENT TIMESTAMP 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, RADIANS, RAND, 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>.
|
|
For more information about check constraints involving LOB data types and
|
|
expressions, see the <a href="../dbp/rbafokickoff.htm">Database Programming</a> book.</p>
|
|
<a name="wq1336"></a>
|
|
<h3 id="wq1336"><a href="rbafzmst02.htm#ToC_937">NOT LOGGED INITIALLY</a></h3><a id="idx2146" name="idx2146"></a>
|
|
<p>Any changes made to the table by INSERT, DELETE, or UPDATE statements in
|
|
the same unit of work after the table is created 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>The NOT LOGGED INITIALLY option is useful for situations where a large
|
|
result set needs to be created with data from an alternate source (another
|
|
table or a file) and recovery of the table is not necessary. Using this option
|
|
will save the overhead of logging (journaling) the data.</p>
|
|
<p>ACTIVATE NOT LOGGED INITIALLY is ignored if the table has a
|
|
DATALINK column with FILE LINK CONTROL.</p>
|
|
<a name="wq1337"></a>
|
|
<h3 id="wq1337"><a href="rbafzmst02.htm#ToC_938">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="idx2147" name="idx2147"></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="idx2148" name="idx2148"></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="wq1338"></a>
|
|
<h3 id="wq1338"><a href="rbafzmst02.htm#ToC_939">distribution-clause</a></h3>
|
|
<dl class="parml">
|
|
<dt class="bold">IN <var class="pv">nodegroup-name</var> </dt><a id="idx2149" name="idx2149"></a><a id="idx2150" name="idx2150"></a>
|
|
<dd>Specifies the nodegroup across which the data in the table will be distributed.
|
|
The name must identify a nodegroup that exists at the current server. If this
|
|
clause is specified, the table is created as a distributed table across all
|
|
the systems in the nodegroup.
|
|
<p>A LOB, DATALINK, or IDENTITY column
|
|
is not allowed in a distributed table.</p>
|
|
<p>The DB2 Multisystem product must be
|
|
installed to create a distributed table. For more information about distributed
|
|
tables, see the <a href="../dbmult/rzaf3kickoff.htm">DB2® Multisystem</a> book.</p>
|
|
</dd>
|
|
<dt class="bold">DISTRIBUTE BY HASH (<var class="pv">column-name</var>,...) </dt><a id="idx2151" name="idx2151"></a>
|
|
<dd>Specifies the partitioning key. The partitioning key is used to determine
|
|
on which node in the nodegroup a row will be placed. 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. If the DISTRIBUTE BY clause
|
|
is not specified, the first column of the primary key is used as the partitioning
|
|
key. If there is no primary key, the first column of the table that is not
|
|
floating point, date, time, or timestamp is used as the partitioning key.
|
|
<p>The columns that make up the partitioning key must be a subset of the columns
|
|
that make up any unique constraints over the table. Floating point, LOB, DataLink,
|
|
and ROWID columns cannot be used in a partitioning key.</p>
|
|
</dd>
|
|
</dl>
|
|
<a name="wq1339"></a>
|
|
<h3 id="wq1339"><a href="rbafzmst02.htm#ToC_940">partitioning-clause</a></h3>
|
|
<dl class="parml">
|
|
<dt class="bold">PARTITION BY RANGE</dt><a id="idx2152" name="idx2152"></a>
|
|
<dd>Specifies that ranges of column values are used to determine
|
|
the target data partition when inserting a row into the table. The number
|
|
of partitions must not exceed 256. <span>A table cannot be partitioned
|
|
if it contains an identity column.</span>
|
|
<dl class="parml">
|
|
<dt class="bold"><var class="pv">column-name</var> </dt><a id="idx2153" name="idx2153"></a>
|
|
<dd>Specifies a column in the partitioning key. The partitioning key is
|
|
used to determine into which partition in the table a row will be placed.
|
|
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.
|
|
<p>Floating
|
|
point, LOB, DataLink, and ROWID columns cannot be used in a partitioning key.</p>
|
|
</dd>
|
|
<dt class="bold">NULLS LAST</dt><a id="idx2154" name="idx2154"></a>
|
|
<dd>Indicates that null values are treated as positive infinity for comparison
|
|
purposes.
|
|
</dd>
|
|
<dt class="bold">NULLS FIRST</dt><a id="idx2155" name="idx2155"></a>
|
|
<dd>Indicates that null values are treated as negative infinity for comparison
|
|
purposes.
|
|
</dd>
|
|
</dl>
|
|
<dl class="parml">
|
|
<dt class="bold">PARTITION <var class="pv">partition-name</var> </dt><a id="idx2156" name="idx2156"></a>
|
|
<dd>Names the partition. A <var class="pv">partition-name</var> must not identify a data
|
|
partition that was previously specified in the CREATE TABLE statement.
|
|
<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>
|
|
<dd>Specifies the boundaries of a range partition. The boundaries must be
|
|
specified in ascending sequence. The ranges must not overlap.
|
|
<dl class="parml">
|
|
<dt class="bold"><var class="pv">starting-clause</var></dt>
|
|
<dd>Specifies the low end of the range for a data partition. The number
|
|
of specified starting values must be the same as the number of columns in
|
|
the partitioning key.
|
|
<dl class="parml">
|
|
<dt class="bold">STARTING FROM</dt>
|
|
<dd>Introduces the <var class="pv">starting-clause</var>.
|
|
</dd>
|
|
<dt class="bold"><var class="pv">constant</var></dt>
|
|
<dd>Specifies a constant that must conform to the rules of a constant for
|
|
the data type of the corresponding column of the partition key. If the corresponding
|
|
column of the partition key is a distinct type, the constant must conform
|
|
to the rules of the source type of the distinct type. The value must not be
|
|
in the range of any other <var class="pv">boundary-spec</var> for the table.
|
|
</dd>
|
|
<dt class="bold">MINVALUE</dt>
|
|
<dd>Specifies a value lower than the lowest possible value for
|
|
the data type of the corresponding column of the partition key. If MINVALUE
|
|
is specified, all subsequent values in the <var class="pv">starting-clause</var> must also
|
|
be MINVALUE.
|
|
</dd>
|
|
<dt class="bold">INCLUSIVE</dt>
|
|
<dd>Specifies that the specified range values are included in the data partition.
|
|
</dd>
|
|
<dt class="bold">EXCLUSIVE</dt>
|
|
<dd>Specifies that the specified range values are excluded from the data
|
|
partition. This specification is ignored when MINVALUE or MAXVALUE is specified.
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold"><var class="pv">ending-clause</var></dt>
|
|
<dd>Specifies the high end of the range for a data partition. The number
|
|
of specified ending values must be the same as the number of columns in the
|
|
data partitioning key.
|
|
<dl class="parml">
|
|
<dt class="bold">ENDING AT</dt>
|
|
<dd>Introduces the <var class="pv">ending-clause</var>.
|
|
</dd>
|
|
<dt class="bold"><var class="pv">constant</var></dt>
|
|
<dd>Specifies a constant that must conform to the rules of a constant for
|
|
the data type of the corresponding column of the partition key. If the corresponding
|
|
column of the partition key is a distinct type, the constant must conform
|
|
to the rules of the source type of the distinct type. The value must not be
|
|
in the range of any other <var class="pv">boundary-spec</var> for the table.
|
|
</dd>
|
|
<dt class="bold">MAXVALUE</dt>
|
|
<dd>Specifies a value higher than the highest possible value
|
|
for the data type of the corresponding column of the partition key. If MAXVALUE
|
|
is specified, all subsequent values in the <var class="pv">ending-clause</var> must also
|
|
be MAXVALUE.
|
|
</dd>
|
|
<dt class="bold">INCLUSIVE</dt>
|
|
<dd>Specifies that the specified range values are included in the data partition.
|
|
</dd>
|
|
<dt class="bold">EXCLUSIVE</dt>
|
|
<dd>Specifies that the specified range values are excluded from the data
|
|
partition. This specification is ignored when MINVALUE or MAXVALUE is specified.
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold">EVERY <var class="pv">integer-constant</var></dt>
|
|
<dd>Specifies that multiple data partitions will be added where <var class="pv">integer-constant</var> specifies the width of each data partition range. If EVERY is specified,
|
|
only a single SMALLINT, INTEGER, BIGINT, DECIMAL, NUMERIC, DATE, or TIMESTAMP
|
|
column can be specified for the partition key.
|
|
<p>The starting value of the
|
|
first data partition is the specified STARTING value. The starting value of
|
|
each subsequent partition is the starting value of the previous partition
|
|
+ <var class="pv">integer-constant</var>. If the <var class="pv">starting-clause</var> specified EXCLUSIVE,
|
|
the starting value of every partition is EXCLUSIVE. Otherwise, the starting
|
|
value of every partition is INCLUSIVE.</p>
|
|
<p>The ending value of every partition
|
|
of the range is (start + <var class="pv">integer-constant</var> - 1). If the <var class="pv">ending-clause</var> specified EXCLUSIVE, the ending value of every partition is EXCLUSIVE.
|
|
Otherwise, the ending value of every partition is INCLUSIVE.</p>
|
|
<p>The number
|
|
of partitions added is determined by adding <var class="pv">integer-constant</var> repeatedly
|
|
to the STARTING value until the ENDING value is reached. For example: </p>
|
|
<pre class="xmp"> <span class="bold">CREATE TABLE</span> FOO
|
|
<span class="bold">(</span>A <span class="bold"> INT)</span>
|
|
<span class="bold">PARTITION BY RANGE(</span>A<span class="bold">)</span>
|
|
<span class="bold">(STARTING(</span>1<span class="bold">) ENDING(</span>10<span class="bold">) EVERY(</span>2<span class="bold">))</span></pre><p class="indatacontent">is equivalent to
|
|
the following CREATE TABLE statement:</p>
|
|
<pre class="xmp"> <span class="bold">CREATE TABLE</span> FOO
|
|
<span class="bold">(</span>A <span class="bold"> INT)</span>
|
|
<span class="bold">(PARTITION BY RANGE(</span>A<span class="bold">)</span>
|
|
<span class="bold">(STARTING(</span>1<span class="bold">) ENDING(</span>2<span class="bold">),</span>
|
|
<span class="bold"> STARTING(</span>3<span class="bold">) ENDING(</span>4<span class="bold">),</span>
|
|
<span class="bold"> STARTING(</span>5<span class="bold">) ENDING(</span>6<span class="bold">),</span>
|
|
<span class="bold"> STARTING(</span>7<span class="bold">) ENDING(</span>8<span class="bold">),</span>
|
|
<span class="bold"> STARTING(</span>9<span class="bold">) ENDING(</span>10<span class="bold">))</span></pre>
|
|
<p>In the case of dates and timestamps, the
|
|
EVERY value must be a labeled duration. For example: </p>
|
|
<pre class="xmp"> <span class="bold">CREATE TABLE</span> FOO
|
|
<span class="bold">(</span>A <span class="bold"> DATE)</span>
|
|
<span class="bold">PARTITION BY RANGE(</span>A<span class="bold">)</span>
|
|
<span class="bold">(STARTING(</span>'2001-01-01'<span class="bold">) ENDING(</span>'2010-01-01'<span class="bold">) EVERY(</span>3<span class="bold"> MONTHS))</span></pre>
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold">PARTITION BY HASH</dt><a id="idx2157" name="idx2157"></a>
|
|
<dd>Specifies that the hash function is used to determine the target data
|
|
partition when inserting a row into the table. <span>A table cannot
|
|
be partitioned if it contains an identity column.</span>
|
|
<dl class="parml">
|
|
<dt class="bold">(<var class="pv">column-name</var>,...) </dt><a id="idx2158" name="idx2158"></a>
|
|
<dd>Specifies the partitioning key. The partitioning key is used to determine
|
|
into which partition in the table a row will be placed. 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.
|
|
<p>The columns that make
|
|
up the partitioning key must be a subset of the columns that make up any unique
|
|
constraints over the table. Floating point, LOB, date, time, timestamp, DataLink,
|
|
and ROWID columns cannot be used in a partitioning key.</p>
|
|
</dd>
|
|
<dt class="bold">INTO <var class="pv">integer</var> PARTITIONS</dt><a id="idx2159" name="idx2159"></a>
|
|
<dd>Specifies the number of partitions. The number of partitions must not
|
|
exceed 256.
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
</dl>
|
|
<a name="unctabl"></a>
|
|
<h3 id="unctabl"><a href="rbafzmst02.htm#ToC_941">Notes</a></h3>
|
|
<p><span class="bold">Table attributes:</span> Tables are created as physical
|
|
files. When a table is created, the file wait time and record wait time attributes
|
|
are set to the default that is specified on the WAITFILE and WAITRCD keywords
|
|
of the Create Physical File (CRTLF) command.</p>
|
|
<p>SQL tables are created so that space used by deleted rows will be reclaimed
|
|
by future insert requests. This attribute can be changed via the command <var class="pv">CHGPF</var> and specifying the <var class="pv">REUSEDLT(*NO)</var> parameter. For more information
|
|
about the <var class="pv">CHGPF</var> command, see the <a href="../rbam6/rbam6clmain.htm">CL Reference</a> information in the <span class="bold">Programming</span> category of the iSeries Information Center.</p>
|
|
<p>A distributed table is created on all of the servers across which the table
|
|
is distributed. For more information about distributed tables, see the <a href="../dbmult/rzaf3kickoff.htm">DB2 Multisystem</a> book.</p>
|
|
<p><span class="bold">Table journaling:</span> When a table is created, journaling
|
|
may be automatically started.</p>
|
|
<ul>
|
|
<li>If a data area called QDFTJRN exists in the same schema that the table
|
|
is created into and the user is authorized to the data area, journaling will
|
|
be started to the journal named in the data area if all the following are
|
|
true:
|
|
<ul>
|
|
<li>The identified schema for the table must not be QSYS, QSYS2,
|
|
QRECOVERY, QSPL, QRCL, QRPLOBJ, QGPL, QTEMP, SYSIBM, or any of the iASP equivalents
|
|
to these libraries.</li>
|
|
<li>The journal specified in the data area must exist and the user must be
|
|
authorized to start journaling to the journal.</li>
|
|
<li>The first 10 bytes of the data area must contain the name of the schema
|
|
in which to find the journal.</li>
|
|
<li>The second 10 bytes must contain the name of the journal.</li>
|
|
<li>The remaining bytes contain the object types being implicitly
|
|
journaled and the options that affect when implicit journaling is performed.
|
|
The object type must include the value *FILE or *ALL. The value *NONE can
|
|
be used to prevent journaling from being started.</li></ul> For more information, see the <a href="../rzaki/rzakikickoff.htm">Journal Management</a> topic in the iSeries™ Information Center.</li>
|
|
<li>If a data area called QDFTJRN does not exist in the same schema that the
|
|
table is created into or the user is not authorized to the data area, journaling
|
|
will be started to a journal called QSQJRN if it exists in the same schema
|
|
that the table is created into.</li></ul>
|
|
<p><span class="bold">Table ownership:</span> If SQL names were specified:</p>
|
|
<ul>
|
|
<li>If a user profile with the same name as the schema into which the table
|
|
is created exists, the <span class="italic">owner</span> of the table is that
|
|
user profile.</li>
|
|
<li>Otherwise, the <span class="italic">owner</span> of the table is the user
|
|
profile or group user profile of the job executing the statement.</li></ul>
|
|
<p>If system names were specified, the <span class="italic">owner</span> of the
|
|
table is the user profile or group user profile of the job executing the statement.</p>
|
|
<p><span class="bold">Table authority:</span> If SQL names are used, tables are
|
|
created with the system authority of *EXCLUDE to *PUBLIC. If system names
|
|
are used, tables are created with the authority to *PUBLIC as determined by
|
|
the create authority (CRTAUT) parameter of the schema.</p>
|
|
<p>If the owner of the table is a member of a group profile (GRPPRF keyword)
|
|
and group authority is specified (GRPAUT keyword), that group profile will
|
|
also have authority to the table.</p>
|
|
<p><span class="bold">Owner privileges:</span> The owner of the table
|
|
has all table privileges (see <a href="rbafzmstgnt.htm#gnt">GRANT (Table or View Privileges)</a>) with the ability to grant
|
|
these privileges to others.</p>
|
|
<p><span class="bold">Using an identity column:</span> When a table
|
|
has an identity column, the database manager can automatically generate sequential
|
|
numeric values for the column as rows are inserted into the table. Thus, identity
|
|
columns are ideal for primary keys.</p>
|
|
<p>Identity columns and ROWID columns are similar in that both types of columns
|
|
contain values that the database manager generates. ROWID columns can be useful in direct-row
|
|
access. ROWID columns contain values of the ROWID data type, which returns
|
|
a 40-byte VARCHAR value that is not regularly ascending or descending. ROWID
|
|
data values are therefore not well suited to many application uses, such as
|
|
generating employee numbers or product numbers. For data that does not require
|
|
direct-row access, identity columns are usually a better approach, because
|
|
identity columns contain existing numeric data types and can be used in a
|
|
wide variety of uses for which ROWID values would not be suitable.</p>
|
|
<p>When a table is recovered to a point-in-time (using RMVJRNCHG), it is possible
|
|
that a large gap in the sequence of generated values for the identity column
|
|
might result. For example, assume a table has an identity column that has
|
|
an incremental value of 1 and that the last generated value at time T1 was
|
|
100 and the database manager subsequently generates values up to 1000. Now, assume that
|
|
the table is recovered back to time T1. The generated value of the identity
|
|
column for the next row that is inserted after the recovery completes will
|
|
be 1001, leaving a gap from 100 to 1001 in the values of the identity column.</p>
|
|
<p>When CYCLE is specified duplicate values for a column may be generated
|
|
even when the column is GENERATED ALWAYS, unless a unique constraint or unique
|
|
index is defined on the column.</p>
|
|
<p><span class="bold">Creating materialized query tables:</span> To
|
|
ensure that the materialized query table has data before being used by a query:</p>
|
|
<ul>
|
|
<li>DATA INITIALLY IMMEDIATE should be used to create materialized query tables,
|
|
or</li>
|
|
<li>the materialized query table should be created with query optimization
|
|
disabled and then enable the table for query optimization after it is refreshed.</li></ul>
|
|
<p>The isolation level at the time when the CREATE TABLE statement is executed
|
|
is the isolation level for the materialized query table. The <var class="pv">isolation-clause</var> can be used to explicitly specify the isolation level.</p>
|
|
<p><span class="bold">Partitioned table performance:</span> The larger the number
|
|
of partitions in a partitioned table, the greater the overhead in SQL data
|
|
change and SQL data statements. You should create a partitioned table with
|
|
the minimum number of partitions that are required to minimize this overhead.
|
|
It is also highly recommended that a parallelism degree greater than one be
|
|
considered when accessing a partitioned table.</p>
|
|
<p><span class="bold">Syntax alternatives:</span> The following keywords are synonyms
|
|
supported for compatibility to prior releases. These keywords are non-standard
|
|
and should not be used:</p>
|
|
<ul>
|
|
<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>DEFINITION ONLY is a synonym for WITH NO DATA</li>
|
|
<li>PARTITIONING KEY is a synonym for DISTRIBUTE BY HASH.</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 a partition
|
|
that was previously specified in the CREATE 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></ul>
|
|
<a name="maxrcd"></a>
|
|
<h4 id="maxrcd">Maximum row sizes</h4>
|
|
<p>There are two maximum row size restrictions referred to in the description
|
|
of <var class="pv">column-definition</var>.</p>
|
|
<ul>
|
|
<li>The maximum row buffer size is 32766 or, if a VARCHAR, VARGRAPHIC, or
|
|
LOB column is specified, 32740.</li>
|
|
<li>The maximum row data size is 3 758 096 383, if a LOB is specified. If
|
|
a LOB is not specified, then the maximum row data size is 32766 or, if a VARCHAR
|
|
or VARGRAPHIC column is specified, 32740.</li></ul><p class="indatacontent">To determine the length of a row buffer and/or row data add the corresponding
|
|
length of each column of that row based on the byte counts of the data type.</p>
|
|
<p>The follow table gives the byte counts of columns by data type for columns
|
|
that do not allow null values. If any column allows null values, one byte
|
|
is required for every eight columns. </p>
|
|
<a name="bytecount"></a>
|
|
<table id="bytecount" width="100%" summary="" border="1" frame="border" rules="all">
|
|
<caption>Table 52. Byte Counts of Columns by Data Type</caption>
|
|
<thead valign="bottom">
|
|
<tr>
|
|
<th id="wq1340" width="33%" align="left" valign="top">Data Type</th>
|
|
<th id="wq1341" width="33%" align="left" valign="top">Row Buffer Byte Count</th>
|
|
<th id="wq1342" width="33%" align="left" valign="top">Row Data Byte Count</th>
|
|
</tr>
|
|
</thead>
|
|
<tbody valign="top">
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340">SMALLINT</td>
|
|
<td align="left" valign="top" headers="wq1341">2</td>
|
|
<td align="left" valign="top" headers="wq1342">2</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340">INTEGER</td>
|
|
<td align="left" valign="top" headers="wq1341">4</td>
|
|
<td align="left" valign="top" headers="wq1342">4</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340">BIGINT</td>
|
|
<td align="left" valign="top" headers="wq1341">8</td>
|
|
<td align="left" valign="top" headers="wq1342">8</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340">DECIMAL( <var class="pv">p</var>, <var class="pv">s</var>)</td>
|
|
<td align="left" valign="top" headers="wq1341">The integral part of (<var class="pv">p</var>/2) + 1</td>
|
|
<td align="left" valign="top" headers="wq1342">The integral part of (<var class="pv">p</var>/2) + 1</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340">NUMERIC( <var class="pv">p</var>, <var class="pv">s</var>)</td>
|
|
<td align="left" valign="top" headers="wq1341"><var class="pv">p</var></td>
|
|
<td align="left" valign="top" headers="wq1342"><var class="pv">p</var></td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340">FLOAT (single precision)</td>
|
|
<td align="left" valign="top" headers="wq1341">4</td>
|
|
<td align="left" valign="top" headers="wq1342">4</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340">FLOAT (double precision)</td>
|
|
<td align="left" valign="top" headers="wq1341">8</td>
|
|
<td align="left" valign="top" headers="wq1342">8</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340">CHAR( <var class="pv">n</var>)</td>
|
|
<td align="left" valign="top" headers="wq1341"><var class="pv">n</var></td>
|
|
<td align="left" valign="top" headers="wq1342"><var class="pv">n</var></td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340">VARCHAR( <var class="pv">n</var>)</td>
|
|
<td align="left" valign="top" headers="wq1341"><var class="pv">n</var>+2</td>
|
|
<td align="left" valign="top" headers="wq1342"><var class="pv">n</var>+2</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340">CLOB( <var class="pv">n</var>)</td>
|
|
<td align="left" valign="top" headers="wq1341">29+<var class="pv">pad</var></td>
|
|
<td align="left" valign="top" headers="wq1342"><var class="pv">n</var>+29</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340">GRAPHIC(<var class="pv">n</var>)</td>
|
|
<td align="left" valign="top" headers="wq1341"><var class="pv">n</var>*2</td>
|
|
<td align="left" valign="top" headers="wq1342"><var class="pv">n</var>*2</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340">VARGRAPHIC (n)</td>
|
|
<td align="left" valign="top" headers="wq1341"><var class="pv">n</var>*2+2</td>
|
|
<td align="left" valign="top" headers="wq1342"><var class="pv">n</var>*2+2</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340">DBCLOB( <var class="pv">n</var>)</td>
|
|
<td align="left" valign="top" headers="wq1341">29+<var class="pv">pad</var></td>
|
|
<td align="left" valign="top" headers="wq1342"><var class="pv">n</var>*2+29</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340">BINARY( <var class="pv">n</var>)</td>
|
|
<td align="left" valign="top" headers="wq1341"><var class="pv">n</var></td>
|
|
<td align="left" valign="top" headers="wq1342"><var class="pv">n</var></td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340">VARBINARY( <var class="pv">n</var>)</td>
|
|
<td align="left" valign="top" headers="wq1341"><var class="pv">n</var>+2</td>
|
|
<td align="left" valign="top" headers="wq1342"><var class="pv">n</var>+2</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340">BLOB( <var class="pv">n</var>)</td>
|
|
<td align="left" valign="top" headers="wq1341">29+<var class="pv">pad</var></td>
|
|
<td align="left" valign="top" headers="wq1342"><var class="pv">n</var>+29</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340">DATE</td>
|
|
<td align="left" valign="top" headers="wq1341">10</td>
|
|
<td align="left" valign="top" headers="wq1342">4</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340">TIME</td>
|
|
<td align="left" valign="top" headers="wq1341">8</td>
|
|
<td align="left" valign="top" headers="wq1342">3</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340">TIMESTAMP</td>
|
|
<td align="left" valign="top" headers="wq1341">26</td>
|
|
<td align="left" valign="top" headers="wq1342">10</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340">DATALINK( <var class="pv">n</var>)</td>
|
|
<td align="left" valign="top" headers="wq1341"><var class="pv">n</var>+24</td>
|
|
<td align="left" valign="top" headers="wq1342"><var class="pv">n</var>+24</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340">ROWID</td>
|
|
<td align="left" valign="top" headers="wq1341">42</td>
|
|
<td align="left" valign="top" headers="wq1342">28</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="top" headers="wq1340"><var class="pv">distinct-type</var></td>
|
|
<td align="left" valign="top" headers="wq1341">The byte count for the source type.</td>
|
|
<td align="left" valign="top" headers="wq1342">The byte count for the source type.</td>
|
|
</tr>
|
|
<tr>
|
|
<td colspan="3" align="left" valign="top" headers="wq1340 wq1341 wq1342">
|
|
<a name="wq1343"></a>
|
|
<div class="notetitle" id="wq1343">Notes:</div>
|
|
<div class="notebody">
|
|
<p><var class="pv">pad</var> is a value from 1 to 15 necessary
|
|
for boundary alignment.</p></div></td>
|
|
</tr>
|
|
</tbody>
|
|
</table>
|
|
<a name="wq1344"></a>
|
|
<h4 id="wq1344">Precision as described to the database:</h4>
|
|
<ul>
|
|
<li>Floating-point fields are defined in the iSeries database with a decimal
|
|
precision, not a bit precision. The algorithm used to convert the number of
|
|
bits to decimal is <var class="pv">decimal precision</var> = <var class="pv">CEILING(n/3.31)</var>,
|
|
where <var class="pv">n</var> is the number of bits to convert. The decimal precision is
|
|
used to determine how many digits to display using interactive SQL.</li>
|
|
<li>SMALLINT fields are stored with a decimal precision of 4,0.</li>
|
|
<li>INTEGER fields are stored with a decimal precision of 9,0.</li>
|
|
<li>BIGINT fields are stored with a decimal precision of 19,0.</li></ul>
|
|
<a name="lngnt"></a>
|
|
<h4 id="lngnt">LONG VARCHAR and LONG VARGRAPHIC</h4>
|
|
<p>The non-standard syntax of LONG VARCHAR and LONG VARGRAPHIC is supported,
|
|
but deprecated. The alternative standard syntax of VARCHAR(integer) and VARGRAPHIC(integer),
|
|
is preferred. VARCHAR(integer) and VARGRAPHIC(integer) are recommended. After
|
|
the CREATE TABLE statement is processed, the database manager considers a
|
|
LONG VARCHAR column to be VARCHAR and a LONG VARGRAPHIC column to be VARGRAPHIC.
|
|
The maximum length is calculated in a product-specific fashion that is not
|
|
portable.</p>
|
|
<dl class="parml">
|
|
<dt class="bold">LONG VARCHAR <span><sup class="fn"><a href="rbafzmsthctabl.htm#longfn2">68</a></sup></span> </dt><a id="idx2160" name="idx2160"></a>
|
|
<dd>For a varying length character string whose maximum length is determined
|
|
by the amount of space available in the row.
|
|
</dd>
|
|
<dt class="bold">LONG VARGRAPHIC <span><sup class="fn"><a href="rbafzmsthctabl.htm#longfn2">68</a></sup></span> </dt><a id="idx2161" name="idx2161"></a>
|
|
<dd>For a varying length graphic string whose maximum length is determined
|
|
by the amount of space available in the row.
|
|
</dd>
|
|
</dl>
|
|
<p>The maximum length of a LONG column is determined as follows. Let: </p>
|
|
<ul>
|
|
<li><tt class="xph">i</tt> be the sum of the row buffer byte counts of all columns in
|
|
the table that are not LONG VARCHAR or LONG VARGRAPHIC</li>
|
|
<li><tt class="xph">j</tt> be the number of LONG VARCHAR and LONG VARGRAPHIC columns
|
|
in the table</li>
|
|
<li><tt class="xph">k</tt> be the number of columns in the row that allow nulls.</li></ul><p class="indatacontent"> The length of each LONG VARCHAR column is INTEGER((32716 - <tt class="xph">i</tt>-((<tt class="xph">k</tt>+7)/8))/<tt class="xph">j</tt>).</p>
|
|
<p>The length of each LONG VARGRAPHIC column is determined by taking the length
|
|
calculated for a LONG VARCHAR column and dividing it by 2. The integer portion
|
|
of the result is the length.</p>
|
|
<a name="ctsysrl"></a>
|
|
<h3 id="ctsysrl"><a href="rbafzmst02.htm#ToC_945">Rules for System Name Generation</a></h3><a id="idx2162" name="idx2162"></a><a id="idx2163" name="idx2163"></a>
|
|
<p>There are specific instances when the system generates a system table,
|
|
view, index, or column name. These instances and the name generation rules
|
|
are described in the following sections.</p>
|
|
<a name="cnamrul"></a>
|
|
<h4 id="cnamrul">Rules for Column Name Generation</h4><a id="idx2164" name="idx2164"></a>
|
|
<p>A system-column-name is generated if the system-column-name is not specified
|
|
when a table or view is created and the column-name is not a valid system-column-name.</p>
|
|
<p>If the column-name does not contain special characters and is longer than
|
|
10 characters, a 10-character system-column-name will be generated as: </p>
|
|
<ul>
|
|
<li>The first 5 characters of the name</li>
|
|
<li>A 5 digit unique number</li></ul>
|
|
<p>For example: </p>
|
|
<pre class="xmp">The system-column-name for LONGCOLUMNNAME would be LONGC00001</pre>
|
|
<p>If the column name is delimited: </p>
|
|
<ul>
|
|
<li>The first 5 characters from within the delimiters will be used as the
|
|
first 5 characters of the system-column-name. If there are fewer than 5 characters
|
|
within the delimiters, the name will be padded on the right with underscore
|
|
(_) characters. Lower case characters are folded to upper case characters.
|
|
The only valid characters in a system-column-name are: A-Z, 0-9, @, #, $,
|
|
and _. Any other characters will be changed to the underscore (_) character.
|
|
If the first character ends up as an underscore, it will be changed to the
|
|
letter Q.</li>
|
|
<li>A 5 digit unique number is appended to the 5 characters.</li></ul>
|
|
<p>For example: </p>
|
|
<pre class="xmp"> The system-column-name for "abc" would be ABC__00001
|
|
The system-column-name for "COL2.NAME" would be COL2_00001
|
|
The system-column-name for "C 3" would be C_3__00001
|
|
The system-column-name for "??" would be Q____00001
|
|
The system-column-name for "*column1" would be QCOLU00001</pre>
|
|
<a name="namrul"></a>
|
|
<h4 id="namrul">Rules for Table Name Generation</h4><a id="idx2165" name="idx2165"></a><a id="idx2166" name="idx2166"></a>
|
|
<p>A system name will be generated if a table, view, alias, or index is created
|
|
with either: </p>
|
|
<ul>
|
|
<li>A name longer than 10 characters</li>
|
|
<li>A name that contains characters not valid in a system name</li></ul><p class="indatacontent"> The SQL name or its corresponding system name may both be used in SQL
|
|
statements to access the file once it is created. However, the SQL name is
|
|
only recognized by DB2 UDB for iSeries and the system name must be used in other environments.</p>
|
|
<p>If the name does not contain special characters and is longer than 10 characters,
|
|
a 10-character system name will be generated as: </p>
|
|
<ul>
|
|
<li>The first 5 characters of the name</li>
|
|
<li>A 5 digit unique number</li></ul>
|
|
<p>For example: </p>
|
|
<pre class="xmp"> The system name for LONGTABLENAME would be LONGT00001</pre>
|
|
<p>If the SQL name contains special characters, the system name is generated
|
|
as: </p>
|
|
<ul>
|
|
<li>The first 4 characters of the name</li>
|
|
<li>A 4 digit unique number</li></ul>
|
|
<p>In addition: </p>
|
|
<ul>
|
|
<li>All special characters are replaced by the underscore (_)</li>
|
|
<li>Any trailing blanks are removed from the name</li>
|
|
<li>The name is delimited by double quotes (") if the delimiters are required
|
|
for the name to be a valid system name.</li></ul>
|
|
<p>For example: </p>
|
|
<pre class="xmp"> The system name for "??" would be "__0001"
|
|
The system name for "longtablename" would be "long0001"
|
|
The system name for "LONGTableName" would be LONG0001
|
|
The system name for "A b " would be "A_b0001"</pre>
|
|
<p>SQL ensures the system name is unique by searching the cross reference
|
|
file. If the name already exists in the cross reference file, the number is
|
|
incremented until the name is no longer a duplicate.</p>
|
|
<p>If a unique name cannot be determined using the above rules, an additional
|
|
character is added to the counter in the name, and the number is incremented
|
|
until a unique name can be found or the range is exhausted. For example, if
|
|
creating "longtablename" and names "long0001" through "long9999" already exist,
|
|
the name would become "lon00001".</p>
|
|
<a name="wq1345"></a>
|
|
<h3 id="wq1345"><a href="rbafzmst02.htm#ToC_948">Examples</a></h3>
|
|
<p><span class="italic">Example 1:</span> Given administrative authority, create
|
|
a table named 'ROSSITER.INVENTORY' with the following columns: </p>
|
|
<dl>
|
|
<dt class="bold">Part number</dt>
|
|
<dd>Small integer, must not be null
|
|
</dd>
|
|
<dt class="bold">Description</dt>
|
|
<dd>Character of length 0 to 24, allows nulls
|
|
</dd>
|
|
<dt class="bold">Quantity on hand,</dt>
|
|
<dd>Integer allows nulls
|
|
</dd>
|
|
</dl>
|
|
<p></p>
|
|
<pre class="xmp"> <span class="bold">CREATE TABLE</span> ROSSITER.INVENTORY
|
|
<span class="bold">(</span>PARTNO <span class="bold">SMALLINT NOT NULL,</span>
|
|
DESCR <span class="bold">VARCHAR(</span>24<span class="bold">),</span>
|
|
QONHAND <span class="bold">INT)</span></pre>
|
|
<p><span class="italic">Example 2:</span> Create a table named DEPARTMENT with
|
|
the following columns: </p>
|
|
<dl>
|
|
<dt class="bold">Department number</dt>
|
|
<dd>Character of length 3, must not be null
|
|
</dd>
|
|
<dt class="bold">Department name</dt>
|
|
<dd>Character of length 0 through 36, must not be null
|
|
</dd>
|
|
<dt class="bold">Manager number</dt>
|
|
<dd>Character of length 6
|
|
</dd>
|
|
<dt class="bold">Administrative dept.</dt>
|
|
<dd>Character of length 3, must not be null
|
|
</dd>
|
|
<dt class="bold">Location name</dt>
|
|
<dd>Character of length 16, allows nulls
|
|
</dd>
|
|
</dl>
|
|
<p>The primary key is column DEPTNO. </p>
|
|
<a name="refctb"></a>
|
|
<pre id="refctb" class="xmp"> <span class="bold">CREATE TABLE</span> DEPARTMENT
|
|
<span class="bold">(</span>DEPTNO <span class="bold">CHAR(</span>3<span class="bold">) NOT NULL</span>,
|
|
DEPTNAME <span class="bold">VARCHAR(</span>36<span class="bold">) NOT NULL</span>,
|
|
MGRNO <span class="bold">CHAR(</span>6<span class="bold">)</span>,
|
|
ADMRDEPT <span class="bold">CHAR(</span>3<span class="bold">) NOT NULL</span>,
|
|
LOCATION <span class="bold">CHAR(</span>16<span class="bold">)</span>,
|
|
<span class="bold">PRIMARY KEY(</span>DEPTNO<span class="bold">))</span></pre>
|
|
<p><span class="italic">Example 3:</span> Create a table named REORG_PROJECTS
|
|
which has the same column definitions as the columns in the view PRJ_LEADER.</p>
|
|
<pre class="xmp"> <span class="bold">CREATE TABLE</span> REORG_PROJECTS
|
|
<span class="bold">LIKE</span> PRJ_LEADER</pre>
|
|
<p><span class="italic">Example 4:</span> Create an EMPLOYEE2 table with an identity
|
|
column named EMP_NO. Define the identity column so that DB2 will always
|
|
generate the values for the column. Use the default value, which is 1, for
|
|
the first value that should be assigned and for the incremental difference
|
|
between the subsequently generated consecutive numbers.</p>
|
|
<pre class="xmp"> <span class="bold">CREATE TABLE</span> EMPLOYEE2
|
|
<span class="bold">(</span> EMPNO <span class="bold">INTEGER GENERATED ALWAYS AS IDENTITY</span>,
|
|
ID <span class="bold">SMALLINT</span>,
|
|
NAME <span class="bold">CHAR(30)</span>,
|
|
SALARY <span class="bold">DECIMAL(5,2)</span>,
|
|
DEPTNO <span class="bold">SMALLINT)</span></pre>
|
|
<p><span class="italic">Example 5:</span> Assume a very large transaction table
|
|
named TRANS contains one row for each transaction processed by a company.
|
|
The table is defined with many columns. Create a materialized query table
|
|
for the TRANS table that contains daily summary data for the date and amount
|
|
of a transaction.</p>
|
|
<pre class="xmp"> <span class="bold">CREATE TABLE</span> STRANS
|
|
<span class="bold">AS (SELECT</span> YEAR <span class="bold">AS</span> SYEAR, MONTH <span class="bold">AS</span> SMONTH, DAY <span class="bold">AS</span> SDAY, <span class="bold">SUM(</span>AMOUNT<span class="bold">) AS</span> SSUM
|
|
<span class="bold">FROM</span> TRANS
|
|
<span class="bold">GROUP BY</span> YEAR, MONTH, DAY <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>
|
|
<hr /><div class="fnnum"><a id="longfn2" name="longfn2">68</a>.</div>
|
|
<div class="fntext">This option is provided for compatibility with other
|
|
products. It is recommended that VARCHAR(integer) or VARGRAPHIC(integer)
|
|
be specified instead.</div>
|
|
<br />
|
|
<hr /><br />
|
|
[ <a href="#Top_Of_Page">Top of Page</a> | <a href="rbafzmstcsequence.htm">Previous Page</a> | <a href="rbafzmsthctrigger.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>
|