Mohamed Houri’s Oracle Notes

August 4, 2015

Degree of Parallelism is 16 because of table property

Filed under: Oracle — hourim @ 10:11 am

I have been pleasantly surprised by the following Note at the bottom of an execution plan coming from a 12.1.0.2.0 Oracle instance


SQL> select * from v$version;

BANNER                                                                               CON_ID
-------------------------------------------------------------------------------- ----------
Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production              0
PL/SQL Release 12.1.0.2.0 - Production                                                    0
CORE    12.1.0.2.0      Production                                                        0
TNS for Linux: Version 12.1.0.2.0 - Production                                            0
NLSRTL Version 12.1.0.2.0 - Production                                                    0


SQL> create table t_par as select rownum n1, trunc((rownum -1/3)) n2, mod(rownum, 5) n3
    from dual
    connect by level<=1e6;
  
SQL> create index t_part_idx on t_par(n1);

Index created.
 
SQL> alter table t_par parallel 16;

Table altered.  

SQL> select count(1) from t_par where n1> 1;

  COUNT(1)
----------
    999999

SQL> select * from table(dbms_xplan.display_cursor);
----------------------------------------------------------------------------------------------------------------
| Id  | Operation              | Name     | Rows  | Bytes | Cost (%CPU)| Time     |    TQ  |IN-OUT| PQ Distrib |
----------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |          |       |       |    48 (100)|          |        |      |            |
|   1 |  SORT AGGREGATE        |          |     1 |     5 |            |          |        |      |            |
|   2 |   PX COORDINATOR       |          |       |       |            |          |        |      |            |
|   3 |    PX SEND QC (RANDOM) | :TQ10000 |     1 |     5 |            |          |  Q1,00 | P->S | QC (RAND)  |
|   4 |     SORT AGGREGATE     |          |     1 |     5 |            |          |  Q1,00 | PCWP |            |
|   5 |      PX BLOCK ITERATOR |          |   999K|  4882K|    48   (3)| 00:00:01 |  Q1,00 | PCWC |            |
|*  6 |       TABLE ACCESS FULL| T_PAR    |   999K|  4882K|    48   (3)| 00:00:01 |  Q1,00 | PCWP |            |
----------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   6 - access(:Z>=:Z AND :Z<=:Z)
       filter("N1">1)

Note
-----
   - Degree of Parallelism is 16 because of table property

As you can point it out, thanks to the above Note, we can immediately guess that the Optimizer decided to run the query in parallel because the T_PAR table has been decorated with a DOP of 16

SQL> select table_name,degree
  2  from user_tables
  3  where table_name = 'T_PAR';

TABLE_NAME    DEGREE
------------ -------
T_PAR        16 

A nice 12c add.

A couple of month ago a query running on 11.2.0.3 which used to run very quickly suddenly started deviating dangerously from its habitual execution time. The end user told me that they didn’t changed anything and he asked to investigate the root cause of this performance degradation. The corresponding SQL real time monitoring looks like:

Global Stats
======================================================================================
| Elapsed |   Cpu   |    IO    | Concurrency | Buffer | Read | Read  | Write | Write |
| Time(s) | Time(s) | Waits(s) |  Waits(s)   |  Gets  | Reqs | Bytes | Reqs  | Bytes |
======================================================================================
|     799 |     443 |      356 |        0.01 |     3M | 398K |  11GB |  122K |  24GB |
======================================================================================

Parallel Execution Details (DOP=4 , Servers Allocated=8)
SQL Plan Monitoring Details (Plan Hash Value=637438362)
========================================================================================================================
| Id    |                 Operation                  |       Name        |  Rows   |Execs |   Rows   | Temp | Activity |
|       |                                            |                   | (Estim) |      | (Actual) |      |   (%)    |
========================================================================================================================
|     0 | SELECT STATEMENT                           |                   |         |    9 |        0 |      |     0.13 |
|     1 |   PX COORDINATOR                           |                   |         |    9 |          |      |          |
|     2 |    PX SEND QC (RANDOM)                     | :TQ10003          |     19M |    4 |          |      |          |
|     3 |     HASH JOIN RIGHT SEMI                   |                   |     19M |    4 |        0 |      |          |
|     4 |      PX RECEIVE                            |                   |      3M |    4 |     1853 |      |          |
|     5 |       PX SEND HASH                         | :TQ10002          |      3M |    4 |     1853 |      |          |
|     6 |        VIEW                                | VW_NSO_1          |      3M |    4 |     1853 |      |          |
|     7 |         FILTER                             |                   |         |    4 |     1853 |      |          |
|     8 |          NESTED LOOPS                      |                   |      3M |    4 |     1853 |      |          |
|     9 |           BUFFER SORT                      |                   |         |    4 |       38 |      |          |
|    10 |            PX RECEIVE                      |                   |         |    4 |       38 |      |          |
|    11 |             PX SEND ROUND-ROBIN            | :TQ10000          |         |    1 |       38 |      |          |
|    12 |              HASH JOIN                     |                   |   69556 |    1 |       38 |      |          |
|    13 |               INLIST ITERATOR              |                   |         |    1 |     6258 |      |          |
|    14 |                TABLE ACCESS BY INDEX ROWID | TAB_001X          |   69556 |  840 |     6258 |      |          |
|    15 |                 INDEX RANGE SCAN           | IDX_TAB_001X25    |   69556 |  840 |     6258 |      |          |
|    16 |               INDEX FAST FULL SCAN         | PK_TAB_00X13      |     18M |    1 |      19M |      |     0.27 |
|    17 |           INDEX RANGE SCAN                 | PK_IDX_MAIN_TAB   |      36 |   38 |     1853 |      |          |
| -> 18 |      BUFFER SORT                           |                   |         |    4 |        0 |  26G |    34.18 |
| -> 19 |       PX RECEIVE                           |                   |    648M |    4 |     566M |      |     4.14 |
| -> 20 |        PX SEND HASH                        | :TQ10001          |    648M |    1 |     566M |      |    13.89 |
| -> 21 |         TABLE ACCESS FULL                  | MAIN_TABLE_001    |    648M |    1 |     566M |      |    47.40 |
========================================================================================================================

The BUFFER SORT operation at line 18 was killing the performance of this query as far as it was buffering 566M of rows.

Looking back to the previous execution plans shows that they were serial plans!!! What makes this new plan running in parallel? I was practically sure from where this was coming. I know that this application rebuilds indexes from time to time. And I know that very often, they use parallel rebuild to accelerate the operation. But I know also that very often, DBA forget to set back the indexes at their default value at the end of the index rebuild process. Indeed the primary index PK_IDX_MAIN_TAB was at a DOP of 4 while it shouldn’t. Putting back this index to degree 1 sets back the corresponding execution plan to the serial execution plan the underlying query used to follow in the past:

Global Stats
=================================================
| Elapsed |   Cpu   |  Other   | Fetch | Buffer |
| Time(s) | Time(s) | Waits(s) | Calls |  Gets  |
=================================================
|      43 |      43 |     0.02 |    11 |     4M |
=================================================

SQL Plan Monitoring Details (Plan Hash Value=1734192894)
============================================================================================
| Id |              Operation              |       Name        |  Rows   |Execs |   Rows   |
|    |                                     |                   | (Estim) |      | (Actual) |
============================================================================================
|  0 | SELECT STATEMENT                    |                   |         |    1 |      108 |
|  1 |   HASH JOIN RIGHT SEMI              |                   |     19M |    1 |      108 |
|  2 |    VIEW                             | VW_NSO_1          |    701K |    1 |      108 |
|  3 |     FILTER                          |                   |         |    1 |      108 |
|  4 |      NESTED LOOPS                   |                   |    701K |    1 |      108 |
|  5 |       HASH JOIN                     |                   |   19387 |    1 |        3 |
|  6 |        INLIST ITERATOR              |                   |         |    1 |        3 |
|  7 |         TABLE ACCESS BY INDEX ROWID | TAB_001X          |   19387 |  168 |        3 |
|  8 |          INDEX RANGE SCAN           | IDX_TAB_001X25    |   19387 |  168 |        3 |
|  9 |        INDEX FAST FULL SCAN         | PK_TAB_00X13      |     18M |    1 |      19M |
| 10 |       INDEX RANGE SCAN              | PK_IDX_MAIN_TAB   |      36 |    3 |      108 |
| 11 |    TABLE ACCESS FULL                | MAIN_TABLE_001    |    648M |    1 |     677M |
============================================================================================ 

In this context of rebuild indexes left at a DOP > 1 and this nicely 12c added Note about the reason for which Oracle has decided to use parallel run, I was curious to know if the 12c Note will show the same information if the parallel plan was due to an index having a DOP > 1

SQL> alter table t_par noparallel;

SQL> alter index T_PART_IDX parallel 16;

SQL> select count(1) from t_par where n1> 1;

  COUNT(1)
----------
    999999

SQL> select * from table(dbms_xplan.display_cursor);

SQL_ID  4s7n5z52gun33, child number 0
-------------------------------------
---------------------------------------------------------------------------------------------------------------------
| Id  | Operation                 | Name       | Rows  | Bytes | Cost (%CPU)| Time     |    TQ  |IN-OUT| PQ Distrib |
---------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT          |            |       |       |   610 (100)|          |        |      |            |
|   1 |  SORT AGGREGATE           |            |     1 |     5 |            |          |        |      |            |
|   2 |   PX COORDINATOR          |            |       |       |            |          |        |      |            |
|   3 |    PX SEND QC (RANDOM)    | :TQ10000   |     1 |     5 |            |          |  Q1,00 | P->S | QC (RAND)  |
|   4 |     SORT AGGREGATE        |            |     1 |     5 |            |          |  Q1,00 | PCWP |            |
|   5 |      PX BLOCK ITERATOR    |            |   999K|  4882K|   610   (1)| 00:00:01 |  Q1,00 | PCWC |            |
|*  6 |       INDEX FAST FULL SCAN| T_PART_IDX |   999K|  4882K|   610   (1)| 00:00:01 |  Q1,00 | PCWP |            |
---------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   6 - access(:Z>=:Z AND :Z<=:Z)
       filter("N1">1)

Unfortunately there is no Note indicating that the above parallel execution plan is due to the parallel degree of the index T_PART_IDX.

Advertisements

Leave a Comment »

No comments yet.

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

Create a free website or 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: