Saturday, April 5, 2014

Analysing Parallel Execution Skew - Data Flow Operations (DFOs) And DFO Trees

This is the second part of the video tutorial "Analysing Parallel Execution Skew". In this part I introduce the concept of "Data Flow Operations (DFOs)" and "DFO Trees", which is what a Parallel Execution plan is made of. DFOs / DFO Trees are specific to Parallel Execution and don't have any counterpart in a serial execution plan.

Understanding the implications of DFOs / DFO Trees is important as prerequisite for understanding some of the effects shown in the later parts of the video tutorial, hence I covered this as a separate topic.

Note that this tutorial also demonstrates some new 12c features regarding Parallel Execution, in particular how Oracle 12c now lifts many of the previous limitations that lead to the generation of multiple DFO Trees.

Here is a link to the video on my Youtube channel.

If you want to reproduce and play around with the DFO Tree variations shown in the tutorial here is the script for creating the tables and running the queries / DML commands used in the tutorial:

-- Table creation
set echo on timing on time on

drop table t1;

purge table t1;

drop table t2;

purge table t2;

drop table t3;

purge table t3;

drop table t4;

purge table t4;

drop table t5;

purge table t5;

drop table x;

purge table x;

create table t1
as
select  /*+ use_nl(a b) */
        (rownum * 2) as id
      , rownum as id2
      , rpad('x', 100) as filler
from
        (select /*+ cardinality(1000) */ * from dual
connect by
        level <= 1000) a, (select /*+ cardinality(2) */ * from dual connect by level <= 2) b
;

exec dbms_stats.gather_table_stats(null, 't1')

alter table t1 cache;

create table t2
compress
as
select
        (rownum * 2) + 1 as id
      , mod(rownum, 2000) + 1 as id2
      , rpad('x', 100) as filler
from
        (select /*+ cardinality(1000000) */ * from dual
connect by
        level <= 1000000) a, (select /*+ cardinality(2) */ * from dual connect by level <= 2) b
;

exec dbms_stats.gather_table_stats(null, 't2')

alter table t2 cache;

create table t3
as
select  /*+ use_nl(a b) */
        (rownum * 2) as id
      , rownum as id2
      , rpad('x', 100) as filler
from
        (select /*+ cardinality(1000) */ * from dual
connect by
        level <= 1000) a, (select /*+ cardinality(2) */ * from dual connect by level <= 2) b
;

exec dbms_stats.gather_table_stats(null, 't3')

alter table t3 cache;

create table t4
compress
as
select
        (rownum * 2) + 1 as id
      , mod(rownum, 2000) + 1 as id2
      , rpad('x', 100) as filler
from
        (select /*+ cardinality(1000000) */ * from dual
connect by
        level <= 1000000) a, (select /*+ cardinality(2) */ * from dual connect by level <= 2) b
;

exec dbms_stats.gather_table_stats(null, 't4')

alter table t4 cache;

create table t5
as
select  /*+ use_nl(a b) */
        (rownum * 2) as id
      , rownum as id2
      , rpad('x', 100) as filler
from
        (select /*+ cardinality(1000) */ * from dual
connect by
        level <= 1000) a, (select /*+ cardinality(2) */ * from dual connect by level <= 2) b
;

exec dbms_stats.gather_table_stats(null, 't5')

alter table t5 cache;

create table x
compress
as
select * from t2
where 1 = 2;

create unique index x_idx1 on x (id);

alter table t1 parallel 2;

alter table t2 parallel 2;

alter table t3 parallel 15;

alter table t4 parallel 15;

alter table t5 parallel 15;

---------------------------------------------------------------
-- Single DFO tree (with Parallel Execution Skew), many DFOs --
---------------------------------------------------------------

set echo on timing on time on verify on

define num_cpu = "15"

select
        max(t1_id)
      , max(t1_filler)
      , max(t2_id)
      , max(t2_filler)
      , max(t3_id)
      , max(t3_filler)
from    (
          select  /*+ monitor
                     no_merge
                     no_merge(v_1)
                     no_merge(v_5)
                     parallel(t1 &num_cpu)
                     PQ_DISTRIBUTE(T1 HASH HASH)
                     PQ_DISTRIBUTE(V_5 HASH HASH)
                     leading (v_1 v_5 t1)
                     use_hash(v_1 v_5 t1)
                     swap_join_inputs(t1)
                  */
                  t1.id     as t1_id
                , regexp_replace(v_5.t3_filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') as t1_filler
                , v_5.*
          from    (
                    select  /*+ parallel(t2 &num_cpu)
                                parallel(t3 &num_cpu)
                                leading(t3 t2)
                                use_hash(t3 t2)
                                swap_join_inputs(t2)
                                PQ_DISTRIBUTE(T2 HASH HASH)
                            */
                            t2.id     as t2_id
                          , t2.filler as t2_filler
                          , t2.id2    as t2_id2
                          , t3.id     as t3_id
                          , t3.filler as t3_filler
                    from
                            t1 t2
                          , t2 t3
                    where
                            t3.id2 = t2.id2 (+)
                    and     regexp_replace(t3.filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') = regexp_replace(t2.filler (+), '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c')
                    and     mod(t3.id2, 3) = 0
                  ) v_1
                , (
                    select  /*+ parallel(t2 &num_cpu)
                                parallel(t3 &num_cpu)
                                leading(t3 t2)
                                use_hash(t3 t2)
                                swap_join_inputs(t2)
                                PQ_DISTRIBUTE(T2 HASH HASH)
                            */
                            t2.id     as t2_id
                          , t2.filler as t2_filler
                          , t2.id2    as t2_id2
                          , t3.id     as t3_id
                          , t3.filler as t3_filler
                    from
                            t1 t2
                          , t2 t3
                    where
                            t3.id = t2.id (+)
                    and     regexp_replace(t3.filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') = regexp_replace(t2.filler (+), '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c')
                    and     mod(t3.id2, 3) = 0
                  ) v_5
                , t1
          where
                  v_1.t3_id = v_5.t3_id
          and     v_5.t2_id2 = t1.id2 (+) + 2001
          and     regexp_replace(v_5.t3_filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') = regexp_replace(t1.filler (+), '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c')
        )
;

---------------------------------------------------------------------------------------------------------------------------------------------------
-- Multiple DFO trees no parent / child (with different DOPs), separate slave sets, one active after the other (12.1: Still multiple DFO trees)  --
---------------------------------------------------------------------------------------------------------------------------------------------------

set echo on timing on time on verify on

with a as (
select /*+ materialize monitor no_merge */
       t1.id     as t1_id
     , regexp_replace(t3_filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') as t1_filler
     , v1.*
from   (
        select /*+ no_merge pq_distribute(t3 hash hash) */
              t2.id     as t2_id
            , t2.filler as t2_filler
            , t2.id2    as t2_id2
            , t3.id     as t3_id
            , t3.filler as t3_filler
        from
              t1 t2
            , t2 t3
        where
              t3.id2 = t2.id
        and   regexp_replace(t3.filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') = regexp_replace(t2.filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c')
        and   mod(t3.id2, 2) = 0
       ) v1
     , t1
where
       v1.t2_id2 = t1.id2
),
b as (
select /*+ materialize monitor no_merge */
       t1.id     as t1_id
     , regexp_replace(t3_filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') as t1_filler
     , v1.*
from   (
        select /*+ no_merge pq_distribute(t3 hash hash) */
              t2.id     as t2_id
            , t2.filler as t2_filler
            , t2.id2    as t2_id2
            , t3.id     as t3_id
            , t3.filler as t3_filler
        from
              t3 t2
            , t4 t3
        where
              t3.id2 = t2.id
        and   regexp_replace(t3.filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') = regexp_replace(t2.filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c')
        and   mod(t3.id2, 2) = 0
       ) v1
     , t5 t1
where
       v1.t2_id2 = t1.id2
)
select max(t1_id), max(t1_filler), max(t2_id), max(t2_filler), max(t3_id), max(t3_filler) from (
select  /*+ no_merge */
        a.t1_id
      , a.t1_filler
      , a.t2_id
      , a.t2_filler
      , a.t3_id
      , regexp_replace(a.t3_filler, '^\s+([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') as t3_filler
from
        a
      , b
where
        a.t3_id = b.t3_id
and     regexp_replace(a.t3_filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') = regexp_replace(b.t3_filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c')
and     mod(a.t1_id, 4) = 0
and     mod(b.t1_id, 4) = 0
)
;

-------------------------------------------------------------------------------------------------------------------------------
-- Multiple DFO trees parent / child (with different DOPs), separate slave sets, concurrently active (12.1: Single DFO tree) --
-------------------------------------------------------------------------------------------------------------------------------

set echo on timing on time on

alter session enable parallel dml;

truncate table x;

insert  /*+ append parallel(x 4) */ into x
select  /*+ leading(v1 v2) */
        v_1.id
      , v_1.id2
      , v_1.filler
from    (
           select
                   id
                 , id2
                 , filler
           from    (
                      select  /*+ parallel(t2 4) no_merge */
                              rownum as id
                            , t2.id2
                            , t2.filler
                      from
                              t2
                      where
                              mod(t2.id2, 3) = 0
                      and     regexp_replace(t2.filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') = regexp_replace(t2.filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'i')
                   ) v1
        ) v_1
      , (
          select
                   id
                 , id2
                 , filler
          from     (
                     select  /*+ parallel(t2 8) no_merge */
                             rownum as id
                           , t2.id2
                           , t2.filler
                     from
                             t2
                     where
                             mod(t2.id2, 3) = 0
                     and     regexp_replace(t2.filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') = regexp_replace(t2.filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'i')
                   ) v2
        ) v_2
where
        v_1.id = v_2.id
and     v_1.filler = v_2.filler
;

commit;

--------------------------------------------------------------------------------------------------------------------------------------
-- Multiple DFO trees parent / child (with different DOPs), separate slave sets, *not* concurrently active  (12.1: Single DFO tree) --
--------------------------------------------------------------------------------------------------------------------------------------

set echo on timing on time on

alter session enable parallel dml;

truncate table x;

insert  /*+ append parallel(x 4) */ into x
select
        v1.*
from    (
          select  /*+ parallel(t2 4) */
                  lag(t2.id) over (order by regexp_replace(t2.filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c')) as id
                , t2.id2
                , regexp_replace(t2.filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') as filler
          from
                  t2
          where
                  mod(t2.id2, 3) = 0
        ) v1
      , (
          select  /*+ parallel(t2 8) */
                  lag(id) over (order by regexp_replace(filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c')) as id
                , id2
                , regexp_replace(t2.filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') as filler
          from
                  t2
          where
                  mod(t2.id2, 3) = 0
        ) v2
where
        v1.id = v2.id
and     v1.filler = v2.filler
;

commit;

----------------------------------------------------------------------------------------------------------------------------------------------------------------------
-- Multiple DFO trees, no parent/child, multiple DFO tree starts, no separate slave sets, concurrently active (12.1: Single DFO tree, new parallel FILTER/SUBQUERY) --
----------------------------------------------------------------------------------------------------------------------------------------------------------------------

set echo on timing on time on

select  /*+ no_merge(x) */
        *
from    (
          select
                  v1.filler
                , (select /*+ parallel(x 2) */ id from t2 x where x.id = v1.id) as id
                , (select /*+ parallel(x 2) */ id2 from t2 x where x.id = v1.id) as id2
          from    (
                    select  /*+ parallel(t2 4) */
                            t2.id
                          , t2.id2
                          , t2.filler
                    from
                            t2
                  ) v1
                , (
                    select  /*+ parallel(t2 8) */
                            t2.id
                          , t2.id2
                          , t2.filler
                    from
                            t2
                  ) v2
          where
                  v1.id = v2.id
          and     v1.filler = v2.filler
        ) x
where
        rownum <= 100
;

----------------------------------------------------------------------------------------------------------------------------------------------------------
-- Multiple DFO trees, no parent/child, multiple DFO tree starts, separate slave sets, concurrently active (12.1: Single DFO tree, new parallel FILTER) --
----------------------------------------------------------------------------------------------------------------------------------------------------------

set echo on timing on time on

select  /*+ parallel(t2 8)
            parallel(t3 8)
            leading(t3 t2)
            use_hash(t3 t2)
            swap_join_inputs(t2)
            PQ_DISTRIBUTE(T2 HASH HASH)
            --PQ_FILTER(@"SEL$1" NONE)
        */
        t2.id     as t2_id
      , t2.filler as t2_filler
      , t2.id2    as t2_id2
      , t3.id     as t3_id
      , t3.filler as t3_filler
from
        t1 t2
      , t2 t3
where
        t3.id2 = t2.id2 (+)
and     regexp_replace(t3.filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') = regexp_replace(t2.filler (+), '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c')
and     mod(t3.id2, 3) = 0
and     not exists (select /*+ no_unnest parallel(t2 2) */ null from t2 x where x.id2 = t2.id2)
;

-------------------------------------------------------------------------------------------------------------------------------------------------------------
-- Multiple DFO trees, no parent/child, multiple DFO tree starts, separate slave sets, concurrently active (12.1: Still multiple DFO trees, serial FILTER) --
-------------------------------------------------------------------------------------------------------------------------------------------------------------

set echo on timing on time on

alter session enable parallel dml;

truncate table x;

insert  /*+ append parallel(x 4) */ into x
select  /*+ leading(v1 v2) */
        v_1.id
      , v_1.id2
      , v_1.filler
from    (
           select
                   id
                 , id2
                 , filler
           from    (
                      select  /*+ parallel(t2 4) no_merge */
                              rownum as id
                            , t2.id2
                            , t2.filler
                      from
                              t2
                      where
                              mod(t2.id2, 3) = 0
                      and     regexp_replace(t2.filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') = regexp_replace(t2.filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'i')
                   ) v1
        ) v_1
      , (
          select
                   id
                 , id2
                 , filler
          from     (
                     select  /*+ parallel(t2 8) no_merge */
                             rownum as id
                           , t2.id2
                           , t2.filler
                     from
                             t2
                     where
                             mod(t2.id2, 3) = 0
                     and     regexp_replace(t2.filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'c') = regexp_replace(t2.filler, '^([[:alnum:]]+)\s+$', lpad('\1', 10), 1, 1, 'i')
                   ) v2
        ) v_2
where
        v_1.id = v_2.id
and     v_1.filler = v_2.filler
and     not exists (select /*+ no_unnest parallel(y 2) */ null from t2 y where y.id2 = v_1.id2)
;

commit;