Quick Search:
 
 Oracle PL/SQL: INDEXES: Virtual / NoSegment Jump to:  
Category: >> Oracle PL/SQL >> INDEXES: Virtual / NoSegment  

<< lastnext >>

Snippet Name: INDEXES: Virtual / NoSegment

Description: Virtual Indexes are another undocumented feature used by Oracle.

Virtual indexes allow us to simulate the existence of an index and test its impact without actually building the actual index.

Virtual indexes, as the name suggests are pseudo-indexes that will not behave the same way that normal indexes behave, and are meant for analysis and tuning purposes.

A virtual index is created in a slightly different manner than the normal indexes. A virtual index has no segment pegged to it, i.e., the DBA_SEGMENTS view will not show an entry for this. Oracle handles such indexes internally and few required dictionary tables are updated so that the optimizer can be made aware of its presence and generate an execution plan considering such indexes.

1. They are permanent and continue to exist unless dropped.

2. Their creation does not affect existing and new sessions. Only sessions marked for Virtual Index usage will be affected by their existence.

3. Virtual indexes will be used only when the parameter "_use_nosegment_indexes" is set to true.

4. The Rule based optimizer does not recognize Virtual Indexes but the CBO does recognize them.

5. Dictionary view DBA_SEGMENTS will not show entries for Virtual Indexes. The table DBA_INDEXES and DBA_OBJECTS will have an entry for them in Oracle 8i; in Oracle 9i onwards, DBA_INDEXES no longer show Virtual Indexes.

6. Virtual Indexes cannot be altered, and will in fact throw a "Fake Index" error.

7. Make sure to drop virtual indexs after analysis and tuning is completed.

Also see:
» INDEXES: View table indexes
» INDEXES: Analyze Index
» INDEXES: Block Dump
» INDEXES: Rebuild Reverse
» INDEXES:
» INDEXES: ENABLE (function-based index)
» INDEXES: DISABLE (function-based index)
» INDEXES: Alter Index Parallel
» INDEXES: Alter Index Deallocate Unused
» INDEXES: Alter Index Allocate Extent
» INDEXES: Reverse Key Indexes
» INDEXES: Bitmap Join Indexes
» INDEXES: Bitmap Indexes
» INDEXES: Unique indexes
» INDEXES: Parallel Index
» INDEXES: Compute Statistics
» INDEXES: SORT and NOSORT
» INDEXES: Function-Based Index
» INDEXES: DROP index
» INDEXES: Alter index
» INDEXES: Single Column Non-unique
» INDEXES: Index Usage Notes
» Compressed Indexes
» Create INDEX

Comment: (none)

Language: PL/SQL
Highlight Mode: PLSQL
Last Modified: March 10th, 2009

CREATE INDEX <index_name>
ON <table_name> (<column_name>, [<column_name>]) NOSEGMENT;
 
 
-- for example: 
 
CREATE TABLE vtest AS
SELECT table_name, tablespace_name
FROM all_tables;
 
CREATE INDEX v_idx_vtest_tablename
ON vtest(tablename)
NOSEGMENT;
 
 
-- full example
 
SET autotrace ON explain;
 
ALTER session SET "_use_nosegment_indexes" = TRUE;
 
Session altered.
 
-- we now have following table called "SALES"
 
DESC SALES;
Name NULL? TYPE
------------------------------
SALES_DATE DATE
SALES_AMOUNT NUMBER(9,2)
 
-- explain plan output before creating the virtual index:
 
Execution Plan
------------------------------
Plan hash VALUE: 4006579748
 
------------------------------
| Id | Operation | Name |
------------------------------
| 0 | SELECT STATEMENT | |
|* 1 | TABLE ACCESS FULL| SALES |
------------------------------
 
 
-- create the virtual index using the keyword "NOSEGMENT". 
 
CREATE INDEX sales_idx ON SALES(sales_date) nosegment;
 
INDEX created.
 
Execution Plan
------------------------------
Plan hash VALUE: 842018266
 
------------------------------
| Id | Operation | Name |
------------------------------
| 0 | SELECT STATEMENT | |
| 1 | TABLE ACCESS BY INDEX ROWID| SALES |
|* 2 | INDEX RANGE SCAN | SALES_IDX |
------------------------------
 
-- drop the index:
 
DROP INDEX sales_idx;
 
INDEX dropped.


 
   Home |    Search |    Code Library |    Sponsors |    Privacy |    Terms of Use |    Contact Us © 2003 - 2024 psoug.org