RE: query performance following 12c upgrade

  • From: Jonathan Lewis <jonathan@xxxxxxxxxxxxxxxxxx>
  • To: Steve Bradshaw <sjb1970@xxxxxxxxx>
  • Date: Wed, 23 Sep 2015 14:02:41 +0000



Both queries claim to have taken 0.01 seconds to run, doing no physical I/O but
visiting 145 buffers; but the 12c plan says that it's using dynamic sampling
and obeying a directive.

I think that if you enabled SQL trace you would find that the rest of your 13
seconds is Oracle running dynamic sampling queries against the data so that it
can decide on the best execution plan. It might also be spending some time
querying the data dictionary to find out what the SQL Directives for this table
were; that would be a little unusual but I think I saw a bug note on MoS
recently that said something about one table ending up with literally thousands
of directives associated with it.

All the automatic dynamic stats and dynamic sampling switches off when you set
the database back to 11.2.0.4.
I can't remember the parameter names, but there are a couple of parameters you
could use to disable some of the adaptive and dynamic stuff if this is causing
a system-wide problem.


Regards
Jonathan Lewis
http://jonathanlewis.wordpress.com
@jloracle
________________________________
From: Steve Bradshaw [sjb1970@xxxxxxxxx]
Sent: 23 September 2015 14:53
To: Jonathan Lewis
Cc: ORACLE-L
Subject: Re: query performance following 12c upgrade

Hi,

Please see the attached. opti12 is the results when run with
optimizer_featured_enable=12.1.0.2, and opti11 it is 11.2.0.3

I've had to anonymyse the data/columns/tables etc so the formatting may be a
little out.

Thanks

Steve



On Wed, Sep 23, 2015 at 12:04 PM, Jonathan Lewis
<jonathan@xxxxxxxxxxxxxxxxxx<mailto:jonathan@xxxxxxxxxxxxxxxxxx>> wrote:

Stephen,

They may be deceiving you.

Since the queries take only a few seconds to run you can do the following:

spool xxx
set serveroutput off
set linesize 180
set trimspool on
set pagesize 60
alter session set statistics_level = all;
{run the query}
select * from table(dbms_xplan.display_cursor(null,null,'allstats last
outline'));
alter session set statistics_level = typcial;
spool off

This will pull the actual execution plan from memory.
With the options I've given this will also include you some details about the
work done (allstats last), and perhaps some clues about the strategy that the
optimizer followed (outline).




Regards
Jonathan Lewis
http://jonathanlewis.wordpress.com
@jloracle
________________________________
From: Steve Bradshaw [sjb1970@xxxxxxxxx<mailto:sjb1970@xxxxxxxxx>]
Sent: 23 September 2015 11:54
To: Jonathan Lewis
Cc: ORACLE-L
Subject: Re: query performance following 12c upgrade

Hi Jonathan,

Thanks for the reply.

The plans I've been looking at are from sqplus with autotrace on - is that
incorrect?

Steve


On Wed, Sep 23, 2015 at 11:30 AM, Jonathan Lewis
<jonathan@xxxxxxxxxxxxxxxxxx<mailto:jonathan@xxxxxxxxxxxxxxxxxx>> wrote:


The difference in performance is so extreme that I'd first have to check
whether or not the plans were true, they look like plans from EXPLAIN PLAN
rather than plans pulled from memory. It would also help to see the predicate
sections anyway.

If these really are the run-time plans with such a massive difference in
performance I'd also want to check for any significant changes in data content,
or physical data location.



Regards
Jonathan Lewis
http://jonathanlewis.wordpress.com
@jloracle
________________________________
From: oracle-l-bounce@xxxxxxxxxxxxx<mailto:oracle-l-bounce@xxxxxxxxxxxxx>
[oracle-l-bounce@xxxxxxxxxxxxx<mailto:oracle-l-bounce@xxxxxxxxxxxxx>] on behalf
of Steve Bradshaw [sjb1970@xxxxxxxxx<mailto:sjb1970@xxxxxxxxx>]
Sent: 23 September 2015 11:08
To: ORACLE-L
Subject: query performance following 12c upgrade

Hi,

Looking for ideas as to why a query has started taking a lot longer to execute
since upgrading to 12.1.0.2 from 11.2.0.3.

Its a simple 1 table query, that is performing an index skip scan. Under
12c, the query is taking 12-13 seconds to return a row, whereas previously it
was a fraction of a second.

There is a difference in the plans between the 2 versions. Under 12c, the
table access is 'TABLE ACCESS BY INDEX ROWID BATCHED'.

From the 12c database:

------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes |
Cost (%CPU)| Time |
------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 2 | 76 |
573 (80)| 00:00:01 |
|* 1 | TABLE ACCESS BY INDEX ROWID BATCHED| TABLE1 | 2 | 76 |
573 (80)| 00:00:01 |
|* 2 | INDEX SKIP SCAN | TABLE1_IDX_7 | 7 | |
572 (80)| 00:00:01 |
------------------------------------------------------------------------------------------------------

From the 12c database (having set optimizer_features_enabled to 11.2.0.3 for
the session):

----------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost
(%CPU)| Time |
----------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 38 | 573
(80)| 00:00:01 |
|* 1 | TABLE ACCESS BY INDEX ROWID| TABLE1 | 1 | 38 | 573
(80)| 00:00:01 |
|* 2 | INDEX SKIP SCAN | TABLE1_IDX_7 | 7 | | 572
(80)| 00:00:01 |
----------------------------------------------------------------------------------------------

Any ideas how I can fix this without changing the parameter at the database
level?

Thanks in advance,

Steve


Other related posts: