Anomaly in “BITMAP CONVERSION TO ROWIDS” estimation

Let’s create our test harness first:

CREATE TABLE IDXTEST AS select 1e6 + rownum id, 1e6 + trunc(rownum/1000)*2 id2, rpad(‘a’,399,’a’) filler
from dual connect by level <2e6
order by dbms_random.value;

CREATE BITMAP INDEX IDXTEST_IDX1 ON IDXTEST (id2);

I’ve created a table with column id2 having a single unique value per 1000 rows.

Let’s have a look at 2 execution plans (of 2 a bit different queries):
1st one uses bitmap index to return all rows for given indexed column


SQL_ID  bv039034q966g, child number 1                                                                                                                                                                   
-------------------------------------                                                                                                                                                                   
select id2 FROM IDXTEST                                                                                                                                                                                 
                                                                                                                                                                                                        
Plan hash value: 1842016195                                                                                                                                                                             
                                                                                                                                                                                                        
---------------------------------------------------------------------------------------------                                                                                                           
| Id  | Operation                    | Name         | Rows  | Bytes | Cost (%CPU)| Time     |                                                                                                           
---------------------------------------------------------------------------------------------                                                                                                           
|   0 | SELECT STATEMENT             |              |       |       |   900 (100)|          |                                                                                                           
|   1 |  BITMAP CONVERSION TO ROWIDS |              |  1999K|    11M|   900   (0)| 00:00:01 |                                                                                                           
|   2 |   BITMAP INDEX FAST FULL SCAN| IDXTEST_IDX1 |       |       |            |          |                                                                                                           
---------------------------------------------------------------------------------------------                                                                                                           
                                                                                                                                                                                                    

Second one returns distinct value of bitmap indexed column:

SQL_ID  0gtn94fcg82hj, child number 0                                                                                                                                                                   
-------------------------------------                                                                                                                                                                   
select distinct id2 FROM IDXTEST                                                                                                                                                                        
                                                                                                                                                                                                        
Plan hash value: 473080087                                                                                                                                                                              
                                                                                                                                                                                                        
---------------------------------------------------------------------------------------------                                                                                                           
| Id  | Operation                    | Name         | Rows  | Bytes | Cost (%CPU)| Time     |                                                                                                           
---------------------------------------------------------------------------------------------                                                                                                           
|   0 | SELECT STATEMENT             |              |       |       |   949 (100)|          |                                                                                                           
|   1 |  HASH UNIQUE                 |              |  2000 | 12000 |   949   (6)| 00:00:01 |                                                                                                           
|   2 |   BITMAP INDEX FAST FULL SCAN| IDXTEST_IDX1 |  1999K|    11M|   900   (0)| 00:00:01 |                                                                                                           
---------------------------------------------------------------------------------------------                                                                                                           
                                                                                                                                                                                                        

You can see that Oracle estimate the 2nd query a bit higher and it doesn’t estimate “BITMAP CONVERSION TO ROWIDS” at all which is very suspicious for me as that operation on big datasets can be both CPU and IO(temp) intensive.
Let’s see what is in reality?

Let’s repeat our exercise one more time with ALTER SESSION SET statistics_level=ALL
And show execution plan as select * from TABLE(dbms_xplan.display_cursor(null,null,’typical +iostats last’));
instead of select * from TABLE(dbms_xplan.display);

So here is my results:
1st execution:

SQL_ID  bv039034q966g, child number 2                                                                                                  
-------------------------------------                                                                                                  
select id2 FROM IDXTEST                                                                                                                
                                                                                                                                       
Plan hash value: 1842016195                                                                                                            
                                                                                                                                       
---------------------------------------------------------------------------------------------------------------------------------------                                                                 
| Id  | Operation                    | Name         | Starts | E-Rows |E-Bytes| Cost (%CPU)| E-Time   | A-Rows |   A-Time   | Buffers | 
---------------------------------------------------------------------------------------------------------------------------------------                                                                 
|   0 | SELECT STATEMENT             |              |      1 |        |       |   900 (100)|          |   1999K|00:00:05.93 |    2012 | 
|   1 |  BITMAP CONVERSION TO ROWIDS |              |      1 |   1999K|    11M|   900   (0)| 00:00:01 |   1999K|00:00:05.93 |    2012 | 
|   2 |   BITMAP INDEX FAST FULL SCAN| IDXTEST_IDX1 |      1 |        |       |            |          |   2000 |00:00:00.05 |    2012 | 
---------------------------------------------------------------------------------------------------------------------------------------

2nd execution:

SQL_ID  0gtn94fcg82hj, child number 1                                                                                                  
-------------------------------------                                                                                                  
select distinct id2 FROM IDXTEST                                                                                                       
                                                                                                                                       
Plan hash value: 473080087                                                                                                              
                                                                                                                                        
--------------------------------------------------------------------------------------------------------------------------------------- 
| Id  | Operation                    | Name         | Starts | E-Rows |E-Bytes| Cost (%CPU)| E-Time   | A-Rows |   A-Time   | Buffers | 
--------------------------------------------------------------------------------------------------------------------------------------- 
|   0 | SELECT STATEMENT             |              |      1 |        |       |   949 (100)|          |   2000 |00:00:00.02 |    1012 | 
|   1 |  HASH UNIQUE                 |              |      1 |   2000 | 12000 |   949   (6)| 00:00:01 |   2000 |00:00:00.02 |    1012 | 
|   2 |   BITMAP INDEX FAST FULL SCAN| IDXTEST_IDX1 |      1 |   1999K|    11M|   900   (0)| 00:00:01 |   2000 |00:00:00.01 |    1012 | 
--------------------------------------------------------------------------------------------------------------------------------------- 

You can see that in reality 2nd execution is faster more than 100 times (0.02 sec vs 5 sec).
It seems a severe limitation of Oracle optimizer that can block potentially very beneficial (from performance perspective) execution plans. I’m going to publish some “near real life” example in my next blog.

No Parse execution and on the fly DDL change

There was an interesting question on PGDay17

“What is going on if we have a cursor cached on server side and suddenly (for the client) underlying DDL changed (added column, changed column type, etc. etc.).  I was claiming that an additional round trip would happened with re-parse request, but I was wrong!

I made an experiment and here is results:

“usual execution“: w/o DDL change for the underlying table,
That is an execution after cursor have been cached both on server and client side, actually I have not closed the cursor, but reused the same cursor:

DDL_chg1execution after DDL: I’ve added a single column to the underlying table:
It is the same cursor and the same round of execution as above, but I’ve just added a column.

DDL_chg2

You can see Oracle sends the same packet as after 1st execution and  parsing so client aware of a new column.

For just in case the very 1st query execution result is here:

DDL_chg3

PS.
Oracle resend column definitions to client after any changes that invalidate underlying cursor. For example I executed ALTER TABLE … DEALLOCATE UNUSED and observed the same effect.

 

Remote daemon autot

When you do performance troubleshooting and investigation it is quite common to measure some “deltas” (for example v$sesstat deltas) . It is also important that your measurement do not posses a “quantum” effect :), i.e.  doesn’t influence your measured process. Sometimes you can neglect such effects, sometimes (for example for parsing investigations) when you measure a tiny effect it can be quite annoying.

So I decided to implement (and  just did it)  a small daemon to measure session stats on behalf of my “main” session.

The idea is quite simple:

  1. You have a pretty small  web server which keeps connection/s with the same database as your main session.
  2. You communicate with the daemon with a very underutilized sqlplus feature – “remote scripting” , i.e. you can call *.sql (or other file) not only from your local machine but rather from any other place on the network (like http://localhost:7777/some.sql).
  3. Your daemon keeps your “main session” v$sesstat snapshots and gives you back “delta” results.

You can download the daemon from here:

https://github.com/drema201/RDAutot/tree/master/build/distributions

to run the daemon you need:

RDAutot.bat scott/tyger@localhost:1521:ORCL  [optional port]

and to use it from sqlplus:

@http://127.0.0.1:80/stats/sid=&SID/statname=(parse)/

select count(1) from dba_tables;

@http://127.0.0.1:80/stats/sid=&SID/statname=(parse)/

PS

statname takes as input REGEXP_LIKE expression and unfortunately you need to do URLEncode by yourself  😦 (Oracle http client inside sqlplus seems very primitive and in many cases just truncates http request after unknown character)

 

TNS protocol decypher – 1st execution

CURSOR_SELECT_1ST

Here you can see a network packet for the 1st execution of the cursor:

  • cursor number =0 – as no cursor has been opened on server side so far
  • 0x0193 = 403 – a length of my SQL statement (SELECT /* ….. FROM YYYTEST …..)
  • 0x0A = 10 – prefetch size for the cursor (default JDBC prefetch size)
  • 0x28 = 40 – a size of my bind variables array, i.e. :f1, :f2, …., :f40

and after the sql text itself you can see a section of bind definitions:

CURSOR_SELECT_1ST_2

Cursor “no parse” execution trace

 

There are approximately 4 “types” of SQL cursor execution in Oracle.

hard parse
soft parse
softer soft parse
no parse

See http://alexzeng.wordpress.com/2012/12/31/oracle-core-hard-parse-soft-parse-soft-soft-parse-no-parse-at-all/
for instance.

However I was always wondering what is going under the hood for “no parse” case.
Your client (JDBC or whatever) should communicate somehow with your Oracle server.
It can’t be SQL statement itself otherwise some kind of parsing is unavoidable.
So it seems natural that you need to exchange some kind of identifier.

But what exact identifier/s are used in Oracle vs. client  communication.
I’ve read/heard several times that some kind of Oracle handles exists in sessions PGA area, etc. but never seen the details.

So I decided to trace it by myself.

It seems Wireshark is an ultimate tool to see what is going on on networking layer.

My Java testcase look like:

Connection con = dataSource.getConnection();
PreparedStatement ps = con.prepareStatement(SQL);
PreparedStatement ps2 = con.prepareStatement(SQL2);
for (int j=1; j<30; j++) {   //traverse 1st 30 param sets
..... set bind variables
for (int l=1;l<=8;l++) {
   ResultSet rs= ps.executeQuery();
   ResultSet rs2= ps2.executeQuery();
    while (rs.next()){
        System.out.print('.');
    }
    while (rs2.next()){
        System.out.print('.');
    }
   rs.close();
   rs2.close();
}
...
}

First of all no network round trip on  con.prepareStatement(SQL) step (it seems postponed to make simultaneously  prepare and execute phase)

1st execution of  ResultSet rs= ps.executeQuery() looks like below:
You easily can see text of my SELECT query here:cursor0

According to TNS protocol spec here:
http://thesprawl.org/research/oracle-tns-protocol/
0x03 is a code of TTI function call and ox5e is a subcode for query (SELECT) operation.

However the most interesting part is 2nd and all consequent executions (they should go as “no parse” variant)

Let’s compare 2nd and 3rd execution of:

ResultSet rs= ps.executeQuery();
ResultSet rs2= ps2.executeQuery();

2nd execution
cursor_comp1

3rd execution:

cursor_comp2

You can see 2 interesting parts here:

  • 1st part just after 0x03 ox53  – looks like a counter of consequent SQL executions for your session ( 0x07, 0x08, 0x09, 0x0a)
  • 2nd part 0x03 for one query and 2nd one 0x05  are repeatable for all executions (I have shown only 2 of them here)

So it seems our desirable cursor identifier and it is definitely not a sql_id or sql handler (as been claimed somewhere).
The most interesting question however what does it mean exactly.

Let’s do a CURSORDUMP as described here:
http://blog.tanelpoder.com/2009/07/09/identify-the-sql-statement-causing-those-wait-x-lines-in-a-top-truncated-sql-tracefile/
oradebug setospid 1820
oradebug dump cursordump 1

And the extract of result looks like:

Cursor#3(0xffff80ffbde11c48) state=BOUND curiob=0xffff80ffbde28a40
 curflg=4e fl2=0 par=0x0 ses=0x1fcbd8db0
----- Dump Cursor sql_id=6ndm9d5b9vg1t xsc=0xffff80ffbde28a40 cur=0xffff80ffbde11c48 -----

LibraryHandle:  Address=1fb2d5ae8 Hash=569dbc39 LockMode=N PinMode=0 LoadLockMode=0 Status=VALD
  ObjectName:  Name=SELECT /* NoParse_40Issue */ * FROM YYTEST WHERE (f1,f2,f3,f4,f5,f6,f7,f8,f9,f10,f11,f12,f13,f14,f15,f16,f17,f18,f19,f20,f21,f22,f23,f24,f25,f26,f27,f28,f29,f30,f31,f32,f33,f34,f35,f36,f37,f38,f39,f40) IN ((:f1,:f2,:f3,:f4,:f5,:f6,:f7,:f8,:f9,:f10,:f11,:f12,:f13,:f14,:f15,:f16,:f17,:f18,:f19,:f20,:f21,:f22,:f23,:f24,:f25,:f26,:f27,:f28,:f29,:f30,:f31,:f32,:f33,:f34,:f35,:f36,:f37,:f38,:f39,:f40))
    FullHashValue=258bfcabddf89e5c6a366969569dbc39 Namespace=SQL AREA(00) Type=CURSOR(00) Identifier=1453177913 OwnerIdn=85
  Statistics:  InvalidationCount=4 ExecutionCount=30 LoadCount=6 ActiveLocks=2 TotalLockCount=2 TotalPinCount=1
  Counters:  BrokenCount=1 RevocablePointer=1 KeepDependency=5 BucketInUse=1 HandleInUse=1 HandleReferenceCount=0
  Concurrency:  DependencyMutex=1fb2d5b98(0, 6, 0, 0) Mutex=1fb2d5c18(164, 99, 0, 6)
  Flags=RON/PIN/TIM/PN0/DBN/[10012841]
...............................
...................................
................................
Cursor#5(0xffff80ffbde11d68) state=BOUND curiob=0xffff80ffbdca1f80
 curflg=4e fl2=0 par=0x0 ses=0x1fcbd8db0
----- Dump Cursor sql_id=84mwtcmy0b3za xsc=0xffff80ffbdca1f80 cur=0xffff80ffbde11d68 -----

LibraryHandle:  Address=1fb2ce130 Hash=fc058fea LockMode=N PinMode=0 LoadLockMode=0 Status=VALD
  ObjectName:  Name=SELECT /* NoParse_40Issue */ * FROM YYTEST WHERE (f1,f2,f3,f4,f5,f6,f7,f8,f9,f10,f11,f12,f13,f14,f15,f16,f17,f18,f19,f20) IN ((:f1,:f2,:f3,:f4,:f5,:f6,:f7,:f8,:f9,:f10,:f11,:f12,:f13,:f14,:f15,:f16,:f17,:f18,:f19,:f20))
    FullHashValue=fa2532489a58f35a824f9964fc058fea Namespace=SQL AREA(00) Type=CURSOR(00) Identifier=4228222954 OwnerIdn=85
  Statistics:  InvalidationCount=4 ExecutionCount=29 LoadCount=6 ActiveLocks=2 TotalLockCount=2 TotalPinCount=1
  Counters:  BrokenCount=1 RevocablePointer=1 KeepDependency=5 BucketInUse=1 HandleInUse=1 HandleReferenceCount=0
  Concurrency:  DependencyMutex=1fb2ce1e0(0, 6, 0, 0) Mutex=1fb2ce260(164, 91, 0, 6)
  Flags=RON/PIN/TIM/PN0/DBN/[10012841]

 

So you can see that JDBC client  passes “slot number in open cursor array in UGA” for “no parse” execution
(see again : http://blog.tanelpoder.com/2009/07/09/identify-the-sql-statement-causing-those-wait-x-lines-in-a-top-truncated-sql-tracefile/)