Oracle® Database Administrator's Guide 11g Release 2 (11.2) Part Number E10595-04 |
|
|
View PDF |
To alter an index, your schema must contain the index or you must have the ALTER ANY INDEX
system privilege. With the ALTER INDEX
statement, you can:
Rebuild or coalesce an existing index
Deallocate unused space or allocate a new extent
Specify parallel execution (or not) and alter the degree of parallelism
Alter storage parameters or physical attributes
Specify LOGGING
or NOLOGGING
Enable or disable key compression
Mark the index unusable
Make the index invisible
Rename the index
Start or stop the monitoring of index usage
You cannot alter index column structure.
More detailed discussions of some of these operations are contained in the following sections:
See Also:
Oracle Database SQL Language Reference for details on the ALTER
INDEX
statement
Alter the storage parameters of any index, including those created by the database to enforce primary and unique key integrity constraints, using the ALTER INDEX
statement. For example, the following statement alters the emp_ename
index:
ALTER INDEX emp_ename STORAGE (PCTINCREASE 50);
The parameters INITIAL
and MINEXTENTS
cannot be altered. All new settings for the other storage parameters affect only extents subsequently allocated for the index.
For indexes that implement integrity constraints, you can adjust storage parameters by issuing an ALTER TABLE
statement that includes the USING INDEX
subclause of the ENABLE
clause. For example, the following statement changes the storage options of the index created on table emp
to enforce the primary key constraint:
ALTER TABLE emp ENABLE PRIMARY KEY USING INDEX;
See Also:
Oracle Database SQL Language Reference for syntax and restrictions on the use of theALTER INDEX
statementBefore rebuilding an existing index, compare the costs and benefits associated with rebuilding to those associated with coalescing indexes as described in Table 20-1.
When you rebuild an index, you use an existing index as the data source. Creating an index in this manner enables you to change storage characteristics or move to a new tablespace. Rebuilding an index based on an existing data source removes intra-block fragmentation. Compared to dropping the index and using the CREATE INDEX
statement, re-creating an existing index offers better performance.
The following statement rebuilds the existing index emp_name
:
ALTER INDEX emp_name REBUILD;
The REBUILD
clause must immediately follow the index name, and precede any other options. It cannot be used in conjunction with the DEALLOCATE UNUSED
clause.
You have the option of rebuilding the index online. Rebuilding online enables you to update base tables at the same time that you are rebuilding. The following statement rebuilds the emp_name
index online:
ALTER INDEX emp_name REBUILD ONLINE;
Note:
Online index rebuilding has stricter limitations on the maximum key length that can be handled, compared to other methods of rebuilding an index. If an ORA-1450 (maximum key length exceeded) error occurs when rebuilding online, try rebuilding offline, coalescing, or dropping and recreating the index.If you do not have the space required to rebuild an index, you can choose instead to coalesce the index. Coalescing an index is an online operation.
When you make an index unusable, it is ignored by the optimizer and is not maintained by DML. When you make one partition of a partitioned index unusable, the other partitions of the index remain valid.
An unusable index or index partition must be rebuilt, or dropped and re-created, before it can be used.
To make an index unusable:
Submit the following statement:
ALTER INDEX index_name UNUSABLE;
To make an index partition unusable:
Submit the following statement:
ALTER INDEX index_name MODIFY PARTITION partition_name UNUSABLE;
To determine if an index is valid or unusable:
SELECT INDEX_NAME, STATUS FROM USER_INDEXES
WHERE INDEX_NAME = 'index_name';
For example, to determine if the index ind1
is unusable, submit this query:
SELECT INDEX_NAME, STATUS FROM USER_INDEXES WHERE INDEX_NAME = 'IND1'; INDEX_NAME STATUS ------------------------------ -------- IND1 UNUSABLE
To determine if an index partition is unusable:
SELECT PARTITION_NAME, STATUS FROM USER_IND_PARTITIONS
WHERE INDEX_NAME = 'index_name';
For example, to determine the unusable status of the partitions in the index custzip
, submit this query:
SELECT PARTITION_NAME, STATUS FROM USER_IND_PARTITIONS WHERE INDEX_NAME = 'CUSTZIP'; PARTITION_NAME STATUS ------------------------------ -------- CUSTZIP_P1 USABLE CUSTZIP_P2 UNUSABLE CUSTZIP_P3 USABLE
See Also:
Oracle Database SQL Language Reference for more information about the UNUSABLE
keyword, including restrictions
An invisible index is ignored by the optimizer unless you explicitly set the OPTIMIZER_USE_INVISIBLE_INDEXES
initialization parameter to TRUE
at the session or system level. Making an index invisible is an alternative to making it unusable or dropping it. You cannot make an individual index partition invisible. Attempting to do so produces an error.
To make an index invisible:
Submit the following SQL statement:
ALTER INDEX index INVISIBLE;
To make an invisible index visible again:
Submit the following SQL statement:
ALTER INDEX index VISIBLE;
To determine whether an index is visible or invisible:
Query the dictionary views USER_INDEXES
, ALL_INDEXES
, or DBA_INDEXES
.
For example, to determine if the index ind1
is invisible, issue the following query:
SELECT INDEX_NAME, VISIBILITY FROM USER_INDEXES WHERE INDEX_NAME = 'IND1'; INDEX_NAME VISIBILITY ---------- ---------- IND1 VISIBLE
To rename an index, issue this statement:
ALTER INDEX index_name RENAME TO new_name;
Oracle Database provides a means of monitoring indexes to determine whether they are being used. If an index is not being used, then it can be dropped, eliminating unnecessary statement overhead.
To start monitoring the usage of an index, issue this statement:
ALTER INDEX index MONITORING USAGE;
Later, issue the following statement to stop the monitoring:
ALTER INDEX index NOMONITORING USAGE;
The view V$OBJECT_USAGE
can be queried for the index being monitored to see if the index has been used. The view contains a USED
column whose value is YES
or NO
, depending upon if the index has been used within the time period being monitored. The view also contains the start and stop times of the monitoring period, and a MONITORING
column (YES
/NO
) to indicate if usage monitoring is currently active.
Each time that you specify MONITORING USAGE
, the V$OBJECT_USAGE
view is reset for the specified index. The previous usage information is cleared or reset, and a new start time is recorded. When you specify NOMONITORING USAGE
, no further monitoring is performed, and the end time is recorded for the monitoring period. Until the next ALTER INDEX...MONITORING USAGE
statement is issued, the view information is left unchanged.