Friday, September 12, 2008

RMAN Tracing

RMAN Tracing allows us the capability to get wom insight into what RMAN is doing behind the scenes so to speak.

Trace an RMAN Session

Trace an RMAN session to a trace file using the trace=/tracefilename.trc as part of the rman execution. Then in the RMAN execute set the debug on.

Example:

rman target username/password@target catalog username/password@catalog trace=/tmp/rman_test.trc

RMAN> run
{debug on;
report obsolete;
debug off;
}


Trace via the RMAN Channel

Another way to trace RMAN activity would be to configure the trace when configuring the RMAN channel.

1. Make sure timed_statistics = true for all performance testing.

2. set the NLS_DATE_FORMAT = 'DD-MON-YYYY HH24:MI:SS'.

3. Configure the Channel with Trace/Debug options

trace 1 - general trace info for skg and sbt
trace 5 - verbose channel tracing of skg and sbt calls

CONFIGURE CHANNEL DEVICE TYPE
DISK DEBUG=5 TRACE 1;

or

CONFIGURE CHANNEL DEVICE TYPE SBT PARMS "ENV=(....) DEBUG=5 TRACE 5;

Note: (Trace is only useful for tape backup and restore tracing)

Thursday, September 11, 2008

Oracle 11g SecureFiles

Summary

Oracle Secure Files also known as Fast Files is Oracle’s improvement to storage of large object types (LOBs). Secure Files gives comparable performance to a file system for LOBs and LOBs can store many types from data from images, large amounts of text, word documents, excel spreadsheets, XML, HTML, etc. as well as DICOM formatted medical images.

This is a step forward in helping manage unstructured data with the Oracle database by boosting performance, but also by improving security. Secure Files extends Transparent Data Encryption to LOBs, this not only makes storing and managing unstructured content easier, but improves the security of the unstructured content.

If that was not enough Secure Files also gives advanced file system features such as compression and data de-duplication. Data De-duplication is where duplicate objects in LOBs tied to many records within the database is only stored once rather then a copy for each record. This not only improves storage space, but can also offer performance improvements. Compression like it indicates compresses LOB data transparently offering storage savings and a performance boost, but Oracle takes it a step further and automatically determines if the data is able to be compressed and if so are the space savings from the compression of benefit.

By default normal LOB storage is used, called BASIC file. To use SecureFile for LOB storage the SECUREFILE lob Storage keyword must be used.


The default behavior for securefile usage can be changed via the db_securefile initialization parameter.

db_securefile={ALWAYS FORCE PERMITTED NEVER IGNORE}

ALWAYS – Always attempts to create all LOBs as SECUREFILE LOBs
FORCE - all LOBs created in the system will be created as SECUREFILE LOBs.
PERMITTED – Allows LOBs that use SecureFiles.
NEVER – Never Allows LOBs that use SecureFiles, they will always be BASICFILE LOBs
IGNORE – Ignore errors that otherwise would be raised by forcing LOBs as SECUREFILE LOBs

Can be set dynamically via an ALTER SYSTEM:

SQL> ALTER SYSTEM SET db_securefile = 'ALWAYS' ;

Securefiles offer a lot of benefits over the old LOB storage method, such as deduplication capability, compression and encryption.

Compression has 2 forms medium which is the default and high. Keep in mind the high level of compression the larger resource impact on the database you should expect.

CREATE TABLE t1 ( a CLOB)
LOB(a) STORE AS SECUREFILE
(COMPRESS
CACHE
NOLOGGING );

CREATE TABLE t1 ( a CLOB)
LOB(a) STORE AS SECUREFILE
( COMPRESS HIGH
CACHE
NOLOGGING );


Encryption for SecureFiles is implemented via the Transparent Data Encryption (TDE) and SecureFiles extends that TDE for LOB data types. Encryption is performed at the block level and uses the following valid encryption levels 2DES168, AES128, AES192 (default) and AES256. Keep in mind for SecureFiles the NO SALT option is not supported.

CREATE TABLE t1 ( a CLOB ENCRYPT USING 'AES128')
LOB(a) STORE AS SECUREFILE
( CACHE );

DeDuplication can be a powerful feature that can reduce the amount of storage space for LOBs as all duplicated LOBs are only stored once. With the desire to reduce database disk space the compress and DeDuplication can provide significant cost savings for storage.

CREATE TABLE t1 ( REGION VARCHAR2(20), ID NUMBER, a BLOB)
LOB(a) STORE AS SECUREFILE
( DEDUPLICATE
CACHE)

CREATE TABLE t1 ( a CLOB)
LOB(a) STORE AS SECUREFILE
( COMPRESS HIGH
DEDUPLICATE
CACHE ) ;

Oracle Secure Files utilizes Shared IO Pool. The shared IO pool is used from the SGA and allocations are always for a specific session and therefore the data is specific to the session. We can look at the Shared IO Pool via the v$sga_dynamic_componets and v$sgainfo V$ views. If we examine the memory structures of the SGA we can see what the Shared IO Pool max size is in relationship to the other memory structures of the database.

SQL> select name, bytes from v$sgainfo ;

NAME BYTES
-------------------------------- ----------
Fixed SGA Size 1334380
Redo Buffers 5844992
Buffer Cache Size 268435456
Shared Pool Size 239075328
Large Pool Size 4194304
Java Pool Size 12582912
Streams Pool Size 4194304
Shared IO Pool Size 0
Granule Size 4194304
Maximum SGA Size 535662592
Startup overhead in Shared Pool 46137344
Free SGA Memory Available 0


SQL> select * from v$sga_dynamic_components where component='Shared IO Pool' ;

COMPONENT CURRENT_SIZE
---------------------------------------------------------------- ------------
MIN_SIZE MAX_SIZE USER_SPECIFIED_SIZE OPER_COUNT LAST_OPER_TYP LAST_OPER
---------- ---------- ------------------- ---------- ------------- ---------
LAST_OPER GRANULE_SIZE
--------- ------------
Shared IO Pool 0
0 0 0 0 STATIC
4194304


When a session is unable to find free memory in the Shared IO Pool, PGA memory would be used. To see PGA memory allocations you can use the V$SECUREFILE_TIMER view which gets an entry each time memory is allocated out of the PGA.

SQL> select * from v$securefile_timer where name like '%PGA%';

NAME LAYER_ID OWNTIME MAXTIME MINTIME INVOCATIONS LAYER_NAME
------------------------- ---------- ------- ------- ------- ----------- --------------------------------------------------
kdlw kcbi PGA alloc timer 2 0 0 0 0
Write gather cache
kdlw kcbi PGA free timer 2 0 0 0 0
Write gather cache
kdlw kcb PGA borrow timer 2 0 0 0 0
Write gather cache
kdlw kcb PGA free timer 2 0 0 0 0
Write gather cache

Oracle 11g Results Cache

Summary

Oracle 11g has many new features one of particular interest in the idea of a results cache. Results cache allows a query’s result to be cached allowing for large performance improvements for queries that are executed multiple times. The results cache works best for tables with mostly static data and has particular queries that return the same results over and over.

One particular point of interest for the result cache is that fact that the result cache does not work when logged in as sysdba.

We can see in the explain plan of a query when the RESULT CACHE is being used as shown below:

----------------------------------------------------------------------------------------------------------------
Id Operation Name Rows Bytes TempSpc Cost (%CPU) Time
----------------------------------------------------------------------------------------------------------------
0 SELECT STATEMENT 85120 1745K 660 (1) 00:00:08
1 RESULT CACHE 5g4sqrbmnk7tw4ct7s8ak9vdgd
2 SORT ORDER BY 85120 1745K 6696K 660 (1) 00:00:08
3 PARTITION REFERENCE ALL 85120 1745K 107 (1) 00:00:02
4 TABLE ACCESS FULL ORDER_ITEMS 85120 1745K 107 (1) 00:00:02
----------------------------------------------------------------------------------------------------------------


Test Results

SQL> set linesize 150
SQL> set timing on
SQL> set echo on
SQL>
SQL> drop table results_cache_test ;

Table dropped.

Elapsed: 00:00:00.10
SQL>
SQL> -- run create a table for our testing
SQL> -- so not to skew results
SQL> create table results_cache_test
2 as
3 select *
4 from dba_tables ;

Table created.

Elapsed: 00:00:00.56
SQL>
SQL> create unique index results_cache_test_pk
2 on results_cache_test (owner, table_name) ;

Index created.

Elapsed: 00:00:00.04
SQL>
SQL> execute dbms_stats.gather_table_stats ('MRMESSIN', 'RESULTS_CACHE_TEST') ;

PL/SQL procedure successfully completed.

Elapsed: 00:00:00.95
SQL>
SQL> -- set autotrace on for first round with index
SQL> set autotrace on ;
SQL>
SQL> -- run to see the results
SQL> select table_name, cache, read_only
2 from results_cache_test
3 where owner = 'MRMESSIN' ;

TABLE_NAME CACHE REA
------------------------------ ----- ---
DEPT N NO
EMP N NO
DEMO_USERS N NO
DEMO_CUSTOMERS N NO
DEMO_ORDERS N NO
DEMO_ORDER_ITEMS N NO
DEMO_PRODUCT_INFO N NO
DEMO_STATES N NO
DEMO_PAGE_HIERARCHY N NO
EAGLE N NO
HELP_TABLE N NO

TABLE_NAME CACHE REA
------------------------------ ----- ---
BIG_EMP N NO
DEMO_IMAGES N NO
BIG_EMP2 N YES

14 rows selected.

Elapsed: 00:00:00.01

Execution Plan
----------------------------------------------------------
Plan hash value: 2738702378

----------------------------------------------------------------------------------------
Id Operation Name Rows Bytes Cost (%CPU) Time
----------------------------------------------------------------------------------------
0 SELECT STATEMENT 95 3515 25 (0) 00:00:01
* 1 TABLE ACCESS FULL RESULTS_CACHE_TEST 95 3515 25 (0) 00:00:01
----------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter("OWNER"='MRMESSIN')


Statistics
----------------------------------------------------------
1 recursive calls
0 db block gets
85 consistent gets
0 physical reads
0 redo size
800 bytes sent via SQL*Net to client
416 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
14 rows processed

SQL>
SQL> -- run a second time to cache the results
SQL> select /*+ result_cache */ table_name, cache, read_only
2 from results_cache_test
3 where owner = 'MRMESSIN' ;

TABLE_NAME CACHE REA
------------------------------ ----- ---
DEPT N NO
EMP N NO
DEMO_USERS N NO
DEMO_CUSTOMERS N NO
DEMO_ORDERS N NO
DEMO_ORDER_ITEMS N NO
DEMO_PRODUCT_INFO N NO
DEMO_STATES N NO
DEMO_PAGE_HIERARCHY N NO
EAGLE N NO
HELP_TABLE N NO

TABLE_NAME CACHE REA
------------------------------ ----- ---
BIG_EMP N NO
DEMO_IMAGES N NO
BIG_EMP2 N YES

14 rows selected.

Elapsed: 00:00:00.04

Execution Plan
----------------------------------------------------------
Plan hash value: 2738702378

-------------------------------------------------------------------------------------------------
Id Operation Name Rows Bytes Cost (%CPU) Time
-------------------------------------------------------------------------------------------------
0 SELECT STATEMENT 95 3515 25 (0) 00:00:01
1 RESULT CACHE 6qrad2hzvx6xm6rwrx23ncuwwg
* 2 TABLE ACCESS FULL RESULTS_CACHE_TEST 95 3515 25 (0) 00:00:01
-------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

2 - filter("OWNER"='MRMESSIN')

Result Cache Information (identified by operation id):
------------------------------------------------------

1 - column-count=3; dependencies=(MRMESSIN.RESULTS_CACHE_TEST); parameters=(nls); name="select /*+ result_cache */ table_name, cache, read_only
from results_cache_test
where owner = 'MRMESSIN' "



Statistics
----------------------------------------------------------
1 recursive calls
0 db block gets
85 consistent gets
0 physical reads
0 redo size
800 bytes sent via SQL*Net to client
416 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
14 rows processed

SQL>
SQL> -- run the third time to see query with results cache in place
SQL> select /*+ result_cache */ table_name, cache, read_only
2 from results_cache_test
3 where owner = 'MRMESSIN' ;

TABLE_NAME CACHE REA
------------------------------ ----- ---
DEPT N NO
EMP N NO
DEMO_USERS N NO
DEMO_CUSTOMERS N NO
DEMO_ORDERS N NO
DEMO_ORDER_ITEMS N NO
DEMO_PRODUCT_INFO N NO
DEMO_STATES N NO
DEMO_PAGE_HIERARCHY N NO
EAGLE N NO
HELP_TABLE N NO

TABLE_NAME CACHE REA
------------------------------ ----- ---
BIG_EMP N NO
DEMO_IMAGES N NO
BIG_EMP2 N YES

14 rows selected.

Elapsed: 00:00:00.04

Execution Plan
----------------------------------------------------------
Plan hash value: 2738702378

-------------------------------------------------------------------------------------------------
Id Operation Name Rows Bytes Cost (%CPU) Time
-------------------------------------------------------------------------------------------------
0 SELECT STATEMENT 95 3515 25 (0) 00:00:01
1 RESULT CACHE 6qrad2hzvx6xm6rwrx23ncuwwg
* 2 TABLE ACCESS FULL RESULTS_CACHE_TEST 95 3515 25 (0) 00:00:01
-------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

2 - filter("OWNER"='MRMESSIN')

Result Cache Information (identified by operation id):
------------------------------------------------------

1 - column-count=3; dependencies=(MRMESSIN.RESULTS_CACHE_TEST); parameters=(nls); name="select /*+ result_cache */ table_name, cache, read_only
from results_cache_test
where owner = 'MRMESSIN' "



Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
0 consistent gets
0 physical reads
0 redo size
800 bytes sent via SQL*Net to client
416 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
14 rows processed

SQL>
SQL> set autotrace off
SQL>
SQL> -- drop the index to start second round without index
SQL> drop index results_cache_test_pk ;

Index dropped.

Elapsed: 00:00:00.01
SQL>
SQL> set autotrace on ;
SQL>
SQL> -- run to see the results
SQL> select table_name, cache, read_only
2 from results_cache_test
3 where owner = 'MRMESSIN' ;

TABLE_NAME CACHE REA
------------------------------ ----- ---
DEPT N NO
EMP N NO
DEMO_USERS N NO
DEMO_CUSTOMERS N NO
DEMO_ORDERS N NO
DEMO_ORDER_ITEMS N NO
DEMO_PRODUCT_INFO N NO
DEMO_STATES N NO
DEMO_PAGE_HIERARCHY N NO
EAGLE N NO
HELP_TABLE N NO

TABLE_NAME CACHE REA
------------------------------ ----- ---
BIG_EMP N NO
DEMO_IMAGES N NO
BIG_EMP2 N YES

14 rows selected.

Elapsed: 00:00:00.03

Execution Plan
----------------------------------------------------------
Plan hash value: 2738702378

----------------------------------------------------------------------------------------
Id Operation Name Rows Bytes Cost (%CPU) Time
----------------------------------------------------------------------------------------
0 SELECT STATEMENT 95 3515 25 (0) 00:00:01
* 1 TABLE ACCESS FULL RESULTS_CACHE_TEST 95 3515 25 (0) 00:00:01
----------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter("OWNER"='MRMESSIN')


Statistics
----------------------------------------------------------
234 recursive calls
0 db block gets
116 consistent gets
0 physical reads
0 redo size
800 bytes sent via SQL*Net to client
416 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
5 sorts (memory)
0 sorts (disk)
14 rows processed

SQL>
SQL> -- run a second time to cache the results
SQL> select /*+ result_cache */ table_name, cache, read_only
2 from results_cache_test
3 where owner = 'MRMESSIN' ;

TABLE_NAME CACHE REA
------------------------------ ----- ---
DEPT N NO
EMP N NO
DEMO_USERS N NO
DEMO_CUSTOMERS N NO
DEMO_ORDERS N NO
DEMO_ORDER_ITEMS N NO
DEMO_PRODUCT_INFO N NO
DEMO_STATES N NO
DEMO_PAGE_HIERARCHY N NO
EAGLE N NO
HELP_TABLE N NO

TABLE_NAME CACHE REA

------------------------------ ----- ---
BIG_EMP N NO
DEMO_IMAGES N NO
BIG_EMP2 N YES

14 rows selected.

Elapsed: 00:00:00.04

Execution Plan
----------------------------------------------------------

Plan hash value: 2738702378

-------------------------------------------------------------------------------------------------
Id Operation Name Rows Bytes Cost (%CPU) Time
-------------------------------------------------------------------------------------------------
0 SELECT STATEMENT 95 3515 25 (0) 00:00:01
1 RESULT CACHE 6qrad2hzvx6xm6rwrx23ncuwwg
* 2 TABLE ACCESS FULL RESULTS_CACHE_TEST 95 3515 25 (0) 00:00:01
-------------------------------------------------------------------------------------------------


Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("OWNER"='MRMESSIN')

Result Cache Information (identified by operation id):
------------------------------------------------------
1 - column-count=3; dependencies=(MRMESSIN.RESULTS_CACHE_TEST); parameters=(nls); name="select /*+ result_cache */ table_name, cache, read_only
from results_cache_test
where owner = 'MRMESSIN' "



Statistics
----------------------------------------------------------
1 recursive calls
0 db block gets
85 consistent gets
0 physical reads
0 redo size
800 bytes sent via SQL*Net to client
416 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
14 rows processed

SQL>
SQL> -- run the third time to see query with results cache in place
SQL> select /*+ result_cache */ table_name, cache, read_only
2 from results_cache_test
3 where owner = 'MRMESSIN' ;

TABLE_NAME CACHE REA
------------------------------ ----- ---
DEPT N NO
EMP N NO
DEMO_USERS N NO
DEMO_CUSTOMERS N NO
DEMO_ORDERS N NO
DEMO_ORDER_ITEMS N NO
DEMO_PRODUCT_INFO N NO
DEMO_STATES N NO
DEMO_PAGE_HIERARCHY N NO
EAGLE N NO
HELP_TABLE N NO
BIG_EMP N NO
DEMO_IMAGES N NO
BIG_EMP2 N YES

14 rows selected.

Elapsed: 00:00:00.04

Execution Plan
--------------------------------------------------------
Plan hash value: 2738702378

-------------------------------------------------------------------------------------------------
Id Operation Name Rows Bytes Cost (%CPU) Time
-------------------------------------------------------------------------------------------------
0 SELECT STATEMENT 95 3515 25 (0) 00:00:01
1 RESULT CACHE 6qrad2hzvx6xm6rwrx23ncuwwg
* 2 TABLE ACCESS FULL RESULTS_CACHE_TEST 95 3515 25 (0) 00:00:01
-------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
-----------------------------------------------------

2 - filter("OWNER"='MRMESSIN')

Result Cache Information (identified by operation id):
------------------------------------------------------

1 - column-count=3; dependencies=(MRMESSIN.RESULTS_CACHE_TEST); parameters=(nls); name="select /*+ result_cache */ table_name, cache, read_only
from results_cache_test
where owner = 'MRMESSIN'"

Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
0 consistent gets
0 physical reads
0 redo size
800 bytes sent via SQL*Net to client
416 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
14 rows processed

SQL>
SQL> spool off

Oracle 11g Invisible Indexes

Summary

Oracle has now provided in what is my opinion a huge step forward in query tuning. It will now allow us to hide indexes from the optimizer without have to drop them. If you have every tuned queries of very large tables and had to drop and recreate indexes in your query tuning testing then you will realize right away how useful this is.

Another huge advantage and use of this feature is for batch process tuning. Ever had a situation where you needed an index that would really help your batch process but hurt OLTP transaction query performance. Well now we can hide the index from OLTP, but allow our batch processes to see it.

To use an invisible index you can set the parameter optimizer_use_invisible_indexes to true. The default of this parameter is false and can be set via an alter session or alter system command. Otherwise invisible indexes are completely ignore by the optimizer including through hints.

A special thing to note about invisible indexes is that they can not get optimizer statistics gathered on them while in an invisible state. Therefore to maintain statistics that index will have to be made visible by altering the index or setting the optimizer_use_invisible_indexes to true.


Example

1. Create a table for use in our example:

SQL> create table my_table as select * from scott.emp ;

Table created.


2. Create an index on our table and make it invisible.

SQL> create index my_index on my_table (ename) invisible ;

Index created.


3. Check that the index is invisible using the new VISIBILITY column of the user_indexes, all_indexes or dba_indexes views.

SQL> select index_name, visibility from user_indexes where index_name = 'MY_INDEX';

INDEX_NAME VISIBILIT
------------------------------ ---------
MY_INDEX INVISIBLE

1 row selected.


4. Attempt to gather statistics on our new and cascading to indexes. Not since the index is invisible this fails.

SQL> execute dbms_stats.gather_table_stats ('MRMESSIN', 'MY_TABLE') ;
BEGIN dbms_stats.gather_table_stats ('MRMESSIN', 'MY_TABLE') ; END;

*
ERROR at line 1:
ORA-00904: : invalid identifier
ORA-06512: at "SYS.DBMS_STATS", line 17806
ORA-06512: at "SYS.DBMS_STATS", line 17827
ORA-06512: at line 1


4. Make the invisible indexes visible.

SQL> alter session set optimizer_use_invisible_indexes = true ;

Session altered.


5. Now gather our statistics

SQL> execute dbms_stats.gather_table_stats ('MRMESSIN', 'MY_TABLE') ;

PL/SQL procedure successfully completed.


6. Set the optimizer_use_invisible_indexes back to false for the start of our testing.

SQL> alter session set optimizer_use_invisible_indexes = true ;


7. Set autotrace so we can see our explain plan and data.

SQL> set autotrace traceonly


8. Select from the table using the indexed column in our where clause which under normal circumstances that optimizer would choose to use the index. Note however we are not using the index because it is invisible.

SQL> select empno, ename from my_table where ename = 'BLAKE';

1 row selected.


Execution Plan
----------------------------------------------------------
Plan hash value: 3804444429

----------------------------------------------------------------------------
Id Operation Name Rows Bytes Cost (%CPU) Time
----------------------------------------------------------------------------
0 SELECT STATEMENT 1 10 3 (0) 00:00:01
* 1 TABLE ACCESS FULL MY_TABLE 1 10 3 (0) 00:00:01
----------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter("ENAME"='BLAKE')


Statistics
----------------------------------------------------------
1 recursive calls
0 db block gets
4 consistent gets
0 physical reads
0 redo size
477 bytes sent via SQL*Net to client
416 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
1 rows processed


9. Now lets query seeing if we can use the index Hint to use the index. Not the index is not used.

SQL> select /*+ INDEX(my_table my_index) */ empno, ename from my_table where ename = 'BLAKE’ ;

1 row selected.


Execution Plan
----------------------------------------------------------
Plan hash value: 3804444429

----------------------------------------------------------------------------
Id Operation Name Rows Bytes Cost (%CPU) Time
----------------------------------------------------------------------------
0 SELECT STATEMENT 1 10 3 (0) 00:00:01
* 1 TABLE ACCESS FULL MY_TABLE 1 10 3 (0) 00:00:01
----------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter("ENAME"='BLAKE')


Statistics
----------------------------------------------------------
1 recursive calls
0 db block gets
4 consistent gets
0 physical reads
0 redo size
477 bytes sent via SQL*Net to client
416 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
1 rows processed


10. Now let see if the index is used if we set the parameter optimizer_use_invisible_indexes to true.

SQL> alter session set optimizer_use_invisible_indexes = true ;

Session altered.


11. Note that index is now seen and is being used.

SQL> select empno, ename from my_table where ename = 'BLAKE';

1 row selected.


Execution Plan
----------------------------------------------------------
Plan hash value: 332163487

-----------------------------------------------------------------------------
Id Operation Name RowsBytesCost %CPU) Time
-----------------------------------------------------------------------------
0 SELECT STATEMENT 1 10 2 (0) 00:00:01
1 TABLE ACCESS BY INDEX ROWIDMY_TABLE 1 10 2 (0) 00:00:01
*2 INDEX RANGE SCAN MY_INDEX 1 1 (0) 00:00:01
----------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

2 - access("ENAME"='BLAKE')


Statistics
----------------------------------------------------------
1 recursive calls
0 db block gets
3 consistent gets
0 physical reads
0 redo size
477 bytes sent via SQL*Net to client
416 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
1 rows processed