The CREATE INDEX statement creates an index on a table at the current server.
This statement can be embedded in an application program or issued interactively. It is an executable statement that can be dynamically prepared.
The privileges held by the authorization ID of the statement must include at least one of the following:
The privileges held by the authorization ID of the statement must include at least one of the following:
The privileges held by the authorization ID of the statement must also include at least one of the following:
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:
For information on the system authorities corresponding to SQL privileges, see Corresponding System Authorities When Checking Privileges to a Table or View.
>>-CREATE--+----------------------------+--INDEX--index-name----> +-UNIQUE--+----------------+-+ | '-WHERE NOT NULL-' | '-ENCODED VECTOR-------------' .-,---------------------. V .-ASC--. | >--ON--table-name--(----column-name--+------+-+--)--------------> '-DESC-' >--index-options----------------------------------------------->< index-options: |--+-------------------------------------+----------------------> | .-DISTINCT-. | '-WITH--integer--+----------+--VALUES-' .-PAGESIZE--64------. (1) >--+-----------------+--+-------------------+-------------------| +-NOT PARTITIONED-+ '-PAGESIZE--+-8---+-' '-PARTITIONED-----' +-16--+ +-32--+ +-64--+ +-128-+ '-512-'
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.
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.
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 Database Performance and Query Optimization book.
If SQL names were specified, the index will be created in the schema specified by the implicit or explicit qualifier.
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.
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 Rules for Table Name Generation.
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.
Each column-name must be an unqualified name that identifies a column of the table. The same column may be specified more than once. A column-name 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-n, where n is the number of columns specified that allows nulls.
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.
For non-encoded vector indexes, this is used as a hint to the optimizer.
If an encoded vector index is specified, NOT PARTITIONED is not allowed.
The default value for PAGESIZE is determined by the length of the key and with a minimum value of 64.
If an encoded vector index is specified, PAGESIZE is not allowed.
Effects of the statement: 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.
Sort sequence: 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.
Index attributes: 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.
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 DB2® Multisystem book.
Index ownership: If SQL names were specified:
If system names were specified, the owner of the index is the user profile or group user profile of the job executing the statement.
Index authority: 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.
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.
Example 1: 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.
CREATE UNIQUE INDEX UNIQUE_NAM ON PROJECT(PROJNAME)
Example 2: 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).
CREATE INDEX JOB_BY_DPT ON EMPLOYEE (WORKDEPT, JOB)