Mohamed Houri’s Oracle Notes

January 20, 2014

SQL Plan Management and Indexes: Part ii

Filed under: Sql Plan Managment — hourim @ 1:30 pm

It is strange sometimes in the Oracle word to find a similarity between two concepts that seem to be not related at all. These two concepts I am insinuating to are the functioning of indexes in (a) covering the deadlock threat of unindexed foreign key constraints and (b) reproducibility of a SQL plan baseline.

In my last post about the reproducibility of an index based SQL plan baseline I have found that this plan baseline ceases to be used when

  1.    The index is dropped (obvious)
  2.    The index is renamed(not obvious)
  3.    The leading column(s) of the index is (are) changed

In this post I would like to show another situation where this SPM plan stops to be reproducible and will write few words about the point related to the change of the index leading column(s). You will see the resemblance between the  functioning of the foreign key indexes and the reproducibility of the ”indexed” SPM plans.

As always I will start by the model

 CREATE TABLE t_range
(
ID           NUMBER              NOT NULL,
X            VARCHAR2(30 CHAR)   NOT NULL,
D            DATE,
C1           NUMBER
)
PARTITION BY RANGE (ID)
(
PARTITION P_10000 VALUES LESS THAN (10000) ,
PARTITION P_20000 VALUES LESS THAN (20000) ,
PARTITION P_30000 VALUES LESS THAN (30000) ,
PARTITION P_40000 VALUES LESS THAN (40000) ,
PARTITION P_50000 VALUES LESS THAN (50000) ,
PARTITION P_60000 VALUES LESS THAN (60000)
);

INSERT INTO t_range VALUES (150,   'First Part', sysdate - 2, 42);
INSERT INTO t_range VALUES (11500, 'Second Part',sysdate + 12, 82 );
INSERT INTO t_range VALUES (25000, 'Third Part',sysdate + 5, 102);
INSERT INTO t_range VALUES (34000, 'Fourt Part',sysdate -25, 302);
INSERT INTO t_range VALUES (44000, 'Fifth Part',sysdate -1, 525);
INSERT INTO t_range VALUES (53000, 'Sixth Part',sysdate +15, 1000);
commit;

create index t_r_i1 on t_range(id, c1);
exec dbms_stats.gather_table_stats(user, 't_range');

I have a simple query with two predicates on a range partitioned table which looks like

var n1 number;
var n2 number;
exec :n1 := 150
exec :n2 := 42;

select * from t_range where id = :n1 and c1 = :n2;

Already constrained or protected against any plan instability by the following ”indexed” SPM baseline (see Note below)

SQL_ID  ahufs9gr5x2pm, child number 1
-------------------------------------

select * from t_range where id = :n1 and c1 = :n2

Plan hash value: 2219242098
--------------------------------------------------------------------------------------------------------------
| Id  | Operation                          | Name    | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
--------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                   |         |       |       |     2 (100)|          |       |       |
|   1 |  TABLE ACCESS BY GLOBAL INDEX ROWID| T_RANGE |     1 |    26 |     2   (0)| 00:00:01 | ROWID | ROWID |
|*  2 |   INDEX RANGE SCAN                 | T_R_I1  |     1 |       |     1   (0)| 00:00:01 |       |       |
--------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("ID"=:N1 AND "C1"=:N2)

Note
-----
- SQL plan baseline SQL_PLAN_9q2w8c3tu6407af6ef80e used for this statement

I said above that changing the leading column(s) of the index will stop the reproducibility of the SPM plan. Let me be more precise about this point. I will reverse the order of the t_r_i1 index columns as shown below:

drop index t_r_i1;

create index t_r_i1 on t_range(c1,id); --> columns are reversed

select * from t_range where id = :n1 and c1 = :n2;

ID X                              D                         C1
---------- ------------------------------ ----------------- ----------
150 First Part                     20140118 11:20:53         42

SQL> start c:\x

SQL_ID  ahufs9gr5x2pm, child number 1
-------------------------------------
select * from t_range where id = :n1 and c1 = :n2

Plan hash value: 2219242098

--------------------------------------------------------------------------------------------------------------
| Id  | Operation                          | Name    | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
--------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                   |         |       |       |     2 (100)|          |       |       |
|   1 |  TABLE ACCESS BY GLOBAL INDEX ROWID| T_RANGE |     1 |    26 |     2   (0)| 00:00:01 | ROWID | ROWID |
|*  2 |   INDEX RANGE SCAN                 | T_R_I1  |     1 |       |     1   (0)| 00:00:01 |       |       |
--------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("C1"=:N2 AND "ID"=:N1)

Note
-----
- SQL plan baseline SQL_PLAN_9q2w8c3tu6407af6ef80e used for this statement

Despite I have reversed the index columns the baseline is still used. When you have a predicate on two (or more) columns covered by an index on these columns, the new index you might re-create should always start by these two columns in any order if you want to ensure the reproducibility of the originally attached SPM plan. Spot the resemblance between the indexes on the foreign key which should start by the foreign key columns in any order in order to be able to avoid the deadlock threat when deleting from the parent table.

Having made this precision, let me now investigate the index type influence. Let’s change the orginal baselined index from b-tree to a locally partitioned index type.

drop index t_r_i1;

create index t_r_i1 on t_range(id,c1) local;

select * from t_range where id = :n1 and c1 = :n2;

ID X                              D                         C1
---------- ------------------------------ ----------------- ----------
150 First Part                     20140118 11:20:53         42

SQL_ID  ahufs9gr5x2pm, child number 1
-------------------------------------

select * from t_range where id = :n1 and c1 = :n2

Plan hash value: 963134062
--------------------------------------------------------------------------------------------------------------
| Id  | Operation                          | Name    | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
--------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                   |         |       |       |     2 (100)|          |       |       |
|   1 |  PARTITION RANGE SINGLE            |         |     1 |    26 |     2   (0)| 00:00:01 |   KEY |   KEY |
|   2 |   TABLE ACCESS BY LOCAL INDEX ROWID| T_RANGE |     1 |    26 |     2   (0)| 00:00:01 |   KEY |   KEY |
|*  3 |    INDEX RANGE SCAN                | T_R_I1  |     1 |       |     1   (0)| 00:00:01 |   KEY |   KEY |
--------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
3 - access("ID"=:N1 AND "C1"=:N2)

The SPM baseline ceases to be used.

Changing the index type has an influence on the re-usability of the SPM plan even when you don’t change any order of the indexed columns . In the same context of index type, I have also tried several changes (a) from b-tree to bitmap (b) from global to local and vice versa. For each index type change, the SPM stops to be reproducible.

Nevertheless, I have found two situations where changing the index type did not influenced the reproducibility of the SPM plan : (1) function based index under certain circumstances and (b) reversing an index. Here below how I did observed these two situations respectively

drop index t_r_i1;

create index t_r_i1 on t_range(c1,id, trunc(d));

I added an extra column to the “baselined index” which has the consequence to change its type from b-tree to function based index. Spot what happens to the SPM plan in this case:


select * from t_range where id = :n1 and c1 = :n2;

ID X                              D                         C1
---------- ------------------------------ ----------------- ----------
150 First Part                     20140118 11:20:53         42

start c:\x

SQL_ID  ahufs9gr5x2pm, child number 1
-------------------------------------
select * from t_range where id = :n1 and c1 = :n2

Plan hash value: 2219242098
--------------------------------------------------------------------------------------------------------------
| Id  | Operation                          | Name    | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
--------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                   |         |       |       |     2 (100)|          |       |       |
|   1 |  TABLE ACCESS BY GLOBAL INDEX ROWID| T_RANGE |     1 |    26 |     2   (0)| 00:00:01 | ROWID | ROWID |
|*  2 |   INDEX RANGE SCAN                 | T_R_I1  |     1 |       |     1   (0)| 00:00:01 |       |       |
--------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("C1"=:N2 AND "ID"=:N1)

Note
-----
- SQL plan baseline SQL_PLAN_9q2w8c3tu6407af6ef80e used for this statement

The baseline is still reproducible. When you change a “baselined” b-tree index to a function based index starting with the “baselined” index columns, then the SPM will still be reproducible. Spot the resemblance with the function based index that are able to cover the foreign key(FK) deadlock threat when they start by the FK columns in any order.

And finally Reversing my original ”baselined” index


create index t_r_i1 on t_range(id, c1) reverse;

select * from t_range where id = :n1 and c1 = :n2;

ID X                              D                         C1
---------- ------------------------------ ----------------- ----------
150 First Part                     20140118 11:20:53         42

start c:\x

SQL_ID  ahufs9gr5x2pm, child number 1
-------------------------------------
select * from t_range where id = :n1 and c1 = :n2

Plan hash value: 2219242098
--------------------------------------------------------------------------------------------------------------
| Id  | Operation                          | Name    | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
--------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                   |         |       |       |     2 (100)|          |       |       |
|   1 |  TABLE ACCESS BY GLOBAL INDEX ROWID| T_RANGE |     1 |    26 |     2   (0)| 00:00:01 | ROWID | ROWID |
|*  2 |   INDEX RANGE SCAN                 | T_R_I1  |     1 |       |     1   (0)| 00:00:01 |       |       |
--------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("ID"=:N1 AND "C1"=:N2)

Note
-----
- SQL plan baseline SQL_PLAN_9q2w8c3tu6407af6ef80e used for this statement

Not good. I would have been inclined  to say that reversing the index should stop the reproducibility of the baseline plan. Because reversing an index might solve a buffer busy wait problem but might also in the meantime create a db file sequential read wait problem. Why then continue restricting other plans to be used because of this SPM plan reproducibility which is, in contrast to its original situation, is using a costly reversed index?

 

1 Comment »

  1. […] Changing the index type (with particular situations for function based and reverse indexes) […]

    Pingback by SPM reproducibility: changing the _optimizer_skip_scan_enabled value | Mohamed Houri’s Oracle Notes — March 17, 2014 @ 9:36 am | 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

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: