分类: Oracle
2008-10-12 11:46:13
OPTIMIZER_USE_INVISIBLE_INDEXES
parameter is set to TRUE at the instance or session level. Indexes can be created as invisible by using the INVISIBLE
keyword, and their visibility can be toggled using the ALTER INDEX
command.The following script creates and populates a table, then creates an invisible index on it.CREATE INDEX index_name ON table_name(column_name) INVISIBLE; ALTER INDEX index_name INVISIBLE; ALTER INDEX index_name VISIBLE;
A query using the indexed column in theCREATE TABLE ii_tab ( id NUMBER ); BEGIN FOR i IN 1 .. 10000 LOOP INSERT INTO ii_tab VALUES (i); END LOOP; COMMIT; END; / CREATE INDEX ii_tab_id ON ii_tab(id) INVISIBLE; EXEC DBMS_STATS.gather_table_stats(USER, 'ii_tab', cascade=> TRUE);
WHERE
clause ignores the index and does a full table scan.Setting theSET AUTOTRACE ON SELECT * FROM ii_tab WHERE id = 9999; ---------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ---------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 3 | 7 (0)| 00:00:01 | |* 1 | TABLE ACCESS FULL| II_TAB | 1 | 3 | 7 (0)| 00:00:01 | ----------------------------------------------------------------------------
OPTIMIZER_USE_INVISIBLE_INDEXES
parameter makes the index available to the optimizer.Making the index visible means it is still available to the optimizer when theALTER SESSION SET OPTIMIZER_USE_INVISIBLE_INDEXES=TRUE; SELECT * FROM ii_tab WHERE id = 9999; ------------------------------------------------------------------------------ | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ------------------------------------------------------------------------------ | 0 | SELECT STATEMENT | | 1 | 3 | 1 (0)| 00:00:01 | |* 1 | INDEX RANGE SCAN| II_TAB_ID | 1 | 3 | 1 (0)| 00:00:01 | ------------------------------------------------------------------------------
OPTIMIZER_USE_INVISIBLE_INDEXES
parameter is reset.Invisible indexes can be useful for processes with specific indexing needs, where the presence of the indexes may adversely affect other functional areas. They are also useful for testing the impact of dropping an index.ALTER SESSION SET OPTIMIZER_USE_INVISIBLE_INDEXES=FALSE; ALTER INDEX ii_tab_id VISIBLE; ------------------------------------------------------------------------------ | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ------------------------------------------------------------------------------ | 0 | SELECT STATEMENT | | 1 | 3 | 1 (0)| 00:00:01 | |* 1 | INDEX RANGE SCAN| II_TAB_ID | 1 | 3 | 1 (0)| 00:00:01 | ------------------------------------------------------------------------------
VISIBILITY
column of the [DBA|ALL|USER]_INDEXES
views.