The Cost of Adaptive Execution Plans in Oracle (a Small Study) Part 3

November 26, 2013

My previous two posts, The Cost of Adaptive Execution Plans in Oracle (a Small Study) Part 1 and The Cost of Adaptive Execution Plans in Oracle (a Small Study) Part 2,  focused on estimating the impact of OPTIMIZER_ADAPTIVE_REPORTING_ONLY parameter in Oracle 12c. The parameter controls if the adaptive plan would be acted upon. The adaptive plan, however, is always generated.

The post will try to estimate the impact of adaptive execution plans, while taking into account the resources needed for generating the adaptive execution plans. Since I was not able to find a way to suppress the generation of adaptive plans in Oracle 12c, I decided to just use an older version of the optimizer. I did that by utilizing “optimizer_features_enable” parameter.

Here is the table/view setup script, and here is the test script.

We can see the difference in elapsed time using this query:

select avg(r), avg(a) , STATS_T_TEST_PAIRED (R,A) FROM track_v

avg(r) = 1.5880118 avg(a) = 2.5002121 STATS_T_TEST_PAIRED (R,A) /p/ = 0

The adaptive (12c)  plan takes almost 1 millisecond more than the non-adaptive, “old-style” 11gR2 plan.

This query can show where the difference comes from:

select c.name , avg (a.val) a , avg (r.val) r , STATS_T_TEST_PAIRED (r.val,A.val)
from stats_a a , stats_r r , v$statname c
where a.id = r.id
and a.stat = r.stat
and a.stat = c.statistic#
group by c.name

The only statistics that are difference are:
CCursor + sql area evicted – the SQL with AEP(12c) on consumed more that the SQL run with 11gR2
CPU used by this session – the SQL with AEP(12c) on consumed more that the SQL run with 11gR2
parse time cpu – the SQL with AEP(12c) on consumed more that the SQL run with 11gR2
parse time elapsed – the SQL with AEP(12c) on consumed more that the SQL run with 11gR2
recursive cpu usage – the SQL with AEP(12c) on consumed more that the SQL run with 11gR2
sql area evicted – the SQL with AEP(12c) on consumed more that the SQL run with 11gR2

In conclusion, “adaptive execution plans” is a wonderful feature. The resource it needs are typically negligible, except for very light (fast) OLTP type queries.


The Cost of Adaptive Execution Plans in Oracle (a Small Study) Part 2

November 21, 2013

In my previous post, I tried to find out the performance impact of adaptive execution plans (AEP). During the test, I used OPTIMIZER_ADAPTIVE_REPORTING_ONLY parameter to switch on and off adaptive execution plans(AEP). It should be noted that the parameter does not control the generation of AEP, but rather the executtion of the “adaptive” part. I came to a rather surprising result that turning off adaptive execution plans actually made the query run slower. This behavior seems to be a side -effect of frequent shared pool flushing. The original test, i.e. the one that showed tuning on adaptive execution plans speeds up a query, is reproducible, however! I ran it at least three times and I got similar results.

To confirm the peculiar results, I ran a new test that avoids SQL reuse by generating unique SQL statements. Here is the new table/view setup script. Here is the new test procedure. After running it, we can see the expected outcome – adaptive execution plans do cost something.

select avg(r), avg(a) , STATS_T_TEST_PAIRED (R,A) FROM track_v

avg(r) = 2.05312594     avg(a) = 2.07863544     STATS_T_TEST_PAIRED (R,A) /p/ = 0

The difference is quite small – approximately 2% of the overall time or a fraction of a millisecond.
The following query allows us drill down and see where the difference comes from :
select c.name , avg (a.val) a , avg (r.val) r , STATS_T_TEST_PAIRED (r.val,A.val)
from stats_a a , stats_r r , v$statname c
where a.id = r.id
and a.stat = r.stat
and a.stat = c.statistic#
group by c.name

The only statistics that are statistically different are:
CCursor + sql area evicted            – the SQL with AEP on consumed less that the SQL with AEP off
CPU used by this session               – the SQL with AEP on consumed more (marginally) that the SQL with AEP off
parse time elapsed                          – the SQL with AEP on consumed more that the SQL with AEP off
sql area evicted                                – the SQL with AEP on consumed less that the SQL with AEP off


The Cost of Adaptive Execution Plans in Oracle (a Small Study) Part 1

September 26, 2013

Adaptive execution plans is a new Oracle 12c feature. I consider it one of the most important ones.

Oracle 12c would pick the join method based on the actual number of rows retrieved during the first execution of the query.

There are a few great papers about this topic:
Here is the Oracle’s white paper and here is Kerry Osborbe’s Hostsos 2013 presentation. There is even a video.

Every time a new feature that fundamentally changes the way Oracle works is introduced, we should ask ourselves what is the cost, in terms of CPU or other resources, used by that feature.
For me, the cost is an issue only when the feature does not change the join type that was initially chosen.
If the feature causes a change of join type, then the benefits of it would be huge, so it is not worth worrying about the cost.

I’ll measure the elapsed times  / looking at internals is hard… :) / of a query with and without adaptive execution plans and then run a paired t-test to see if there is a statistically significant difference. I’ll use OPTIMIZER_ADAPTIVE_REPORTING_ONLY to turn on and off the feature and I’ll do my best to get rid of any bias in this test.

First, let’s see what happened when we have a query that uses Hash Join. The table/view set up scripts is here. The test procedure is here. I get the end-result using this simple query:
select avg(r),             avg(a) ,              STATS_T_TEST_PAIRED (R,A)   FROM track_v

For this case, we get avg(r) = 450.6991608  ,   avg(a) =      451.5071414  ,   STATS_T_TEST_PAIRED (R,A) /p/ =   0.48716074654373898

This means that for 10K runs, we are nowhere near statistical significance (p< 0.05). Things were not different for 100K runs:

avg(r) = 336.78178535 , avg(a) = 336.67725615 , STATS_T_TEST_PAIRED (R,A) /p/ = 0.82934281196842896

Therefore, the adaptive execution plan feature does not add any meaningful cost when Hash Joins are used.

Let’s see the behavior for a query the uses nested loops. The table/view set up scripts are here. The test procedure is here. I ran 100K iterations, and this is what I got:
select avg(r), avg(a) , STATS_T_TEST_PAIRED (R,A) FROM track_v

For this case, we get avg(r) = 15.31589686 ,   avg(a) =      15.11440871 ,   STATS_T_TEST_PAIRED (R,A) /p/ =   0.015795071536522352

Very interesting result – using adaptive execution plans is slightly faster even when no runtime change of join type is happening. The result seems to have statistical significance…

I then run 500K iterations and I got the even stronger result:
avg(r) = 20.4530 , avg(a) = 19.982423, STATS_T_TEST_PAIRED (R,A) /p/ = 0.00000320884674226468

The averages went up probably because there was some load on the box, but the statistical significance of the difference is out of the question.

So, it appears that the cost of adaptive execution plans is actually negative when it comes to nested loops (NL).

Updated 11/21/2013:
This result seems to be a side-effect of frequent shared pool flushing. It is still a reproducible result though. Check my new post that uses unique SQLs rather than flushing the shared pool to guarantee that no SQL plans are reused.

Overall, adaptive execution plans could bring huge benefits without any cost. I cannot think of a scenario where we should turn them off…