Skip Headers

Oracle9i SQL Reference
Release 2 (9.2)

Part Number A96540-02
Go to Documentation Home
Home
Go to Book List
Book List
Go to Table of Contents
Contents
Go to Index
Index
Go to Master Index
Master Index
Go to Feedback page
Feedback

Go to previous page Go to next page
View PDF

ALTER INDEX

Purpose

Use the ALTER INDEX statement to change or rebuild an existing index.

See Also:

CREATE INDEX for information on creating an index

Prerequisites

The index must be in your own schema or you must have ALTER ANY INDEX system privilege.

To execute the MONITORING USAGE clause, the index must be in your own schema.

To modify a domain index, you must have EXECUTE object privilege on the indextype of the index.

Schema object privileges are granted on the parent index, not on individual index partitions or subpartitions.

You must have tablespace quota to modify, rebuild, or split an index partition or to modify or rebuild an index subpartition.

See Also:

CREATE INDEX and Oracle9i Data Cartridge Developer's Guide for information on domain indexes

Syntax

alter_index::=

Text description of statements_176.gif follows
Text description of alter_index


(deallocate_unused_clause::=, allocate_extent_clause::=, parallel_clause::=, physical_attributes_clause::=, logging_clause::=, rebuild_clause::=, alter_index_partitioning::=)

deallocate_unused_clause::=

Text description of statements_177.gif follows
Text description of deallocate_unused_clause


allocate_extent_clause::=

Text description of statements_178.gif follows
Text description of allocate_extent_clause


parallel_clause::=

Text description of statements_179.gif follows
Text description of parallel_clause


physical_attributes_clause::=

Text description of statements_180.gif follows
Text description of physical_attributes_clause


(storage_clause::=)

logging_clause::=

Text description of statements_147.gif follows
Text description of logging_clause


rebuild_clause::=

Text description of statements_132.gif follows
Text description of rebuild_clause


(physical_attributes_clause::=, key_compression::=, logging_clause::=)

key_compression::=

Text description of statements_181.gif follows
Text description of key_compression


alter_index_partitioning::=

Text description of statements_156.gif follows
Text description of alter_index_partitioning


(modify_index_default_attrs::=, modify_index_partition::=, rename_index_partition::=, drop_index_partition::=, split_index_partition::=, modify_index_subpartition::=)

modify_index_default_attrs::=

Text description of statements_178a.gif follows
Text description of modify_index_default_attrs


(physical_attributes_clause::=, logging_clause::=)

modify_index_partition::=

Text description of statements_183.gif follows
Text description of modify_index_partition


(physical_attributes_clause::=, logging_clause::=, allocate_extent_clause::=, deallocate_unused_clause::=)

rename_index_partition::=

Text description of statements_184.gif follows
Text description of rename_index_partition


drop_index_partition::=

Text description of statements_185.gif follows
Text description of drop_index_partition


split_index_partition::=

Text description of statements_186.gif follows
Text description of split_index_partition


(parallel_clause::=)

index_partition_description::=

Text description of statements_184a.gif follows
Text description of index_partition_description


(key_compression::=)

segment_attributes_clause::=

Text description of statements_185a.gif follows
Text description of segment_attributes_clause


(physical_attributes_clause::=, logging_clause::=)

modify_index_subpartition::=

Text description of statements_188.gif follows
Text description of modify_index_subpartition


(allocate_extent_clause::=, deallocate_unused_clause::=)

Semantics

schema

Specify the schema containing the index. If you omit schema, Oracle assumes the index is in your own schema.

index

Specify the name of the index to be altered.

Restrictions on Modifying Indexes

deallocate_unused_clause

Use the deallocate_unused_clause to explicitly deallocate unused space at the end of the index and make the freed space available for other segments in the tablespace.

If index is range-partitioned or hash-partitioned, Oracle deallocates unused space from each index partition. If index is a local index on a composite-partitioned table, Oracle deallocates unused space from each index subpartition.

Restrictions on Deallocating Space
KEEP integer

The KEEP clause lets you specify the number of bytes above the high water mark that the index will have after deallocation. If the number of remaining extents are less than MINEXTENTS, then MINEXTENTS is set to the current number of extents. If the initial extent becomes smaller than INITIAL, then INITIAL is set to the value of the current initial extent. If you omit KEEP, all unused space is freed.

See Also:

ALTER TABLE for a complete description of this clause

allocate_extent_clause

The allocate_extent_clause lets you explicitly allocate a new extent for the index. For a local index on a hash-partitioned table, Oracle allocates a new extent for each partition of the index.

Restriction on Allocating Extents

You cannot specify this clause for an index on a temporary table or for a range-partitioned or composite-partitioned index.

See Also:

allocate_extent_clause for a full description of this clause

parallel_clause

Use the PARALLEL clause to change the default degree of parallelism for queries and DML on the index.

Restriction on Parallelizing Indexes

You cannot specify this clause for an index on a temporary table.


Note:

The syntax of the parallel_clause supersedes syntax appearing in earlier releases of Oracle. Superseded syntax is still supported for backward compatibility, but may result in slightly different behavior than that documented.


NOPARALLEL

Specify NOPARALLEL for serial execution. This is the default.

PARALLEL

Specify PARALLEL if you want Oracle to select a degree of parallelism equal to the number of CPUs available on all participating instances times the value of the PARALLEL_THREADS_PER_CPU initialization parameter.

PARALLEL integer

Specification of integer indicates the degree of parallelism, which is the number of parallel threads used in the parallel operation. Each parallel thread may use one or two parallel execution servers. Normally Oracle calculates the optimum degree of parallelism, so it is not necessary for you to specify integer.

See Also:

"Notes on the parallel_clause" for CREATE TABLE and "Enabling Parallel Queries: Example"

physical_attributes_clause

Use the physical_attributes_clause to change the values of parameters for a nonpartitioned index, all partitions and subpartitions of a partitioned index, a specified partition, or all subpartitions of a specified partition.

See Also:
Restrictions on Index Physical Attributes
storage_clause

Use the storage_clause to change the storage parameters for a nonpartitioned index, index partition, or all partitions of a partitioned index, or default values of these parameters for a partitioned index.

See Also:

storage_clause

logging_clause

Use the logging_clause to specify whether subsequent Direct Loader (SQL*Loader) and direct-path INSERT operations against a nonpartitioned index, a range or hash index partition, or all partitions or subpartitions of a composite-partitioned index will be logged (LOGGING) or not logged (NOLOGGING) in the redo log file.

An index segment can have logging attributes different from those of the base table and different from those of other index segments for the same base table.

Restriction on Index Logging

You cannot specify this clause for an index on a temporary table.

See Also:
RECOVERABLE | UNRECOVERABLE

These keywords are deprecated and have been replaced with LOGGING and NOLOGGING, respectively. Although RECOVERABLE and UNRECOVERABLE are supported for backward compatibility, Oracle Corporation strongly recommends that you use the LOGGING and NOLOGGING keywords.

RECOVERABLE is not a valid keyword for creating partitioned tables or LOB storage characteristics. UNRECOVERABLE is not a valid keyword for creating partitioned or index-organized tables. Also, it can be specified only with the AS subquery clause of CREATE INDEX.

rebuild_clause

Use the rebuild_clause to re-create an existing index or one of its partitions or subpartitions. If index is marked UNUSABLE, a successful rebuild will mark it USABLE. For a function-based index, this clause also enables the index. If the function on which the index is based does not exist, the rebuild statement will fail.

Restrictions on Rebuilding Indexes
PARTITION Clause

Use the PARTITION clause to rebuild one partition of an index. You can also use this clause to move an index partition to another tablespace or to change a create-time physical attribute.


Note:

The storage of partitioned database entities in tablespaces of different block sizes is subject to several restrictions. Please refer to Oracle9i Database Administrator's Guide for a discussion of these restrictions.


Restriction on Rebuilding Partitions

You cannot specify this clause for a local index on a composite-partitioned table. Instead, use the REBUILD SUBPARTITION clause.

See Also:

Oracle9i Database Administrator's Guide for more information about partition maintenance operations and "Rebuilding Unusable Index Partitions: Example"

SUBPARTITION Clause

Use the SUBPARTITION clause to rebuild one subpartition of an index. You can also use this clause to move an index subpartition to another tablespace. If you do not specify TABLESPACE, the subpartition is rebuilt in the same tablespace.


Note:

The storage of partitioned database entities in tablespaces of different block sizes is subject to several restrictions. Please refer to Oracle9i Database Administrator's Guide for a discussion of these restrictions.


Restrictions on Modifying Index Subpartitions
REVERSE | NOREVERSE

Indicate whether the bytes of the index block are stored in reverse order:

Restrictions on Reverse Indexes
parallel_clause

Use the parallel_clause to parallelize the rebuilding of the index.

See Also:

"Rebuilding an Index in Parallel: Example"

TABLESPACE Clause

Specify the tablespace where the rebuilt index, index partition, or index subpartition will be stored. The default is the default tablespace where the index or partition resided before you rebuilt it.

COMPRESS | NOCOMPRESS

Specify COMPRESS to enable key compression, which eliminates repeated occurrence of key column values. Use integer to specify the prefix length (number of prefix columns to compress).

Oracle compresses only nonpartitioned indexes that are nonunique or unique indexes of at least two columns.

Specify NOCOMPRESS to disable key compression. This is the default.

Restriction on Key Compression

You cannot specify COMPRESS for a bitmap index.

ONLINE Clause

Specify ONLINE to allow DML operations on the table or partition during rebuilding of the index.

Restrictions on ONLINE
COMPUTE STATISTICS Clause

Specify COMPUTE STATISTICS if you want to collect statistics at relatively little cost during the rebuilding of an index. These statistics are stored in the data dictionary for ongoing use by the optimizer in choosing a plan of execution for SQL statements.

The types of statistics collected depend on the type of index you are rebuilding.


Note:

If you create an index using another index (instead of a table), the original index might not provide adequate statistical information. Therefore, Oracle generally uses the base table to compute the statistics, which will improve the statistics but may negatively affect performance.


Additional methods of collecting statistics are available in PL/SQL packages and procedures

See Also:

Oracle9i Supplied PL/SQL Packages and Types Reference and "Collecting Index Statistics: Example"

logging_clause

Specify whether the ALTER INDEX ... REBUILD operation will be logged.

See Also:

logging_clause for a full description of this clause

PARAMETERS Clause

The PARAMETERS clause applies only to domain indexes. This clause specifies the parameter string that is passed uninterpreted to the appropriate ODCI indextype routine. The maximum length of the parameter string is 1000 characters.

If you are altering or rebuilding an entire index, the string must refer to index-level parameters. If you are rebuilding a partition of the index, the string must refer to partition-level parameters.

If index is marked UNUSABLE, modifying the parameters alone does not make it USABLE. You must also rebuild the UNUSABLE index to make it usable.


Note:

If you have installed Oracle Text, you can rebuild your Oracle Text domain indexes using parameters specific to that product. For more information on those parameters, please refer to Oracle Text Reference.


Restrictions on the PARAMETERS Clause

ENABLE Clause

ENABLE applies only to a function-based index that has been disabled because a user-defined function used by the index was dropped or replaced. This clause enables such an index if these conditions are true:

Restriction on Enabling Function-based Indexes

You cannot specify any other clauses of ALTER INDEX in the same statement with ENABLE.

DISABLE Clause

DISABLE applies only to a function-based index. This clause enables you to disable the use of a function-based index. You might want to do so, for example, while working on the body of the function. Afterward you can either rebuild the index or specify another ALTER INDEX statement with the ENABLE keyword.

UNUSABLE Clause

Specify UNUSABLE to mark the index or index partition(s) or index subpartition(s) UNUSABLE. An unusable index must be rebuilt, or dropped and re-created, before it can be used. While one partition is marked UNUSABLE, the other partitions of the index are still valid. You can execute statements that require the index if the statements do not access the unusable partition. You can also split or rename the unusable partition before rebuilding it.

Restriction on Marking Indexes Unusable

You cannot specify this clause for an index on a temporary table.

RENAME Clause

Use this clause to rename an index. The new_index_name is a single identifier and does not include the schema name.

Restriction on Renaming Indexes

For a domain index, neither index nor any partitions of index can be marked IN_PROGRESS or FAILED.

See Also:

"Renaming an Index: Example"

COALESCE Clause

Specify COALESCE to instruct Oracle to merge the contents of index blocks where possible to free blocks for reuse.

Restrictions on Coalescing Index Blocks

MONITORING USAGE | NOMONITORING USAGE

Use this clause to determine whether Oracle should monitor index use.

To see whether the index has been used since this ALTER INDEX ... NOMONITORING USAGE statement was issued, query the USED column of the V$OBJECT_USAGE dynamic performance view.

See Also:

Oracle9i Database Reference for information on the data dictionary and dynamic performance views

UPDATE BLOCK REFERENCES Clause

The UPDATE BLOCK REFERENCES clause is valid only for normal and domain indexes on index-organized tables. Specify this clause to update all the stale "guess" data block addresses stored as part of the index row with the correct database address for the corresponding block identified by the primary key.


Note:

For a domain index, Oracle executes the ODCIIndexAlter routine with the alter_option parameter set to AlterIndexUpdBlockRefs. This routine enables the cartridge code to update the stale "guess" data block addresses in the index.


Restriction on UPDATE BLOCK REFERENCES

You cannot combine this clause with any other clause of ALTER INDEX.

alter_index_partitioning

The partitioning clauses of the ALTER INDEX statement are valid only for partitioned indexes.


Note:

The storage of partitioned database entities in tablespaces of different block sizes is subject to several restrictions. Please refer to Oracle9i Database Administrator's Guide for a discussion of these restrictions.


Restrictions on Altering Index Partitions
modify_index_default_attrs

Specify new values for the default attributes of a partitioned index.

Restriction on Modifying Partition Default Attributes

The only attribute you can specify for an index on a hash-partitioned or composite-partitioned table is TABLESPACE.

TABLESPACE

Specify the default tablespace for new partitions of an index or subpartitions of an index partition.

logging_clause

Specify the default logging attribute of a partitioned index or an index partition.

See Also:

logging_clause for a full description of this clause

FOR PARTITION

Use the FOR PARTITION clause to specify the default attributes for the subpartitions of a partition of a local index on a composite-partitioned table.

Restriction on FOR PARTITION

You cannot specify FOR PARTITION for a list partition.

See Also:

"Modifying Default Attributes: Example"

modify_index_partition

Use the modify_index_partition clause to modify the real physical attributes, logging attribute, or storage characteristics of index partition partition or its subpartitions.

UPDATE BLOCK REFERENCES

The UPDATE BLOCK REFERENCES clause is valid only for normal indexes on index-organized tables. Use this clause to update all stale "guess" data block addresses stored in the secondary index partition.

Restrictions on UPDATE BLOCK REFERENCES
rename_index_partition

Use the rename_index_partition clauses to rename index partition or subpartition to new_name.

Restrictions on Renaming Index Partitions
drop_index_partition

Use the drop_index_partition clause to remove a partition and the data in it from a partitioned global index. When you drop a partition of a global index, Oracle marks the index's next partition UNUSABLE. You cannot drop the highest partition of a global index.

See Also:

"Dropping an Index Partition: Example"

split_index_partition

Use the split_index_partition clause to split a partition of a global partitioned index into two partitions, adding a new partition to the index.

Splitting a partition marked UNUSABLE results in two partitions, both marked UNUSABLE. You must rebuild the partitions before you can use them.

Splitting a usable partition results in two partitions populated with index data. Both new partitions are usable.

AT Clause

Specify the new noninclusive upper bound for split_partition_1. The value_list must evaluate to less than the presplit partition bound for partition_name_old and greater than the partition bound for the next lowest partition (if there is one).

INTO Clause

Specify (optionally) the name and physical attributes of each of the two partitions resulting from the split.

See Also:

"Splitting a Partition: Example"

modify_index_subpartition

Use the modify_index_subpartition clause to mark UNUSABLE or allocate or deallocate storage for a subpartition of a local index on a composite-partitioned table. All other attributes of such a subpartition are inherited from partition-level default attributes.

Examples

Storing Index Blocks in Reverse Order: Example

The following statement rebuilds index ord_customer_ix (created in "Creating an Index: Example") so that the bytes of the index block are stored in reverse order:

ALTER INDEX ord_customer_ix REBUILD REVERSE;
Collecting Index Statistics: Example

The following statement collects statistics on the nonpartitioned ord_customer_ix index:

ALTER INDEX ord_customer_ix REBUILD COMPUTE STATISTICS;

The type of statistics collected depends on the type of index you are rebuilding.

See Also:

Oracle9i Database Concepts

Rebuilding an Index in Parallel: Example

The following statement causes the index to be rebuilt from the existing index by using parallel execution processes to scan the old and to build the new index:

ALTER INDEX ord_customer_ix REBUILD PARALLEL;
Modifying Real Attributes: Example

The following statement alters the oe.cust_lname_ix index so that future data blocks within this index use 5 initial transaction entries and an incremental extent of 100 kilobytes:

/* Unless you change the default tablespace of sample user oe,
   or specify different tablespace storage for the index, this
   example fails because the default tablespace originally assigned
   to oe is locally managed.
*/
ALTER INDEX oe.cust_lname_ix  
    INITRANS 5  
    STORAGE (NEXT 100K); 

If the oe.cust_lname_ix index were partitioned, this statement would also alter the default attributes of future partitions of the index. New partitions added in the future would then use 5 initial transaction entries and an incremental extent of 100K.

Enabling Parallel Queries: Example

The following statement sets the parallel attributes for index upper_ix (created in "Creating a Function-Based Index: Example") so that scans on the index will be parallelized:

ALTER INDEX upper_ix PARALLEL;
Renaming an Index: Example

The following statement renames an index:

ALTER INDEX upper_ix RENAME TO upper_name_ix;
Marking an Index Unusable: Examples

The following statements use the cost_ix index, which was created in "Creating a Global Partitioned Index: Example". Partition p1 of that index was dropped in "Dropping an Index Partition: Example". The first statement marks the marks index partition p2 as UNUSABLE:

ALTER INDEX cost_ix
   MODIFY PARTITION p2 UNUSABLE;

The next statement marks the entire index cost_ix as UNUSABLE:

ALTER INDEX cost_ix UNUSABLE;
Rebuilding Unusable Index Partitions: Example

The following statements rebuild partitions p2 and p3 of the cost_ix index, making the index once more usable: The rebuilding of partition p3 will not be logged:

ALTER INDEX cost_ix 
   REBUILD PARTITION p2;
ALTER INDEX cost_ix
   REBUILD PARTITION p3 NOLOGGING;
Changing MAXEXTENTS: Example

The following statement changes the maximum number of extents for partition p3 and changes the logging attribute:

/* This example will fail if the tablespace in which partition p3
   resides is locally managed.
*/
ALTER INDEX cost_ix MODIFY PARTITION p3
   STORAGE(MAXEXTENTS 30) LOGGING;
Renaming an Index Partition: Example

The following statement renames an index partition of the cost_ix index (created in "Creating a Global Partitioned Index: Example"):

ALTER INDEX cost_ix
   RENAME PARTITION p3 TO p3_Q3;
Splitting a Partition: Example

The following statement splits partition p2 of index cost_ix (created in "Creating a Global Partitioned Index: Example") into p2a and p2b:

ALTER INDEX cost_ix
   SPLIT PARTITION p2 AT (1500) 
   INTO ( PARTITION p2a TABLESPACE tbs_01 LOGGING,
          PARTITION p2b TABLESPACE tbs_02);
Dropping an Index Partition: Example

The following statement drops index partition p1 from the cost_ix index:

ALTER INDEX cost_ix
   DROP PARTITION p1;
Modifying Default Attributes: Example

The following statement alters the default attributes of local partitioned index prod_idx, which was created in "Creating an Index on a Hash-Partitioned Table: Example.". New partitions added in the future will use 5 initial transaction entries and an incremental extent of 100K:

ALTER INDEX prod_idx
      MODIFY DEFAULT ATTRIBUTES INITRANS 5 STORAGE (NEXT 100K);