Tuesday, October 6, 2009

Virtual Indexes

Virtual Indexes are another undocumented feature used by Oracle. Virtual indexes, as the name suggests are pseudo-indexes that will not behave the same way that normal indexes behave, and are meant for a very specific purpose.
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.
As per Oracle, this functionality is not intended for standalone usage. It is part of the Oracle Enterprise Manger Tuning Pack (Virtual Index Wizard). The virtual index wizard functionality allows the user to test a potential new index prior to actually building the new index in the database. It allows the CBO to evaluate the potential new index for a selected SQL statement by building an explain plan that is aware of the potential new index. This allows the user to determine if the optimizer would use the index, once implemented.
Therefore, the feature is here to be supported from Enterprise Manager and not for standalone usage. I went a bit further and actually tested it using SQL*Plus, basically, trying to use the same feature but without the enterprise manager.
I do not see much use of Virtual Indexes in a development area where we can create and drop indexes while testing. However, this feature could prove handy if a query or group of queries have to be tested in production (for want of simulation or urgency!), to determine if a new index will improve the performance, without impacting existing or new sessions.
Below are some attributes of the Virtual Indexes.
1. These are permanent and continue to exist unless we drop them.
2. Their creation will not affect existing and new sessions. Only sessions marked for Virtual Index usage will become aware of their existence.
3. Such indexes will be used only when the hidden parameter "_use_nosegment_indexes" is set to true.
4. The Rule based optimizer did not recognize Virtual Indexes when I
tested, however, CBO recognizes them. In all of my examples, I have used CBO. However, I did not carry out intensive testing in RBO and you may come across exceptions to this view.
5. Dictionary view DBA_SEGMENTS will not show an entry 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 throw a "fake index" error!
7. Virtual Indexes can be analyzed, using the ANALYZE command or DBMS_STATS package, but the statistics cannot be viewed (in Oracle 8i, DBA_INDEXES will not show this either). Oracle may be generating artificial statistics and storing it somewhere for referring it later.
Creating Virtual Index
Creating a Virtual Index can be achieved by using the NOSEGMENT clause with the CREATE INDEX command.
e.g.:
SQL> create unique index am304_u1 on am304(col2) nosegment;

Index created.
Parameter _USE_NOSEGMENT_INDEXES
This is a hidden/internal parameter and therefore undocumented. Such parameters should not be altered for Oracle databases unless Oracle Support either advises or recommends that you do so. In our case, we make an exception (!), but only to be set at session level. Do not set it for the complete instance.
Setting the "_use_nosegment_indexes" parameter enables the optimizer to use virtual indexes.
Examples:
Creating the virtual index:
SQL> create index am301_n1 on am301(col1) nosegment;

Index created.
Checking some dictionary tables:
SQL> select segment_name, segment_type, bytes
2 from dba_segments
3 where segment_name = 'AM301_N1';

no rows selected


SQL> select object_name, object_type, status
2 from dba_objects
3 where object_name = 'AM301_N1';

OBJECT_NAME |OBJECT_TYPE |STATUS
------------------|-----------------|---------------
AM301_N1 |INDEX |VALID


SQL> select index_name, index_type, status
2 from dba_indexes
3 where index_name = 'AM301_N1';

INDEX_NAME |INDEX_TYPE |STATUS
------------------------------|------------|---------------
AM301_N1 |NORMAL |VALID
Working with the Virtual indexes:
SQL> create table am301
2 (col1 number, col2 varchar2(20));

Table created.

SQL> insert into am301 values(dbms_random.random, dbms_random.string('A', 20));

1 row created.

SQL> insert into am301 values(dbms_random.random, dbms_random.string('A', 20));

1 row created.

SQL> insert into am301 values(dbms_random.random, dbms_random.string('A', 20));

1 row created.

SQL> insert into am301 values(dbms_random.random, dbms_random.string('A', 20));

1 row created.

SQL> select * from am301;

COL1 COL2
---------- --------------------
-512599724 aCR_PdFVdSGJLCOLCjJQ
-2.049E+09 qiVUlonc^p^R_X_W_^Xn
-189009085 prTNPqPUod^miAnLXrMA
2082093299 Bq_icbmcpNFNUKDRdMi]

--Though inserting alpha-numeric, Oracle also inserted
--special characters in col2. This one is a bug and is
--resolved in 9i+.

SQL> insert into am301 select * from am301;

4 rows created.

SQL> insert into am301 select * from am301;

8 rows created.

SQL> insert into am301 select * from am301;

16 rows created.

SQL> alter session set optimizer_mode=first_rows;

Session altered.

SQL> create index am301_n1 on am301(col1) nosegment;

Index created.

SQL> analyze table am301 compute statistics;

Table analyzed.

SQL> analyze index am301_n1 compute statistics;

Index analyzed.

--It is recommended to use dbms_stats package to
--generate statistics. Analyze is used here as an
--example only.

SQL> set autotrace on

SQL> select * from am301 where col1 = 2082093299;

COL1 COL2
---------- --------------------
2082093299 Bq_icbmcpNFNUKDRdMi]
2082093299 Bq_icbmcpNFNUKDRdMi]
..

32 rows selected.

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=FIRST_ROWS (Cost=1 Card=32 Bytes=864)
1 0 TABLE ACCESS (FULL) OF 'AM301' (Cost=1 Card=32 Bytes=864)


SQL> alter session set "_use_nosegment_indexes" = true;
--set only for the session testing it.

Session altered.

SQL> select * from am301 where col1 = 2082093299;

COL1 COL2
---------- --------------------
2082093299 Bq_icbmcpNFNUKDRdMi]
2082093299 Bq_icbmcpNFNUKDRdMi]

32 rows selected.

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=FIRST_ROWS (Cost=207 Card=32 Bytes=864)
1 0 TABLE ACCESS (BY INDEX ROWID) OF 'AM301' (Cost=207 Card=32 Bytes=864)
2 1 INDEX (RANGE SCAN) OF 'AM301_N1' (NON-UNIQUE) (Cost=7 Card=32)
Trying to alter the virual index:
SQL> alter index am301_n1 rebuild;
alter index am301_n1 rebuild
*
ERROR at line 1:
ORA-08114: can not alter a fake index


SQL> alter index am301_n1 storage(pctincrease 0);
alter index am301_n1 storage(pctincrease 0)
*
ERROR at line 1:
ORA-08114: can not alter a fake index
Trying to re-create the index as a real one:
SQL> create index am301_n1 on am301(col1);
create index am301_n1 on am301(col1)
*
ERROR at line 1:
ORA-00955: name is already used by an existing object
As the Virtual Index has an entry in some of the dictionary tables, it will prevent the creation of an object with the same name. The alternative is to drop and recreate the Virtual Index as a real index.
Dropping and re-creating again as real index:
SQL> drop index am301_n1;

Index dropped.

SQL> create index am301_n1 on am301(col1);

Index created.
However, a Virtual Index will not prevent the creation of an index with the same column(s).
In the example below, a Virtual Index is created with name DUMMY, afterwards a new index with a different name is created with the same column and structure. Both of the indexes will show in the DBA_OBJECTS listing.
SQL> create index dummy on am310(col1, col2, col3) nosegment;

Index created.

SQL> create index am310_n1 on am310(col1, col2, col3);

Index created.

No comments:

Post a Comment