The next part of the video tutorial explaining the XPLAN_ASH Active Session History functionality has been published. In this part I begin the actual walk-through of the script output.
More parts to follow.
Thursday, January 22, 2015
Video Tutorial: XPLAN_ASH Active Session History - Part 2
Labels:
Video Tutorial,
XPLAN_ASH
New Version Of XPLAN_ASH Utility - In-Memory Support
A new version 4.21 of the XPLAN_ASH utility is available for download. I publish this version because it will be used in the recent video tutorials explaining the Active Session History functionality of the script.
As usual the latest version can be downloaded here.
This is mainly a maintenance release that fixes some incompatibilities of the 4.2 version with less recent versions (10.2 and 11.2.0.1).
As an extra however, this version now differentiates between general CPU usage and in-memory CPU usage (similar to 12.1.0.2 Real-Time SQL Monitoring). This is not done in all possible sections of the output yet, but the most important ones are already covered.
So if you already use the 12.1.0.2 in-memory option this might be helpful to understand how much of your CPU time is spent on in-memory operations vs. non in-memory. Depending on your query profile you might be surprised by the results.
Here are the notes from the change log:
- Forgot to address a minor issue where the SET_COUNT determined per DFO_TREE (either one or two slave sets) is incorrect in the special case of DFO trees having only S->P distributions (pre-12c style). Previous versions used a SET_COUNT of 2 in such a case which is incorrect, since there is only one slave set. 12c changes this behaviour with the new PX SELECTOR operator and requires again two sets.
- For RAC Cross Instance Parallel Execution specific output some formatting and readability was improved (more linebreaks etc.)
- Minor SQL issue fixed in "SQL statement execution ASH Summary" that prevented execution in 10.2 (ORA-32035)
- The NO_STATEMENT_QUEUING hint prevented the "OPTIMIZER_FEATURES_ENABLE" hint from being recognized, therefore some queries failed in 11.2.0.1 again with ORA-03113. Fixed
- "ON CPU" now distinguishes between "ON CPU INMEMORY" and "ON CPU" for in-memory scans
As usual the latest version can be downloaded here.
This is mainly a maintenance release that fixes some incompatibilities of the 4.2 version with less recent versions (10.2 and 11.2.0.1).
As an extra however, this version now differentiates between general CPU usage and in-memory CPU usage (similar to 12.1.0.2 Real-Time SQL Monitoring). This is not done in all possible sections of the output yet, but the most important ones are already covered.
So if you already use the 12.1.0.2 in-memory option this might be helpful to understand how much of your CPU time is spent on in-memory operations vs. non in-memory. Depending on your query profile you might be surprised by the results.
Here are the notes from the change log:
- Forgot to address a minor issue where the SET_COUNT determined per DFO_TREE (either one or two slave sets) is incorrect in the special case of DFO trees having only S->P distributions (pre-12c style). Previous versions used a SET_COUNT of 2 in such a case which is incorrect, since there is only one slave set. 12c changes this behaviour with the new PX SELECTOR operator and requires again two sets.
- For RAC Cross Instance Parallel Execution specific output some formatting and readability was improved (more linebreaks etc.)
- Minor SQL issue fixed in "SQL statement execution ASH Summary" that prevented execution in 10.2 (ORA-32035)
- The NO_STATEMENT_QUEUING hint prevented the "OPTIMIZER_FEATURES_ENABLE" hint from being recognized, therefore some queries failed in 11.2.0.1 again with ORA-03113. Fixed
- "ON CPU" now distinguishes between "ON CPU INMEMORY" and "ON CPU" for in-memory scans
Friday, January 16, 2015
Free Webinar "Oracle Exadata & In-Memory Real-World Performance"
It's webinar time again.
Join me on Wednesday, January 28th at AllThingsOracle.com for a session based on a real world customer experience.
The session starts at 3pm UK (16:00 Central European) time. The webinar is totally free and the recording will made available afterwards.
Here's the link to the official landing page where you can register and below is the official abstract:
Join me on Wednesday, January 28th at AllThingsOracle.com for a session based on a real world customer experience.
The session starts at 3pm UK (16:00 Central European) time. The webinar is totally free and the recording will made available afterwards.
Here's the link to the official landing page where you can register and below is the official abstract:
Abstract
After a short introduction into what the Oracle Exadata Database Machine is, in this one-hour webinar I will look at an analysis of different database query profiles that are based on a real-world customer case, how these different profiles influence the efficiency of Exadata’s “secret sauce” features, as well as the new Oracle In-Memory column store option. Based on the analysis different optimization strategies are presented along with lessons learned.
Labels:
Advert,
AllThingsOracle,
Exadata,
InMemory,
webinar
Sunday, January 11, 2015
Video Tutorial: XPLAN_ASH Active Session History - Introduction
I finally got around preparing another part of the XPLAN_ASH video tutorial.
This part is about the main funcationality of XPLAN_ASH: SQL statement execution analysis using Active Session History and Real-Time SQL Monitoring.
In this video tutorial I'll explain what the output of XPLAN_ASH is supposed to mean when using the Active Session History functionality of the script. Before diving into the details of the script output using sample reports I provide some overview and introduction in this part that hopefully makes it simpler to understand how the output is organized and what it is supposed to mean.
This is the initial, general introduction part. More parts to follow.
This part is about the main funcationality of XPLAN_ASH: SQL statement execution analysis using Active Session History and Real-Time SQL Monitoring.
In this video tutorial I'll explain what the output of XPLAN_ASH is supposed to mean when using the Active Session History functionality of the script. Before diving into the details of the script output using sample reports I provide some overview and introduction in this part that hopefully makes it simpler to understand how the output is organized and what it is supposed to mean.
This is the initial, general introduction part. More parts to follow.
Thursday, January 8, 2015
"SELECT * FROM TABLE" Runs Out Of TEMP Space
Now that I've shown in the previous post in general that sometimes Parallel Execution plans might end up with unnecessary BUFFER SORT operations, let's have a look what particular side effects are possible due to this.
What would you say if someone tells you that (s)he just did a simple, straightforward "SELECT * FROM TABLE" that took several minutes to execute without returning, only to then error out with "ORA-01652 unable to extend temp segment", and the TABLE in question is actually nothing but a simple, partitioned heap table, so no special tricks, no views, synonyms, VPD etc. involved, it's really just a plain simple table?
Some time ago I was confronted with such a case at a client. Of course, the first question is, why would someone run a plain SELECT * FROM TABLE, but nowadays with power users and developers using GUI based tools like TOAD or SQLDeveloper, this is probably the GUI approach of a table describe command. Since these tools by default show the results in a grid that only fetches the first n rows, this typically isn't really a threat even in case of large tables, besides the common problems with allocated PX servers in case the table is queried using Parallel Execution, and the users simply keep the grid/cursor open and hence don't allow re-using the PX servers for different executions.
But have a look at the following output, in this case taken from 12.1.0.2, but assuming the partitioned table T_PART in question is marked parallel, resides on Exadata, has many partitions that are compressed via HCC, that uncompressed represent several TB of data (11.2.0.4 on Exadata produces a similar plan):
Can you spot the problem? It's again the "unnecessary BUFFER SORTS" problem introduced in the previous post. In particular the operation ID = 3 BUFFER SORT is "deadly" if the table T_PART is large, because it needs to buffer the whole table data before any row will be returned to the client. This explains why this simple SELECT * FROM T_PART will potentially run out of TEMP space, assuming the uncompressed table data is larger in size than the available TEMP space. Even if it doesn't run out of TEMP space it will be a totally inefficient operation, copying all table data to PGA (unlikely sufficient) respectively TEMP before returning any rows to the client.
But why does a simple SELECT * FROM TABLE come up with such an execution plan? A hint is the VW_TE_2 alias shown in the NAME column of the plan: It's the result of the "table expansion" transformation that was introduced in 11.2 allowing to set some partition's local indexes to unusable but still make use of the usable index partitions of other partitions. It takes a bit of effort to bring the table into a state where such a plan will be produced for a plain SELECT * FROM TABLE, but as you can see, it is possible. And as you can see from the CONCATENATION operation in the plan, the transformed query produced by the "table expansion" then triggered another transformation, the "concatenation" transformation mentioned in the previous post, that then results in the addition of unnecessary BUFFER SORT operations when combined with Parallel Execution.
Here is a manual rewrite that corresponds to the query that is the result of both, the "table expansion" and the "concatenation" transformation:
But if you run an EXPLAIN PLAN on above manual rewrite, then 12.1.0.2 produces the following simple and elegant plan:
I've disabled the "table expansion" transformation in this case, because it kicks in again when optimizing this query and just adds some harmless (and useless) branches to the plan that confuse the issue. Without those additional, useless branches it is very similar to the above plan, but without any BUFFER SORT operations, hence it doesn't cause any overhead and should return the first rows rather quickly, no matter how large the table is.
The 11.2.0.4 optimizer unfortunately again adds unnecessary BUFFER SORT operations even to the manual rewrite above, so as mentioned in the previous post the problem of those spurious BUFFER SORTs isn't limited to the CONCATENATION transformation.
Of course, since all this is related to Parallel Execution, a simple workaround to the problem is to run the SELECT * FROM TABLE using a NO_PARALLEL hint, and all those strange side effects of BUFFER SORTS will be gone. And not having unusable local indexes will also prevent the problem, because then the "table expansion" transformation won't kick in.
Interestingly, if the optimizer is told about the true intention of initially fetching only the first n rows from the SELECT * FROM TABLE - for example simply by adding a corresponding FIRST_ROWS(n) hint - at least in my tests using 12.1.0.2 all the complex transformations were rejected and a plain (parallel) FULL TABLE SCAN was preferred instead, simply because it is now differently costed, which would allow working around the problem, too.
If you want to reproduce the issue, here's a sample table definition, along with some comments what I had to do to bring it into the state required to reproduce:
What would you say if someone tells you that (s)he just did a simple, straightforward "SELECT * FROM TABLE" that took several minutes to execute without returning, only to then error out with "ORA-01652 unable to extend temp segment", and the TABLE in question is actually nothing but a simple, partitioned heap table, so no special tricks, no views, synonyms, VPD etc. involved, it's really just a plain simple table?
Some time ago I was confronted with such a case at a client. Of course, the first question is, why would someone run a plain SELECT * FROM TABLE, but nowadays with power users and developers using GUI based tools like TOAD or SQLDeveloper, this is probably the GUI approach of a table describe command. Since these tools by default show the results in a grid that only fetches the first n rows, this typically isn't really a threat even in case of large tables, besides the common problems with allocated PX servers in case the table is queried using Parallel Execution, and the users simply keep the grid/cursor open and hence don't allow re-using the PX servers for different executions.
But have a look at the following output, in this case taken from 12.1.0.2, but assuming the partitioned table T_PART in question is marked parallel, resides on Exadata, has many partitions that are compressed via HCC, that uncompressed represent several TB of data (11.2.0.4 on Exadata produces a similar plan):
SQL> explain plan for 2 select * from t_part p; Explained. SQL> SQL> select * from table(dbms_xplan.display(format => 'BASIC PARTITION PARALLEL')); Plan hash value: 2545275170 ------------------------------------------------------------------------------------------------------------------------ | Id | Operation | Name | Pstart| Pstop | TQ |IN-OUT| PQ Distrib | ------------------------------------------------------------------------------------------------------------------------ | 0 | SELECT STATEMENT | | | | | | | | 1 | PX COORDINATOR | | | | | | | | 2 | PX SEND QC (RANDOM) | :TQ10002 | | | Q1,02 | P->S | QC (RAND) | | 3 | BUFFER SORT | | | | Q1,02 | PCWP | | | 4 | VIEW | VW_TE_2 | | | Q1,02 | PCWP | | | 5 | UNION-ALL | | | | Q1,02 | PCWP | | | 6 | CONCATENATION | | | | Q1,02 | PCWP | | | 7 | BUFFER SORT | | | | Q1,02 | PCWC | | | 8 | PX RECEIVE | | | | Q1,02 | PCWP | | | 9 | PX SEND ROUND-ROBIN | :TQ10000 | | | | S->P | RND-ROBIN | | 10 | BUFFER SORT | | | | | | | | 11 | PARTITION RANGE SINGLE | | 2 | 2 | | | | | 12 | TABLE ACCESS BY LOCAL INDEX ROWID BATCHED| T_PART | 2 | 2 | | | | |* 13 | INDEX RANGE SCAN | T_PART_IDX | 2 | 2 | | | | | 14 | BUFFER SORT | | | | Q1,02 | PCWC | | | 15 | PX RECEIVE | | | | Q1,02 | PCWP | | | 16 | PX SEND ROUND-ROBIN | :TQ10001 | | | | S->P | RND-ROBIN | | 17 | BUFFER SORT | | | | | | | | 18 | PARTITION RANGE SINGLE | | 4 | 4 | | | | | 19 | TABLE ACCESS BY LOCAL INDEX ROWID BATCHED| T_PART | 4 | 4 | | | | |* 20 | INDEX RANGE SCAN | T_PART_IDX | 4 | 4 | | | | | 21 | PX BLOCK ITERATOR | | 6 | 20 | Q1,02 | PCWC | | |* 22 | TABLE ACCESS FULL | T_PART | 6 | 20 | Q1,02 | PCWP | | | 23 | PX BLOCK ITERATOR | |KEY(OR)|KEY(OR)| Q1,02 | PCWC | | |* 24 | TABLE ACCESS FULL | T_PART |KEY(OR)|KEY(OR)| Q1,02 | PCWP | | ------------------------------------------------------------------------------------------------------------------------ Predicate Information (identified by operation id): --------------------------------------------------- 13 - access("P"."DT">=TO_DATE(' 2001-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND "P"."DT"<TO_DATE(' 2002-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) 20 - access("P"."DT">=TO_DATE(' 2003-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND "P"."DT"<TO_DATE(' 2004-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) filter(LNNVL("P"."DT"<TO_DATE(' 2002-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) OR LNNVL("P"."DT">=TO_DATE(' 2001-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss'))) 22 - filter("P"."DT">=TO_DATE(' 2005-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND "P"."DT"<TO_DATE(' 2020-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND (LNNVL("P"."DT"<TO_DATE(' 2004-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) OR LNNVL("P"."DT">=TO_DATE(' 2003-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss'))) AND (LNNVL("P"."DT"<TO_DATE(' 2002-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) OR LNNVL("P"."DT">=TO_DATE(' 2001-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')))) 24 - filter("P"."DT"<TO_DATE(' 2005-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND "P"."DT">=TO_DATE(' 2004-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') OR "P"."DT"<TO_DATE(' 2001-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') OR "P"."DT"<TO_DATE(' 2003-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND "P"."DT">=TO_DATE(' 2002-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss'))
Can you spot the problem? It's again the "unnecessary BUFFER SORTS" problem introduced in the previous post. In particular the operation ID = 3 BUFFER SORT is "deadly" if the table T_PART is large, because it needs to buffer the whole table data before any row will be returned to the client. This explains why this simple SELECT * FROM T_PART will potentially run out of TEMP space, assuming the uncompressed table data is larger in size than the available TEMP space. Even if it doesn't run out of TEMP space it will be a totally inefficient operation, copying all table data to PGA (unlikely sufficient) respectively TEMP before returning any rows to the client.
But why does a simple SELECT * FROM TABLE come up with such an execution plan? A hint is the VW_TE_2 alias shown in the NAME column of the plan: It's the result of the "table expansion" transformation that was introduced in 11.2 allowing to set some partition's local indexes to unusable but still make use of the usable index partitions of other partitions. It takes a bit of effort to bring the table into a state where such a plan will be produced for a plain SELECT * FROM TABLE, but as you can see, it is possible. And as you can see from the CONCATENATION operation in the plan, the transformed query produced by the "table expansion" then triggered another transformation, the "concatenation" transformation mentioned in the previous post, that then results in the addition of unnecessary BUFFER SORT operations when combined with Parallel Execution.
Here is a manual rewrite that corresponds to the query that is the result of both, the "table expansion" and the "concatenation" transformation:
select * from ( select /*+ opt_param('_optimizer_table_expansion', 'false') */ * from t_part p where ("P"."DT">=TO_DATE(' 2001-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND "P"."DT"<TO_DATE(' 2002-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) union all select * from t_part p where ("P"."DT">=TO_DATE(' 2003-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND "P"."DT"<TO_DATE(' 2004-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) and (LNNVL("P"."DT"<TO_DATE(' 2002-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) OR LNNVL("P"."DT">=TO_DATE(' 2001-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss'))) union all select * from t_part p where ("P"."DT">=TO_DATE(' 2005-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND "P"."DT"<TO_DATE(' 2020-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND (LNNVL("P"."DT"<TO_DATE(' 2004-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) OR LNNVL("P"."DT">=TO_DATE(' 2003-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss'))) AND (LNNVL("P"."DT"<TO_DATE(' 2002-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) OR LNNVL("P"."DT">=TO_DATE(' 2001-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')))) ) union all select * from t_part p where ("P"."DT"<TO_DATE(' 2005-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND "P"."DT">=TO_DATE(' 2004-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') OR "P"."DT"<TO_DATE(' 2001-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') OR "P"."DT"<TO_DATE(' 2003-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND "P"."DT">=TO_DATE(' 2002-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) ;
But if you run an EXPLAIN PLAN on above manual rewrite, then 12.1.0.2 produces the following simple and elegant plan:
-------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Pstart| Pstop | TQ |IN-OUT| PQ Distrib | -------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | | | | | | | 1 | PX COORDINATOR | | | | | | | | 2 | PX SEND QC (RANDOM) | :TQ10000 | | | Q1,00 | P->S | QC (RAND) | | 3 | UNION-ALL | | | | Q1,00 | PCWP | | | 4 | VIEW | | | | Q1,00 | PCWP | | | 5 | UNION-ALL | | | | Q1,00 | PCWP | | | 6 | PX SELECTOR | | | | Q1,00 | PCWP | | | 7 | PARTITION RANGE SINGLE | | 2 | 2 | Q1,00 | PCWP | | | 8 | TABLE ACCESS BY LOCAL INDEX ROWID BATCHED| T_PART | 2 | 2 | Q1,00 | PCWP | | |* 9 | INDEX RANGE SCAN | T_PART_IDX | 2 | 2 | Q1,00 | PCWP | | | 10 | PX SELECTOR | | | | Q1,00 | PCWP | | | 11 | PARTITION RANGE SINGLE | | 4 | 4 | Q1,00 | PCWP | | | 12 | TABLE ACCESS BY LOCAL INDEX ROWID BATCHED| T_PART | 4 | 4 | Q1,00 | PCWP | | |* 13 | INDEX RANGE SCAN | T_PART_IDX | 4 | 4 | Q1,00 | PCWP | | | 14 | PX BLOCK ITERATOR | | 6 | 20 | Q1,00 | PCWC | | |* 15 | TABLE ACCESS FULL | T_PART | 6 | 20 | Q1,00 | PCWP | | | 16 | PX BLOCK ITERATOR | |KEY(OR)|KEY(OR)| Q1,00 | PCWC | | |* 17 | TABLE ACCESS FULL | T_PART |KEY(OR)|KEY(OR)| Q1,00 | PCWP | | -------------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 9 - access("P"."DT">=TO_DATE(' 2001-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND "P"."DT"<TO_DATE(' 2002-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) 13 - access("P"."DT">=TO_DATE(' 2003-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND "P"."DT"<TO_DATE(' 2004-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) filter(LNNVL("P"."DT"<TO_DATE(' 2002-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) OR LNNVL("P"."DT">=TO_DATE(' 2001-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss'))) 15 - filter((LNNVL("P"."DT"<TO_DATE(' 2004-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) OR LNNVL("P"."DT">=TO_DATE(' 2003-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss'))) AND (LNNVL("P"."DT"<TO_DATE(' 2002-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')) OR LNNVL("P"."DT">=TO_DATE(' 2001-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss')))) 17 - filter("P"."DT"<TO_DATE(' 2005-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND "P"."DT">=TO_DATE(' 2004-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') OR "P"."DT"<TO_DATE(' 2001-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') OR "P"."DT"<TO_DATE(' 2003-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND "P"."DT">=TO_DATE(' 2002-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss'))
I've disabled the "table expansion" transformation in this case, because it kicks in again when optimizing this query and just adds some harmless (and useless) branches to the plan that confuse the issue. Without those additional, useless branches it is very similar to the above plan, but without any BUFFER SORT operations, hence it doesn't cause any overhead and should return the first rows rather quickly, no matter how large the table is.
The 11.2.0.4 optimizer unfortunately again adds unnecessary BUFFER SORT operations even to the manual rewrite above, so as mentioned in the previous post the problem of those spurious BUFFER SORTs isn't limited to the CONCATENATION transformation.
Of course, since all this is related to Parallel Execution, a simple workaround to the problem is to run the SELECT * FROM TABLE using a NO_PARALLEL hint, and all those strange side effects of BUFFER SORTS will be gone. And not having unusable local indexes will also prevent the problem, because then the "table expansion" transformation won't kick in.
Interestingly, if the optimizer is told about the true intention of initially fetching only the first n rows from the SELECT * FROM TABLE - for example simply by adding a corresponding FIRST_ROWS(n) hint - at least in my tests using 12.1.0.2 all the complex transformations were rejected and a plain (parallel) FULL TABLE SCAN was preferred instead, simply because it is now differently costed, which would allow working around the problem, too.
If you want to reproduce the issue, here's a sample table definition, along with some comments what I had to do to bring it into the state required to reproduce:
-- The following things have to come together to turn a simple SELECT * from partitioned table into a complex execution plan -- including Table Expansion and Concatenation: -- -- - Unusable index partitions to trigger Table Expansion -- - Partitions with usable indexes that are surrounded by partitions with unusable indexes -- - And such a partition needs to have an index access path that is cheaper than a corresponding FTS, typically by deleting the vast majority of rows without resetting the HWM -- - All this also needs to be reflected properly in the statistics -- -- If this scenario is combined with Parallel Execution the "Parallel Concatenation" bug that plasters the plan with superfluous BUFFER SORT will lead to the fact -- that the whole table will have to be kept in memory / TEMP space when running SELECT * from the table, because the bug adds, among many other BUFFER SORTs, one deadly BUFFER SORT -- on top level before returning data to the coordinator, typically operation ID = 3 -- create table t_part (dt not null, id not null, filler) partition by range (dt) ( partition p_1 values less than (date '2001-01-01'), partition p_2 values less than (date '2002-01-01'), partition p_3 values less than (date '2003-01-01'), partition p_4 values less than (date '2004-01-01'), partition p_5 values less than (date '2005-01-01'), partition p_6 values less than (date '2006-01-01'), partition p_7 values less than (date '2007-01-01'), partition p_8 values less than (date '2008-01-01'), partition p_9 values less than (date '2009-01-01'), partition p_10 values less than (date '2010-01-01'), partition p_11 values less than (date '2011-01-01'), partition p_12 values less than (date '2012-01-01'), partition p_13 values less than (date '2013-01-01'), partition p_14 values less than (date '2014-01-01'), partition p_15 values less than (date '2015-01-01'), partition p_16 values less than (date '2016-01-01'), partition p_17 values less than (date '2017-01-01'), partition p_18 values less than (date '2018-01-01'), partition p_19 values less than (date '2019-01-01'), partition p_20 values less than (date '2020-01-01') ) as with generator as ( select /*+ cardinality(1000) */ rownum as id, rpad('x', 100) as filler from dual connect by level <= 1e3 ) select add_months(date '2000-01-01', trunc( case when id >= 300000 and id < 700000 then id + 100000 when id >= 700000 then id + 200000 else id end / 100000) * 12) as dt , id , filler from ( select (a.id + (b.id - 1) * 1e3) - 1 + 100000 as id , rpad('x', 100) as filler from generator a, generator b ) ; delete from t_part partition (p_2); commit; exec dbms_stats.gather_table_stats(null, 't_part') create unique index t_part_idx on t_part (dt, id) local; alter index t_part_idx modify partition p_1 unusable; alter index t_part_idx modify partition p_3 unusable; alter index t_part_idx modify partition p_5 unusable; alter table t_part parallel; alter index t_part_idx parallel; set echo on pagesize 0 linesize 200 explain plan for select * from t_part p; select * from table(dbms_xplan.display(format => 'BASIC PARTITION PARALLEL'));
Labels:
11.2.0.4,
11gR2,
12.1.0.1,
12.1.0.2,
12cR1,
Freaky stuff,
Parallel Execution,
Query Transformation
Monday, January 5, 2015
Unnecessary BUFFER SORT Operations - Parallel Concatenation Transformation
When using Parallel Execution, depending on the plan shape and the operations used, Oracle sometimes needs to turn non-blocking operations into blocking operations, which means in this case that the row source no longer passes its output data directly to the parent operation but buffers some data temporarily in PGA memory / TEMP. This is either accomplished via the special HASH JOIN BUFFERED operation, or simply by adding BUFFER SORT operations to the plan.
The reason for such a behaviour in parallel plans is the limitation of Oracle Parallel Execution that allows only a single data redistribution to be active concurrently. You can read more about that here.
However, sometimes the optimizer adds unnecessary BUFFER SORT operations to parallel execution plans, and one of the most obvious examples is when the so called "concatenation" query transformation is applied by the optimizer and Parallel Execution is involved.
UPDATE Please note: As mentioned below by Martin (thanks) what I call here "concatenation transformation" typically is called "OR expansion transformation" in CBO speak, and this term probably much better describes what the transformation is about. So whenever I wrote here "concatenation transformation" this can be substituted with "OR expansion transformation".
To understand the issue, first of all, what is the concatenation transformation about?
Whenever there are predicates combined with OR there is the possibility to rewrite the different conditions as separate queries unioned together.
In order to ensure that the result of the rewritten query doesn't contain any unwanted duplicates, the different branches of the UNIONed statement need to filter out any data fulfillinh conditions of previous branches - this is probably where originally the (at first sight) odd (and in the meanwhile documented) LNNVL function came into existence.
The predicates can be either single-table filters, where the concatenation might open up different access paths to the same table (like different indexes), or it might be predicates combining multiple tables, like joins or subqueries.
Here is a short example of the latter (the parallel hints are commented out but are used in the further examples to demonstrate the issue with Parallel Execution) - using version 12.1.0.2:
select max(id) from ( select /* parallel(t1 8) parallel(t2 8) */ t2.* from t1 , t2 where (t1.id = t2.id or t1.id = t2.id2) );In this example the join condition using an OR prevents any efficient join method between T1 and T2 when not re-writing the statement - Oracle can only resort to a NESTED LOOP join with a repeated full table scan of one of the tables, which is reflected in a rather high estimated cost:
----------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
----------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 16 | 2177M (2)| 23:37:34 |
| 1 | SORT AGGREGATE | | 1 | 16 | | |
| 2 | NESTED LOOPS | | 3999K| 61M| 2177M (2)| 23:37:34 |
| 3 | TABLE ACCESS FULL| T2 | 2000K| 19M| 1087 (1)| 00:00:01 |
|* 4 | TABLE ACCESS FULL| T1 | 2 | 12 | 1089 (2)| 00:00:01 |
----------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
4 - filter("T1"."ID"="T2"."ID" OR "T1"."ID"="T2"."ID2")
The same statement could be expressed by the following manual rewrite:
select max(id) from ( select /* parallel(t1 8) parallel(t2 8) */ t2.* from t1 , t2 where t1.id = t2.id2 --------- union all --------- select /* parallel(t1 8) parallel(t2 8) */ t2.* from t1 , t2 where t1.id = t2.id and lnnvl(t1.id = t2.id2) );Notice the LNNVL function in the second branch of the UNION ALL that filters out any rows fulfilling the condition used in the first branch. Also note that using UNION instead of UNION ALL plus LNNVL(s) to filter out any duplicate rows is also potentially incorrect as each query branch might produce duplicate rows that need to be retained as they are also part of the original query result. At the expense of visiting the tables multiple times we now get at least efficient join methods in each branch (and hence a significantly lower cost estimate):
-------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes |TempSpc| Cost (%CPU)| Time | -------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 13 | | 11945 (1)| 00:00:01 | | 1 | SORT AGGREGATE | | 1 | 13 | | | | | 2 | VIEW | | 2100K| 26M| | 11945 (1)| 00:00:01 | | 3 | UNION-ALL | | | | | | | |* 4 | HASH JOIN | | 2000K| 30M| 34M| 5972 (1)| 00:00:01 | | 5 | TABLE ACCESS FULL| T1 | 2000K| 11M| | 1086 (1)| 00:00:01 | | 6 | TABLE ACCESS FULL| T2 | 2000K| 19M| | 1087 (1)| 00:00:01 | |* 7 | HASH JOIN | | 100K| 1562K| 34M| 5972 (1)| 00:00:01 | | 8 | TABLE ACCESS FULL| T1 | 2000K| 11M| | 1086 (1)| 00:00:01 | | 9 | TABLE ACCESS FULL| T2 | 2000K| 19M| | 1087 (1)| 00:00:01 | -------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 4 - access("T1"."ID"="T2"."ID2") 7 - access("T1"."ID"="T2"."ID") filter(LNNVL("T1"."ID"="T2"."ID2"))And in fact, when not preventing the concatenation transformation (NO_EXPAND hint), the optimizer comes up with the following execution plan for the original statement:
------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes |TempSpc| Cost (%CPU)| Time | ------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1 | 16 | | 11945 (1)| 00:00:01 | | 1 | SORT AGGREGATE | | 1 | 16 | | | | | 2 | CONCATENATION | | | | | | | |* 3 | HASH JOIN | | 2000K| 30M| 34M| 5972 (1)| 00:00:01 | | 4 | TABLE ACCESS FULL| T1 | 2000K| 11M| | 1086 (1)| 00:00:01 | | 5 | TABLE ACCESS FULL| T2 | 2000K| 19M| | 1087 (1)| 00:00:01 | |* 6 | HASH JOIN | | 100K| 1562K| 34M| 5972 (1)| 00:00:01 | | 7 | TABLE ACCESS FULL| T1 | 2000K| 11M| | 1086 (1)| 00:00:01 | | 8 | TABLE ACCESS FULL| T2 | 2000K| 19M| | 1087 (1)| 00:00:01 | ------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 3 - access("T1"."ID"="T2"."ID2") 6 - access("T1"."ID"="T2"."ID") filter(LNNVL("T1"."ID"="T2"."ID2"))The only difference between those two plans for the manual and automatic rewrite is the CONCATENATION operator instead of UNION ALL, and that the subquery isn't merged in case of the UNION ALL (additional VIEW operator). So far everything works as expected and you have seen the effect and rationale of the concatenation transformation. If we run now the original statement using Parallel Execution (turn comments into hints), depending on the exact version used the resulting execution plans show various inefficiencies. For reference, this is the parallel execution plan I get from 12.1.0.2 when using above manual rewrite:
------------------------------------------------------------------------------------------------------------------------ | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib | ------------------------------------------------------------------------------------------------------------------------ | 0 | SELECT STATEMENT | | 1 | 13 | 606 (2)| 00:00:01 | | | | | 1 | SORT AGGREGATE | | 1 | 13 | | | | | | | 2 | PX COORDINATOR | | | | | | | | | | 3 | PX SEND QC (RANDOM) | :TQ10004 | 1 | 13 | | | Q1,04 | P->S | QC (RAND) | | 4 | SORT AGGREGATE | | 1 | 13 | | | Q1,04 | PCWP | | | 5 | VIEW | | 2100K| 26M| 606 (2)| 00:00:01 | Q1,04 | PCWP | | | 6 | UNION-ALL | | | | | | Q1,04 | PCWP | | |* 7 | HASH JOIN | | 2000K| 30M| 303 (2)| 00:00:01 | Q1,04 | PCWP | | | 8 | PX RECEIVE | | 2000K| 11M| 151 (1)| 00:00:01 | Q1,04 | PCWP | | | 9 | PX SEND HYBRID HASH | :TQ10000 | 2000K| 11M| 151 (1)| 00:00:01 | Q1,00 | P->P | HYBRID HASH| | 10 | STATISTICS COLLECTOR | | | | | | Q1,00 | PCWC | | | 11 | PX BLOCK ITERATOR | | 2000K| 11M| 151 (1)| 00:00:01 | Q1,00 | PCWC | | | 12 | TABLE ACCESS FULL | T1 | 2000K| 11M| 151 (1)| 00:00:01 | Q1,00 | PCWP | | | 13 | PX RECEIVE | | 2000K| 19M| 151 (1)| 00:00:01 | Q1,04 | PCWP | | | 14 | PX SEND HYBRID HASH | :TQ10001 | 2000K| 19M| 151 (1)| 00:00:01 | Q1,01 | P->P | HYBRID HASH| | 15 | PX BLOCK ITERATOR | | 2000K| 19M| 151 (1)| 00:00:01 | Q1,01 | PCWC | | | 16 | TABLE ACCESS FULL | T2 | 2000K| 19M| 151 (1)| 00:00:01 | Q1,01 | PCWP | | |* 17 | HASH JOIN | | 100K| 1562K| 303 (2)| 00:00:01 | Q1,04 | PCWP | | | 18 | PX RECEIVE | | 2000K| 11M| 151 (1)| 00:00:01 | Q1,04 | PCWP | | | 19 | PX SEND HYBRID HASH | :TQ10002 | 2000K| 11M| 151 (1)| 00:00:01 | Q1,02 | P->P | HYBRID HASH| | 20 | STATISTICS COLLECTOR | | | | | | Q1,02 | PCWC | | | 21 | PX BLOCK ITERATOR | | 2000K| 11M| 151 (1)| 00:00:01 | Q1,02 | PCWC | | | 22 | TABLE ACCESS FULL | T1 | 2000K| 11M| 151 (1)| 00:00:01 | Q1,02 | PCWP | | | 23 | PX RECEIVE | | 2000K| 19M| 151 (1)| 00:00:01 | Q1,04 | PCWP | | | 24 | PX SEND HYBRID HASH | :TQ10003 | 2000K| 19M| 151 (1)| 00:00:01 | Q1,03 | P->P | HYBRID HASH| | 25 | PX BLOCK ITERATOR | | 2000K| 19M| 151 (1)| 00:00:01 | Q1,03 | PCWC | | | 26 | TABLE ACCESS FULL | T2 | 2000K| 19M| 151 (1)| 00:00:01 | Q1,03 | PCWP | | ------------------------------------------------------------------------------------------------------------------------ Predicate Information (identified by operation id): --------------------------------------------------- 7 - access("T1"."ID"="T2"."ID2") 17 - access("T1"."ID"="T2"."ID") filter(LNNVL("T1"."ID"="T2"."ID2"))This is a pretty straightforward parallel plan, with the only possibly noteable exception of the new 12c "HYBRID HASH" distribution feature being used. Now let's have a look at the resulting execution plan when the concatenation transformation gets used:
------------------------------------------------------------------------------------------------------------------------------ | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib | ------------------------------------------------------------------------------------------------------------------------------ | 0 | SELECT STATEMENT | | 1 | 16 | 606 (2)| 00:00:01 | | | | | 1 | SORT AGGREGATE | | 1 | 16 | | | | | | | 2 | PX COORDINATOR | | | | | | | | | | 3 | PX SEND QC (RANDOM) | :TQ20003 | 1 | 16 | | | Q2,03 | P->S | QC (RAND) | | 4 | SORT AGGREGATE | | 1 | 16 | | | Q2,03 | PCWP | | | 5 | CONCATENATION | | | | | | Q2,03 | PCWP | | |* 6 | HASH JOIN | | 2000K| 30M| 303 (2)| 00:00:01 | Q2,03 | PCWP | | | 7 | PX RECEIVE | | 2000K| 11M| 151 (1)| 00:00:01 | Q2,03 | PCWP | | | 8 | PX SEND HYBRID HASH | :TQ20001 | 2000K| 11M| 151 (1)| 00:00:01 | Q2,01 | P->P | HYBRID HASH| | 9 | STATISTICS COLLECTOR | | | | | | Q2,01 | PCWC | | | 10 | BUFFER SORT | | 1 | 16 | | | Q2,01 | PCWP | | | 11 | PX BLOCK ITERATOR | | 2000K| 11M| 151 (1)| 00:00:01 | Q2,01 | PCWC | | | 12 | TABLE ACCESS FULL | T1 | 2000K| 11M| 151 (1)| 00:00:01 | Q2,01 | PCWP | | | 13 | PX RECEIVE | | 2000K| 19M| 151 (1)| 00:00:01 | Q2,03 | PCWP | | | 14 | PX SEND HYBRID HASH | :TQ20002 | 2000K| 19M| 151 (1)| 00:00:01 | Q2,02 | P->P | HYBRID HASH| | 15 | BUFFER SORT | | 1 | 16 | | | Q2,02 | PCWP | | | 16 | PX BLOCK ITERATOR | | 2000K| 19M| 151 (1)| 00:00:01 | Q2,02 | PCWC | | | 17 | TABLE ACCESS FULL | T2 | 2000K| 19M| 151 (1)| 00:00:01 | Q2,02 | PCWP | | | 18 | BUFFER SORT | | | | | | Q2,03 | PCWC | | | 19 | PX RECEIVE | | 100K| 1562K| 303 (2)| 00:00:01 | Q2,03 | PCWP | | | 20 | PX SEND ROUND-ROBIN | :TQ20000 | 100K| 1562K| 303 (2)| 00:00:01 | | S->P | RND-ROBIN | | 21 | BUFFER SORT | | 1 | 16 | | | | | | | 22 | PX COORDINATOR | | | | | | | | | | 23 | PX SEND QC (RANDOM) | :TQ10002 | 100K| 1562K| 303 (2)| 00:00:01 | Q1,02 | P->S | QC (RAND) | | 24 | BUFFER SORT | | 1 | 16 | | | Q1,02 | PCWP | | |* 25 | HASH JOIN BUFFERED | | 100K| 1562K| 303 (2)| 00:00:01 | Q1,02 | PCWP | | | 26 | PX RECEIVE | | 2000K| 11M| 151 (1)| 00:00:01 | Q1,02 | PCWP | | | 27 | PX SEND HYBRID HASH | :TQ10000 | 2000K| 11M| 151 (1)| 00:00:01 | Q1,00 | P->P | HYBRID HASH| | 28 | STATISTICS COLLECTOR | | | | | | Q1,00 | PCWC | | | 29 | BUFFER SORT | | 1 | 16 | | | Q1,00 | PCWP | | | 30 | PX BLOCK ITERATOR | | 2000K| 11M| 151 (1)| 00:00:01 | Q1,00 | PCWC | | | 31 | TABLE ACCESS FULL | T1 | 2000K| 11M| 151 (1)| 00:00:01 | Q1,00 | PCWP | | | 32 | PX RECEIVE | | 2000K| 19M| 151 (1)| 00:00:01 | Q1,02 | PCWP | | | 33 | PX SEND HYBRID HASH | :TQ10001 | 2000K| 19M| 151 (1)| 00:00:01 | Q1,01 | P->P | HYBRID HASH| | 34 | BUFFER SORT | | 1 | 16 | | | Q1,01 | PCWP | | | 35 | PX BLOCK ITERATOR | | 2000K| 19M| 151 (1)| 00:00:01 | Q1,01 | PCWC | | | 36 | TABLE ACCESS FULL | T2 | 2000K| 19M| 151 (1)| 00:00:01 | Q1,01 | PCWP | | ------------------------------------------------------------------------------------------------------------------------------ Predicate Information (identified by operation id): --------------------------------------------------- 6 - access("T1"."ID"="T2"."ID2") 25 - access("T1"."ID"="T2"."ID") filter(LNNVL("T1"."ID"="T2"."ID2"))This looks a bit weird, and when comparing it to the plan gotten from the manual rewrite, it shows the following unnecessary differences: - There are various BUFFER SORT operations that don't make a lot of sense, for example each parallel table scan is followed by a BUFFER SORT operation, and even the HASH JOIN BUFFERED in the lower part of the plan is followed by a BUFFER SORT (double buffering?) - The plan is decomposed into two so called DFO trees, which you can see for example from the two PX COORDINATOR operators (operation id 2 and 22), which adds another unnecessary serial execution part to the plan and can have additional side effects I explain in one of my video tutorials. This means that such execution plan shapes possibly will have a much higher demand for PGA memory than necessary (the BUFFER SORT operation will attempt to keep the data produced by the child row source in PGA), and also might cause additional I/O to and from TEMP. Since PGA memory consumed by one session influences also the Auto PGA allocation of other sessions this means that such executions not only affect the particular SQL execution in question but also any other concurrent executions allocating PGA memory. Depending on the amount of data to be buffered BUFFER SORT operations closer to the root of the execution plan are more likely to have significant impact performance-wise, as they might have to buffer large amounts of data. One very obvious sign of inefficiency are double BUFFERing operations, like a HASH JOIN BUFFERED followed by a BUFFER SORT as parent operation, which you can spot in the sample plan shown above. Another interesting point is that the parallel plans differ from point release to point release and show different levels of inefficiencies, for example, 10.2.0.5, 11.1.0.7 and 11.2.0.1 produce different plans than 11.2.0.2, which is again different from what 11.2.0.3 & 11.2.0.4 produce - and using OPTIMIZER_FEATURES_ENABLE in newer versions to emulate older versions doesn't always reproduce the exact plans produced by the actual, older versions. So all in all this looks like a pretty messy part of the optimizer. Furthermore the problem doesn't always show up - it seems to depend largely on the exact version and the plan shape used. For example, replacing the SELECT MAX(ID) FROM () outermost query in above example with a simple SELECT ID FROM () results in a plan where the concatenation transformation doesn't produce all those strange BUFFER SORTS - although it still produces a plan decomposed into two DFO trees in some versions. It also interesting to note that depending on version and plan shape sometimes the manual rewrite using UNION ALL is also affected by either unluckily placed or unnecessary BUFFER SORT operations, but not to the same extent as the plans resulting from the CONCATENATION transformation. In the next post I'll show how this inefficiency can have some interesting side effects when being triggered by / combined with other transformations.
Footnote
Table structures used in the test cases:create table t1 compress as select (rownum * 2) + 1 as id , mod(rownum, 2000) + 1 as id2 , rpad('x', 100) as filler from (select /*+ cardinality(100000) */ * from dual connect by level <= 100000) a, (select /*+ cardinality(20) */ * from dual connect by level <= 20) b ; exec dbms_stats.gather_table_stats(null, 't1') create table t2 compress as select * from t1; exec dbms_stats.gather_table_stats(null, 't2')
Subscribe to:
Posts (Atom)