Mohamed Houri’s Oracle Notes

March 9, 2013

SQL PATCH and invisible index

Filed under: Oracle — hourim @ 4:01 pm

I was playing with the demo presented in the oracle optimizer blog on how to use SQL path to inject a hint into a packaged application and then decided to extend it a little bit to see how this SQL patch will react if I make invisible the index used in the hint. You can get the script I used directly from the optimizer group blog.

Suppose you have the following query into a packaged application which does’nt allow any SQL code alteration

SQL>  explain plan for
  2  Select count(*), max(emp1no)
  3  From   (Select *
  4          From   emp1
  5          Where  deptno = 10);

Explained.

SQL>  select * from table(dbms_xplan.display);

---------------------------------------------------------------------------
| Id  | Operation          | Name | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |     1 |    16 |   241   (2)| 00:00:03 |
|   1 |  SORT AGGREGATE    |      |     1 |    16 |            |          |
|*  2 |   TABLE ACCESS FULL| EMP1 | 95000 |  1484K|   241   (2)| 00:00:03 |
---------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - filter("DEPTNO"=10) 

And you want to access the EMP table via its index EMP1_I1. As explained in the optimizer blog article, you can use the dbms_sqldiag_internal.i_create_patch as follows:

SQL>  begin
  2    sys.dbms_sqldiag_internal.i_create_patch(
  3        sql_text  => 'Select count(*), max(emp1no) From   (Select * From   emp1 Where  deptno = 10)',
  4        hint_text => 'INDEX(@SEL$2 emp1)',
  5        name      => 'index_patch');
  6  end;
  7  /

SQL>  Select count(*), max(emp1no)
  2  From   (Select *
  3          From   emp1
  4          Where  deptno = 10);

  COUNT(*) MAX(EMP1NO)
---------- -----------
     99900      100000

SQL>  select * from table(dbms_xplan.display_cursor);

-----------------------------------------------------------------------------
| Id  | Operation                    | Name    | Rows  | Bytes | Cost (%CPU)|    
-----------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |         |       |       |   912 (100)|          
|   1 |  SORT AGGREGATE              |         |     1 |    16 |            |          
|   2 |   TABLE ACCESS BY INDEX ROWID| EMP1    | 95000 |  1484K|   912   (1)|
|*  3 |    INDEX RANGE SCAN          | EMP1_I1 | 95000 |       |   188   (2)| 
-----------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   3 - access("DEPTNO"=10)

Note
-----
   - SQL patch "index_patch" used for this statement

And the index is used without altering the packaged application.

But what will happen if we make the index EMP1_I1 invisible

SQL> alter index emp1_I1 invisible;

Index altered.

SQL> Select count(*), max(emp1no)
  2      From   (Select *
  3              From   emp1
  4              where  deptno = 10);

  COUNT(*) MAX(EMP1NO)
---------- -----------
     99900      100000

SQL> select * from table(dbms_xplan.display_cursor);

---------------------------------------------------------------------------
| Id  | Operation          | Name | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |       |       |   241 (100)|          |
|   1 |  SORT AGGREGATE    |      |     1 |     8 |            |          |
|*  2 |   TABLE ACCESS FULL| EMP1 | 95000 |   742K|   241   (2)| 00:00:03 |
---------------------------------------------------------------------------

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

   2 - filter("DEPTNO"=10)

Note
-----
   - SQL patch "index_patch" used for this statement

The SQL patch is marked as being used but the hint which is supposed to add to the packaged query is not used. We have FULL TABLE ACCES SCAN instead.

That is, invisible index, represent one of the other reasons to look for when you note that, despite your SQL path is used, the hint is not applied

And wait!! What if I drop this index?

SQL> drop index emp1_i1;

Index dropped.

SQL> Select count(*), max(emp1no)
  2      From   (Select *
  3              From   emp1
  4              where  deptno = 10);

  COUNT(*) MAX(EMP1NO)
---------- -----------
     99900      100000

SQL> select * from table(dbms_xplan.display_cursor);

---------------------------------------------------------------------------
| Id  | Operation          | Name | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |       |       |   241 (100)|          |
|   1 |  SORT AGGREGATE    |      |     1 |     8 |            |          |
|*  2 |   TABLE ACCESS FULL| EMP1 | 95000 |   742K|   241   (2)| 00:00:03 |
---------------------------------------------------------------------------

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

   2 - filter("DEPTNO"=10)

Note
-----
   - SQL patch "index_patch" used for this statement

Definitely This Note about SQL patch which accompanies the execution plan is not to be always trusted. Something needs to be changed here. How could a non reproducible SQL PATH be marked as being used when it did not what it is supposed to do. May be the optimizer group should identify a non reproducible SQL path, marks it as such and display it into the dba_sql_patches table via a column such as reproducible (No/Yes)

Advertisements

1 Comment »

  1. […] SQL Plan Baseline I wanted to know how these two technologies collaborate together. As I did in my preceding blog article I used the demo proposed by the optimizer group. Remember from the previous post that […]

    Pingback by SQL Patch and SQL Plan Baseline how do they collaborate | — March 9, 2013 @ 8:39 pm | Reply


RSS feed for comments on this post. TrackBack URI

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s

Create a free website or blog at WordPress.com.

Tony's Oracle Tips

Tony Hasler's light hearted approach to learning about Oracle

Richard Foote's Oracle Blog

Focusing Specifically On Oracle Indexes, Database Administration and Some Great Music

Hatem Mahmoud Oracle's blog

Just another Oracle blog : Database topics and techniques

Mohamed Houri’s Oracle Notes

Qui se conçoit bien s’énonce clairement

Oracle Diagnostician

Performance troubleshooting as exact science

Raheel's Blog

Things I have learnt as Oracle DBA

Coskan's Approach to Oracle

What I learned about Oracle

So Many Oracle Manuals, So Little Time

“Books to the ceiling, Books to the sky, My pile of books is a mile high. How I love them! How I need them! I'll have a long beard by the time I read them”—Lobel, Arnold. Whiskers and Rhymes. William Morrow & Co, 1988.

EU Careers info

Your career in the European Union

Carlos Sierra's Tools and Tips

Tools and Tips for Oracle Performance and SQL Tuning

Oracle Scratchpad

Just another Oracle weblog

OraStory

Dominic Brooks on Oracle Performance, Tuning, Data Quality & Sensible Design ... (Now with added Sets Appeal)

%d bloggers like this: