ibm-information-center/dist/eclipse/plugins/i5OS.ic.db2_5.4.0.1/rbafzmstxcindx.htm

266 lines
15 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 INDEX statement, CREATE INDEX,
SQL statements, INDEX clause, UNIQUE clause, in CREATE INDEX statement,
WHERE NOT NULL clause, ENCODED VECTOR clause, index-name, ON clause, table-name,
ASC clause, DESC clause, WITH DISTINCT VALUES clause, PARTITIONED clause,
NOT PARTITIONED clause, PAGESIZE clause" />
<title>CREATE INDEX</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="xcindx"></a>
<h2 id="xcindx"><a href="rbafzmst02.htm#ToC_888">CREATE INDEX</a></h2><a id="idx1896" name="idx1896"></a><a id="idx1897" name="idx1897"></a><a id="idx1898" name="idx1898"></a>
<a name="cindx"></a>
<p id="cindx">The CREATE INDEX statement creates an index on a table at the
current server.</p>
<a name="wq1249"></a>
<h3 id="wq1249"><a href="rbafzmst02.htm#ToC_889">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="wq1250"></a>
<h3 id="wq1250"><a href="rbafzmst02.htm#ToC_890">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 Logical File (CRTLF) command</li>
<li>*CHANGE to the data dictionary if the library into which the index is
created is an SQL schema with a data dictionary</li></ul></li>
<li>Administrative authority</li></ul>
<p>The privileges held by the authorization ID of the statement must also
include at least one of the following: </p>
<ul>
<li>For the referenced table:
<ul>
<li>The INDEX privilege on the table</li>
<li>The system authority *EXECUTE on the library containing the table</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>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>.</p>
<a name="wq1251"></a>
<h3 id="wq1251"><a href="rbafzmst02.htm#ToC_891">Syntax</a></h3>
<a href="rbafzmstxcindx.htm#synscrtidx"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn290.htm"
border="0" /></span><a href="#skipsyn-289"><img src="c.gif" alt="Skip visual syntax diagram"
border="0" /></a>>>-CREATE--+----------------------------+--INDEX--<span class="italic">index-name</span>---->
+-UNIQUE--+----------------+-+
| '-WHERE NOT NULL-' |
'-ENCODED VECTOR-------------'
.-,---------------------.
V .-ASC--. |
>--ON--<span class="italic">table-name</span>--(----<span class="italic">column-name</span>--+------+-+--)-------------->
'-DESC-'
>--<span class="italic">index-options</span>----------------------------------------------->&lt;
index-options:
|--+-------------------------------------+---------------------->
| .-DISTINCT-. |
'-WITH--<span class="italic">integer</span>--+----------+--VALUES-'
.-<span>PAGESIZE</span>--<span><span class="italic">64</span></span>------. (1)
>--+-----------------+--+-------------------+-------------------|
+-NOT PARTITIONED-+ '-<span>PAGESIZE</span>--+-<span>8</span>---+-'
'-PARTITIONED-----' +-<span>16</span>--+
+-<span>32</span>--+
+-<span>64</span>--+
+-<span>128</span>-+
'-<span>512</span>-'
</pre>
<a name="skipsyn-289" id="skipsyn-289"></a>
<a name="wq1252"></a>
<div class="notelisttitle" id="wq1252">Notes:</div>
<ol type="1">
<li>The <var class="pv">index-options</var> may be specified in any order.</li>
</ol>
<a name="synscrtidx"></a>
<h3 id="synscrtidx"><a href="rbafzmst02.htm#ToC_892">Description</a></h3>
<dl class="parml">
<dt class="bold">UNIQUE </dt><a id="idx1899" name="idx1899"></a>
<dd>Prevents the table from containing two or more rows with the same value
of the index key. The constraint is enforced when rows of the table are updated
or new rows are inserted.
<p>The constraint is also checked during the execution
of the CREATE INDEX statement. If the table already contains rows with duplicate
key values, the index is not created.</p>
<p>When UNIQUE is used, null values
are treated as any other values. For example, if the key is a single column
that can contain null values, that column can contain no more than one null
value.</p>
</dd>
<dt class="bold">UNIQUE WHERE NOT NULL</dt><a id="idx1900" name="idx1900"></a><a id="idx1901" name="idx1901"></a>
<dd>Prevents the table from containing two or more rows with the same nonnull
value of the index key. Multiple null values are allowed; otherwise, this
is identical to UNIQUE.
</dd>
<dt class="bold">ENCODED VECTOR </dt><a id="idx1902" name="idx1902"></a>
<dd>Specifies that the resulting index will be an encoded vector index (EVI).
<p>An encoded vector index cannot be used to ensure an ordering of rows. It is
used by the database manager to improve the performance of queries. For more
information, see the <a href="../rzajq/rzajqkickoff.htm">Database Performance and Query Optimization</a> book.</p>
</dd>
<dt class="bold"><var class="pv">index-name</var> </dt><a id="idx1903" name="idx1903"></a>
<dd>Names the index. The name, including the implicit or explicit qualifier,
must not be the same as an index, table, view, alias, or file that already
exists at the current server.
<p>If SQL names were specified, the index will
be created in the schema specified by the implicit or explicit qualifier.</p>
<p>If system names were specified, the index name will be created in the
schema that is specified by the qualifier. If not qualified, the index name
will be created in the same schema as the table over which the index is created.</p>
<p>If the index name is not a valid system name, DB2 UDB for iSeries will generate a
system name. For information on the rules for generating a name, see <a href="rbafzmsthctabl.htm#namrul">Rules for Table Name Generation</a>.</p>
</dd>
<dt class="bold">ON <var class="pv">table-name</var> </dt><a id="idx1904" name="idx1904"></a><a id="idx1905" name="idx1905"></a>
<dd>Identifies the table on which the index is to be created. The <var class="pv">table-name</var> must identify a base table (not a view) that exists at the current server.
<p>If the table is a partitioned table, an alias may be specified which identifies
a single partition. The created index will then only be created over the specified
partition.</p>
</dd>
<dt class="bold"><var class="pv">(column-name, ... )</var></dt>
<dd>Identifies the list of columns that will be part of the index
key.
<p>Each <var class="pv">column-name</var> must be an unqualified name that identifies
a column of the table. The same column may be specified more than once. A <var class="pv">column-name</var> must not identify a LOB or DATALINK column, or a distinct
type based on a LOB or DATALINK column. The number of columns must not exceed
120, and the sum of their byte lengths must not exceed 32766-<span class="italic">n</span>, where <span class="italic">n</span> is the number of columns specified
that allows nulls. </p>
<dl class="parml">
<dt class="bold">ASC </dt><a id="idx1906" name="idx1906"></a>
<dd>Specifies that the index entries are to be kept in ascending
order of the column values. ASC is the default.
</dd>
<dt class="bold">DESC </dt><a id="idx1907" name="idx1907"></a>
<dd>Specifies that the index entries are to be kept in descending order
of the column values.
</dd>
</dl>
</dd>
<dt class="bold">WITH <var class="pv">integer</var> DISTINCT VALUES </dt><a id="idx1908" name="idx1908"></a>
<dd>Specifies the estimated number of distinct key values. This clause may
be specified for any type of index.
<p>For encoded vector indexes this is
used to determine the initial size of the codes assigned to each distinct
key value. The default value is 256.</p>
<p>For non-encoded vector indexes,
this is used as a hint to the optimizer.</p>
</dd>
<dt class="bold">PARTITIONED</dt><a id="idx1909" name="idx1909"></a>
<dd>Specifies that an index partition should be created for each data partition
defined for the table using the specified columns. The <var class="pv">table-name</var> must
identify a partitioned table. If the index is unique, the columns of the index
must be the same or a superset of the columns of the data partition key. PARTITIONED
is the default if the index is not unique and the table is partitioned.
</dd>
<dt class="bold">NOT PARTITIONED</dt><a id="idx1910" name="idx1910"></a>
<dd>Specifies that a single index should be created that spans all of the
data partitions defined for the table. The <var class="pv">table-name</var> must identify
a partitioned table. NOT PARTITIONED is the default if the index is unique
and the table is partitioned. An index on a table that is not partitioned
is also by default not partitioned.
<p>If an encoded vector index is specified,
NOT PARTITIONED is not allowed.</p>
</dd>
<dt class="bold">PAGESIZE</dt><a id="idx1911" name="idx1911"></a>
<dd>Specifies the logical page used for the index in kilobytes. Indexes
with larger logical page sizes are typically more efficient when scanned during
query processing. Indexes with smaller logical page sizes are typically more
efficient for simple index probes and individual key look ups.
<p>The default value for PAGESIZE is determined by the length of the key and
with a minimum value of 64.</p>
<p>If an encoded vector index is specified,
PAGESIZE is not allowed.</p>
</dd>
</dl>
<a name="wq1254"></a>
<h3 id="wq1254"><a href="rbafzmst02.htm#ToC_893">Notes</a></h3>
<p><span class="bold">Effects of the statement:</span> CREATE INDEX creates a
description of the index. If the named table already contains data, CREATE
INDEX creates the index entries for it. If the table does not yet contain
data, the index entries are created when data is inserted into the table.</p>
<p><span class="bold">Sort sequence:</span> Any index created over columns containing
SBCS or mixed data is created with the sort sequence in effect at the time
the statement is executed. For sort sequences other than *HEX, the key for
SBCS data or mixed data is the weighted value of the key based on the sort
sequence.</p>
<p><span class="bold">Index attributes:</span> An index is created as a keyed
logical file. When an index 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 Logical File (CRTLF) command.</p>
<p>An index created over 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&reg; Multisystem</a> book.</p>
<p><span class="bold">Index ownership:</span> If SQL names were specified:</p>
<ul>
<li>If a user profile with the same name as the schema into which the index
is created exists, the <span class="italic">owner</span> of the index is that
user profile.</li>
<li>Otherwise, the <span class="italic">owner</span> of the index 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
index is the user profile or group user profile of the job executing the statement.</p>
<p><span class="bold">Index authority:</span> If SQL names are used, indexes are
created with the system authority of *EXCLUDE on *PUBLIC. If system names
are used, indexes 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 index 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 index.</p>
<a name="wq1255"></a>
<h3 id="wq1255"><a href="rbafzmst02.htm#ToC_894">Examples</a></h3>
<p><span class="italic">Example 1:</span> Create an index named UNIQUE_NAM
on the PROJECT table. The purpose of the index is to ensure that there are
not two entries in the table with the same value for project name (PROJNAME).
The index entries are to be in ascending order.</p>
<p> </p>
<pre class="xmp"> <span class="bold">CREATE UNIQUE INDEX</span> UNIQUE_NAM
<span class="bold">ON</span> PROJECT<span class="bold">(</span>PROJNAME<span class="bold">)</span></pre>
<p><span class="italic">Example 2:</span> Create an index named JOB_BY_DPT
on the EMPLOYEE table. Arrange the index entries in ascending order by job
title (JOB) within each department (WORKDEPT). </p>
<pre class="xmp"> <span class="bold">CREATE INDEX</span> JOB_BY_DPT
<span class="bold">ON</span> EMPLOYEE <span class="bold">(</span>WORKDEPT, JOB<span class="bold">)</span></pre>
<hr /><br />
[ <a href="#Top_Of_Page">Top of Page</a> | <a href="rbafzmstcftb.htm">Previous Page</a> | <a href="rbafzmstcreatep.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>