Dimensional Benchmarking of Oracle v10-v12 Queries for SQL Bursting Problems

What we call the beginning is often the end
And to make an end is to make a beginning.
The end is where we start from. And every phrase
And sentence that is right (where every word is at home,
Taking its place to support the others,
The word neither diffident nor ostentatious,
An easy commerce of the old and the new,
The common word exact without vulgarity,
The formal word precise but not pedantic,
The complete consort dancing together)
Every phrase and every sentence is an end and a beginning,
Every poem an epitaph

– from Little Gidding by T.S. Eliot

A few years ago I wrote some SQL queries to assign dated records into groups defined by each record being within a fixed window of its starting record (the original Scribd document I wrote is embedded at the bottom). This is a bit harder than it sounds in pure SQL, without using PL/SQL, and I could only do it using new features from versions 10 and 11 of Oracle. With companies increasingly migrating to version 12, I thought it might be interesting to compare these queries with a query using the new 12c feature MATCH_RECOGNIZE. It turns out that the 12c query is both simpler and faster than the earlier queries. I’ll describe the problem with a simple functional test data set first, then will give the SQL for each of four methods with the execution plan for a larger data set. At the end I summarise the results from the four methods across a range of problem sizes.

I obtained these results on my Windows 10 home computer with Oracle 12.1, and used my own benchmarking framework that I wrote around the same time as the original queries, and have now published on GitHub, A Framework for Dimensional Benchmarking of SQL Query Performance.

See also Dimensional Benchmarking of General SQL Bursting Problems.

‘Bursting’ Problem Definition

The problem is to determine the break groups using distance from the group start point. In other words, once a group starts, all records that start within a fixed distance from the group start are in the group, and the first record after the end of a group defines the next group start. The data are partitioned by some key in general (here person_id). The problem data structure is based on a question posed in Tom Kyte’s Oracle forum, Activities and breaks, while the test data are my own.

ACTIVITY Table

CREATE TABLE activity (
    activity_id     NUMBER,
    person_id       NUMBER,
    start_date      DATE,
    end_date        DATE,
    activity_name   VARCHAR2(10)
)
/
CREATE INDEX activity_N1 ON activity (person_id, start_date, Nvl (end_date, '01-JAN-3000'))
/
CREATE INDEX activity_N2 ON activity (person_id, Nvl (end_date, '01-JAN-3000'), start_date)
/

Functional Test Data
I created test data with a test burst maximum length of 3 days, as follows, with groups shown at detailed level.

 PERSON_ID START_DAT END_DATE  GROUP_STA GROUP_END
---------- --------- --------- --------- ---------
         3 01-JUN-11 03-JUN-11 01-JUN-11 07-JUN-11
           02-JUN-11 05-JUN-11 01-JUN-11 07-JUN-11
           04-JUN-11 07-JUN-11 01-JUN-11 07-JUN-11
           08-JUN-11 16-JUN-11 08-JUN-11 16-JUN-11
           09-JUN-11 14-JUN-11 08-JUN-11 16-JUN-11
           20-JUN-11 30-JUN-11 20-JUN-11 30-JUN-11

         4 01-JUN-11 03-JUN-11 01-JUN-11 07-JUN-11
           02-JUN-11 05-JUN-11 01-JUN-11 07-JUN-11
           04-JUN-11 07-JUN-11 01-JUN-11 07-JUN-11
           08-JUN-11 16-JUN-11 08-JUN-11 16-JUN-11
           09-JUN-11 15-JUN-11 08-JUN-11 16-JUN-11
           20-JUN-11 30-JUN-11 20-JUN-11 30-JUN-11

         5 01-JUN-11 03-JUN-11 01-JUN-11 07-JUN-11
           02-JUN-11 05-JUN-11 01-JUN-11 07-JUN-11
           04-JUN-11 07-JUN-11 01-JUN-11 07-JUN-11
           08-JUN-11 16-JUN-11 08-JUN-11 16-JUN-11
           09-JUN-11 14-JUN-11 08-JUN-11 16-JUN-11
           15-JUN-11 30-JUN-11 15-JUN-11 30-JUN-11

18 rows selected.

The queries shown later give the groups at summary level, as follows:

 PERSON_ID GROUP_STA GROUP_END   NUM_ROWS
---------- --------- --------- ----------
         3 01-JUN-11 07-JUN-11          3
           08-JUN-11 16-JUN-11          2
           20-JUN-11 30-JUN-11          1

         4 01-JUN-11 07-JUN-11          3
           08-JUN-11 16-JUN-11          2
           20-JUN-11 30-JUN-11          1

         5 01-JUN-11 07-JUN-11          3
           08-JUN-11 16-JUN-11          2
           15-JUN-11 30-JUN-11          1

9 rows selected.

In the following sections, the query (and other SQL) is listed first, followed by the execution plan for the largest problem (W30-D30).

Model Query

WITH all_rows AS (
SELECT person_id,
       start_date,
       end_date,
       group_start
  FROM activity
 MODEL
    PARTITION BY (person_id)
    DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn)
    MEASURES (start_date, end_date, start_date group_start)
    RULES (
       group_start[rn = 1] = start_date[cv()],
       group_start[rn > 1] = CASE WHEN start_date[cv()] - group_start[cv()-1] > Sys_Context('bench_ctx', 'deep') THEN start_date[cv()] ELSE group_start[cv()-1] END
    )
)
SELECT  person_id       person_id,
        group_start     group_start,
        MAX(end_date)   group_end,
        COUNT(*)        num_rows
  FROM all_rows
GROUP BY person_id, group_start
ORDER BY person_id, group_start

Plan hash value: 2323700320

-----------------------------------------------------------------------------------------------------------------------
| Id  | Operation             | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-----------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |          |      1 |        |   3325 |00:00:00.27 |     248 |       |       |          |
|   1 |  SORT GROUP BY        |          |      1 |  45000 |   3325 |00:00:00.27 |     248 |   267K|   267K|  237K (0)|
|   2 |   VIEW                |          |      1 |  45000 |  45000 |00:00:00.13 |     248 |       |       |          |
|   3 |    SQL MODEL ORDERED  |          |      1 |  45000 |  45000 |00:00:00.12 |     248 |  4279K|  1428K| 2957K (0)|
|   4 |     WINDOW SORT       |          |      1 |  45000 |  45000 |00:00:00.03 |     248 |  2108K|   682K| 1873K (0)|
|   5 |      TABLE ACCESS FULL| ACTIVITY |      1 |  45000 |  45000 |00:00:00.01 |     248 |       |       |          |
-----------------------------------------------------------------------------------------------------------------------

Recursive Subquery Factors Query 1 – Direct

WITH act AS (
SELECT person_id, start_date, end_date, Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn
  FROM activity
),     rsq (person_id, rn, start_date, end_date, group_start) AS (
SELECT person_id, rn, start_date, end_date, start_date
  FROM act
 WHERE rn = 1
 UNION ALL
SELECT  act.person_id,
        act.rn,
        act.start_date,
        act.end_date,
        CASE WHEN act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end
  FROM act
  JOIN rsq
    ON rsq.rn              = act.rn - 1
   AND rsq.person_id       = act.person_id
)
SELECT  person_id       person_id,
        group_start     group_start,
        Max (end_date)  group_end,
        COUNT(*)        num_rows
FROM rsq
GROUP BY person_id, group_start
ORDER BY person_id, group_start

Plan hash value: 941514960

--------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |          |      1 |        |   3325 |00:07:08.74 |    3790K|       |       |          |
|   1 |  SORT GROUP BY                             |          |      1 |    151 |   3325 |00:07:08.74 |    3790K|   302K|   302K|  268K (0)|
|   2 |   VIEW                                     |          |      1 |    151 |  45000 |00:07:08.09 |    3790K|       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|          |      1 |        |  45000 |00:07:08.07 |    3790K|  2048 |  2048 | 2881K (0)|
|*  4 |     VIEW                                   |          |      1 |      1 |      3 |00:00:00.06 |     248 |       |       |          |
|*  5 |      WINDOW SORT PUSHED RANK               |          |      1 |  45000 |      3 |00:00:00.06 |     248 |  2958K|   766K| 2629K (0)|
|   6 |       TABLE ACCESS FULL                    | ACTIVITY |      1 |  45000 |  45000 |00:00:00.01 |     248 |       |       |          |
|*  7 |     HASH JOIN                              |          |  15000 |    150 |  44997 |00:06:13.31 |    3720K|  1321K|  1321K|  683K (0)|
|   8 |      RECURSIVE WITH PUMP                   |          |  15000 |        |  45000 |00:00:00.03 |       0 |       |       |          |
|   9 |      VIEW                                  |          |  15000 |  45000 |    675M|00:07:56.72 |    3720K|       |       |          |
|  10 |       WINDOW SORT                          |          |  15000 |  45000 |    675M|00:06:20.44 |    3720K|  2108K|   682K| 1873K (0)|
|  11 |        TABLE ACCESS FULL                   | ACTIVITY |  15000 |  45000 |    675M|00:01:03.31 |    3720K|       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   4 - filter("RN"=1)
   5 - filter(ROW_NUMBER() OVER ( PARTITION BY "PERSON_ID" ORDER BY "START_DATE")<=1)
   7 - access("RSQ"."RN"="ACT"."RN"-1 AND "RSQ"."PERSON_ID"="ACT"."PERSON_ID")

Recursive Subquery Factors Query 2 - With Temporary Table

Temporary Table Definition

CREATE GLOBAL TEMPORARY TABLE activity_tmp (
  person_id     NUMBER,
  start_date    DATE,
  end_date      DATE,
  act_rownum    NUMBER
)
ON COMMIT DELETE ROWS
/
CREATE INDEX activity_tmp_N1 ON activity_tmp (act_rownum, person_id)
/

SQL - Insert to temporary table

INSERT INTO activity_tmp SELECT person_id, start_date, end_date, Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) FROM activity

Query using temporary table

WITH rsq (person_id, rn, start_date, end_date, group_start) AS (
SELECT person_id, act_rownum, start_date, end_date, start_date
  FROM activity_tmp
 WHERE act_rownum = 1
 UNION ALL
SELECT  act.person_id,
        act.act_rownum,
        act.start_date,
        act.end_date,
        CASE WHEN act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end
  FROM rsq
  JOIN activity_tmp act
    ON act.act_rownum     = rsq.rn + 1
   AND act.person_id      = rsq.person_id
)
SELECT  person_id       person_id,
        group_start     group_start,
        Max (end_date)  group_end,
        COUNT(*)        num_rows
FROM rsq
GROUP BY person_id, group_start
ORDER BY person_id, group_start

Plan hash value: 4212061972

---------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name            | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
---------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |                 |      1 |        |   3325 |00:00:00.42 |     131K|       |       |          |
|   1 |  SORT GROUP BY                             |                 |      1 |      6 |   3325 |00:00:00.42 |     131K|   302K|   302K|  268K (0)|
|   2 |   VIEW                                     |                 |      1 |      6 |  45000 |00:00:00.38 |     131K|       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|                 |      1 |        |  45000 |00:00:00.37 |     131K|  2048 |  2048 | 2881K (0)|
|   4 |     TABLE ACCESS BY INDEX ROWID BATCHED    | ACTIVITY_TMP    |      1 |      3 |      3 |00:00:00.01 |       5 |       |       |          |
|*  5 |      INDEX RANGE SCAN                      | ACTIVITY_TMP_N1 |      1 |      3 |      3 |00:00:00.01 |       2 |       |       |          |
|   6 |     NESTED LOOPS                           |                 |  15000 |      3 |  44997 |00:00:00.16 |   61137 |       |       |          |
|   7 |      RECURSIVE WITH PUMP                   |                 |  15000 |        |  45000 |00:00:00.01 |       0 |       |       |          |
|   8 |      TABLE ACCESS BY INDEX ROWID BATCHED   | ACTIVITY_TMP    |  45000 |      1 |  44997 |00:00:00.12 |   61137 |       |       |          |
|*  9 |       INDEX RANGE SCAN                     | ACTIVITY_TMP_N1 |  45000 |    466 |  44997 |00:00:00.05 |   16140 |       |       |          |
---------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   5 - access("ACT_ROWNUM"=1)
   9 - access("ACT"."ACT_ROWNUM"="RSQ"."RN"+1 AND "ACT"."PERSON_ID"="RSQ"."PERSON_ID")

Note
-----
   - dynamic statistics used: dynamic sampling (level=2)
   - this is an adaptive plan

Match Recognize Query

SELECT  person_id       person_id,
        group_start     group_start,
        group_end       group_end,
        num_rows        num_rows
  FROM activity
 MATCH_RECOGNIZE (
   PARTITION BY person_id
   ORDER BY start_date
   MEASURES FIRST (start_date) group_start,
            FINAL MAX (end_date) group_end,
            COUNT(*) num_rows
      ONE ROW PER MATCH
  PATTERN (strt sm*)
   DEFINE sm AS sm.start_date <= strt.start_date + Sys_Context('bench_ctx', 'deep')
  ) m
ORDER BY person_id, group_start

Plan hash value: 3670115155

--------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                        | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                                 |          |      1 |        |   3325 |00:00:00.04 |     248 |       |       |          |
|   1 |  SORT ORDER BY                                   |          |      1 |  45000 |   3325 |00:00:00.04 |     248 |   302K|   302K|  268K (0)|
|   2 |   VIEW                                           |          |      1 |  45000 |   3325 |00:00:00.03 |     248 |       |       |          |
|   3 |    MATCH RECOGNIZE SORT DETERMINISTIC FINITE AUTO|          |      1 |  45000 |   3325 |00:00:00.03 |     248 |  2108K|   682K| 1873K (0)|
|   4 |     TABLE ACCESS FULL                            | ACTIVITY |      1 |  45000 |  45000 |00:00:00.01 |     248 |       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------------

Performance

500w records are generated for each of three persons, where w is a 'width' parameter, with start dates randomized across a century, and a depth parameter is passed to the query for the number of days group limit via a system context.

Records Input and Output

W10 W20 W30
Input Records -> 15,000 30,000 45,000
Output Records
D10 6,166 7,710 8,451
D20 3,951 4,537 4,771
D30 2,910 3,199 3,325

Model Query (elapsed seconds)

MOD_QRY W10 W20 W30
D10 0.09 0.16 1.25
D20 0.08 0.16 0.24
D30 0.10 0.16 0.28

Recursive Subquery Factors Query 1 - Direct (elapsed seconds)

RSF_QRY W10 W20 W30
D10 46 187 423
D20 46 190 440
D30 47 187 429

Recursive Subquery Factors Query 2 - With Temporary Table (elapsed seconds)

RSF_TMP W10 W20 W30
D10 0.19 0.34 0.53
D20 0.16 0.41 0.51
D30 0.16 0.32 0.51

Match Recognize Query (elapsed seconds)

MTH_QRY W10 W20 W30
D10 0.07 0.04 0.06
D20 0.02 0.03 0.04
D30 0.02 0.03 0.04

Conclusions

  • The new 12c feature MATCH_RECOGNIZE is a very powerful technique, and was much faster than the other techniques for this problem
  • The results above showed that recursive subquery factoring had timings that increased quadratically with number of records; this was due to a product between the number of starts and full scans on a subquery
  • This kind of unscaleable quadratic resource usage can often be avoided by the use of a temporary table with appropriate indexes, as demonstrated
  • The depth parameter had little effect on timing, but I included it for the purpose of demonstration of the benchmarking framework

Original Scribd Document

Loading...

Full Output Log

SQL> 
SQL> COLUMN "Database"	FORMAT A20
SQL> COLUMN "Time"		FORMAT A20
SQL> COLUMN "Version"	FORMAT A30
SQL> COLUMN "Session"	FORMAT 9999990
SQL> COLUMN "OS User"	FORMAT A10
SQL> COLUMN "Machine"	FORMAT A20
SQL> SET LINES 180
SQL> SET PAGES 1000
SQL> 
SQL> SELECT 'Start: ' || dbs.name "Database", To_Char (SYSDATE,'DD-MON-YYYY HH24:MI:SS') "Time",
  2  	Replace (Substr(ver.banner, 1, Instr(ver.banner, '64')-4), 'Enterprise Edition Release ', '') "Version"
  3    FROM v$database dbs,  v$version ver
  4   WHERE ver.banner LIKE 'Oracle%';

Database             Time                 Version
-------------------- -------------------- ------------------------------
Start: ORCL          06-NOV-2016 14:11:19 Oracle Database 12c 12.1.0.2.0

SQL> 
SQL> DEFINE RUNDESC='Burst-One'
SQL> 
SQL> SET SERVEROUTPUT ON
SQL> SET TIMING ON
SQL> 
SQL> ALTER SESSION SET NLS_DATE_FORMAT = 'DD-MON-YYYY';

Session altered.

Elapsed: 00:00:00.00
SQL> BEGIN
  2  
  3    Utils.Clear_Log;
  4    Bench_Queries.Create_Run (
  5  			p_run_desc		=> '&RUNDESC',
  6  			p_points_wide_list	=> L1_num_arr (10, 20, 30),
  7  			p_points_deep_list	=> L1_num_arr (10, 20, 30),
  8  			p_query_group		=> 'BURST',
  9                          p_redo_data_yn          => 'Y');
 10    Bench_Queries.Execute_Run;
 11  
 12  END;
 13  /
old   5: 			p_run_desc		=> '&RUNDESC',
new   5: 			p_run_desc		=> 'Burst-One',

PL/SQL procedure successfully completed.

Elapsed: 00:34:01.19
SQL> PROMPT Default log
Default log
SQL> @../sql/L_Log_Default

TEXT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Bench run 1 created

Elapsed: 00:00:00.00
SQL> PROMPT Execute_Run log
Execute_Run log
SQL> @../sql/L_Log_Gp

TEXT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Bench run id = 1

Wide Points
===========
10, 20, 30

Deep Points
===========
10, 20, 30
Header="person_id","group_start","group_end","num_rows","Random"
mid=
        person_id       person_id,
        group_start     group_start,
        MAX(end_date)   group_end,
        COUNT(*)        num_rows

new='"' ||  person_id       || '","' || group_start     || '","' || MAX(end_date)   || '","' ||
        COUNT(*) || '","#?"'

/* MOD_QRY */ WITH all_rows AS ( SELECT person_id, start_date, end_date, group_start FROM activity MODEL PARTITION BY (person_id) DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY start
_date) rn) MEASURES (start_date, end_date, start_date group_start) RULES ( group_start[rn = 1] = start_date[cv()], group_start[rn > 1] = CASE WHEN start_date[cv()] - group_start[cv()-1] > Sys_Context(
'bench_ctx', 'deep') THEN start_date[cv()] ELSE group_start[cv()-1] END ) ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || MAX(end_date) || '","' || COUNT(*)
 || '","#?"' FROM all_rows GROUP BY person_id, group_start ORDER BY person_id, group_start

Header="person_id","group_start","group_end","num_rows","Random"
mid=
        person_id       person_id,
        group_start     group_start,
        Max (end_date)  group_end,
        COUNT(*)        num_rows

new='"' ||  person_id       || '","' || group_start     || '","' || Max (end_date)  || '","' ||
        COUNT(*) || '","#?"'

/* RSF_QRY */ WITH act AS ( SELECT person_id, start_date, end_date, Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn FROM activity ),	rsq (person_id, rn, start_date, end_date, group_s
tart) AS ( SELECT person_id, rn, start_date, end_date, start_date FROM act WHERE rn = 1 UNION ALL SELECT act.person_id, act.rn, act.start_date, act.end_date, CASE WHEN act.start_date - rsq.group_start
 <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end FROM act JOIN rsq ON rsq.rn = act.rn - 1 AND rsq.person_id = act.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"'
|| person_id || '","' || group_start || '","' || Max (end_date) || '","' || COUNT(*) || '","#?"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id, group_start

Header="person_id","group_start","group_end","num_rows","Random"
mid=
        person_id       person_id,
        group_start     group_start,
        Max (end_date)  group_end,
        COUNT(*)        num_rows

new='"' ||  person_id       || '","' || group_start     || '","' || Max (end_date)  || '","' ||
        COUNT(*) || '","#?"'

/* RSF_TMP */ WITH rsq (person_id, rn, start_date, end_date, group_start) AS ( SELECT person_id, act_rownum, start_date, end_date, start_date FROM activity_tmp WHERE act_rownum = 1 UNION ALL SELECT ac
t.person_id, act.act_rownum, act.start_date, act.end_date, CASE WHEN act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end FROM rsq JOIN act
ivity_tmp act ON act.act_rownum = rsq.rn + 1 AND act.person_id = rsq.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || Max (end_date) || '","' || CO
UNT(*) || '","#?"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id, group_start

Header="person_id","group_start","group_end","num_rows","Random"
mid=
        person_id       person_id,
        group_start     group_start,
        group_end       group_end,
        num_rows        num_rows

new='"' ||  person_id       || '","' || group_start     || '","' || group_end       || '","' ||
        num_rows || '","#?"'

/* MTH_QRY */ SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || group_end || '","' || num_rows || '","#?"' FROM activity MATCH_RECOGNIZE ( PARTITION BY person_i
d ORDER BY start_date MEASURES FIRST (start_date) group_start, FINAL MAX (end_date) group_end, COUNT(*) num_rows ONE ROW PER MATCH PATTERN (strt sm*) DEFINE sm AS sm.start_date <= strt.start_date + Sy
s_Context('bench_ctx', 'deep') ) m ORDER BY person_id, group_start

Activity truncated
15000 (5000) records (per person) added, average group size (from) = 2.6 (5000), # of groups = 1937.7

Timer Set: Setup, Constructed at 06 Nov 2016 14:11:20, written at 14:11:22
==========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer                  Elapsed         CPU         Calls       Ela/Call       CPU/Call
------------------  ----------  ----------  ------------  -------------  -------------
Add_Act                   1.72        0.94             1        1.71500        0.94000
Gather_Table_Stats        0.63        0.39             1        0.62800        0.39000
GRP_CNT                   0.07        0.08             1        0.07400        0.08000
(Other)                   0.00        0.00             1        0.00100        0.00000
------------------  ----------  ----------  ------------  -------------  -------------
Total                     2.42        1.41             4        0.60450        0.35250
------------------  ----------  ----------  ------------  -------------  -------------
/* MOD_QRY */ WITH all_rows AS ( SELECT person_id, start_date, end_date, group_start FROM activity MODEL PARTITION BY (person_id) DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY start
_date) rn) MEASURES (start_date, end_date, start_date group_start) RULES ( group_start[rn = 1] = start_date[cv()], group_start[rn > 1] = CASE WHEN start_date[cv()] - group_start[cv()-1] > Sys_Context(
'bench_ctx', 'deep') THEN start_date[cv()] ELSE group_start[cv()-1] END ) ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || MAX(end_date) || '","' || COUNT(*)
 || '","5447"' FROM all_rows GROUP BY person_id, group_start ORDER BY person_id, group_start

SQL_ID  f5zc3ryz1du2j, child number 0
-------------------------------------
/* MOD_QRY */ WITH all_rows AS ( SELECT person_id, start_date,
end_date, group_start FROM activity MODEL PARTITION BY (person_id)
DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY
start_date) rn) MEASURES (start_date, end_date, start_date group_start)
RULES ( group_start[rn = 1] = start_date[cv()], group_start[rn > 1] =
CASE WHEN start_date[cv()] - group_start[cv()-1] >
Sys_Context('bench_ctx', 'deep') THEN start_date[cv()] ELSE
group_start[cv()-1] END ) ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' ||
person_id || '","' || group_start || '","' || MAX(end_date) || '","' ||
COUNT(*) || '","5447"' FROM all_rows GROUP BY person_id, group_start
ORDER BY person_id, group_start

Plan hash value: 2323700320

-----------------------------------------------------------------------------------------------------------------------
| Id  | Operation             | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-----------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |          |      1 |        |   6166 |00:00:00.08 |      84 |       |       |          |
|   1 |  SORT GROUP BY        |          |      1 |  15000 |   6166 |00:00:00.08 |      84 |   478K|   478K|  424K (0)|
|   2 |   VIEW                |          |      1 |  15000 |  15000 |00:00:00.04 |      84 |       |       |          |
|   3 |    SQL MODEL ORDERED  |          |      1 |  15000 |  15000 |00:00:00.04 |      84 |  1977K|  1439K| 1169K (0)|
|   4 |     WINDOW SORT       |          |      1 |  15000 |  15000 |00:00:00.01 |      84 |   761K|   499K|  676K (0)|
|   5 |      TABLE ACCESS FULL| ACTIVITY |      1 |  15000 |  15000 |00:00:00.01 |      84 |       |       |          |
-----------------------------------------------------------------------------------------------------------------------


Timer Set: Cursor, Constructed at 06 Nov 2016 14:11:22, written at 14:11:22
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.00             1        0.00200        0.00000
First fetch              0.08        0.08             1        0.08000        0.08000
Write to file            0.01        0.01             8        0.00150        0.00125
Remaining fetches        0.01        0.00             7        0.00071        0.00000
Write plan               0.17        0.18             1        0.16500        0.18000
(Other)                  0.08        0.05             1        0.07800        0.05000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.34        0.32            20        0.01710        0.01600
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:11:22, written at 14:11:22
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.00             9        0.00111        0.00000
(Other)        0.35        0.33             1        0.34700        0.33000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.36        0.33            10        0.03570        0.03300
-------  ----------  ----------  ------------  -------------  -------------
6167 rows written to MOD_QRY.csv
Summary for W/D = 10/10 , bench_run_statistics_id = 1

Timer Set: Run_One, Constructed at 06 Nov 2016 14:11:22, written at 14:11:22
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.37        0.33             1        0.36600        0.33000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.37        0.33             2        0.18300        0.16500
-------  ----------  ----------  ------------  -------------  -------------
/* RSF_QRY */ WITH act AS ( SELECT person_id, start_date, end_date, Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn FROM activity ),	rsq (person_id, rn, start_date, end_date, group_s
tart) AS ( SELECT person_id, rn, start_date, end_date, start_date FROM act WHERE rn = 1 UNION ALL SELECT act.person_id, act.rn, act.start_date, act.end_date, CASE WHEN act.start_date - rsq.group_start
 <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end FROM act JOIN rsq ON rsq.rn = act.rn - 1 AND rsq.person_id = act.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"'
|| person_id || '","' || group_start || '","' || Max (end_date) || '","' || COUNT(*) || '","5630"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id, group_start

SQL_ID  6187j0s4bmnc9, child number 0
-------------------------------------
/* RSF_QRY */ WITH act AS ( SELECT person_id, start_date, end_date,
Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn FROM
activity ), rsq (person_id, rn, start_date, end_date, group_start) AS (
SELECT person_id, rn, start_date, end_date, start_date FROM act WHERE
rn = 1 UNION ALL SELECT act.person_id, act.rn, act.start_date,
act.end_date, CASE WHEN act.start_date - rsq.group_start <=
Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE
act.start_date end FROM act JOIN rsq ON rsq.rn = act.rn - 1 AND
rsq.person_id = act.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */
'"' || person_id || '","' || group_start || '","' || Max (end_date) ||
'","' || COUNT(*) || '","5630"' FROM rsq GROUP BY person_id,
group_start ORDER BY person_id, group_start

Plan hash value: 941514960

--------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |          |      1 |        |   6166 |00:00:46.44 |     435K|       |       |          |
|   1 |  SORT GROUP BY                             |          |      1 |     51 |   6166 |00:00:46.44 |     435K|   549K|   549K|  487K (0)|
|   2 |   VIEW                                     |          |      1 |     51 |  15000 |00:00:46.14 |     435K|       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|          |      1 |        |  15000 |00:00:46.13 |     435K|  2048 |  2048 |  991K (0)|
|*  4 |     VIEW                                   |          |      1 |      1 |      3 |00:00:00.01 |      84 |       |       |          |
|*  5 |      WINDOW SORT PUSHED RANK               |          |      1 |  15000 |      3 |00:00:00.01 |      84 |  1045K|   546K|  928K (0)|
|   6 |       TABLE ACCESS FULL                    | ACTIVITY |      1 |  15000 |  15000 |00:00:00.01 |      84 |       |       |          |
|*  7 |     HASH JOIN                              |          |   5000 |     50 |  14997 |00:00:40.42 |     420K|  1321K|  1321K|  640K (0)|
|   8 |      RECURSIVE WITH PUMP                   |          |   5000 |        |  15000 |00:00:00.01 |       0 |       |       |          |
|   9 |      VIEW                                  |          |   5000 |  15000 |     75M|00:00:51.68 |     420K|       |       |          |
|  10 |       WINDOW SORT                          |          |   5000 |  15000 |     75M|00:00:40.97 |     420K|   761K|   499K|  676K (0)|
|  11 |        TABLE ACCESS FULL                   | ACTIVITY |   5000 |  15000 |     75M|00:00:06.70 |     420K|       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   4 - filter("RN"=1)
   5 - filter(ROW_NUMBER() OVER ( PARTITION BY "PERSON_ID" ORDER BY "START_DATE")<=1)
   7 - access("RSQ"."RN"="ACT"."RN"-1 AND "RSQ"."PERSON_ID"="ACT"."PERSON_ID")


Timer Set: Cursor, Constructed at 06 Nov 2016 14:11:22, written at 14:12:09
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.00             1        0.00200        0.00000
First fetch             46.44       46.41             1       46.44300       46.41000
Write to file            0.01        0.02             8        0.00138        0.00250
Remaining fetches        0.01        0.00             7        0.00100        0.00000
Write plan               0.12        0.12             1        0.12200        0.12000
(Other)                  0.01        0.01             1        0.01100        0.01000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                   46.60       46.56            20        2.32980        2.32800
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:11:22, written at 14:12:09
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.02             9        0.00089        0.00222
(Other)       46.60       46.56             1       46.60200       46.56000
-------  ----------  ----------  ------------  -------------  -------------
Total         46.61       46.58            10        4.66100        4.65800
-------  ----------  ----------  ------------  -------------  -------------
6167 rows written to RSF_QRY.csv
Summary for W/D = 10/10 , bench_run_statistics_id = 2

Timer Set: Run_One, Constructed at 06 Nov 2016 14:11:22, written at 14:12:09
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run           46.62       46.59             1       46.61900       46.59000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total         46.62       46.59             2       23.30950       23.29500
-------  ----------  ----------  ------------  -------------  -------------
/* RSF_TMP */ WITH rsq (person_id, rn, start_date, end_date, group_start) AS ( SELECT person_id, act_rownum, start_date, end_date, start_date FROM activity_tmp WHERE act_rownum = 1 UNION ALL SELECT ac
t.person_id, act.act_rownum, act.start_date, act.end_date, CASE WHEN act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end FROM rsq JOIN act
ivity_tmp act ON act.act_rownum = rsq.rn + 1 AND act.person_id = rsq.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || Max (end_date) || '","' || CO
UNT(*) || '","5319"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id, group_start

INSERT INTO activity_tmp SELECT person_id, start_date, end_date, Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) FROM activity
SQL_ID  5mkzvt2g6pw9f, child number 0
-------------------------------------
/* RSF_TMP */ WITH rsq (person_id, rn, start_date, end_date,
group_start) AS ( SELECT person_id, act_rownum, start_date, end_date,
start_date FROM activity_tmp WHERE act_rownum = 1 UNION ALL SELECT
act.person_id, act.act_rownum, act.start_date, act.end_date, CASE WHEN
act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep')
THEN rsq.group_start ELSE act.start_date end FROM rsq JOIN activity_tmp
act ON act.act_rownum = rsq.rn + 1 AND act.person_id = rsq.person_id )
SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' ||
group_start || '","' || Max (end_date) || '","' || COUNT(*) ||
'","5319"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id,
group_start

Plan hash value: 4212061972

---------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name            | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
---------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |                 |      1 |        |   6166 |00:00:00.12 |   35601 |       |       |          |
|   1 |  SORT GROUP BY                             |                 |      1 |      6 |   6166 |00:00:00.12 |   35601 |   549K|   549K|  487K (0)|
|   2 |   VIEW                                     |                 |      1 |      6 |  15000 |00:00:00.11 |   35601 |       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|                 |      1 |        |  15000 |00:00:00.11 |   35601 |  2048 |  2048 |  991K (0)|
|   4 |     TABLE ACCESS BY INDEX ROWID BATCHED    | ACTIVITY_TMP    |      1 |      3 |      3 |00:00:00.01 |       5 |       |       |          |
|*  5 |      INDEX RANGE SCAN                      | ACTIVITY_TMP_N1 |      1 |      3 |      3 |00:00:00.01 |       2 |       |       |          |
|   6 |     NESTED LOOPS                           |                 |   5000 |      3 |  14997 |00:00:00.05 |   20378 |       |       |          |
|   7 |      RECURSIVE WITH PUMP                   |                 |   5000 |        |  15000 |00:00:00.01 |       0 |       |       |          |
|   8 |      TABLE ACCESS BY INDEX ROWID BATCHED   | ACTIVITY_TMP    |  15000 |      1 |  14997 |00:00:00.04 |   20378 |       |       |          |
|*  9 |       INDEX RANGE SCAN                     | ACTIVITY_TMP_N1 |  15000 |    150 |  14997 |00:00:00.02 |    5381 |       |       |          |
---------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   5 - access("ACT_ROWNUM"=1)
   9 - access("ACT"."ACT_ROWNUM"="RSQ"."RN"+1 AND "ACT"."PERSON_ID"="RSQ"."PERSON_ID")

Note
-----
   - dynamic statistics used: dynamic sampling (level=2)
   - this is an adaptive plan


Timer Set: Cursor, Constructed at 06 Nov 2016 14:12:09, written at 14:12:10
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.05        0.05             1        0.05100        0.05000
Open cursor              0.01        0.02             1        0.01200        0.02000
First fetch              0.12        0.12             1        0.12400        0.12000
Write to file            0.01        0.00             8        0.00150        0.00000
Remaining fetches        0.01        0.02             7        0.00086        0.00286
Write plan               0.14        0.14             1        0.13600        0.14000
(Other)                  0.33        0.03             1        0.32600        0.03000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.67        0.38            20        0.03335        0.01900
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:12:09, written at 14:12:10
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.00             9        0.00111        0.00000
(Other)        0.69        0.38             1        0.69400        0.38000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.70        0.38            10        0.07040        0.03800
-------  ----------  ----------  ------------  -------------  -------------
6167 rows written to RSF_TMP.csv
Summary for W/D = 10/10 , bench_run_statistics_id = 3

Timer Set: Run_One, Constructed at 06 Nov 2016 14:12:09, written at 14:12:10
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.71        0.39             1        0.71200        0.39000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.71        0.39             2        0.35600        0.19500
-------  ----------  ----------  ------------  -------------  -------------
/* MTH_QRY */ SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || group_end || '","' || num_rows || '","6063"' FROM activity MATCH_RECOGNIZE ( PARTITION BY person
_id ORDER BY start_date MEASURES FIRST (start_date) group_start, FINAL MAX (end_date) group_end, COUNT(*) num_rows ONE ROW PER MATCH PATTERN (strt sm*) DEFINE sm AS sm.start_date <= strt.start_date +
Sys_Context('bench_ctx', 'deep') ) m ORDER BY person_id, group_start

SQL_ID  chb3dm71jabhs, child number 0
-------------------------------------
/* MTH_QRY */ SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id ||
'","' || group_start || '","' || group_end || '","' || num_rows ||
'","6063"' FROM activity MATCH_RECOGNIZE ( PARTITION BY person_id ORDER
BY start_date MEASURES FIRST (start_date) group_start, FINAL MAX
(end_date) group_end, COUNT(*) num_rows ONE ROW PER MATCH PATTERN (strt
sm*) DEFINE sm AS sm.start_date <= strt.start_date +
Sys_Context('bench_ctx', 'deep') ) m ORDER BY person_id, group_start

Plan hash value: 3670115155

--------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                        | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                                 |          |      1 |        |   6166 |00:00:00.03 |      84 |       |       |          |
|   1 |  SORT ORDER BY                                   |          |      1 |  15000 |   6166 |00:00:00.03 |      84 |   549K|   457K|  487K (0)|
|   2 |   VIEW                                           |          |      1 |  15000 |   6166 |00:00:00.03 |      84 |       |       |          |
|   3 |    MATCH RECOGNIZE SORT DETERMINISTIC FINITE AUTO|          |      1 |  15000 |   6166 |00:00:00.03 |      84 |   761K|   499K|  676K (0)|
|   4 |     TABLE ACCESS FULL                            | ACTIVITY |      1 |  15000 |  15000 |00:00:00.01 |      84 |       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------------


Timer Set: Cursor, Constructed at 06 Nov 2016 14:12:10, written at 14:12:10
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.04        0.00             1        0.03500        0.00000
First fetch              0.03        0.03             1        0.03300        0.03000
Write to file            0.01        0.01             8        0.00163        0.00125
Remaining fetches        0.00        0.00             7        0.00014        0.00000
Write plan               0.14        0.13             1        0.13700        0.13000
(Other)                  0.01        0.02             1        0.01100        0.02000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.23        0.19            20        0.01150        0.00950
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:12:10, written at 14:12:10
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.01             9        0.00111        0.00111
(Other)        0.23        0.18             1        0.23300        0.18000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.24        0.19            10        0.02430        0.01900
-------  ----------  ----------  ------------  -------------  -------------
6167 rows written to MTH_QRY.csv
Summary for W/D = 10/10 , bench_run_statistics_id = 4

Timer Set: Run_One, Constructed at 06 Nov 2016 14:12:10, written at 14:12:10
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000005), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.25        0.19             1        0.25000        0.19000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.25        0.19             2        0.12500        0.09500
-------  ----------  ----------  ------------  -------------  -------------
Activity truncated
15000 (5000) records (per person) added, average group size (from) = 3.9 (5000), # of groups = 1271

Timer Set: Setup, Constructed at 06 Nov 2016 14:12:10, written at 14:12:11
==========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                  Elapsed         CPU         Calls       Ela/Call       CPU/Call
------------------  ----------  ----------  ------------  -------------  -------------
Add_Act                   0.86        0.76             1        0.85900        0.76000
Gather_Table_Stats        0.21        0.13             1        0.21100        0.13000
GRP_CNT                   0.07        0.07             1        0.07400        0.07000
(Other)                   0.00        0.00             1        0.00000        0.00000
------------------  ----------  ----------  ------------  -------------  -------------
Total                     1.14        0.96             4        0.28600        0.24000
------------------  ----------  ----------  ------------  -------------  -------------
/* MOD_QRY */ WITH all_rows AS ( SELECT person_id, start_date, end_date, group_start FROM activity MODEL PARTITION BY (person_id) DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY start
_date) rn) MEASURES (start_date, end_date, start_date group_start) RULES ( group_start[rn = 1] = start_date[cv()], group_start[rn > 1] = CASE WHEN start_date[cv()] - group_start[cv()-1] > Sys_Context(
'bench_ctx', 'deep') THEN start_date[cv()] ELSE group_start[cv()-1] END ) ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || MAX(end_date) || '","' || COUNT(*)
 || '","8357"' FROM all_rows GROUP BY person_id, group_start ORDER BY person_id, group_start

SQL_ID  g6nv9dbmygm6m, child number 0
-------------------------------------
/* MOD_QRY */ WITH all_rows AS ( SELECT person_id, start_date,
end_date, group_start FROM activity MODEL PARTITION BY (person_id)
DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY
start_date) rn) MEASURES (start_date, end_date, start_date group_start)
RULES ( group_start[rn = 1] = start_date[cv()], group_start[rn > 1] =
CASE WHEN start_date[cv()] - group_start[cv()-1] >
Sys_Context('bench_ctx', 'deep') THEN start_date[cv()] ELSE
group_start[cv()-1] END ) ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' ||
person_id || '","' || group_start || '","' || MAX(end_date) || '","' ||
COUNT(*) || '","8357"' FROM all_rows GROUP BY person_id, group_start
ORDER BY person_id, group_start

Plan hash value: 2323700320

-----------------------------------------------------------------------------------------------------------------------
| Id  | Operation             | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-----------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |          |      1 |        |   3951 |00:00:00.08 |      84 |       |       |          |
|   1 |  SORT GROUP BY        |          |      1 |  15000 |   3951 |00:00:00.08 |      84 |   302K|   302K|  268K (0)|
|   2 |   VIEW                |          |      1 |  15000 |  15000 |00:00:00.04 |      84 |       |       |          |
|   3 |    SQL MODEL ORDERED  |          |      1 |  15000 |  15000 |00:00:00.03 |      84 |  1977K|  1439K| 1165K (0)|
|   4 |     WINDOW SORT       |          |      1 |  15000 |  15000 |00:00:00.01 |      84 |   761K|   499K|  676K (0)|
|   5 |      TABLE ACCESS FULL| ACTIVITY |      1 |  15000 |  15000 |00:00:00.01 |      84 |       |       |          |
-----------------------------------------------------------------------------------------------------------------------


Timer Set: Cursor, Constructed at 06 Nov 2016 14:12:11, written at 14:12:11
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.00             1        0.00100        0.00000
First fetch              0.08        0.08             1        0.07700        0.08000
Write to file            0.01        0.00             5        0.00200        0.00000
Remaining fetches        0.00        0.00             4        0.00075        0.00000
Write plan               0.10        0.11             1        0.10000        0.11000
(Other)                  0.02        0.02             1        0.01600        0.02000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.21        0.21            14        0.01479        0.01500
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:12:11, written at 14:12:11
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.00             6        0.00150        0.00000
(Other)        0.22        0.21             1        0.21500        0.21000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.22        0.21             7        0.03200        0.03000
-------  ----------  ----------  ------------  -------------  -------------
3952 rows written to MOD_QRY.csv
Summary for W/D = 10/20 , bench_run_statistics_id = 5

Timer Set: Run_One, Constructed at 06 Nov 2016 14:12:11, written at 14:12:11
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.23        0.21             1        0.23200        0.21000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.23        0.21             2        0.11600        0.10500
-------  ----------  ----------  ------------  -------------  -------------
/* RSF_QRY */ WITH act AS ( SELECT person_id, start_date, end_date, Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn FROM activity ),	rsq (person_id, rn, start_date, end_date, group_s
tart) AS ( SELECT person_id, rn, start_date, end_date, start_date FROM act WHERE rn = 1 UNION ALL SELECT act.person_id, act.rn, act.start_date, act.end_date, CASE WHEN act.start_date - rsq.group_start
 <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end FROM act JOIN rsq ON rsq.rn = act.rn - 1 AND rsq.person_id = act.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"'
|| person_id || '","' || group_start || '","' || Max (end_date) || '","' || COUNT(*) || '","8381"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id, group_start

SQL_ID  5030tpfmqq83q, child number 0
-------------------------------------
/* RSF_QRY */ WITH act AS ( SELECT person_id, start_date, end_date,
Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn FROM
activity ), rsq (person_id, rn, start_date, end_date, group_start) AS (
SELECT person_id, rn, start_date, end_date, start_date FROM act WHERE
rn = 1 UNION ALL SELECT act.person_id, act.rn, act.start_date,
act.end_date, CASE WHEN act.start_date - rsq.group_start <=
Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE
act.start_date end FROM act JOIN rsq ON rsq.rn = act.rn - 1 AND
rsq.person_id = act.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */
'"' || person_id || '","' || group_start || '","' || Max (end_date) ||
'","' || COUNT(*) || '","8381"' FROM rsq GROUP BY person_id,
group_start ORDER BY person_id, group_start

Plan hash value: 941514960

--------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |          |      1 |        |   3951 |00:00:46.28 |     435K|       |       |          |
|   1 |  SORT GROUP BY                             |          |      1 |     51 |   3951 |00:00:46.28 |     435K|   337K|   337K|  299K (0)|
|   2 |   VIEW                                     |          |      1 |     51 |  15000 |00:00:46.21 |     435K|       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|          |      1 |        |  15000 |00:00:46.21 |     435K|  2048 |  2048 |  991K (0)|
|*  4 |     VIEW                                   |          |      1 |      1 |      3 |00:00:00.01 |      84 |       |       |          |
|*  5 |      WINDOW SORT PUSHED RANK               |          |      1 |  15000 |      3 |00:00:00.01 |      84 |  1045K|   546K|  928K (0)|
|   6 |       TABLE ACCESS FULL                    | ACTIVITY |      1 |  15000 |  15000 |00:00:00.01 |      84 |       |       |          |
|*  7 |     HASH JOIN                              |          |   5000 |     50 |  14997 |00:00:40.33 |     420K|  1321K|  1321K|  675K (0)|
|   8 |      RECURSIVE WITH PUMP                   |          |   5000 |        |  15000 |00:00:00.01 |       0 |       |       |          |
|   9 |      VIEW                                  |          |   5000 |  15000 |     75M|00:00:51.50 |     420K|       |       |          |
|  10 |       WINDOW SORT                          |          |   5000 |  15000 |     75M|00:00:40.87 |     420K|   761K|   499K|  676K (0)|
|  11 |        TABLE ACCESS FULL                   | ACTIVITY |   5000 |  15000 |     75M|00:00:06.84 |     420K|       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   4 - filter("RN"=1)
   5 - filter(ROW_NUMBER() OVER ( PARTITION BY "PERSON_ID" ORDER BY "START_DATE")<=1)
   7 - access("RSQ"."RN"="ACT"."RN"-1 AND "RSQ"."PERSON_ID"="ACT"."PERSON_ID")


Timer Set: Cursor, Constructed at 06 Nov 2016 14:12:11, written at 14:12:58
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.02             1        0.00300        0.02000
First fetch             46.28       46.26             1       46.28300       46.26000
Write to file            0.01        0.02             5        0.00220        0.00400
Remaining fetches        0.00        0.00             4        0.00075        0.00000
Write plan               0.09        0.08             1        0.09100        0.08000
(Other)                  0.01        0.00             1        0.01100        0.00000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                   46.40       46.38            14        3.31443        3.31286
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:12:11, written at 14:12:58
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.02             6        0.00167        0.00333
(Other)       46.40       46.37             1       46.40300       46.37000
-------  ----------  ----------  ------------  -------------  -------------
Total         46.41       46.39             7        6.63043        6.62714
-------  ----------  ----------  ------------  -------------  -------------
3952 rows written to RSF_QRY.csv
Summary for W/D = 10/20 , bench_run_statistics_id = 6

Timer Set: Run_One, Constructed at 06 Nov 2016 14:12:11, written at 14:12:58
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run           46.42       46.41             1       46.42100       46.41000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total         46.42       46.41             2       23.21050       23.20500
-------  ----------  ----------  ------------  -------------  -------------
/* RSF_TMP */ WITH rsq (person_id, rn, start_date, end_date, group_start) AS ( SELECT person_id, act_rownum, start_date, end_date, start_date FROM activity_tmp WHERE act_rownum = 1 UNION ALL SELECT ac
t.person_id, act.act_rownum, act.start_date, act.end_date, CASE WHEN act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end FROM rsq JOIN act
ivity_tmp act ON act.act_rownum = rsq.rn + 1 AND act.person_id = rsq.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || Max (end_date) || '","' || CO
UNT(*) || '","6601"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id, group_start

INSERT INTO activity_tmp SELECT person_id, start_date, end_date, Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) FROM activity
SQL_ID  fvyh87y5xfv0r, child number 0
-------------------------------------
/* RSF_TMP */ WITH rsq (person_id, rn, start_date, end_date,
group_start) AS ( SELECT person_id, act_rownum, start_date, end_date,
start_date FROM activity_tmp WHERE act_rownum = 1 UNION ALL SELECT
act.person_id, act.act_rownum, act.start_date, act.end_date, CASE WHEN
act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep')
THEN rsq.group_start ELSE act.start_date end FROM rsq JOIN activity_tmp
act ON act.act_rownum = rsq.rn + 1 AND act.person_id = rsq.person_id )
SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' ||
group_start || '","' || Max (end_date) || '","' || COUNT(*) ||
'","6601"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id,
group_start

Plan hash value: 4212061972

---------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name            | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
---------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |                 |      1 |        |   3951 |00:00:00.13 |   35601 |       |       |          |
|   1 |  SORT GROUP BY                             |                 |      1 |      6 |   3951 |00:00:00.13 |   35601 |   337K|   337K|  299K (0)|
|   2 |   VIEW                                     |                 |      1 |      6 |  15000 |00:00:00.12 |   35601 |       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|                 |      1 |        |  15000 |00:00:00.11 |   35601 |  2048 |  2048 |  991K (0)|
|   4 |     TABLE ACCESS BY INDEX ROWID BATCHED    | ACTIVITY_TMP    |      1 |      3 |      3 |00:00:00.01 |       5 |       |       |          |
|*  5 |      INDEX RANGE SCAN                      | ACTIVITY_TMP_N1 |      1 |      3 |      3 |00:00:00.01 |       2 |       |       |          |
|   6 |     NESTED LOOPS                           |                 |   5000 |      3 |  14997 |00:00:00.05 |   20378 |       |       |          |
|   7 |      RECURSIVE WITH PUMP                   |                 |   5000 |        |  15000 |00:00:00.01 |       0 |       |       |          |
|   8 |      TABLE ACCESS BY INDEX ROWID BATCHED   | ACTIVITY_TMP    |  15000 |      1 |  14997 |00:00:00.04 |   20378 |       |       |          |
|*  9 |       INDEX RANGE SCAN                     | ACTIVITY_TMP_N1 |  15000 |    150 |  14997 |00:00:00.02 |    5381 |       |       |          |
---------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   5 - access("ACT_ROWNUM"=1)
   9 - access("ACT"."ACT_ROWNUM"="RSQ"."RN"+1 AND "ACT"."PERSON_ID"="RSQ"."PERSON_ID")

Note
-----
   - dynamic statistics used: dynamic sampling (level=2)
   - this is an adaptive plan


Timer Set: Cursor, Constructed at 06 Nov 2016 14:12:58, written at 14:12:58
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.02        0.02             1        0.02400        0.02000
Open cursor              0.01        0.02             1        0.01100        0.02000
First fetch              0.13        0.12             1        0.12600        0.12000
Write to file            0.01        0.02             5        0.00180        0.00400
Remaining fetches        0.00        0.00             4        0.00075        0.00000
Write plan               0.10        0.11             1        0.10300        0.11000
(Other)                  0.01        0.01             1        0.01300        0.01000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.29        0.30            14        0.02064        0.02143
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:12:58, written at 14:12:58
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.02             6        0.00117        0.00333
(Other)        0.29        0.28             1        0.29300        0.28000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.30        0.30             7        0.04286        0.04286
-------  ----------  ----------  ------------  -------------  -------------
3952 rows written to RSF_TMP.csv
Summary for W/D = 10/20 , bench_run_statistics_id = 7

Timer Set: Run_One, Constructed at 06 Nov 2016 14:12:58, written at 14:12:58
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.31        0.31             1        0.30700        0.31000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.31        0.31             2        0.15350        0.15500
-------  ----------  ----------  ------------  -------------  -------------
/* MTH_QRY */ SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || group_end || '","' || num_rows || '","8807"' FROM activity MATCH_RECOGNIZE ( PARTITION BY person
_id ORDER BY start_date MEASURES FIRST (start_date) group_start, FINAL MAX (end_date) group_end, COUNT(*) num_rows ONE ROW PER MATCH PATTERN (strt sm*) DEFINE sm AS sm.start_date <= strt.start_date +
Sys_Context('bench_ctx', 'deep') ) m ORDER BY person_id, group_start

SQL_ID  5qh2ma0quym30, child number 0
-------------------------------------
/* MTH_QRY */ SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id ||
'","' || group_start || '","' || group_end || '","' || num_rows ||
'","8807"' FROM activity MATCH_RECOGNIZE ( PARTITION BY person_id ORDER
BY start_date MEASURES FIRST (start_date) group_start, FINAL MAX
(end_date) group_end, COUNT(*) num_rows ONE ROW PER MATCH PATTERN (strt
sm*) DEFINE sm AS sm.start_date <= strt.start_date +
Sys_Context('bench_ctx', 'deep') ) m ORDER BY person_id, group_start

Plan hash value: 3670115155

--------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                        | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                                 |          |      1 |        |   3951 |00:00:00.02 |      84 |       |       |          |
|   1 |  SORT ORDER BY                                   |          |      1 |  15000 |   3951 |00:00:00.02 |      84 |   337K|   337K|  299K (0)|
|   2 |   VIEW                                           |          |      1 |  15000 |   3951 |00:00:00.01 |      84 |       |       |          |
|   3 |    MATCH RECOGNIZE SORT DETERMINISTIC FINITE AUTO|          |      1 |  15000 |   3951 |00:00:00.01 |      84 |   761K|   499K|  676K (0)|
|   4 |     TABLE ACCESS FULL                            | ACTIVITY |      1 |  15000 |  15000 |00:00:00.01 |      84 |       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------------


Timer Set: Cursor, Constructed at 06 Nov 2016 14:12:58, written at 14:12:58
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.00             1        0.00200        0.00000
First fetch              0.02        0.01             1        0.01600        0.01000
Write to file            0.01        0.02             5        0.00180        0.00400
Remaining fetches        0.00        0.00             4        0.00025        0.00000
Write plan               0.09        0.08             1        0.08500        0.08000
(Other)                  0.01        0.02             1        0.01100        0.02000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.12        0.13            14        0.00886        0.00929
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:12:58, written at 14:12:58
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.02             6        0.00150        0.00333
(Other)        0.13        0.12             1        0.12600        0.12000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.14        0.14             7        0.01929        0.02000
-------  ----------  ----------  ------------  -------------  -------------
3952 rows written to MTH_QRY.csv
Summary for W/D = 10/20 , bench_run_statistics_id = 8

Timer Set: Run_One, Constructed at 06 Nov 2016 14:12:58, written at 14:12:58
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.14        0.14             1        0.14200        0.14000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.14        0.14             2        0.07100        0.07000
-------  ----------  ----------  ------------  -------------  -------------
Activity truncated
15000 (5000) records (per person) added, average group size (from) = 5.3 (5000), # of groups = 943

Timer Set: Setup, Constructed at 06 Nov 2016 14:12:58, written at 14:12:59
==========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer                  Elapsed         CPU         Calls       Ela/Call       CPU/Call
------------------  ----------  ----------  ------------  -------------  -------------
Add_Act                   0.84        0.79             1        0.83700        0.79000
Gather_Table_Stats        0.08        0.08             1        0.07900        0.08000
GRP_CNT                   0.08        0.08             1        0.07500        0.08000
(Other)                   0.00        0.00             1        0.00000        0.00000
------------------  ----------  ----------  ------------  -------------  -------------
Total                     0.99        0.95             4        0.24775        0.23750
------------------  ----------  ----------  ------------  -------------  -------------
/* MOD_QRY */ WITH all_rows AS ( SELECT person_id, start_date, end_date, group_start FROM activity MODEL PARTITION BY (person_id) DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY start
_date) rn) MEASURES (start_date, end_date, start_date group_start) RULES ( group_start[rn = 1] = start_date[cv()], group_start[rn > 1] = CASE WHEN start_date[cv()] - group_start[cv()-1] > Sys_Context(
'bench_ctx', 'deep') THEN start_date[cv()] ELSE group_start[cv()-1] END ) ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || MAX(end_date) || '","' || COUNT(*)
 || '","569"' FROM all_rows GROUP BY person_id, group_start ORDER BY person_id, group_start

SQL_ID  3tpqqst0n8vft, child number 0
-------------------------------------
/* MOD_QRY */ WITH all_rows AS ( SELECT person_id, start_date,
end_date, group_start FROM activity MODEL PARTITION BY (person_id)
DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY
start_date) rn) MEASURES (start_date, end_date, start_date group_start)
RULES ( group_start[rn = 1] = start_date[cv()], group_start[rn > 1] =
CASE WHEN start_date[cv()] - group_start[cv()-1] >
Sys_Context('bench_ctx', 'deep') THEN start_date[cv()] ELSE
group_start[cv()-1] END ) ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' ||
person_id || '","' || group_start || '","' || MAX(end_date) || '","' ||
COUNT(*) || '","569"' FROM all_rows GROUP BY person_id, group_start
ORDER BY person_id, group_start

Plan hash value: 2323700320

-----------------------------------------------------------------------------------------------------------------------
| Id  | Operation             | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-----------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |          |      1 |        |   2910 |00:00:00.10 |      84 |       |       |          |
|   1 |  SORT GROUP BY        |          |      1 |  15000 |   2910 |00:00:00.10 |      84 |   214K|   214K|  190K (0)|
|   2 |   VIEW                |          |      1 |  15000 |  15000 |00:00:00.06 |      84 |       |       |          |
|   3 |    SQL MODEL ORDERED  |          |      1 |  15000 |  15000 |00:00:00.05 |      84 |  1977K|  1439K| 1140K (0)|
|   4 |     WINDOW SORT       |          |      1 |  15000 |  15000 |00:00:00.02 |      84 |   761K|   499K|  676K (0)|
|   5 |      TABLE ACCESS FULL| ACTIVITY |      1 |  15000 |  15000 |00:00:00.01 |      84 |       |       |          |
-----------------------------------------------------------------------------------------------------------------------


Timer Set: Cursor, Constructed at 06 Nov 2016 14:12:59, written at 14:13:00
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00100        0.00000
Open cursor              0.00        0.00             1        0.00300        0.00000
First fetch              0.10        0.11             1        0.09600        0.11000
Write to file            0.01        0.00             4        0.00150        0.00000
Remaining fetches        0.00        0.00             3        0.00067        0.00000
Write plan               0.09        0.10             1        0.08700        0.10000
(Other)                  0.55        0.04             1        0.55300        0.04000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.75        0.25            12        0.06233        0.02083
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:12:59, written at 14:13:00
================================================================================
[Timer timed: Elapsed (per call): 0.02 (0.000016), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.00             4        0.00125        0.00000
(Other)        0.76        0.25             1        0.75600        0.25000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.76        0.25             5        0.15220        0.05000
-------  ----------  ----------  ------------  -------------  -------------
2911 rows written to MOD_QRY.csv
Summary for W/D = 10/30 , bench_run_statistics_id = 9

Timer Set: Run_One, Constructed at 06 Nov 2016 14:12:59, written at 14:13:00
============================================================================
[Timer timed: Elapsed (per call): 0.02 (0.000015), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.82        0.28             1        0.82400        0.28000
(Other)        0.00        0.00             1        0.00100        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.83        0.28             2        0.41250        0.14000
-------  ----------  ----------  ------------  -------------  -------------
/* RSF_QRY */ WITH act AS ( SELECT person_id, start_date, end_date, Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn FROM activity ),	rsq (person_id, rn, start_date, end_date, group_s
tart) AS ( SELECT person_id, rn, start_date, end_date, start_date FROM act WHERE rn = 1 UNION ALL SELECT act.person_id, act.rn, act.start_date, act.end_date, CASE WHEN act.start_date - rsq.group_start
 <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end FROM act JOIN rsq ON rsq.rn = act.rn - 1 AND rsq.person_id = act.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"'
|| person_id || '","' || group_start || '","' || Max (end_date) || '","' || COUNT(*) || '","8963"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id, group_start

SQL_ID  akgqgmsubsxm4, child number 0
-------------------------------------
/* RSF_QRY */ WITH act AS ( SELECT person_id, start_date, end_date,
Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn FROM
activity ), rsq (person_id, rn, start_date, end_date, group_start) AS (
SELECT person_id, rn, start_date, end_date, start_date FROM act WHERE
rn = 1 UNION ALL SELECT act.person_id, act.rn, act.start_date,
act.end_date, CASE WHEN act.start_date - rsq.group_start <=
Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE
act.start_date end FROM act JOIN rsq ON rsq.rn = act.rn - 1 AND
rsq.person_id = act.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */
'"' || person_id || '","' || group_start || '","' || Max (end_date) ||
'","' || COUNT(*) || '","8963"' FROM rsq GROUP BY person_id,
group_start ORDER BY person_id, group_start

Plan hash value: 941514960

--------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |          |      1 |        |   2910 |00:00:46.68 |     435K|       |       |          |
|   1 |  SORT GROUP BY                             |          |      1 |     51 |   2910 |00:00:46.68 |     435K|   267K|   267K|  237K (0)|
|   2 |   VIEW                                     |          |      1 |     51 |  15000 |00:00:46.58 |     435K|       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|          |      1 |        |  15000 |00:00:46.58 |     435K|  2048 |  2048 |  991K (0)|
|*  4 |     VIEW                                   |          |      1 |      1 |      3 |00:00:00.02 |      84 |       |       |          |
|*  5 |      WINDOW SORT PUSHED RANK               |          |      1 |  15000 |      3 |00:00:00.02 |      84 |  1045K|   546K|  928K (0)|
|   6 |       TABLE ACCESS FULL                    | ACTIVITY |      1 |  15000 |  15000 |00:00:00.01 |      84 |       |       |          |
|*  7 |     HASH JOIN                              |          |   5000 |     50 |  14997 |00:00:40.67 |     420K|  1321K|  1321K|  652K (0)|
|   8 |      RECURSIVE WITH PUMP                   |          |   5000 |        |  15000 |00:00:00.01 |       0 |       |       |          |
|   9 |      VIEW                                  |          |   5000 |  15000 |     75M|00:00:51.99 |     420K|       |       |          |
|  10 |       WINDOW SORT                          |          |   5000 |  15000 |     75M|00:00:41.29 |     420K|   761K|   499K|  676K (0)|
|  11 |        TABLE ACCESS FULL                   | ACTIVITY |   5000 |  15000 |     75M|00:00:06.81 |     420K|       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   4 - filter("RN"=1)
   5 - filter(ROW_NUMBER() OVER ( PARTITION BY "PERSON_ID" ORDER BY "START_DATE")<=1)
   7 - access("RSQ"."RN"="ACT"."RN"-1 AND "RSQ"."PERSON_ID"="ACT"."PERSON_ID")


Timer Set: Cursor, Constructed at 06 Nov 2016 14:13:00, written at 14:13:47
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.00             1        0.00200        0.00000
First fetch             46.68       46.67             1       46.68200       46.67000
Write to file            0.01        0.02             4        0.00125        0.00500
Remaining fetches        0.00        0.00             3        0.00100        0.00000
Write plan               0.09        0.09             1        0.09000        0.09000
(Other)                  0.01        0.02             1        0.01400        0.02000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                   46.80       46.80            12        3.89967        3.90000
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:13:00, written at 14:13:47
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.02             4        0.00125        0.00500
(Other)       46.80       46.78             1       46.80300       46.78000
-------  ----------  ----------  ------------  -------------  -------------
Total         46.81       46.80             5        9.36160        9.36000
-------  ----------  ----------  ------------  -------------  -------------
2911 rows written to RSF_QRY.csv
Summary for W/D = 10/30 , bench_run_statistics_id = 10

Timer Set: Run_One, Constructed at 06 Nov 2016 14:13:00, written at 14:13:47
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run           46.82       46.82             1       46.81600       46.82000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total         46.82       46.82             2       23.40800       23.41000
-------  ----------  ----------  ------------  -------------  -------------
/* RSF_TMP */ WITH rsq (person_id, rn, start_date, end_date, group_start) AS ( SELECT person_id, act_rownum, start_date, end_date, start_date FROM activity_tmp WHERE act_rownum = 1 UNION ALL SELECT ac
t.person_id, act.act_rownum, act.start_date, act.end_date, CASE WHEN act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end FROM rsq JOIN act
ivity_tmp act ON act.act_rownum = rsq.rn + 1 AND act.person_id = rsq.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || Max (end_date) || '","' || CO
UNT(*) || '","7602"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id, group_start

INSERT INTO activity_tmp SELECT person_id, start_date, end_date, Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) FROM activity
SQL_ID  cutyv51tsp73k, child number 0
-------------------------------------
/* RSF_TMP */ WITH rsq (person_id, rn, start_date, end_date,
group_start) AS ( SELECT person_id, act_rownum, start_date, end_date,
start_date FROM activity_tmp WHERE act_rownum = 1 UNION ALL SELECT
act.person_id, act.act_rownum, act.start_date, act.end_date, CASE WHEN
act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep')
THEN rsq.group_start ELSE act.start_date end FROM rsq JOIN activity_tmp
act ON act.act_rownum = rsq.rn + 1 AND act.person_id = rsq.person_id )
SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' ||
group_start || '","' || Max (end_date) || '","' || COUNT(*) ||
'","7602"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id,
group_start

Plan hash value: 4212061972

---------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name            | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
---------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |                 |      1 |        |   2910 |00:00:00.12 |   35601 |       |       |          |
|   1 |  SORT GROUP BY                             |                 |      1 |      6 |   2910 |00:00:00.12 |   35601 |   267K|   267K|  237K (0)|
|   2 |   VIEW                                     |                 |      1 |      6 |  15000 |00:00:00.12 |   35601 |       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|                 |      1 |        |  15000 |00:00:00.11 |   35601 |  2048 |  2048 |  991K (0)|
|   4 |     TABLE ACCESS BY INDEX ROWID BATCHED    | ACTIVITY_TMP    |      1 |      3 |      3 |00:00:00.01 |       5 |       |       |          |
|*  5 |      INDEX RANGE SCAN                      | ACTIVITY_TMP_N1 |      1 |      3 |      3 |00:00:00.01 |       2 |       |       |          |
|   6 |     NESTED LOOPS                           |                 |   5000 |      3 |  14997 |00:00:00.05 |   20378 |       |       |          |
|   7 |      RECURSIVE WITH PUMP                   |                 |   5000 |        |  15000 |00:00:00.01 |       0 |       |       |          |
|   8 |      TABLE ACCESS BY INDEX ROWID BATCHED   | ACTIVITY_TMP    |  15000 |      1 |  14997 |00:00:00.04 |   20378 |       |       |          |
|*  9 |       INDEX RANGE SCAN                     | ACTIVITY_TMP_N1 |  15000 |    150 |  14997 |00:00:00.02 |    5381 |       |       |          |
---------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   5 - access("ACT_ROWNUM"=1)
   9 - access("ACT"."ACT_ROWNUM"="RSQ"."RN"+1 AND "ACT"."PERSON_ID"="RSQ"."PERSON_ID")

Note
-----
   - dynamic statistics used: dynamic sampling (level=2)
   - this is an adaptive plan


Timer Set: Cursor, Constructed at 06 Nov 2016 14:13:47, written at 14:13:47
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.02        0.03             1        0.02400        0.03000
Open cursor              0.01        0.00             1        0.01100        0.00000
First fetch              0.13        0.13             1        0.12500        0.13000
Write to file            0.01        0.01             4        0.00150        0.00250
Remaining fetches        0.00        0.00             3        0.00067        0.00000
Write plan               0.10        0.10             1        0.10400        0.10000
(Other)                  0.01        0.01             1        0.01100        0.01000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.28        0.28            12        0.02358        0.02333
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:13:47, written at 14:13:47
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.00        0.00             4        0.00075        0.00000
(Other)        0.29        0.29             1        0.29200        0.29000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.30        0.29             5        0.05900        0.05800
-------  ----------  ----------  ------------  -------------  -------------
2911 rows written to RSF_TMP.csv
Summary for W/D = 10/30 , bench_run_statistics_id = 11

Timer Set: Run_One, Constructed at 06 Nov 2016 14:13:47, written at 14:13:47
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.30        0.31             1        0.30300        0.31000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.30        0.31             2        0.15150        0.15500
-------  ----------  ----------  ------------  -------------  -------------
/* MTH_QRY */ SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || group_end || '","' || num_rows || '","9691"' FROM activity MATCH_RECOGNIZE ( PARTITION BY person
_id ORDER BY start_date MEASURES FIRST (start_date) group_start, FINAL MAX (end_date) group_end, COUNT(*) num_rows ONE ROW PER MATCH PATTERN (strt sm*) DEFINE sm AS sm.start_date <= strt.start_date +
Sys_Context('bench_ctx', 'deep') ) m ORDER BY person_id, group_start

SQL_ID  b89bart4jj4a5, child number 0
-------------------------------------
/* MTH_QRY */ SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id ||
'","' || group_start || '","' || group_end || '","' || num_rows ||
'","9691"' FROM activity MATCH_RECOGNIZE ( PARTITION BY person_id ORDER
BY start_date MEASURES FIRST (start_date) group_start, FINAL MAX
(end_date) group_end, COUNT(*) num_rows ONE ROW PER MATCH PATTERN (strt
sm*) DEFINE sm AS sm.start_date <= strt.start_date +
Sys_Context('bench_ctx', 'deep') ) m ORDER BY person_id, group_start

Plan hash value: 3670115155

--------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                        | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                                 |          |      1 |        |   2910 |00:00:00.01 |      84 |       |       |          |
|   1 |  SORT ORDER BY                                   |          |      1 |  15000 |   2910 |00:00:00.01 |      84 |   267K|   267K|  237K (0)|
|   2 |   VIEW                                           |          |      1 |  15000 |   2910 |00:00:00.01 |      84 |       |       |          |
|   3 |    MATCH RECOGNIZE SORT DETERMINISTIC FINITE AUTO|          |      1 |  15000 |   2910 |00:00:00.01 |      84 |   761K|   499K|  676K (0)|
|   4 |     TABLE ACCESS FULL                            | ACTIVITY |      1 |  15000 |  15000 |00:00:00.01 |      84 |       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------------


Timer Set: Cursor, Constructed at 06 Nov 2016 14:13:47, written at 14:13:47
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.00             1        0.00100        0.00000
First fetch              0.02        0.02             1        0.01500        0.02000
Write to file            0.01        0.00             4        0.00150        0.00000
Remaining fetches        0.00        0.00             3        0.00000        0.00000
Write plan               0.09        0.09             1        0.08600        0.09000
(Other)                  0.01        0.01             1        0.01100        0.01000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.12        0.12            12        0.00992        0.01000
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:13:47, written at 14:13:47
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.00             4        0.00125        0.00000
(Other)        0.13        0.12             1        0.12600        0.12000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.13        0.12             5        0.02620        0.02400
-------  ----------  ----------  ------------  -------------  -------------
2911 rows written to MTH_QRY.csv
Summary for W/D = 10/30 , bench_run_statistics_id = 12

Timer Set: Run_One, Constructed at 06 Nov 2016 14:13:47, written at 14:13:47
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.14        0.12             1        0.13800        0.12000
(Other)        0.00        0.00             1        0.00100        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.14        0.12             2        0.06950        0.06000
-------  ----------  ----------  ------------  -------------  -------------
Activity truncated
30000 (10000) records (per person) added, average group size (from) = 4.2 (10000), # of groups = 2401

Timer Set: Setup, Constructed at 06 Nov 2016 14:13:47, written at 14:13:51
==========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer                  Elapsed         CPU         Calls       Ela/Call       CPU/Call
------------------  ----------  ----------  ------------  -------------  -------------
Add_Act                   3.03        1.66             1        3.02900        1.66000
Gather_Table_Stats        0.14        0.14             1        0.13700        0.14000
GRP_CNT                   0.16        0.15             1        0.15700        0.15000
(Other)                   0.00        0.00             1        0.00100        0.00000
------------------  ----------  ----------  ------------  -------------  -------------
Total                     3.32        1.95             4        0.83100        0.48750
------------------  ----------  ----------  ------------  -------------  -------------
/* MOD_QRY */ WITH all_rows AS ( SELECT person_id, start_date, end_date, group_start FROM activity MODEL PARTITION BY (person_id) DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY start
_date) rn) MEASURES (start_date, end_date, start_date group_start) RULES ( group_start[rn = 1] = start_date[cv()], group_start[rn > 1] = CASE WHEN start_date[cv()] - group_start[cv()-1] > Sys_Context(
'bench_ctx', 'deep') THEN start_date[cv()] ELSE group_start[cv()-1] END ) ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || MAX(end_date) || '","' || COUNT(*)
 || '","916"' FROM all_rows GROUP BY person_id, group_start ORDER BY person_id, group_start

SQL_ID  ckjsfbtyzbs2v, child number 0
-------------------------------------
/* MOD_QRY */ WITH all_rows AS ( SELECT person_id, start_date,
end_date, group_start FROM activity MODEL PARTITION BY (person_id)
DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY
start_date) rn) MEASURES (start_date, end_date, start_date group_start)
RULES ( group_start[rn = 1] = start_date[cv()], group_start[rn > 1] =
CASE WHEN start_date[cv()] - group_start[cv()-1] >
Sys_Context('bench_ctx', 'deep') THEN start_date[cv()] ELSE
group_start[cv()-1] END ) ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' ||
person_id || '","' || group_start || '","' || MAX(end_date) || '","' ||
COUNT(*) || '","916"' FROM all_rows GROUP BY person_id, group_start
ORDER BY person_id, group_start

Plan hash value: 2323700320

-----------------------------------------------------------------------------------------------------------------------
| Id  | Operation             | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-----------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |          |      1 |        |   7710 |00:00:00.16 |     191 |       |       |          |
|   1 |  SORT GROUP BY        |          |      1 |  30000 |   7710 |00:00:00.16 |     191 |   619K|   619K|  550K (0)|
|   2 |   VIEW                |          |      1 |  30000 |  30000 |00:00:00.07 |     191 |       |       |          |
|   3 |    SQL MODEL ORDERED  |          |      1 |  30000 |  30000 |00:00:00.07 |     191 |  3145K|  1439K| 2084K (0)|
|   4 |     WINDOW SORT       |          |      1 |  30000 |  30000 |00:00:00.02 |     191 |  1399K|   597K| 1243K (0)|
|   5 |      TABLE ACCESS FULL| ACTIVITY |      1 |  30000 |  30000 |00:00:00.01 |     191 |       |       |          |
-----------------------------------------------------------------------------------------------------------------------


Timer Set: Cursor, Constructed at 06 Nov 2016 14:13:51, written at 14:13:51
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.00             1        0.00200        0.00000
First fetch              0.15        0.16             1        0.15400        0.16000
Write to file            0.02        0.00             9        0.00167        0.00000
Remaining fetches        0.01        0.02             8        0.00113        0.00250
Write plan               0.09        0.09             1        0.08600        0.09000
(Other)                  0.01        0.01             1        0.01100        0.01000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.28        0.28            22        0.01259        0.01273
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:13:51, written at 14:13:51
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.00            10        0.00120        0.00000
(Other)        0.28        0.28             1        0.27800        0.28000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.29        0.28            11        0.02636        0.02545
-------  ----------  ----------  ------------  -------------  -------------
7711 rows written to MOD_QRY.csv
Summary for W/D = 20/10 , bench_run_statistics_id = 13

Timer Set: Run_One, Constructed at 06 Nov 2016 14:13:51, written at 14:13:51
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.30        0.29             1        0.29700        0.29000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.30        0.29             2        0.14850        0.14500
-------  ----------  ----------  ------------  -------------  -------------
/* RSF_QRY */ WITH act AS ( SELECT person_id, start_date, end_date, Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn FROM activity ),	rsq (person_id, rn, start_date, end_date, group_s
tart) AS ( SELECT person_id, rn, start_date, end_date, start_date FROM act WHERE rn = 1 UNION ALL SELECT act.person_id, act.rn, act.start_date, act.end_date, CASE WHEN act.start_date - rsq.group_start
 <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end FROM act JOIN rsq ON rsq.rn = act.rn - 1 AND rsq.person_id = act.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"'
|| person_id || '","' || group_start || '","' || Max (end_date) || '","' || COUNT(*) || '","5085"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id, group_start

SQL_ID  2mrdn8ny8yngr, child number 0
-------------------------------------
/* RSF_QRY */ WITH act AS ( SELECT person_id, start_date, end_date,
Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn FROM
activity ), rsq (person_id, rn, start_date, end_date, group_start) AS (
SELECT person_id, rn, start_date, end_date, start_date FROM act WHERE
rn = 1 UNION ALL SELECT act.person_id, act.rn, act.start_date,
act.end_date, CASE WHEN act.start_date - rsq.group_start <=
Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE
act.start_date end FROM act JOIN rsq ON rsq.rn = act.rn - 1 AND
rsq.person_id = act.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */
'"' || person_id || '","' || group_start || '","' || Max (end_date) ||
'","' || COUNT(*) || '","5085"' FROM rsq GROUP BY person_id,
group_start ORDER BY person_id, group_start

Plan hash value: 941514960

--------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |          |      1 |        |   7710 |00:03:06.51 |    1952K|       |       |          |
|   1 |  SORT GROUP BY                             |          |      1 |    101 |   7710 |00:03:06.51 |    1952K|   690K|   690K|  613K (0)|
|   2 |   VIEW                                     |          |      1 |    101 |  30000 |00:03:07.18 |    1952K|       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|          |      1 |        |  30000 |00:03:07.17 |    1952K|  2048 |  2048 | 1936K (0)|
|*  4 |     VIEW                                   |          |      1 |      1 |      3 |00:00:00.04 |     191 |       |       |          |
|*  5 |      WINDOW SORT PUSHED RANK               |          |      1 |  30000 |      3 |00:00:00.04 |     191 |  2037K|   674K| 1810K (0)|
|   6 |       TABLE ACCESS FULL                    | ACTIVITY |      1 |  30000 |  30000 |00:00:00.01 |     191 |       |       |          |
|*  7 |     HASH JOIN                              |          |  10000 |    100 |  29997 |00:02:42.53 |    1910K|  1321K|  1321K|  708K (0)|
|   8 |      RECURSIVE WITH PUMP                   |          |  10000 |        |  30000 |00:00:00.01 |       0 |       |       |          |
|   9 |      VIEW                                  |          |  10000 |  30000 |    300M|00:03:30.02 |    1910K|       |       |          |
|  10 |       WINDOW SORT                          |          |  10000 |  30000 |    300M|00:02:47.07 |    1910K|  1399K|   597K| 1243K (0)|
|  11 |        TABLE ACCESS FULL                   | ACTIVITY |  10000 |  30000 |    300M|00:00:27.40 |    1910K|       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   4 - filter("RN"=1)
   5 - filter(ROW_NUMBER() OVER ( PARTITION BY "PERSON_ID" ORDER BY "START_DATE")<=1)
   7 - access("RSQ"."RN"="ACT"."RN"-1 AND "RSQ"."PERSON_ID"="ACT"."PERSON_ID")


Timer Set: Cursor, Constructed at 06 Nov 2016 14:13:51, written at 14:16:58
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.00             1        0.00200        0.00000
First fetch            186.51      186.41             1      186.50900      186.41000
Write to file            0.02        0.00             9        0.00189        0.00000
Remaining fetches        0.01        0.01             8        0.00088        0.00125
Write plan               0.09        0.10             1        0.09100        0.10000
(Other)                  0.01        0.02             1        0.01100        0.02000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                  186.64      186.54            22        8.48350        8.47909
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:13:51, written at 14:16:58
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.00            11        0.00127        0.00000
(Other)      186.64      186.55             1      186.63700      186.55000
-------  ----------  ----------  ------------  -------------  -------------
Total        186.65      186.55            12       15.55425       15.54583
-------  ----------  ----------  ------------  -------------  -------------
7711 rows written to RSF_QRY.csv
Summary for W/D = 20/10 , bench_run_statistics_id = 14

Timer Set: Run_One, Constructed at 06 Nov 2016 14:13:51, written at 14:16:58
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run          186.66      186.57             1      186.66100      186.57000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total        186.66      186.57             2       93.33050       93.28500
-------  ----------  ----------  ------------  -------------  -------------
/* RSF_TMP */ WITH rsq (person_id, rn, start_date, end_date, group_start) AS ( SELECT person_id, act_rownum, start_date, end_date, start_date FROM activity_tmp WHERE act_rownum = 1 UNION ALL SELECT ac
t.person_id, act.act_rownum, act.start_date, act.end_date, CASE WHEN act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end FROM rsq JOIN act
ivity_tmp act ON act.act_rownum = rsq.rn + 1 AND act.person_id = rsq.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || Max (end_date) || '","' || CO
UNT(*) || '","1356"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id, group_start

INSERT INTO activity_tmp SELECT person_id, start_date, end_date, Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) FROM activity
SQL_ID  g5jbxfqp3x014, child number 0
-------------------------------------
/* RSF_TMP */ WITH rsq (person_id, rn, start_date, end_date,
group_start) AS ( SELECT person_id, act_rownum, start_date, end_date,
start_date FROM activity_tmp WHERE act_rownum = 1 UNION ALL SELECT
act.person_id, act.act_rownum, act.start_date, act.end_date, CASE WHEN
act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep')
THEN rsq.group_start ELSE act.start_date end FROM rsq JOIN activity_tmp
act ON act.act_rownum = rsq.rn + 1 AND act.person_id = rsq.person_id )
SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' ||
group_start || '","' || Max (end_date) || '","' || COUNT(*) ||
'","1356"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id,
group_start

Plan hash value: 4212061972

---------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name            | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
---------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |                 |      1 |        |   7710 |00:00:00.26 |   82728 |       |       |          |
|   1 |  SORT GROUP BY                             |                 |      1 |      6 |   7710 |00:00:00.26 |   82728 |   690K|   690K|  613K (0)|
|   2 |   VIEW                                     |                 |      1 |      6 |  30000 |00:00:00.23 |   82728 |       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|                 |      1 |        |  30000 |00:00:00.23 |   82728 |  2048 |  2048 | 1936K (0)|
|   4 |     TABLE ACCESS BY INDEX ROWID BATCHED    | ACTIVITY_TMP    |      1 |      3 |      3 |00:00:00.01 |       5 |       |       |          |
|*  5 |      INDEX RANGE SCAN                      | ACTIVITY_TMP_N1 |      1 |      3 |      3 |00:00:00.01 |       2 |       |       |          |
|   6 |     NESTED LOOPS                           |                 |  10000 |      3 |  29997 |00:00:00.10 |   40762 |       |       |          |
|   7 |      RECURSIVE WITH PUMP                   |                 |  10000 |        |  30000 |00:00:00.01 |       0 |       |       |          |
|   8 |      TABLE ACCESS BY INDEX ROWID BATCHED   | ACTIVITY_TMP    |  30000 |      1 |  29997 |00:00:00.07 |   40762 |       |       |          |
|*  9 |       INDEX RANGE SCAN                     | ACTIVITY_TMP_N1 |  30000 |    242 |  29997 |00:00:00.03 |   10765 |       |       |          |
---------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   5 - access("ACT_ROWNUM"=1)
   9 - access("ACT"."ACT_ROWNUM"="RSQ"."RN"+1 AND "ACT"."PERSON_ID"="RSQ"."PERSON_ID")

Note
-----
   - dynamic statistics used: dynamic sampling (level=2)
   - this is an adaptive plan


Timer Set: Cursor, Constructed at 06 Nov 2016 14:16:58, written at 14:16:59
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.05        0.05             1        0.05400        0.05000
Open cursor              0.01        0.02             1        0.01200        0.02000
First fetch              0.26        0.26             1        0.26300        0.26000
Write to file            0.02        0.02             9        0.00178        0.00222
Remaining fetches        0.01        0.00             8        0.00100        0.00000
Write plan               0.10        0.11             1        0.10400        0.11000
(Other)                  0.31        0.04             1        0.30800        0.04000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.77        0.50            22        0.03477        0.02273
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:16:58, written at 14:16:59
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.02            11        0.00127        0.00182
(Other)        0.78        0.49             1        0.77700        0.49000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.79        0.51            12        0.06592        0.04250
-------  ----------  ----------  ------------  -------------  -------------
7711 rows written to RSF_TMP.csv
Summary for W/D = 20/10 , bench_run_statistics_id = 15

Timer Set: Run_One, Constructed at 06 Nov 2016 14:16:58, written at 14:16:59
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.80        0.51             1        0.79900        0.51000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.80        0.51             2        0.39950        0.25500
-------  ----------  ----------  ------------  -------------  -------------
/* MTH_QRY */ SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || group_end || '","' || num_rows || '","705"' FROM activity MATCH_RECOGNIZE ( PARTITION BY person_
id ORDER BY start_date MEASURES FIRST (start_date) group_start, FINAL MAX (end_date) group_end, COUNT(*) num_rows ONE ROW PER MATCH PATTERN (strt sm*) DEFINE sm AS sm.start_date <= strt.start_date + S
ys_Context('bench_ctx', 'deep') ) m ORDER BY person_id, group_start

SQL_ID  g47a5qfh3dq9j, child number 0
-------------------------------------
/* MTH_QRY */ SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id ||
'","' || group_start || '","' || group_end || '","' || num_rows ||
'","705"' FROM activity MATCH_RECOGNIZE ( PARTITION BY person_id ORDER
BY start_date MEASURES FIRST (start_date) group_start, FINAL MAX
(end_date) group_end, COUNT(*) num_rows ONE ROW PER MATCH PATTERN (strt
sm*) DEFINE sm AS sm.start_date <= strt.start_date +
Sys_Context('bench_ctx', 'deep') ) m ORDER BY person_id, group_start

Plan hash value: 3670115155

--------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                        | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                                 |          |      1 |        |   7710 |00:00:00.03 |     191 |       |       |          |
|   1 |  SORT ORDER BY                                   |          |      1 |  30000 |   7710 |00:00:00.03 |     191 |   690K|   486K|  613K (0)|
|   2 |   VIEW                                           |          |      1 |  30000 |   7710 |00:00:00.03 |     191 |       |       |          |
|   3 |    MATCH RECOGNIZE SORT DETERMINISTIC FINITE AUTO|          |      1 |  30000 |   7710 |00:00:00.02 |     191 |  1399K|   597K| 1243K (0)|
|   4 |     TABLE ACCESS FULL                            | ACTIVITY |      1 |  30000 |  30000 |00:00:00.01 |     191 |       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------------


Timer Set: Cursor, Constructed at 06 Nov 2016 14:16:59, written at 14:16:59
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.01             1        0.00100        0.01000
First fetch              0.03        0.02             1        0.03100        0.02000
Write to file            0.01        0.03             9        0.00144        0.00333
Remaining fetches        0.01        0.00             8        0.00063        0.00000
Write plan               0.09        0.08             1        0.08600        0.08000
(Other)                  0.01        0.00             1        0.01100        0.00000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.15        0.14            22        0.00668        0.00636
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:16:59, written at 14:16:59
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000009), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.01            10        0.00130        0.00100
(Other)        0.16        0.14             1        0.15600        0.14000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.17        0.15            11        0.01536        0.01364
-------  ----------  ----------  ------------  -------------  -------------
7711 rows written to MTH_QRY.csv
Summary for W/D = 20/10 , bench_run_statistics_id = 16

Timer Set: Run_One, Constructed at 06 Nov 2016 14:16:59, written at 14:16:59
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000012), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.18        0.15             1        0.18000        0.15000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.18        0.15             2        0.09000        0.07500
-------  ----------  ----------  ------------  -------------  -------------
Activity truncated
30000 (10000) records (per person) added, average group size (from) = 6.9 (10000), # of groups = 1445.7

Timer Set: Setup, Constructed at 06 Nov 2016 14:16:59, written at 14:17:01
==========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                  Elapsed         CPU         Calls       Ela/Call       CPU/Call
------------------  ----------  ----------  ------------  -------------  -------------
Add_Act                   1.57        1.55             1        1.57100        1.55000
Gather_Table_Stats        0.21        0.12             1        0.21300        0.12000
GRP_CNT                   0.18        0.19             1        0.18000        0.19000
(Other)                   0.00        0.00             1        0.00000        0.00000
------------------  ----------  ----------  ------------  -------------  -------------
Total                     1.96        1.86             4        0.49100        0.46500
------------------  ----------  ----------  ------------  -------------  -------------
/* MOD_QRY */ WITH all_rows AS ( SELECT person_id, start_date, end_date, group_start FROM activity MODEL PARTITION BY (person_id) DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY start
_date) rn) MEASURES (start_date, end_date, start_date group_start) RULES ( group_start[rn = 1] = start_date[cv()], group_start[rn > 1] = CASE WHEN start_date[cv()] - group_start[cv()-1] > Sys_Context(
'bench_ctx', 'deep') THEN start_date[cv()] ELSE group_start[cv()-1] END ) ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || MAX(end_date) || '","' || COUNT(*)
 || '","7148"' FROM all_rows GROUP BY person_id, group_start ORDER BY person_id, group_start

SQL_ID  97910ugmnj5pd, child number 0
-------------------------------------
/* MOD_QRY */ WITH all_rows AS ( SELECT person_id, start_date,
end_date, group_start FROM activity MODEL PARTITION BY (person_id)
DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY
start_date) rn) MEASURES (start_date, end_date, start_date group_start)
RULES ( group_start[rn = 1] = start_date[cv()], group_start[rn > 1] =
CASE WHEN start_date[cv()] - group_start[cv()-1] >
Sys_Context('bench_ctx', 'deep') THEN start_date[cv()] ELSE
group_start[cv()-1] END ) ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' ||
person_id || '","' || group_start || '","' || MAX(end_date) || '","' ||
COUNT(*) || '","7148"' FROM all_rows GROUP BY person_id, group_start
ORDER BY person_id, group_start

Plan hash value: 2323700320

-----------------------------------------------------------------------------------------------------------------------
| Id  | Operation             | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-----------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |          |      1 |        |   4537 |00:00:00.16 |     191 |       |       |          |
|   1 |  SORT GROUP BY        |          |      1 |  30000 |   4537 |00:00:00.16 |     191 |   337K|   337K|  299K (0)|
|   2 |   VIEW                |          |      1 |  30000 |  30000 |00:00:00.08 |     191 |       |       |          |
|   3 |    SQL MODEL ORDERED  |          |      1 |  30000 |  30000 |00:00:00.07 |     191 |  3145K|  1439K| 2087K (0)|
|   4 |     WINDOW SORT       |          |      1 |  30000 |  30000 |00:00:00.02 |     191 |  1399K|   597K| 1243K (0)|
|   5 |      TABLE ACCESS FULL| ACTIVITY |      1 |  30000 |  30000 |00:00:00.01 |     191 |       |       |          |
-----------------------------------------------------------------------------------------------------------------------


Timer Set: Cursor, Constructed at 06 Nov 2016 14:17:01, written at 14:17:01
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.00             1        0.00200        0.00000
First fetch              0.16        0.15             1        0.15800        0.15000
Write to file            0.01        0.00             6        0.00150        0.00000
Remaining fetches        0.00        0.02             5        0.00080        0.00400
Write plan               0.09        0.09             1        0.08600        0.09000
(Other)                  0.01        0.02             1        0.01100        0.02000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.27        0.28            16        0.01688        0.01750
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:17:01, written at 14:17:01
================================================================================
[Timer timed: Elapsed (per call): 0.03 (0.000026), CPU (per call): 0.03 (0.000030), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.00             6        0.00150        0.00000
(Other)        0.36        0.28             1        0.36400        0.28000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.37        0.28             7        0.05329        0.04000
-------  ----------  ----------  ------------  -------------  -------------
4538 rows written to MOD_QRY.csv
Summary for W/D = 20/20 , bench_run_statistics_id = 17

Timer Set: Run_One, Constructed at 06 Nov 2016 14:17:01, written at 14:17:01
============================================================================
[Timer timed: Elapsed (per call): 0.02 (0.000016), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.40        0.31             1        0.40300        0.31000
(Other)        0.00        0.00             1        0.00100        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.40        0.31             2        0.20200        0.15500
-------  ----------  ----------  ------------  -------------  -------------
/* RSF_QRY */ WITH act AS ( SELECT person_id, start_date, end_date, Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn FROM activity ),	rsq (person_id, rn, start_date, end_date, group_s
tart) AS ( SELECT person_id, rn, start_date, end_date, start_date FROM act WHERE rn = 1 UNION ALL SELECT act.person_id, act.rn, act.start_date, act.end_date, CASE WHEN act.start_date - rsq.group_start
 <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end FROM act JOIN rsq ON rsq.rn = act.rn - 1 AND rsq.person_id = act.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"'
|| person_id || '","' || group_start || '","' || Max (end_date) || '","' || COUNT(*) || '","8331"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id, group_start

SQL_ID  1497zsaj86zzp, child number 0
-------------------------------------
/* RSF_QRY */ WITH act AS ( SELECT person_id, start_date, end_date,
Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn FROM
activity ), rsq (person_id, rn, start_date, end_date, group_start) AS (
SELECT person_id, rn, start_date, end_date, start_date FROM act WHERE
rn = 1 UNION ALL SELECT act.person_id, act.rn, act.start_date,
act.end_date, CASE WHEN act.start_date - rsq.group_start <=
Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE
act.start_date end FROM act JOIN rsq ON rsq.rn = act.rn - 1 AND
rsq.person_id = act.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */
'"' || person_id || '","' || group_start || '","' || Max (end_date) ||
'","' || COUNT(*) || '","8331"' FROM rsq GROUP BY person_id,
group_start ORDER BY person_id, group_start

Plan hash value: 941514960

--------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |          |      1 |        |   4537 |00:03:10.34 |    1952K|       |       |          |
|   1 |  SORT GROUP BY                             |          |      1 |    101 |   4537 |00:03:10.34 |    1952K|   372K|   372K|  330K (0)|
|   2 |   VIEW                                     |          |      1 |    101 |  30000 |00:03:10.47 |    1952K|       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|          |      1 |        |  30000 |00:03:10.46 |    1952K|  2048 |  2048 | 1936K (0)|
|*  4 |     VIEW                                   |          |      1 |      1 |      3 |00:00:00.03 |     191 |       |       |          |
|*  5 |      WINDOW SORT PUSHED RANK               |          |      1 |  30000 |      3 |00:00:00.03 |     191 |  2037K|   674K| 1810K (0)|
|   6 |       TABLE ACCESS FULL                    | ACTIVITY |      1 |  30000 |  30000 |00:00:00.01 |     191 |       |       |          |
|*  7 |     HASH JOIN                              |          |  10000 |    100 |  29997 |00:02:46.07 |    1910K|  1321K|  1321K|  629K (0)|
|   8 |      RECURSIVE WITH PUMP                   |          |  10000 |        |  30000 |00:00:00.02 |       0 |       |       |          |
|   9 |      VIEW                                  |          |  10000 |  30000 |    300M|00:03:31.08 |    1910K|       |       |          |
|  10 |       WINDOW SORT                          |          |  10000 |  30000 |    300M|00:02:47.59 |    1910K|  1399K|   597K| 1243K (0)|
|  11 |        TABLE ACCESS FULL                   | ACTIVITY |  10000 |  30000 |    300M|00:00:28.03 |    1910K|       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   4 - filter("RN"=1)
   5 - filter(ROW_NUMBER() OVER ( PARTITION BY "PERSON_ID" ORDER BY "START_DATE")<=1)
   7 - access("RSQ"."RN"="ACT"."RN"-1 AND "RSQ"."PERSON_ID"="ACT"."PERSON_ID")


Timer Set: Cursor, Constructed at 06 Nov 2016 14:17:01, written at 14:20:12
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.00             1        0.00200        0.00000
First fetch            190.34      190.24             1      190.34000      190.24000
Write to file            0.01        0.01             6        0.00167        0.00167
Remaining fetches        0.01        0.00             5        0.00100        0.00000
Write plan               0.10        0.11             1        0.09900        0.11000
(Other)                  0.01        0.00             1        0.01300        0.00000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                  190.47      190.36            16       11.90431       11.89750
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:17:01, written at 14:20:12
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.01             6        0.00117        0.00167
(Other)      190.51      190.35             1      190.50700      190.35000
-------  ----------  ----------  ------------  -------------  -------------
Total        190.51      190.36             7       27.21629       27.19429
-------  ----------  ----------  ------------  -------------  -------------
4538 rows written to RSF_QRY.csv
Summary for W/D = 20/20 , bench_run_statistics_id = 18

Timer Set: Run_One, Constructed at 06 Nov 2016 14:17:01, written at 14:20:12
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000008), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run          190.52      190.38             1      190.52300      190.38000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total        190.52      190.38             2       95.26150       95.19000
-------  ----------  ----------  ------------  -------------  -------------
/* RSF_TMP */ WITH rsq (person_id, rn, start_date, end_date, group_start) AS ( SELECT person_id, act_rownum, start_date, end_date, start_date FROM activity_tmp WHERE act_rownum = 1 UNION ALL SELECT ac
t.person_id, act.act_rownum, act.start_date, act.end_date, CASE WHEN act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end FROM rsq JOIN act
ivity_tmp act ON act.act_rownum = rsq.rn + 1 AND act.person_id = rsq.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || Max (end_date) || '","' || CO
UNT(*) || '","9102"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id, group_start

INSERT INTO activity_tmp SELECT person_id, start_date, end_date, Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) FROM activity
SQL_ID  730af666u48r7, child number 0
-------------------------------------
/* RSF_TMP */ WITH rsq (person_id, rn, start_date, end_date,
group_start) AS ( SELECT person_id, act_rownum, start_date, end_date,
start_date FROM activity_tmp WHERE act_rownum = 1 UNION ALL SELECT
act.person_id, act.act_rownum, act.start_date, act.end_date, CASE WHEN
act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep')
THEN rsq.group_start ELSE act.start_date end FROM rsq JOIN activity_tmp
act ON act.act_rownum = rsq.rn + 1 AND act.person_id = rsq.person_id )
SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' ||
group_start || '","' || Max (end_date) || '","' || COUNT(*) ||
'","9102"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id,
group_start

Plan hash value: 4212061972

---------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name            | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
---------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |                 |      1 |        |   4537 |00:00:00.31 |   82705 |       |       |          |
|   1 |  SORT GROUP BY                             |                 |      1 |      6 |   4537 |00:00:00.31 |   82705 |   372K|   372K|  330K (0)|
|   2 |   VIEW                                     |                 |      1 |      6 |  30000 |00:00:00.30 |   82705 |       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|                 |      1 |        |  30000 |00:00:00.29 |   82705 |  2048 |  2048 | 1936K (0)|
|   4 |     TABLE ACCESS BY INDEX ROWID BATCHED    | ACTIVITY_TMP    |      1 |      3 |      3 |00:00:00.01 |       5 |       |       |          |
|*  5 |      INDEX RANGE SCAN                      | ACTIVITY_TMP_N1 |      1 |      3 |      3 |00:00:00.01 |       2 |       |       |          |
|   6 |     NESTED LOOPS                           |                 |  10000 |      3 |  29997 |00:00:00.12 |   40739 |       |       |          |
|   7 |      RECURSIVE WITH PUMP                   |                 |  10000 |        |  30000 |00:00:00.01 |       0 |       |       |          |
|   8 |      TABLE ACCESS BY INDEX ROWID BATCHED   | ACTIVITY_TMP    |  30000 |      1 |  29997 |00:00:00.09 |   40739 |       |       |          |
|*  9 |       INDEX RANGE SCAN                     | ACTIVITY_TMP_N1 |  30000 |    290 |  29997 |00:00:00.04 |   10742 |       |       |          |
---------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   5 - access("ACT_ROWNUM"=1)
   9 - access("ACT"."ACT_ROWNUM"="RSQ"."RN"+1 AND "ACT"."PERSON_ID"="RSQ"."PERSON_ID")

Note
-----
   - dynamic statistics used: dynamic sampling (level=2)
   - this is an adaptive plan


Timer Set: Cursor, Constructed at 06 Nov 2016 14:20:12, written at 14:20:12
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.07        0.05             1        0.07200        0.05000
Open cursor              0.02        0.01             1        0.01800        0.01000
First fetch              0.31        0.31             1        0.31400        0.31000
Write to file            0.01        0.02             6        0.00150        0.00333
Remaining fetches        0.01        0.00             5        0.00100        0.00000
Write plan               0.11        0.11             1        0.10900        0.11000
(Other)                  0.02        0.02             1        0.01500        0.02000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.54        0.52            16        0.03388        0.03250
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:20:12, written at 14:20:12
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.00             6        0.00133        0.00000
(Other)        0.55        0.54             1        0.54600        0.54000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.55        0.54             7        0.07914        0.07714
-------  ----------  ----------  ------------  -------------  -------------
4538 rows written to RSF_TMP.csv
Summary for W/D = 20/20 , bench_run_statistics_id = 19

Timer Set: Run_One, Constructed at 06 Nov 2016 14:20:12, written at 14:20:12
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.56        0.55             1        0.56200        0.55000
(Other)        0.00        0.00             1        0.00100        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.56        0.55             2        0.28150        0.27500
-------  ----------  ----------  ------------  -------------  -------------
/* MTH_QRY */ SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || group_end || '","' || num_rows || '","4943"' FROM activity MATCH_RECOGNIZE ( PARTITION BY person
_id ORDER BY start_date MEASURES FIRST (start_date) group_start, FINAL MAX (end_date) group_end, COUNT(*) num_rows ONE ROW PER MATCH PATTERN (strt sm*) DEFINE sm AS sm.start_date <= strt.start_date +
Sys_Context('bench_ctx', 'deep') ) m ORDER BY person_id, group_start

SQL_ID  2t8bgn1k0r1nq, child number 0
-------------------------------------
/* MTH_QRY */ SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id ||
'","' || group_start || '","' || group_end || '","' || num_rows ||
'","4943"' FROM activity MATCH_RECOGNIZE ( PARTITION BY person_id ORDER
BY start_date MEASURES FIRST (start_date) group_start, FINAL MAX
(end_date) group_end, COUNT(*) num_rows ONE ROW PER MATCH PATTERN (strt
sm*) DEFINE sm AS sm.start_date <= strt.start_date +
Sys_Context('bench_ctx', 'deep') ) m ORDER BY person_id, group_start

Plan hash value: 3670115155

--------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                        | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                                 |          |      1 |        |   4537 |00:00:00.03 |     191 |       |       |          |
|   1 |  SORT ORDER BY                                   |          |      1 |  30000 |   4537 |00:00:00.03 |     191 |   407K|   407K|  361K (0)|
|   2 |   VIEW                                           |          |      1 |  30000 |   4537 |00:00:00.02 |     191 |       |       |          |
|   3 |    MATCH RECOGNIZE SORT DETERMINISTIC FINITE AUTO|          |      1 |  30000 |   4537 |00:00:00.02 |     191 |  1399K|   597K| 1243K (0)|
|   4 |     TABLE ACCESS FULL                            | ACTIVITY |      1 |  30000 |  30000 |00:00:00.01 |     191 |       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------------


Timer Set: Cursor, Constructed at 06 Nov 2016 14:20:12, written at 14:20:12
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.00             1        0.00100        0.00000
First fetch              0.03        0.03             1        0.02800        0.03000
Write to file            0.01        0.00             6        0.00133        0.00000
Remaining fetches        0.00        0.00             5        0.00060        0.00000
Write plan               0.10        0.11             1        0.09500        0.11000
(Other)                  0.01        0.02             1        0.01300        0.02000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.15        0.16            16        0.00925        0.01000
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:20:12, written at 14:20:12
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.00             6        0.00117        0.00000
(Other)        0.15        0.16             1        0.15400        0.16000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.16        0.16             7        0.02300        0.02286
-------  ----------  ----------  ------------  -------------  -------------
4538 rows written to MTH_QRY.csv
Summary for W/D = 20/20 , bench_run_statistics_id = 20

Timer Set: Run_One, Constructed at 06 Nov 2016 14:20:12, written at 14:20:12
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.17        0.17             1        0.16900        0.17000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.17        0.17             2        0.08450        0.08500
-------  ----------  ----------  ------------  -------------  -------------
Activity truncated
30000 (10000) records (per person) added, average group size (from) = 9.6 (10000), # of groups = 1037.3

Timer Set: Setup, Constructed at 06 Nov 2016 14:20:12, written at 14:20:14
==========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer                  Elapsed         CPU         Calls       Ela/Call       CPU/Call
------------------  ----------  ----------  ------------  -------------  -------------
Add_Act                   1.79        1.67             1        1.78900        1.67000
Gather_Table_Stats        0.14        0.15             1        0.13600        0.15000
GRP_CNT                   0.15        0.14             1        0.14900        0.14000
(Other)                   0.00        0.00             1        0.00000        0.00000
------------------  ----------  ----------  ------------  -------------  -------------
Total                     2.07        1.96             4        0.51850        0.49000
------------------  ----------  ----------  ------------  -------------  -------------
/* MOD_QRY */ WITH all_rows AS ( SELECT person_id, start_date, end_date, group_start FROM activity MODEL PARTITION BY (person_id) DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY start
_date) rn) MEASURES (start_date, end_date, start_date group_start) RULES ( group_start[rn = 1] = start_date[cv()], group_start[rn > 1] = CASE WHEN start_date[cv()] - group_start[cv()-1] > Sys_Context(
'bench_ctx', 'deep') THEN start_date[cv()] ELSE group_start[cv()-1] END ) ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || MAX(end_date) || '","' || COUNT(*)
 || '","1259"' FROM all_rows GROUP BY person_id, group_start ORDER BY person_id, group_start

SQL_ID  cmg2d89294rjh, child number 0
-------------------------------------
/* MOD_QRY */ WITH all_rows AS ( SELECT person_id, start_date,
end_date, group_start FROM activity MODEL PARTITION BY (person_id)
DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY
start_date) rn) MEASURES (start_date, end_date, start_date group_start)
RULES ( group_start[rn = 1] = start_date[cv()], group_start[rn > 1] =
CASE WHEN start_date[cv()] - group_start[cv()-1] >
Sys_Context('bench_ctx', 'deep') THEN start_date[cv()] ELSE
group_start[cv()-1] END ) ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' ||
person_id || '","' || group_start || '","' || MAX(end_date) || '","' ||
COUNT(*) || '","1259"' FROM all_rows GROUP BY person_id, group_start
ORDER BY person_id, group_start

Plan hash value: 2323700320

-----------------------------------------------------------------------------------------------------------------------
| Id  | Operation             | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-----------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |          |      1 |        |   3199 |00:00:00.16 |     191 |       |       |          |
|   1 |  SORT GROUP BY        |          |      1 |  30000 |   3199 |00:00:00.16 |     191 |   267K|   267K|  237K (0)|
|   2 |   VIEW                |          |      1 |  30000 |  30000 |00:00:00.07 |     191 |       |       |          |
|   3 |    SQL MODEL ORDERED  |          |      1 |  30000 |  30000 |00:00:00.07 |     191 |  3145K|  1439K| 2086K (0)|
|   4 |     WINDOW SORT       |          |      1 |  30000 |  30000 |00:00:00.02 |     191 |  1399K|   597K| 1243K (0)|
|   5 |      TABLE ACCESS FULL| ACTIVITY |      1 |  30000 |  30000 |00:00:00.01 |     191 |       |       |          |
-----------------------------------------------------------------------------------------------------------------------


Timer Set: Cursor, Constructed at 06 Nov 2016 14:20:15, written at 14:20:15
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.02             1        0.00100        0.02000
First fetch              0.16        0.15             1        0.16000        0.15000
Write to file            0.02        0.00             5        0.00400        0.00000
Remaining fetches        0.00        0.00             4        0.00050        0.00000
Write plan               0.09        0.10             1        0.09200        0.10000
(Other)                  0.01        0.00             1        0.01200        0.00000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.29        0.27            14        0.02050        0.01929
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:20:15, written at 14:20:15
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.02        0.00             5        0.00320        0.00000
(Other)        0.28        0.28             1        0.28300        0.28000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.30        0.28             6        0.04983        0.04667
-------  ----------  ----------  ------------  -------------  -------------
3200 rows written to MOD_QRY.csv
Summary for W/D = 20/30 , bench_run_statistics_id = 21

Timer Set: Run_One, Constructed at 06 Nov 2016 14:20:15, written at 14:20:15
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.31        0.28             1        0.30700        0.28000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.31        0.28             2        0.15350        0.14000
-------  ----------  ----------  ------------  -------------  -------------
/* RSF_QRY */ WITH act AS ( SELECT person_id, start_date, end_date, Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn FROM activity ),	rsq (person_id, rn, start_date, end_date, group_s
tart) AS ( SELECT person_id, rn, start_date, end_date, start_date FROM act WHERE rn = 1 UNION ALL SELECT act.person_id, act.rn, act.start_date, act.end_date, CASE WHEN act.start_date - rsq.group_start
 <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end FROM act JOIN rsq ON rsq.rn = act.rn - 1 AND rsq.person_id = act.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"'
|| person_id || '","' || group_start || '","' || Max (end_date) || '","' || COUNT(*) || '","8120"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id, group_start

SQL_ID  f0d0a3v5x32uc, child number 0
-------------------------------------
/* RSF_QRY */ WITH act AS ( SELECT person_id, start_date, end_date,
Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn FROM
activity ), rsq (person_id, rn, start_date, end_date, group_start) AS (
SELECT person_id, rn, start_date, end_date, start_date FROM act WHERE
rn = 1 UNION ALL SELECT act.person_id, act.rn, act.start_date,
act.end_date, CASE WHEN act.start_date - rsq.group_start <=
Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE
act.start_date end FROM act JOIN rsq ON rsq.rn = act.rn - 1 AND
rsq.person_id = act.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */
'"' || person_id || '","' || group_start || '","' || Max (end_date) ||
'","' || COUNT(*) || '","8120"' FROM rsq GROUP BY person_id,
group_start ORDER BY person_id, group_start

Plan hash value: 941514960

--------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |          |      1 |        |   3199 |00:03:07.43 |    1952K|       |       |          |
|   1 |  SORT GROUP BY                             |          |      1 |    101 |   3199 |00:03:07.43 |    1952K|   267K|   267K|  237K (0)|
|   2 |   VIEW                                     |          |      1 |    101 |  30000 |00:03:06.97 |    1952K|       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|          |      1 |        |  30000 |00:03:06.96 |    1952K|  2048 |  2048 | 1936K (0)|
|*  4 |     VIEW                                   |          |      1 |      1 |      3 |00:00:00.03 |     191 |       |       |          |
|*  5 |      WINDOW SORT PUSHED RANK               |          |      1 |  30000 |      3 |00:00:00.03 |     191 |  2037K|   674K| 1810K (0)|
|   6 |       TABLE ACCESS FULL                    | ACTIVITY |      1 |  30000 |  30000 |00:00:00.01 |     191 |       |       |          |
|*  7 |     HASH JOIN                              |          |  10000 |    100 |  29997 |00:02:43.35 |    1910K|  1321K|  1321K|  638K (0)|
|   8 |      RECURSIVE WITH PUMP                   |          |  10000 |        |  30000 |00:00:00.01 |       0 |       |       |          |
|   9 |      VIEW                                  |          |  10000 |  30000 |    300M|00:03:29.32 |    1910K|       |       |          |
|  10 |       WINDOW SORT                          |          |  10000 |  30000 |    300M|00:02:46.14 |    1910K|  1399K|   597K| 1243K (0)|
|  11 |        TABLE ACCESS FULL                   | ACTIVITY |  10000 |  30000 |    300M|00:00:27.53 |    1910K|       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   4 - filter("RN"=1)
   5 - filter(ROW_NUMBER() OVER ( PARTITION BY "PERSON_ID" ORDER BY "START_DATE")<=1)
   7 - access("RSQ"."RN"="ACT"."RN"-1 AND "RSQ"."PERSON_ID"="ACT"."PERSON_ID")


Timer Set: Cursor, Constructed at 06 Nov 2016 14:20:15, written at 14:23:22
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.00             1        0.00200        0.00000
First fetch            187.43      187.33             1      187.42500      187.33000
Write to file            0.01        0.02             5        0.00140        0.00400
Remaining fetches        0.00        0.00             4        0.00100        0.00000
Write plan               0.10        0.09             1        0.09500        0.09000
(Other)                  0.01        0.01             1        0.01200        0.01000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                  187.55      187.45            14       13.39607       13.38929
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:20:15, written at 14:23:22
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.02             5        0.00100        0.00400
(Other)      187.56      187.43             1      187.55700      187.43000
-------  ----------  ----------  ------------  -------------  -------------
Total        187.56      187.45             6       31.26033       31.24167
-------  ----------  ----------  ------------  -------------  -------------
3200 rows written to RSF_QRY.csv
Summary for W/D = 20/30 , bench_run_statistics_id = 22

Timer Set: Run_One, Constructed at 06 Nov 2016 14:20:15, written at 14:23:22
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run          187.57      187.45             1      187.57000      187.45000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total        187.57      187.45             2       93.78500       93.72500
-------  ----------  ----------  ------------  -------------  -------------
/* RSF_TMP */ WITH rsq (person_id, rn, start_date, end_date, group_start) AS ( SELECT person_id, act_rownum, start_date, end_date, start_date FROM activity_tmp WHERE act_rownum = 1 UNION ALL SELECT ac
t.person_id, act.act_rownum, act.start_date, act.end_date, CASE WHEN act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end FROM rsq JOIN act
ivity_tmp act ON act.act_rownum = rsq.rn + 1 AND act.person_id = rsq.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || Max (end_date) || '","' || CO
UNT(*) || '","1342"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id, group_start

INSERT INTO activity_tmp SELECT person_id, start_date, end_date, Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) FROM activity
SQL_ID  8dmkqmghfvkyy, child number 0
-------------------------------------
/* RSF_TMP */ WITH rsq (person_id, rn, start_date, end_date,
group_start) AS ( SELECT person_id, act_rownum, start_date, end_date,
start_date FROM activity_tmp WHERE act_rownum = 1 UNION ALL SELECT
act.person_id, act.act_rownum, act.start_date, act.end_date, CASE WHEN
act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep')
THEN rsq.group_start ELSE act.start_date end FROM rsq JOIN activity_tmp
act ON act.act_rownum = rsq.rn + 1 AND act.person_id = rsq.person_id )
SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' ||
group_start || '","' || Max (end_date) || '","' || COUNT(*) ||
'","1342"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id,
group_start

Plan hash value: 4212061972

---------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name            | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
---------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |                 |      1 |        |   3199 |00:00:00.26 |   82728 |       |       |          |
|   1 |  SORT GROUP BY                             |                 |      1 |      6 |   3199 |00:00:00.26 |   82728 |   267K|   267K|  237K (0)|
|   2 |   VIEW                                     |                 |      1 |      6 |  30000 |00:00:00.23 |   82728 |       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|                 |      1 |        |  30000 |00:00:00.23 |   82728 |  2048 |  2048 | 1936K (0)|
|   4 |     TABLE ACCESS BY INDEX ROWID BATCHED    | ACTIVITY_TMP    |      1 |      3 |      3 |00:00:00.01 |       5 |       |       |          |
|*  5 |      INDEX RANGE SCAN                      | ACTIVITY_TMP_N1 |      1 |      3 |      3 |00:00:00.01 |       2 |       |       |          |
|   6 |     NESTED LOOPS                           |                 |  10000 |      3 |  29997 |00:00:00.10 |   40762 |       |       |          |
|   7 |      RECURSIVE WITH PUMP                   |                 |  10000 |        |  30000 |00:00:00.01 |       0 |       |       |          |
|   8 |      TABLE ACCESS BY INDEX ROWID BATCHED   | ACTIVITY_TMP    |  30000 |      1 |  29997 |00:00:00.07 |   40762 |       |       |          |
|*  9 |       INDEX RANGE SCAN                     | ACTIVITY_TMP_N1 |  30000 |    242 |  29997 |00:00:00.03 |   10765 |       |       |          |
---------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   5 - access("ACT_ROWNUM"=1)
   9 - access("ACT"."ACT_ROWNUM"="RSQ"."RN"+1 AND "ACT"."PERSON_ID"="RSQ"."PERSON_ID")

Note
-----
   - dynamic statistics used: dynamic sampling (level=2)
   - this is an adaptive plan


Timer Set: Cursor, Constructed at 06 Nov 2016 14:23:22, written at 14:23:23
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.05        0.05             1        0.04600        0.05000
Open cursor              0.01        0.00             1        0.01100        0.00000
First fetch              0.26        0.27             1        0.26100        0.27000
Write to file            0.01        0.01             5        0.00140        0.00200
Remaining fetches        0.00        0.00             4        0.00100        0.00000
Write plan               0.11        0.09             1        0.10600        0.09000
(Other)                  0.01        0.01             1        0.01100        0.01000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.45        0.43            14        0.03186        0.03071
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:23:22, written at 14:23:23
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.01             5        0.00120        0.00200
(Other)        0.46        0.44             1        0.46100        0.44000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.47        0.45             6        0.07783        0.07500
-------  ----------  ----------  ------------  -------------  -------------
3200 rows written to RSF_TMP.csv
Summary for W/D = 20/30 , bench_run_statistics_id = 23

Timer Set: Run_One, Constructed at 06 Nov 2016 14:23:22, written at 14:23:23
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.48        0.45             1        0.47500        0.45000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.48        0.45             2        0.23750        0.22500
-------  ----------  ----------  ------------  -------------  -------------
/* MTH_QRY */ SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || group_end || '","' || num_rows || '","3605"' FROM activity MATCH_RECOGNIZE ( PARTITION BY person
_id ORDER BY start_date MEASURES FIRST (start_date) group_start, FINAL MAX (end_date) group_end, COUNT(*) num_rows ONE ROW PER MATCH PATTERN (strt sm*) DEFINE sm AS sm.start_date <= strt.start_date +
Sys_Context('bench_ctx', 'deep') ) m ORDER BY person_id, group_start

SQL_ID  cxahpn1a80c97, child number 0
-------------------------------------
/* MTH_QRY */ SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id ||
'","' || group_start || '","' || group_end || '","' || num_rows ||
'","3605"' FROM activity MATCH_RECOGNIZE ( PARTITION BY person_id ORDER
BY start_date MEASURES FIRST (start_date) group_start, FINAL MAX
(end_date) group_end, COUNT(*) num_rows ONE ROW PER MATCH PATTERN (strt
sm*) DEFINE sm AS sm.start_date <= strt.start_date +
Sys_Context('bench_ctx', 'deep') ) m ORDER BY person_id, group_start

Plan hash value: 3670115155

--------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                        | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                                 |          |      1 |        |   3199 |00:00:00.02 |     191 |       |       |          |
|   1 |  SORT ORDER BY                                   |          |      1 |  30000 |   3199 |00:00:00.02 |     191 |   302K|   302K|  268K (0)|
|   2 |   VIEW                                           |          |      1 |  30000 |   3199 |00:00:00.02 |     191 |       |       |          |
|   3 |    MATCH RECOGNIZE SORT DETERMINISTIC FINITE AUTO|          |      1 |  30000 |   3199 |00:00:00.02 |     191 |  1399K|   597K| 1243K (0)|
|   4 |     TABLE ACCESS FULL                            | ACTIVITY |      1 |  30000 |  30000 |00:00:00.01 |     191 |       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------------


Timer Set: Cursor, Constructed at 06 Nov 2016 14:23:23, written at 14:23:23
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.00             1        0.00100        0.00000
First fetch              0.02        0.02             1        0.02400        0.02000
Write to file            0.01        0.01             5        0.00140        0.00200
Remaining fetches        0.00        0.00             4        0.00025        0.00000
Write plan               0.09        0.08             1        0.08800        0.08000
(Other)                  0.01        0.01             1        0.01200        0.01000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.13        0.12            14        0.00950        0.00857
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:23:23, written at 14:23:23
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.00             5        0.00140        0.00000
(Other)        0.14        0.14             1        0.13900        0.14000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.15        0.14             6        0.02433        0.02333
-------  ----------  ----------  ------------  -------------  -------------
3200 rows written to MTH_QRY.csv
Summary for W/D = 20/30 , bench_run_statistics_id = 24

Timer Set: Run_One, Constructed at 06 Nov 2016 14:23:23, written at 14:23:23
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.15        0.15             1        0.15400        0.15000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.15        0.15             2        0.07700        0.07500
-------  ----------  ----------  ------------  -------------  -------------
Activity truncated
45000 (15000) records (per person) added, average group size (from) = 5.8 (15000), # of groups = 2598.7

Timer Set: Setup, Constructed at 06 Nov 2016 14:23:23, written at 14:23:27
==========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000005), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                  Elapsed         CPU         Calls       Ela/Call       CPU/Call
------------------  ----------  ----------  ------------  -------------  -------------
Add_Act                   3.23        2.46             1        3.23200        2.46000
Gather_Table_Stats        0.18        0.18             1        0.18200        0.18000
GRP_CNT                   0.22        0.22             1        0.22000        0.22000
(Other)                   0.00        0.00             1        0.00000        0.00000
------------------  ----------  ----------  ------------  -------------  -------------
Total                     3.63        2.86             4        0.90850        0.71500
------------------  ----------  ----------  ------------  -------------  -------------
/* MOD_QRY */ WITH all_rows AS ( SELECT person_id, start_date, end_date, group_start FROM activity MODEL PARTITION BY (person_id) DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY start
_date) rn) MEASURES (start_date, end_date, start_date group_start) RULES ( group_start[rn = 1] = start_date[cv()], group_start[rn > 1] = CASE WHEN start_date[cv()] - group_start[cv()-1] > Sys_Context(
'bench_ctx', 'deep') THEN start_date[cv()] ELSE group_start[cv()-1] END ) ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || MAX(end_date) || '","' || COUNT(*)
 || '","5109"' FROM all_rows GROUP BY person_id, group_start ORDER BY person_id, group_start

SQL_ID  b7448kyzsy002, child number 0
-------------------------------------
/* MOD_QRY */ WITH all_rows AS ( SELECT person_id, start_date,
end_date, group_start FROM activity MODEL PARTITION BY (person_id)
DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY
start_date) rn) MEASURES (start_date, end_date, start_date group_start)
RULES ( group_start[rn = 1] = start_date[cv()], group_start[rn > 1] =
CASE WHEN start_date[cv()] - group_start[cv()-1] >
Sys_Context('bench_ctx', 'deep') THEN start_date[cv()] ELSE
group_start[cv()-1] END ) ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' ||
person_id || '","' || group_start || '","' || MAX(end_date) || '","' ||
COUNT(*) || '","5109"' FROM all_rows GROUP BY person_id, group_start
ORDER BY person_id, group_start

Plan hash value: 2323700320

-----------------------------------------------------------------------------------------------------------------------
| Id  | Operation             | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-----------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |          |      1 |        |   8451 |00:00:00.24 |     248 |       |       |          |
|   1 |  SORT GROUP BY        |          |      1 |  45000 |   8451 |00:00:00.24 |     248 |   619K|   619K|  550K (0)|
|   2 |   VIEW                |          |      1 |  45000 |  45000 |00:00:00.12 |     248 |       |       |          |
|   3 |    SQL MODEL ORDERED  |          |      1 |  45000 |  45000 |00:00:00.11 |     248 |  4279K|  1428K| 2975K (0)|
|   4 |     WINDOW SORT       |          |      1 |  45000 |  45000 |00:00:00.03 |     248 |  2108K|   682K| 1873K (0)|
|   5 |      TABLE ACCESS FULL| ACTIVITY |      1 |  45000 |  45000 |00:00:00.01 |     248 |       |       |          |
-----------------------------------------------------------------------------------------------------------------------


Timer Set: Cursor, Constructed at 06 Nov 2016 14:23:27, written at 14:23:27
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.00             1        0.00100        0.00000
First fetch              0.24        0.25             1        0.24300        0.25000
Write to file            0.02        0.00            10        0.00180        0.00000
Remaining fetches        0.01        0.01             9        0.00089        0.00111
Write plan               0.09        0.10             1        0.08900        0.10000
(Other)                  0.01        0.02             1        0.01100        0.02000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.37        0.38            24        0.01542        0.01583
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:23:27, written at 14:23:27
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.00            12        0.00117        0.00000
(Other)        0.37        0.38             1        0.36800        0.38000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.38        0.38            13        0.02938        0.02923
-------  ----------  ----------  ------------  -------------  -------------
8452 rows written to MOD_QRY.csv
Summary for W/D = 30/10 , bench_run_statistics_id = 25

Timer Set: Run_One, Constructed at 06 Nov 2016 14:23:27, written at 14:23:27
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.39        0.38             1        0.39000        0.38000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.39        0.38             2        0.19500        0.19000
-------  ----------  ----------  ------------  -------------  -------------
/* RSF_QRY */ WITH act AS ( SELECT person_id, start_date, end_date, Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn FROM activity ),	rsq (person_id, rn, start_date, end_date, group_s
tart) AS ( SELECT person_id, rn, start_date, end_date, start_date FROM act WHERE rn = 1 UNION ALL SELECT act.person_id, act.rn, act.start_date, act.end_date, CASE WHEN act.start_date - rsq.group_start
 <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end FROM act JOIN rsq ON rsq.rn = act.rn - 1 AND rsq.person_id = act.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"'
|| person_id || '","' || group_start || '","' || Max (end_date) || '","' || COUNT(*) || '","6573"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id, group_start

SQL_ID  agbdj8bgnpgus, child number 0
-------------------------------------
/* RSF_QRY */ WITH act AS ( SELECT person_id, start_date, end_date,
Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn FROM
activity ), rsq (person_id, rn, start_date, end_date, group_start) AS (
SELECT person_id, rn, start_date, end_date, start_date FROM act WHERE
rn = 1 UNION ALL SELECT act.person_id, act.rn, act.start_date,
act.end_date, CASE WHEN act.start_date - rsq.group_start <=
Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE
act.start_date end FROM act JOIN rsq ON rsq.rn = act.rn - 1 AND
rsq.person_id = act.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */
'"' || person_id || '","' || group_start || '","' || Max (end_date) ||
'","' || COUNT(*) || '","6573"' FROM rsq GROUP BY person_id,
group_start ORDER BY person_id, group_start

Plan hash value: 941514960

--------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |          |      1 |        |   8451 |00:07:02.69 |    3790K|       |       |          |
|   1 |  SORT GROUP BY                             |          |      1 |    151 |   8451 |00:07:02.69 |    3790K|   690K|   690K|  613K (0)|
|   2 |   VIEW                                     |          |      1 |    151 |  45000 |00:07:00.19 |    3790K|       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|          |      1 |        |  45000 |00:07:00.18 |    3790K|  2048 |  2048 | 2881K (0)|
|*  4 |     VIEW                                   |          |      1 |      1 |      3 |00:00:00.05 |     248 |       |       |          |
|*  5 |      WINDOW SORT PUSHED RANK               |          |      1 |  45000 |      3 |00:00:00.05 |     248 |  2958K|   766K| 2629K (0)|
|   6 |       TABLE ACCESS FULL                    | ACTIVITY |      1 |  45000 |  45000 |00:00:00.01 |     248 |       |       |          |
|*  7 |     HASH JOIN                              |          |  15000 |    150 |  44997 |00:06:08.13 |    3720K|  1321K|  1321K|  636K (0)|
|   8 |      RECURSIVE WITH PUMP                   |          |  15000 |        |  45000 |00:00:00.02 |       0 |       |       |          |
|   9 |      VIEW                                  |          |  15000 |  45000 |    675M|00:07:50.31 |    3720K|       |       |          |
|  10 |       WINDOW SORT                          |          |  15000 |  45000 |    675M|00:06:14.69 |    3720K|  2108K|   682K| 1873K (0)|
|  11 |        TABLE ACCESS FULL                   | ACTIVITY |  15000 |  45000 |    675M|00:01:01.63 |    3720K|       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   4 - filter("RN"=1)
   5 - filter(ROW_NUMBER() OVER ( PARTITION BY "PERSON_ID" ORDER BY "START_DATE")<=1)
   7 - access("RSQ"."RN"="ACT"."RN"-1 AND "RSQ"."PERSON_ID"="ACT"."PERSON_ID")


Timer Set: Cursor, Constructed at 06 Nov 2016 14:23:27, written at 14:30:30
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.02             1        0.00200        0.02000
First fetch            422.69      422.56             1      422.68700      422.56000
Write to file            0.02        0.01            10        0.00180        0.00100
Remaining fetches        0.01        0.02             9        0.00100        0.00222
Write plan               0.10        0.10             1        0.09500        0.10000
(Other)                  0.01        0.00             1        0.01100        0.00000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                  422.82      422.71            24       17.61758       17.61292
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:23:27, written at 14:30:30
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.02        0.01            12        0.00125        0.00083
(Other)      422.83      422.71             1      422.82500      422.71000
-------  ----------  ----------  ------------  -------------  -------------
Total        422.84      422.72            13       32.52615       32.51692
-------  ----------  ----------  ------------  -------------  -------------
8452 rows written to RSF_QRY.csv
Summary for W/D = 30/10 , bench_run_statistics_id = 26

Timer Set: Run_One, Constructed at 06 Nov 2016 14:23:27, written at 14:30:30
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run          422.85      422.74             1      422.84800      422.74000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total        422.85      422.74             2      211.42400      211.37000
-------  ----------  ----------  ------------  -------------  -------------
/* RSF_TMP */ WITH rsq (person_id, rn, start_date, end_date, group_start) AS ( SELECT person_id, act_rownum, start_date, end_date, start_date FROM activity_tmp WHERE act_rownum = 1 UNION ALL SELECT ac
t.person_id, act.act_rownum, act.start_date, act.end_date, CASE WHEN act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end FROM rsq JOIN act
ivity_tmp act ON act.act_rownum = rsq.rn + 1 AND act.person_id = rsq.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || Max (end_date) || '","' || CO
UNT(*) || '","487"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id, group_start

INSERT INTO activity_tmp SELECT person_id, start_date, end_date, Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) FROM activity
SQL_ID  7rz29bva2v7kp, child number 0
-------------------------------------
/* RSF_TMP */ WITH rsq (person_id, rn, start_date, end_date,
group_start) AS ( SELECT person_id, act_rownum, start_date, end_date,
start_date FROM activity_tmp WHERE act_rownum = 1 UNION ALL SELECT
act.person_id, act.act_rownum, act.start_date, act.end_date, CASE WHEN
act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep')
THEN rsq.group_start ELSE act.start_date end FROM rsq JOIN activity_tmp
act ON act.act_rownum = rsq.rn + 1 AND act.person_id = rsq.person_id )
SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' ||
group_start || '","' || Max (end_date) || '","' || COUNT(*) ||
'","487"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id,
group_start

Plan hash value: 4212061972

---------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name            | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
---------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |                 |      1 |        |   8451 |00:00:00.42 |     131K|       |       |          |
|   1 |  SORT GROUP BY                             |                 |      1 |      6 |   8451 |00:00:00.42 |     131K|   690K|   690K|  613K (0)|
|   2 |   VIEW                                     |                 |      1 |      6 |  45000 |00:00:00.37 |     131K|       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|                 |      1 |        |  45000 |00:00:00.36 |     131K|  2048 |  2048 | 2881K (0)|
|   4 |     TABLE ACCESS BY INDEX ROWID BATCHED    | ACTIVITY_TMP    |      1 |      3 |      3 |00:00:00.01 |       5 |       |       |          |
|*  5 |      INDEX RANGE SCAN                      | ACTIVITY_TMP_N1 |      1 |      3 |      3 |00:00:00.01 |       2 |       |       |          |
|   6 |     NESTED LOOPS                           |                 |  15000 |      3 |  44997 |00:00:00.16 |   61137 |       |       |          |
|   7 |      RECURSIVE WITH PUMP                   |                 |  15000 |        |  45000 |00:00:00.01 |       0 |       |       |          |
|   8 |      TABLE ACCESS BY INDEX ROWID BATCHED   | ACTIVITY_TMP    |  45000 |      1 |  44997 |00:00:00.12 |   61137 |       |       |          |
|*  9 |       INDEX RANGE SCAN                     | ACTIVITY_TMP_N1 |  45000 |    466 |  44997 |00:00:00.05 |   16140 |       |       |          |
---------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   5 - access("ACT_ROWNUM"=1)
   9 - access("ACT"."ACT_ROWNUM"="RSQ"."RN"+1 AND "ACT"."PERSON_ID"="RSQ"."PERSON_ID")

Note
-----
   - dynamic statistics used: dynamic sampling (level=2)
   - this is an adaptive plan


Timer Set: Cursor, Constructed at 06 Nov 2016 14:30:30, written at 14:30:31
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.09        0.08             1        0.08800        0.08000
Open cursor              0.01        0.01             1        0.01400        0.01000
First fetch              0.42        0.42             1        0.41800        0.42000
Write to file            0.02        0.01            10        0.00210        0.00100
Remaining fetches        0.01        0.02             9        0.00111        0.00222
Write plan               0.11        0.11             1        0.11200        0.11000
(Other)                  0.02        0.03             1        0.01700        0.03000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.68        0.68            24        0.02833        0.02833
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:30:30, written at 14:30:31
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.02        0.01            11        0.00145        0.00091
(Other)        0.69        0.69             1        0.69000        0.69000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.71        0.70            12        0.05883        0.05833
-------  ----------  ----------  ------------  -------------  -------------
8452 rows written to RSF_TMP.csv
Summary for W/D = 30/10 , bench_run_statistics_id = 27

Timer Set: Run_One, Constructed at 06 Nov 2016 14:30:30, written at 14:30:31
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.71        0.70             1        0.71400        0.70000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.71        0.70             2        0.35700        0.35000
-------  ----------  ----------  ------------  -------------  -------------
/* MTH_QRY */ SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || group_end || '","' || num_rows || '","6652"' FROM activity MATCH_RECOGNIZE ( PARTITION BY person
_id ORDER BY start_date MEASURES FIRST (start_date) group_start, FINAL MAX (end_date) group_end, COUNT(*) num_rows ONE ROW PER MATCH PATTERN (strt sm*) DEFINE sm AS sm.start_date <= strt.start_date +
Sys_Context('bench_ctx', 'deep') ) m ORDER BY person_id, group_start

SQL_ID  bg9wuu3hmvuaz, child number 0
-------------------------------------
/* MTH_QRY */ SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id ||
'","' || group_start || '","' || group_end || '","' || num_rows ||
'","6652"' FROM activity MATCH_RECOGNIZE ( PARTITION BY person_id ORDER
BY start_date MEASURES FIRST (start_date) group_start, FINAL MAX
(end_date) group_end, COUNT(*) num_rows ONE ROW PER MATCH PATTERN (strt
sm*) DEFINE sm AS sm.start_date <= strt.start_date +
Sys_Context('bench_ctx', 'deep') ) m ORDER BY person_id, group_start

Plan hash value: 3670115155

--------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                        | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                                 |          |      1 |        |   8451 |00:00:00.05 |     248 |       |       |          |
|   1 |  SORT ORDER BY                                   |          |      1 |  45000 |   8451 |00:00:00.05 |     248 |   761K|   499K|  676K (0)|
|   2 |   VIEW                                           |          |      1 |  45000 |   8451 |00:00:00.04 |     248 |       |       |          |
|   3 |    MATCH RECOGNIZE SORT DETERMINISTIC FINITE AUTO|          |      1 |  45000 |   8451 |00:00:00.04 |     248 |  2108K|   682K| 1873K (0)|
|   4 |     TABLE ACCESS FULL                            | ACTIVITY |      1 |  45000 |  45000 |00:00:00.01 |     248 |       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------------


Timer Set: Cursor, Constructed at 06 Nov 2016 14:30:31, written at 14:30:31
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.00             1        0.00100        0.00000
First fetch              0.05        0.06             1        0.05100        0.06000
Write to file            0.02        0.02            10        0.00180        0.00200
Remaining fetches        0.00        0.00             9        0.00033        0.00000
Write plan               0.09        0.09             1        0.08900        0.09000
(Other)                  0.32        0.01             1        0.32400        0.01000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.49        0.18            24        0.02025        0.00750
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:30:31, written at 14:30:31
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.02        0.02            12        0.00133        0.00167
(Other)        0.49        0.16             1        0.48900        0.16000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.51        0.18            13        0.03885        0.01385
-------  ----------  ----------  ------------  -------------  -------------
8452 rows written to MTH_QRY.csv
Summary for W/D = 30/10 , bench_run_statistics_id = 28

Timer Set: Run_One, Constructed at 06 Nov 2016 14:30:31, written at 14:30:31
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.51        0.18             1        0.51300        0.18000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.51        0.18             2        0.25650        0.09000
-------  ----------  ----------  ------------  -------------  -------------
Activity truncated
45000 (15000) records (per person) added, average group size (from) = 9.9 (15000), # of groups = 1515.7

Timer Set: Setup, Constructed at 06 Nov 2016 14:30:31, written at 14:30:34
==========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                  Elapsed         CPU         Calls       Ela/Call       CPU/Call
------------------  ----------  ----------  ------------  -------------  -------------
Add_Act                   2.54        2.39             1        2.53700        2.39000
Gather_Table_Stats        0.23        0.19             1        0.23000        0.19000
GRP_CNT                   0.23        0.23             1        0.23200        0.23000
(Other)                   0.00        0.00             1        0.00100        0.00000
------------------  ----------  ----------  ------------  -------------  -------------
Total                     3.00        2.81             4        0.75000        0.70250
------------------  ----------  ----------  ------------  -------------  -------------
/* MOD_QRY */ WITH all_rows AS ( SELECT person_id, start_date, end_date, group_start FROM activity MODEL PARTITION BY (person_id) DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY start
_date) rn) MEASURES (start_date, end_date, start_date group_start) RULES ( group_start[rn = 1] = start_date[cv()], group_start[rn > 1] = CASE WHEN start_date[cv()] - group_start[cv()-1] > Sys_Context(
'bench_ctx', 'deep') THEN start_date[cv()] ELSE group_start[cv()-1] END ) ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || MAX(end_date) || '","' || COUNT(*)
 || '","8933"' FROM all_rows GROUP BY person_id, group_start ORDER BY person_id, group_start

SQL_ID  4grmsjs1a63h2, child number 0
-------------------------------------
/* MOD_QRY */ WITH all_rows AS ( SELECT person_id, start_date,
end_date, group_start FROM activity MODEL PARTITION BY (person_id)
DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY
start_date) rn) MEASURES (start_date, end_date, start_date group_start)
RULES ( group_start[rn = 1] = start_date[cv()], group_start[rn > 1] =
CASE WHEN start_date[cv()] - group_start[cv()-1] >
Sys_Context('bench_ctx', 'deep') THEN start_date[cv()] ELSE
group_start[cv()-1] END ) ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' ||
person_id || '","' || group_start || '","' || MAX(end_date) || '","' ||
COUNT(*) || '","8933"' FROM all_rows GROUP BY person_id, group_start
ORDER BY person_id, group_start

Plan hash value: 2323700320

-----------------------------------------------------------------------------------------------------------------------
| Id  | Operation             | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-----------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |          |      1 |        |   4771 |00:00:00.23 |     248 |       |       |          |
|   1 |  SORT GROUP BY        |          |      1 |  45000 |   4771 |00:00:00.23 |     248 |   372K|   372K|  330K (0)|
|   2 |   VIEW                |          |      1 |  45000 |  45000 |00:00:00.11 |     248 |       |       |          |
|   3 |    SQL MODEL ORDERED  |          |      1 |  45000 |  45000 |00:00:00.10 |     248 |  4279K|  1428K| 2965K (0)|
|   4 |     WINDOW SORT       |          |      1 |  45000 |  45000 |00:00:00.02 |     248 |  2108K|   682K| 1873K (0)|
|   5 |      TABLE ACCESS FULL| ACTIVITY |      1 |  45000 |  45000 |00:00:00.01 |     248 |       |       |          |
-----------------------------------------------------------------------------------------------------------------------


Timer Set: Cursor, Constructed at 06 Nov 2016 14:30:34, written at 14:30:35
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.00             1        0.00100        0.00000
First fetch              0.23        0.23             1        0.23100        0.23000
Write to file            0.01        0.00             6        0.00167        0.00000
Remaining fetches        0.00        0.02             5        0.00080        0.00400
Write plan               0.09        0.09             1        0.08900        0.09000
(Other)                  0.01        0.02             1        0.01100        0.02000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.35        0.36            16        0.02163        0.02250
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:30:34, written at 14:30:35
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.00             7        0.00100        0.00000
(Other)        0.35        0.36             1        0.35100        0.36000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.36        0.36             8        0.04475        0.04500
-------  ----------  ----------  ------------  -------------  -------------
4772 rows written to MOD_QRY.csv
Summary for W/D = 30/20 , bench_run_statistics_id = 29

Timer Set: Run_One, Constructed at 06 Nov 2016 14:30:34, written at 14:30:35
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.37        0.38             1        0.36600        0.38000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.37        0.38             2        0.18300        0.19000
-------  ----------  ----------  ------------  -------------  -------------
/* RSF_QRY */ WITH act AS ( SELECT person_id, start_date, end_date, Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn FROM activity ),	rsq (person_id, rn, start_date, end_date, group_s
tart) AS ( SELECT person_id, rn, start_date, end_date, start_date FROM act WHERE rn = 1 UNION ALL SELECT act.person_id, act.rn, act.start_date, act.end_date, CASE WHEN act.start_date - rsq.group_start
 <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end FROM act JOIN rsq ON rsq.rn = act.rn - 1 AND rsq.person_id = act.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"'
|| person_id || '","' || group_start || '","' || Max (end_date) || '","' || COUNT(*) || '","9851"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id, group_start

SQL_ID  f91rnkpj0a16w, child number 0
-------------------------------------
/* RSF_QRY */ WITH act AS ( SELECT person_id, start_date, end_date,
Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn FROM
activity ), rsq (person_id, rn, start_date, end_date, group_start) AS (
SELECT person_id, rn, start_date, end_date, start_date FROM act WHERE
rn = 1 UNION ALL SELECT act.person_id, act.rn, act.start_date,
act.end_date, CASE WHEN act.start_date - rsq.group_start <=
Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE
act.start_date end FROM act JOIN rsq ON rsq.rn = act.rn - 1 AND
rsq.person_id = act.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */
'"' || person_id || '","' || group_start || '","' || Max (end_date) ||
'","' || COUNT(*) || '","9851"' FROM rsq GROUP BY person_id,
group_start ORDER BY person_id, group_start

Plan hash value: 941514960

--------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |          |      1 |        |   4771 |00:07:19.84 |    3790K|       |       |          |
|   1 |  SORT GROUP BY                             |          |      1 |    151 |   4771 |00:07:19.84 |    3790K|   407K|   407K|  361K (0)|
|   2 |   VIEW                                     |          |      1 |    151 |  45000 |00:07:20.19 |    3790K|       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|          |      1 |        |  45000 |00:07:20.17 |    3790K|  2048 |  2048 | 2881K (0)|
|*  4 |     VIEW                                   |          |      1 |      1 |      3 |00:00:00.05 |     248 |       |       |          |
|*  5 |      WINDOW SORT PUSHED RANK               |          |      1 |  45000 |      3 |00:00:00.05 |     248 |  2958K|   766K| 2629K (0)|
|   6 |       TABLE ACCESS FULL                    | ACTIVITY |      1 |  45000 |  45000 |00:00:00.01 |     248 |       |       |          |
|*  7 |     HASH JOIN                              |          |  15000 |    150 |  44997 |00:06:22.94 |    3720K|  1321K|  1321K|  717K (0)|
|   8 |      RECURSIVE WITH PUMP                   |          |  15000 |        |  45000 |00:00:00.03 |       0 |       |       |          |
|   9 |      VIEW                                  |          |  15000 |  45000 |    675M|00:08:09.22 |    3720K|       |       |          |
|  10 |       WINDOW SORT                          |          |  15000 |  45000 |    675M|00:06:30.91 |    3720K|  2108K|   682K| 1873K (0)|
|  11 |        TABLE ACCESS FULL                   | ACTIVITY |  15000 |  45000 |    675M|00:01:05.82 |    3720K|       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   4 - filter("RN"=1)
   5 - filter(ROW_NUMBER() OVER ( PARTITION BY "PERSON_ID" ORDER BY "START_DATE")<=1)
   7 - access("RSQ"."RN"="ACT"."RN"-1 AND "RSQ"."PERSON_ID"="ACT"."PERSON_ID")


Timer Set: Cursor, Constructed at 06 Nov 2016 14:30:35, written at 14:37:55
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.00             1        0.00200        0.00000
First fetch            439.84      439.30             1      439.84200      439.30000
Write to file            0.01        0.00             6        0.00183        0.00000
Remaining fetches        0.00        0.01             5        0.00080        0.00200
Write plan               0.10        0.11             1        0.10100        0.11000
(Other)                  0.01        0.01             1        0.01100        0.01000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                  439.97      439.43            16       27.49819       27.46438
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:30:35, written at 14:37:55
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.00             7        0.00129        0.00000
(Other)      439.98      439.43             1      439.97500      439.43000
-------  ----------  ----------  ------------  -------------  -------------
Total        439.98      439.43             8       54.99800       54.92875
-------  ----------  ----------  ------------  -------------  -------------
4772 rows written to RSF_QRY.csv
Summary for W/D = 30/20 , bench_run_statistics_id = 30

Timer Set: Run_One, Constructed at 06 Nov 2016 14:30:35, written at 14:37:55
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000005), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run          439.99      439.45             1      439.99200      439.45000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total        439.99      439.45             2      219.99600      219.72500
-------  ----------  ----------  ------------  -------------  -------------
/* RSF_TMP */ WITH rsq (person_id, rn, start_date, end_date, group_start) AS ( SELECT person_id, act_rownum, start_date, end_date, start_date FROM activity_tmp WHERE act_rownum = 1 UNION ALL SELECT ac
t.person_id, act.act_rownum, act.start_date, act.end_date, CASE WHEN act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end FROM rsq JOIN act
ivity_tmp act ON act.act_rownum = rsq.rn + 1 AND act.person_id = rsq.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || Max (end_date) || '","' || CO
UNT(*) || '","5774"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id, group_start

INSERT INTO activity_tmp SELECT person_id, start_date, end_date, Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) FROM activity
SQL_ID  0v1hk0339c3sj, child number 0
-------------------------------------
/* RSF_TMP */ WITH rsq (person_id, rn, start_date, end_date,
group_start) AS ( SELECT person_id, act_rownum, start_date, end_date,
start_date FROM activity_tmp WHERE act_rownum = 1 UNION ALL SELECT
act.person_id, act.act_rownum, act.start_date, act.end_date, CASE WHEN
act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep')
THEN rsq.group_start ELSE act.start_date end FROM rsq JOIN activity_tmp
act ON act.act_rownum = rsq.rn + 1 AND act.person_id = rsq.person_id )
SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' ||
group_start || '","' || Max (end_date) || '","' || COUNT(*) ||
'","5774"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id,
group_start

Plan hash value: 4212061972

---------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name            | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
---------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |                 |      1 |        |   4771 |00:00:00.42 |     131K|       |       |          |
|   1 |  SORT GROUP BY                             |                 |      1 |      6 |   4771 |00:00:00.42 |     131K|   407K|   407K|  361K (0)|
|   2 |   VIEW                                     |                 |      1 |      6 |  45000 |00:00:00.38 |     131K|       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|                 |      1 |        |  45000 |00:00:00.37 |     131K|  2048 |  2048 | 2881K (0)|
|   4 |     TABLE ACCESS BY INDEX ROWID BATCHED    | ACTIVITY_TMP    |      1 |      3 |      3 |00:00:00.01 |       5 |       |       |          |
|*  5 |      INDEX RANGE SCAN                      | ACTIVITY_TMP_N1 |      1 |      3 |      3 |00:00:00.01 |       2 |       |       |          |
|   6 |     NESTED LOOPS                           |                 |  15000 |      3 |  44997 |00:00:00.16 |   61174 |       |       |          |
|   7 |      RECURSIVE WITH PUMP                   |                 |  15000 |        |  45000 |00:00:00.01 |       0 |       |       |          |
|   8 |      TABLE ACCESS BY INDEX ROWID BATCHED   | ACTIVITY_TMP    |  45000 |      1 |  44997 |00:00:00.12 |   61174 |       |       |          |
|*  9 |       INDEX RANGE SCAN                     | ACTIVITY_TMP_N1 |  45000 |    460 |  44997 |00:00:00.05 |   16177 |       |       |          |
---------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   5 - access("ACT_ROWNUM"=1)
   9 - access("ACT"."ACT_ROWNUM"="RSQ"."RN"+1 AND "ACT"."PERSON_ID"="RSQ"."PERSON_ID")

Note
-----
   - dynamic statistics used: dynamic sampling (level=2)
   - this is an adaptive plan


Timer Set: Cursor, Constructed at 06 Nov 2016 14:37:55, written at 14:37:55
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.07        0.08             1        0.07200        0.08000
Open cursor              0.01        0.02             1        0.01300        0.02000
First fetch              0.42        0.42             1        0.42400        0.42000
Write to file            0.01        0.02             6        0.00200        0.00333
Remaining fetches        0.01        0.00             5        0.00100        0.00000
Write plan               0.11        0.11             1        0.10900        0.11000
(Other)                  0.01        0.01             1        0.01200        0.01000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.65        0.66            16        0.04044        0.04125
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:37:55, written at 14:37:55
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.02             7        0.00114        0.00286
(Other)        0.65        0.64             1        0.65100        0.64000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.66        0.66             8        0.08238        0.08250
-------  ----------  ----------  ------------  -------------  -------------
4772 rows written to RSF_TMP.csv
Summary for W/D = 30/20 , bench_run_statistics_id = 31

Timer Set: Run_One, Constructed at 06 Nov 2016 14:37:55, written at 14:37:55
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.67        0.66             1        0.66800        0.66000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.67        0.66             2        0.33400        0.33000
-------  ----------  ----------  ------------  -------------  -------------
/* MTH_QRY */ SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || group_end || '","' || num_rows || '","1274"' FROM activity MATCH_RECOGNIZE ( PARTITION BY person
_id ORDER BY start_date MEASURES FIRST (start_date) group_start, FINAL MAX (end_date) group_end, COUNT(*) num_rows ONE ROW PER MATCH PATTERN (strt sm*) DEFINE sm AS sm.start_date <= strt.start_date +
Sys_Context('bench_ctx', 'deep') ) m ORDER BY person_id, group_start

SQL_ID  gap7gw29ztuh7, child number 0
-------------------------------------
/* MTH_QRY */ SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id ||
'","' || group_start || '","' || group_end || '","' || num_rows ||
'","1274"' FROM activity MATCH_RECOGNIZE ( PARTITION BY person_id ORDER
BY start_date MEASURES FIRST (start_date) group_start, FINAL MAX
(end_date) group_end, COUNT(*) num_rows ONE ROW PER MATCH PATTERN (strt
sm*) DEFINE sm AS sm.start_date <= strt.start_date +
Sys_Context('bench_ctx', 'deep') ) m ORDER BY person_id, group_start

Plan hash value: 3670115155

--------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                        | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                                 |          |      1 |        |   4771 |00:00:00.04 |     248 |       |       |          |
|   1 |  SORT ORDER BY                                   |          |      1 |  45000 |   4771 |00:00:00.04 |     248 |   407K|   407K|  361K (0)|
|   2 |   VIEW                                           |          |      1 |  45000 |   4771 |00:00:00.04 |     248 |       |       |          |
|   3 |    MATCH RECOGNIZE SORT DETERMINISTIC FINITE AUTO|          |      1 |  45000 |   4771 |00:00:00.04 |     248 |  2108K|   682K| 1873K (0)|
|   4 |     TABLE ACCESS FULL                            | ACTIVITY |      1 |  45000 |  45000 |00:00:00.01 |     248 |       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------------


Timer Set: Cursor, Constructed at 06 Nov 2016 14:37:55, written at 14:37:55
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.00             1        0.00100        0.00000
First fetch              0.04        0.05             1        0.03800        0.05000
Write to file            0.01        0.01             6        0.00183        0.00167
Remaining fetches        0.00        0.00             5        0.00020        0.00000
Write plan               0.09        0.10             1        0.09400        0.10000
(Other)                  0.01        0.00             1        0.01100        0.00000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.16        0.16            16        0.00975        0.01000
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:37:55, written at 14:37:55
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.01        0.01             7        0.00143        0.00143
(Other)        0.16        0.15             1        0.16000        0.15000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.17        0.16             8        0.02125        0.02000
-------  ----------  ----------  ------------  -------------  -------------
4772 rows written to MTH_QRY.csv
Summary for W/D = 30/20 , bench_run_statistics_id = 32

Timer Set: Run_One, Constructed at 06 Nov 2016 14:37:55, written at 14:37:55
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.18        0.16             1        0.17900        0.16000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.18        0.16             2        0.08950        0.08000
-------  ----------  ----------  ------------  -------------  -------------
Activity truncated
45000 (15000) records (per person) added, average group size (from) = 14 (15000), # of groups = 1073.7

Timer Set: Setup, Constructed at 06 Nov 2016 14:37:55, written at 14:37:59
==========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer                  Elapsed         CPU         Calls       Ela/Call       CPU/Call
------------------  ----------  ----------  ------------  -------------  -------------
Add_Act                   3.22        2.49             1        3.21600        2.49000
Gather_Table_Stats        0.19        0.18             1        0.18700        0.18000
GRP_CNT                   0.23        0.24             1        0.23300        0.24000
(Other)                   0.00        0.00             1        0.00100        0.00000
------------------  ----------  ----------  ------------  -------------  -------------
Total                     3.64        2.91             4        0.90925        0.72750
------------------  ----------  ----------  ------------  -------------  -------------
/* MOD_QRY */ WITH all_rows AS ( SELECT person_id, start_date, end_date, group_start FROM activity MODEL PARTITION BY (person_id) DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY start
_date) rn) MEASURES (start_date, end_date, start_date group_start) RULES ( group_start[rn = 1] = start_date[cv()], group_start[rn > 1] = CASE WHEN start_date[cv()] - group_start[cv()-1] > Sys_Context(
'bench_ctx', 'deep') THEN start_date[cv()] ELSE group_start[cv()-1] END ) ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || MAX(end_date) || '","' || COUNT(*)
 || '","4507"' FROM all_rows GROUP BY person_id, group_start ORDER BY person_id, group_start

SQL_ID  3z698sr8q2xag, child number 0
-------------------------------------
/* MOD_QRY */ WITH all_rows AS ( SELECT person_id, start_date,
end_date, group_start FROM activity MODEL PARTITION BY (person_id)
DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY
start_date) rn) MEASURES (start_date, end_date, start_date group_start)
RULES ( group_start[rn = 1] = start_date[cv()], group_start[rn > 1] =
CASE WHEN start_date[cv()] - group_start[cv()-1] >
Sys_Context('bench_ctx', 'deep') THEN start_date[cv()] ELSE
group_start[cv()-1] END ) ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' ||
person_id || '","' || group_start || '","' || MAX(end_date) || '","' ||
COUNT(*) || '","4507"' FROM all_rows GROUP BY person_id, group_start
ORDER BY person_id, group_start

Plan hash value: 2323700320

-----------------------------------------------------------------------------------------------------------------------
| Id  | Operation             | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-----------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |          |      1 |        |   3325 |00:00:00.27 |     248 |       |       |          |
|   1 |  SORT GROUP BY        |          |      1 |  45000 |   3325 |00:00:00.27 |     248 |   267K|   267K|  237K (0)|
|   2 |   VIEW                |          |      1 |  45000 |  45000 |00:00:00.13 |     248 |       |       |          |
|   3 |    SQL MODEL ORDERED  |          |      1 |  45000 |  45000 |00:00:00.12 |     248 |  4279K|  1428K| 2957K (0)|
|   4 |     WINDOW SORT       |          |      1 |  45000 |  45000 |00:00:00.03 |     248 |  2108K|   682K| 1873K (0)|
|   5 |      TABLE ACCESS FULL| ACTIVITY |      1 |  45000 |  45000 |00:00:00.01 |     248 |       |       |          |
-----------------------------------------------------------------------------------------------------------------------


Timer Set: Cursor, Constructed at 06 Nov 2016 14:37:59, written at 14:38:00
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.00             1        0.00200        0.00000
First fetch              0.27        0.27             1        0.26900        0.27000
Write to file            0.51        0.00             5        0.10100        0.00000
Remaining fetches        0.01        0.03             4        0.00225        0.00750
Write plan               0.12        0.12             1        0.12100        0.12000
(Other)                  0.01        0.02             1        0.01200        0.02000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.92        0.44            14        0.06557        0.03143
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:37:59, written at 14:38:00
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.50        0.00             5        0.10060        0.00000
(Other)        0.43        0.44             1        0.42900        0.44000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.93        0.44             6        0.15533        0.07333
-------  ----------  ----------  ------------  -------------  -------------
3326 rows written to MOD_QRY.csv
Summary for W/D = 30/30 , bench_run_statistics_id = 33

Timer Set: Run_One, Constructed at 06 Nov 2016 14:37:59, written at 14:38:00
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            0.94        0.46             1        0.94000        0.46000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.94        0.46             2        0.47000        0.23000
-------  ----------  ----------  ------------  -------------  -------------
/* RSF_QRY */ WITH act AS ( SELECT person_id, start_date, end_date, Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn FROM activity ),	rsq (person_id, rn, start_date, end_date, group_s
tart) AS ( SELECT person_id, rn, start_date, end_date, start_date FROM act WHERE rn = 1 UNION ALL SELECT act.person_id, act.rn, act.start_date, act.end_date, CASE WHEN act.start_date - rsq.group_start
 <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end FROM act JOIN rsq ON rsq.rn = act.rn - 1 AND rsq.person_id = act.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"'
|| person_id || '","' || group_start || '","' || Max (end_date) || '","' || COUNT(*) || '","6817"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id, group_start

SQL_ID  516g8wq4kzryp, child number 0
-------------------------------------
/* RSF_QRY */ WITH act AS ( SELECT person_id, start_date, end_date,
Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn FROM
activity ), rsq (person_id, rn, start_date, end_date, group_start) AS (
SELECT person_id, rn, start_date, end_date, start_date FROM act WHERE
rn = 1 UNION ALL SELECT act.person_id, act.rn, act.start_date,
act.end_date, CASE WHEN act.start_date - rsq.group_start <=
Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE
act.start_date end FROM act JOIN rsq ON rsq.rn = act.rn - 1 AND
rsq.person_id = act.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */
'"' || person_id || '","' || group_start || '","' || Max (end_date) ||
'","' || COUNT(*) || '","6817"' FROM rsq GROUP BY person_id,
group_start ORDER BY person_id, group_start

Plan hash value: 941514960

--------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |          |      1 |        |   3325 |00:07:08.74 |    3790K|       |       |          |
|   1 |  SORT GROUP BY                             |          |      1 |    151 |   3325 |00:07:08.74 |    3790K|   302K|   302K|  268K (0)|
|   2 |   VIEW                                     |          |      1 |    151 |  45000 |00:07:08.09 |    3790K|       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|          |      1 |        |  45000 |00:07:08.07 |    3790K|  2048 |  2048 | 2881K (0)|
|*  4 |     VIEW                                   |          |      1 |      1 |      3 |00:00:00.06 |     248 |       |       |          |
|*  5 |      WINDOW SORT PUSHED RANK               |          |      1 |  45000 |      3 |00:00:00.06 |     248 |  2958K|   766K| 2629K (0)|
|   6 |       TABLE ACCESS FULL                    | ACTIVITY |      1 |  45000 |  45000 |00:00:00.01 |     248 |       |       |          |
|*  7 |     HASH JOIN                              |          |  15000 |    150 |  44997 |00:06:13.31 |    3720K|  1321K|  1321K|  683K (0)|
|   8 |      RECURSIVE WITH PUMP                   |          |  15000 |        |  45000 |00:00:00.03 |       0 |       |       |          |
|   9 |      VIEW                                  |          |  15000 |  45000 |    675M|00:07:56.72 |    3720K|       |       |          |
|  10 |       WINDOW SORT                          |          |  15000 |  45000 |    675M|00:06:20.44 |    3720K|  2108K|   682K| 1873K (0)|
|  11 |        TABLE ACCESS FULL                   | ACTIVITY |  15000 |  45000 |    675M|00:01:03.31 |    3720K|       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   4 - filter("RN"=1)
   5 - filter(ROW_NUMBER() OVER ( PARTITION BY "PERSON_ID" ORDER BY "START_DATE")<=1)
   7 - access("RSQ"."RN"="ACT"."RN"-1 AND "RSQ"."PERSON_ID"="ACT"."PERSON_ID")


Timer Set: Cursor, Constructed at 06 Nov 2016 14:38:00, written at 14:45:09
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.00             1        0.00200        0.00000
First fetch            428.74      428.47             1      428.73900      428.47000
Write to file            0.42        0.03             5        0.08320        0.00600
Remaining fetches        0.00        0.00             4        0.00100        0.00000
Write plan               0.11        0.10             1        0.10700        0.10000
(Other)                  0.01        0.00             1        0.01300        0.00000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                  429.28      428.60            14       30.66293       30.61429
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:38:00, written at 14:45:10
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000011), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.41        0.03             5        0.08240        0.00600
(Other)      429.08      428.60             1      429.07700      428.60000
-------  ----------  ----------  ------------  -------------  -------------
Total        429.49      428.63             6       71.58150       71.43833
-------  ----------  ----------  ------------  -------------  -------------
3326 rows written to RSF_QRY.csv
Summary for W/D = 30/30 , bench_run_statistics_id = 34

Timer Set: Run_One, Constructed at 06 Nov 2016 14:38:00, written at 14:45:10
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run          429.50      428.64             1      429.50200      428.64000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total        429.50      428.64             2      214.75100      214.32000
-------  ----------  ----------  ------------  -------------  -------------
/* RSF_TMP */ WITH rsq (person_id, rn, start_date, end_date, group_start) AS ( SELECT person_id, act_rownum, start_date, end_date, start_date FROM activity_tmp WHERE act_rownum = 1 UNION ALL SELECT ac
t.person_id, act.act_rownum, act.start_date, act.end_date, CASE WHEN act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE act.start_date end FROM rsq JOIN act
ivity_tmp act ON act.act_rownum = rsq.rn + 1 AND act.person_id = rsq.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || Max (end_date) || '","' || CO
UNT(*) || '","9144"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id, group_start

INSERT INTO activity_tmp SELECT person_id, start_date, end_date, Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) FROM activity
SQL_ID  466bfh0g14499, child number 0
-------------------------------------
/* RSF_TMP */ WITH rsq (person_id, rn, start_date, end_date,
group_start) AS ( SELECT person_id, act_rownum, start_date, end_date,
start_date FROM activity_tmp WHERE act_rownum = 1 UNION ALL SELECT
act.person_id, act.act_rownum, act.start_date, act.end_date, CASE WHEN
act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep')
THEN rsq.group_start ELSE act.start_date end FROM rsq JOIN activity_tmp
act ON act.act_rownum = rsq.rn + 1 AND act.person_id = rsq.person_id )
SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' ||
group_start || '","' || Max (end_date) || '","' || COUNT(*) ||
'","9144"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id,
group_start

Plan hash value: 4212061972

---------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name            | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
---------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |                 |      1 |        |   3325 |00:00:00.42 |     131K|       |       |          |
|   1 |  SORT GROUP BY                             |                 |      1 |      6 |   3325 |00:00:00.42 |     131K|   302K|   302K|  268K (0)|
|   2 |   VIEW                                     |                 |      1 |      6 |  45000 |00:00:00.38 |     131K|       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|                 |      1 |        |  45000 |00:00:00.37 |     131K|  2048 |  2048 | 2881K (0)|
|   4 |     TABLE ACCESS BY INDEX ROWID BATCHED    | ACTIVITY_TMP    |      1 |      3 |      3 |00:00:00.01 |       5 |       |       |          |
|*  5 |      INDEX RANGE SCAN                      | ACTIVITY_TMP_N1 |      1 |      3 |      3 |00:00:00.01 |       2 |       |       |          |
|   6 |     NESTED LOOPS                           |                 |  15000 |      3 |  44997 |00:00:00.16 |   61137 |       |       |          |
|   7 |      RECURSIVE WITH PUMP                   |                 |  15000 |        |  45000 |00:00:00.01 |       0 |       |       |          |
|   8 |      TABLE ACCESS BY INDEX ROWID BATCHED   | ACTIVITY_TMP    |  45000 |      1 |  44997 |00:00:00.12 |   61137 |       |       |          |
|*  9 |       INDEX RANGE SCAN                     | ACTIVITY_TMP_N1 |  45000 |    466 |  44997 |00:00:00.05 |   16140 |       |       |          |
---------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   5 - access("ACT_ROWNUM"=1)
   9 - access("ACT"."ACT_ROWNUM"="RSQ"."RN"+1 AND "ACT"."PERSON_ID"="RSQ"."PERSON_ID")

Note
-----
   - dynamic statistics used: dynamic sampling (level=2)
   - this is an adaptive plan


Timer Set: Cursor, Constructed at 06 Nov 2016 14:45:10, written at 14:45:11
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000012), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.07        0.08             1        0.07100        0.08000
Open cursor              0.01        0.02             1        0.01400        0.02000
First fetch              0.42        0.42             1        0.42300        0.42000
Write to file            0.27        0.00             5        0.05300        0.00000
Remaining fetches        0.00        0.02             4        0.00100        0.00500
Write plan               0.11        0.10             1        0.11400        0.10000
(Other)                  0.30        0.00             1        0.30200        0.00000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    1.19        0.64            14        0.08521        0.04571
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:45:10, written at 14:45:11
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000009), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.26        0.00             5        0.05240        0.00000
(Other)        0.99        0.66             1        0.98900        0.66000
-------  ----------  ----------  ------------  -------------  -------------
Total          1.25        0.66             6        0.20850        0.11000
-------  ----------  ----------  ------------  -------------  -------------
3326 rows written to RSF_TMP.csv
Summary for W/D = 30/30 , bench_run_statistics_id = 35

Timer Set: Run_One, Constructed at 06 Nov 2016 14:45:10, written at 14:45:11
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            1.26        0.68             1        1.26300        0.68000
(Other)        0.00        0.00             1        0.00100        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          1.26        0.68             2        0.63200        0.34000
-------  ----------  ----------  ------------  -------------  -------------
/* MTH_QRY */ SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' || group_start || '","' || group_end || '","' || num_rows || '","5630"' FROM activity MATCH_RECOGNIZE ( PARTITION BY person
_id ORDER BY start_date MEASURES FIRST (start_date) group_start, FINAL MAX (end_date) group_end, COUNT(*) num_rows ONE ROW PER MATCH PATTERN (strt sm*) DEFINE sm AS sm.start_date <= strt.start_date +
Sys_Context('bench_ctx', 'deep') ) m ORDER BY person_id, group_start

SQL_ID  byvj7frb0w34f, child number 0
-------------------------------------
/* MTH_QRY */ SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id ||
'","' || group_start || '","' || group_end || '","' || num_rows ||
'","5630"' FROM activity MATCH_RECOGNIZE ( PARTITION BY person_id ORDER
BY start_date MEASURES FIRST (start_date) group_start, FINAL MAX
(end_date) group_end, COUNT(*) num_rows ONE ROW PER MATCH PATTERN (strt
sm*) DEFINE sm AS sm.start_date <= strt.start_date +
Sys_Context('bench_ctx', 'deep') ) m ORDER BY person_id, group_start

Plan hash value: 3670115155

--------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                        | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                                 |          |      1 |        |   3325 |00:00:00.04 |     248 |       |       |          |
|   1 |  SORT ORDER BY                                   |          |      1 |  45000 |   3325 |00:00:00.04 |     248 |   302K|   302K|  268K (0)|
|   2 |   VIEW                                           |          |      1 |  45000 |   3325 |00:00:00.03 |     248 |       |       |          |
|   3 |    MATCH RECOGNIZE SORT DETERMINISTIC FINITE AUTO|          |      1 |  45000 |   3325 |00:00:00.03 |     248 |  2108K|   682K| 1873K (0)|
|   4 |     TABLE ACCESS FULL                            | ACTIVITY |      1 |  45000 |  45000 |00:00:00.01 |     248 |       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------------


Timer Set: Cursor, Constructed at 06 Nov 2016 14:45:11, written at 14:45:12
===========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000007), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer                 Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------------  ----------  ----------  ------------  -------------  -------------
Pre SQL                  0.00        0.00             1        0.00000        0.00000
Open cursor              0.00        0.00             1        0.00200        0.00000
First fetch              0.04        0.05             1        0.03900        0.05000
Write to file            0.30        0.00             5        0.05960        0.00000
Remaining fetches        0.00        0.00             4        0.00000        0.00000
Write plan               0.10        0.09             1        0.10000        0.09000
(Other)                  0.34        0.01             1        0.33800        0.01000
-----------------  ----------  ----------  ------------  -------------  -------------
Total                    0.78        0.15            14        0.05550        0.01071
-----------------  ----------  ----------  ------------  -------------  -------------

Timer Set: File Writer, Constructed at 06 Nov 2016 14:45:11, written at 14:45:12
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.29        0.00             5        0.05880        0.00000
(Other)        0.72        0.20             1        0.72200        0.20000
-------  ----------  ----------  ------------  -------------  -------------
Total          1.02        0.20             6        0.16933        0.03333
-------  ----------  ----------  ------------  -------------  -------------
3326 rows written to MTH_QRY.csv
Summary for W/D = 30/30 , bench_run_statistics_id = 36

Timer Set: Run_One, Constructed at 06 Nov 2016 14:45:11, written at 14:45:12
============================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000006), CPU (per call): 0.00 (0.000000), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Run            1.02        0.20             1        1.02400        0.20000
(Other)        0.00        0.00             1        0.00000        0.00000
-------  ----------  ----------  ------------  -------------  -------------
Total          1.02        0.20             2        0.51200        0.10000
-------  ----------  ----------  ------------  -------------  -------------

Distinct Plans
==============
MOD_QRY: 3/3 (1 of 1)
SQL_ID  3z698sr8q2xag, child number 0
-------------------------------------
/* MOD_QRY */ WITH all_rows AS ( SELECT person_id, start_date,
end_date, group_start FROM activity MODEL PARTITION BY (person_id)
DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY
start_date) rn) MEASURES (start_date, end_date, start_date group_start)
RULES ( group_start[rn = 1] = start_date[cv()], group_start[rn > 1] =
CASE WHEN start_date[cv()] - group_start[cv()-1] >
Sys_Context('bench_ctx', 'deep') THEN start_date[cv()] ELSE
group_start[cv()-1] END ) ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' ||
person_id || '","' || group_start || '","' || MAX(end_date) || '","' ||
COUNT(*) || '","4507"' FROM all_rows GROUP BY person_id, group_start
ORDER BY person_id, group_start

Plan hash value: 2323700320

-----------------------------------------------------------------------------------------------------------------------
| Id  | Operation             | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-----------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |          |      1 |        |   3325 |00:00:00.27 |     248 |       |       |          |
|   1 |  SORT GROUP BY        |          |      1 |  45000 |   3325 |00:00:00.27 |     248 |   267K|   267K|  237K (0)|
|   2 |   VIEW                |          |      1 |  45000 |  45000 |00:00:00.13 |     248 |       |       |          |
|   3 |    SQL MODEL ORDERED  |          |      1 |  45000 |  45000 |00:00:00.12 |     248 |  4279K|  1428K| 2957K (0)|
|   4 |     WINDOW SORT       |          |      1 |  45000 |  45000 |00:00:00.03 |     248 |  2108K|   682K| 1873K (0)|
|   5 |      TABLE ACCESS FULL| ACTIVITY |      1 |  45000 |  45000 |00:00:00.01 |     248 |       |       |          |
-----------------------------------------------------------------------------------------------------------------------

MTH_QRY: 3/3 (1 of 1)
SQL_ID  byvj7frb0w34f, child number 0
-------------------------------------
/* MTH_QRY */ SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id ||
'","' || group_start || '","' || group_end || '","' || num_rows ||
'","5630"' FROM activity MATCH_RECOGNIZE ( PARTITION BY person_id ORDER
BY start_date MEASURES FIRST (start_date) group_start, FINAL MAX
(end_date) group_end, COUNT(*) num_rows ONE ROW PER MATCH PATTERN (strt
sm*) DEFINE sm AS sm.start_date <= strt.start_date +
Sys_Context('bench_ctx', 'deep') ) m ORDER BY person_id, group_start

Plan hash value: 3670115155

--------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                        | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                                 |          |      1 |        |   3325 |00:00:00.04 |     248 |       |       |          |
|   1 |  SORT ORDER BY                                   |          |      1 |  45000 |   3325 |00:00:00.04 |     248 |   302K|   302K|  268K (0)|
|   2 |   VIEW                                           |          |      1 |  45000 |   3325 |00:00:00.03 |     248 |       |       |          |
|   3 |    MATCH RECOGNIZE SORT DETERMINISTIC FINITE AUTO|          |      1 |  45000 |   3325 |00:00:00.03 |     248 |  2108K|   682K| 1873K (0)|
|   4 |     TABLE ACCESS FULL                            | ACTIVITY |      1 |  45000 |  45000 |00:00:00.01 |     248 |       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------------

RSF_QRY: 3/3 (1 of 1)
SQL_ID  516g8wq4kzryp, child number 0
-------------------------------------
/* RSF_QRY */ WITH act AS ( SELECT person_id, start_date, end_date,
Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn FROM
activity ), rsq (person_id, rn, start_date, end_date, group_start) AS (
SELECT person_id, rn, start_date, end_date, start_date FROM act WHERE
rn = 1 UNION ALL SELECT act.person_id, act.rn, act.start_date,
act.end_date, CASE WHEN act.start_date - rsq.group_start <=
Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE
act.start_date end FROM act JOIN rsq ON rsq.rn = act.rn - 1 AND
rsq.person_id = act.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */
'"' || person_id || '","' || group_start || '","' || Max (end_date) ||
'","' || COUNT(*) || '","6817"' FROM rsq GROUP BY person_id,
group_start ORDER BY person_id, group_start

Plan hash value: 941514960

--------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |          |      1 |        |   3325 |00:07:08.74 |    3790K|       |       |          |
|   1 |  SORT GROUP BY                             |          |      1 |    151 |   3325 |00:07:08.74 |    3790K|   302K|   302K|  268K (0)|
|   2 |   VIEW                                     |          |      1 |    151 |  45000 |00:07:08.09 |    3790K|       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|          |      1 |        |  45000 |00:07:08.07 |    3790K|  2048 |  2048 | 2881K (0)|
|*  4 |     VIEW                                   |          |      1 |      1 |      3 |00:00:00.06 |     248 |       |       |          |
|*  5 |      WINDOW SORT PUSHED RANK               |          |      1 |  45000 |      3 |00:00:00.06 |     248 |  2958K|   766K| 2629K (0)|
|   6 |       TABLE ACCESS FULL                    | ACTIVITY |      1 |  45000 |  45000 |00:00:00.01 |     248 |       |       |          |
|*  7 |     HASH JOIN                              |          |  15000 |    150 |  44997 |00:06:13.31 |    3720K|  1321K|  1321K|  683K (0)|
|   8 |      RECURSIVE WITH PUMP                   |          |  15000 |        |  45000 |00:00:00.03 |       0 |       |       |          |
|   9 |      VIEW                                  |          |  15000 |  45000 |    675M|00:07:56.72 |    3720K|       |       |          |
|  10 |       WINDOW SORT                          |          |  15000 |  45000 |    675M|00:06:20.44 |    3720K|  2108K|   682K| 1873K (0)|
|  11 |        TABLE ACCESS FULL                   | ACTIVITY |  15000 |  45000 |    675M|00:01:03.31 |    3720K|       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   4 - filter("RN"=1)
   5 - filter(ROW_NUMBER() OVER ( PARTITION BY "PERSON_ID" ORDER BY "START_DATE")<=1)
   7 - access("RSQ"."RN"="ACT"."RN"-1 AND "RSQ"."PERSON_ID"="ACT"."PERSON_ID")

RSF_TMP: 3/3 (1 of 1)
SQL_ID  466bfh0g14499, child number 0
-------------------------------------
/* RSF_TMP */ WITH rsq (person_id, rn, start_date, end_date,
group_start) AS ( SELECT person_id, act_rownum, start_date, end_date,
start_date FROM activity_tmp WHERE act_rownum = 1 UNION ALL SELECT
act.person_id, act.act_rownum, act.start_date, act.end_date, CASE WHEN
act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep')
THEN rsq.group_start ELSE act.start_date end FROM rsq JOIN activity_tmp
act ON act.act_rownum = rsq.rn + 1 AND act.person_id = rsq.person_id )
SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' ||
group_start || '","' || Max (end_date) || '","' || COUNT(*) ||
'","9144"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id,
group_start

Plan hash value: 4212061972

---------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name            | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
---------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |                 |      1 |        |   3325 |00:00:00.42 |     131K|       |       |          |
|   1 |  SORT GROUP BY                             |                 |      1 |      6 |   3325 |00:00:00.42 |     131K|   302K|   302K|  268K (0)|
|   2 |   VIEW                                     |                 |      1 |      6 |  45000 |00:00:00.38 |     131K|       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|                 |      1 |        |  45000 |00:00:00.37 |     131K|  2048 |  2048 | 2881K (0)|
|   4 |     TABLE ACCESS BY INDEX ROWID BATCHED    | ACTIVITY_TMP    |      1 |      3 |      3 |00:00:00.01 |       5 |       |       |          |
|*  5 |      INDEX RANGE SCAN                      | ACTIVITY_TMP_N1 |      1 |      3 |      3 |00:00:00.01 |       2 |       |       |          |
|   6 |     NESTED LOOPS                           |                 |  15000 |      3 |  44997 |00:00:00.16 |   61137 |       |       |          |
|   7 |      RECURSIVE WITH PUMP                   |                 |  15000 |        |  45000 |00:00:00.01 |       0 |       |       |          |
|   8 |      TABLE ACCESS BY INDEX ROWID BATCHED   | ACTIVITY_TMP    |  45000 |      1 |  44997 |00:00:00.12 |   61137 |       |       |          |
|*  9 |       INDEX RANGE SCAN                     | ACTIVITY_TMP_N1 |  45000 |    466 |  44997 |00:00:00.05 |   16140 |       |       |          |
---------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   5 - access("ACT_ROWNUM"=1)
   9 - access("ACT"."ACT_ROWNUM"="RSQ"."RN"+1 AND "ACT"."PERSON_ID"="RSQ"."PERSON_ID")

Note
-----
   - dynamic statistics used: dynamic sampling (level=2)
   - this is an adaptive plan


Data Points
===========
Data Point:               size_wide      size_deep       cpu_time        elapsed       num_recs       per_part     group_size
Data Point                       10             10           1.42          2.433          15000           5000              3
Data Point                       10             20            .96          1.152          15000           5000              4
Data Point                       10             30            .97           .999          15000           5000              5
Data Point                       20             10           1.97          3.332          30000          10000              4
Data Point                       20             20           1.86          1.973          30000          10000              7
Data Point                       20             30           1.97          2.082          30000          10000             10
Data Point                       30             10           2.86          3.643          45000          15000              6
Data Point                       30             20           2.81          3.007          45000          15000             10
Data Point                       30             30           2.92          3.645          45000          15000             14

num_records_out
===============
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10           6166           3951           2910
MOD_QRY                         W20           7710           4537           3199
MOD_QRY                         W30           8451           4771           3325
MTH_QRY                         W10           6166           3951           2910
MTH_QRY                         W20           7710           4537           3199
MTH_QRY                         W30           8451           4771           3325
RSF_QRY                         W10           6166           3951           2910
RSF_QRY                         W20           7710           4537           3199
RSF_QRY                         W30           8451           4771           3325
RSF_TMP                         W10           6166           3951           2910
RSF_TMP                         W20           7710           4537           3199
RSF_TMP                         W30           8451           4771           3325

num_records_out_SLICE
=====================
Run Type                        D10            D20            D30
MOD_QRY                        8451           4771           3325
MTH_QRY                        8451           4771           3325
RSF_QRY                        8451           4771           3325
RSF_TMP                        8451           4771           3325

num_records_out_RATIO
=====================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10              1              1              1
MOD_QRY                         W20              1              1              1
MOD_QRY                         W30              1              1              1
MTH_QRY                         W10              1              1              1
MTH_QRY                         W20              1              1              1
MTH_QRY                         W30              1              1              1
RSF_QRY                         W10              1              1              1
RSF_QRY                         W20              1              1              1
RSF_QRY                         W30              1              1              1
RSF_TMP                         W10              1              1              1
RSF_TMP                         W20              1              1              1
RSF_TMP                         W30              1              1              1

num_records_out_SLICE_RATIO
===========================
Run Type                        D10            D20            D30
MOD_QRY                           1              1              1
MTH_QRY                           1              1              1
RSF_QRY                           1              1              1
RSF_TMP                           1              1              1

cpu_time
========
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10            .08            .08            .11
MOD_QRY                         W20            .18            .17            .17
MOD_QRY                         W30            .26            .25             .3
MTH_QRY                         W10            .03            .01            .02
MTH_QRY                         W20            .03            .03            .02
MTH_QRY                         W30            .06            .05            .05
RSF_QRY                         W10          46.41          46.28          46.67
RSF_QRY                         W20         186.42         190.24         187.33
RSF_QRY                         W30          422.6         439.31         428.47
RSF_TMP                         W10            .21            .16            .16
RSF_TMP                         W20            .33            .37            .32
RSF_TMP                         W30            .53            .52            .54

cpu_time_SLICE
==============
Run Type                        D10            D20            D30
MOD_QRY                         .26            .25             .3
MTH_QRY                         .06            .05            .05
RSF_QRY                       422.6         439.31         428.47
RSF_TMP                         .53            .52            .54

cpu_time_RATIO
==============
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10           2.67              8            5.5
MOD_QRY                         W20              6           5.67            8.5
MOD_QRY                         W30           4.33              5              6
MTH_QRY                         W10              1              1              1
MTH_QRY                         W20              1              1              1
MTH_QRY                         W30              1              1              1
RSF_QRY                         W10           1547           4628         2333.5
RSF_QRY                         W20           6214        6341.33         9366.5
RSF_QRY                         W30        7043.33         8786.2         8569.4
RSF_TMP                         W10              7             16              8
RSF_TMP                         W20             11          12.33             16
RSF_TMP                         W30           8.83           10.4           10.8

cpu_time_SLICE_RATIO
====================
Run Type                        D10            D20            D30
MOD_QRY                        4.33              5              6
MTH_QRY                           1              1              1
RSF_QRY                     7043.33         8786.2         8569.4
RSF_TMP                        8.83           10.4           10.8

elapsed_time
============
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10           .087           .081           .102
MOD_QRY                         W20           .165           .164           .163
MOD_QRY                         W30           .252           .236            .28
MTH_QRY                         W10           .069           .019           .016
MTH_QRY                         W20           .037           .032           .026
MTH_QRY                         W30           .055            .04           .041
RSF_QRY                         W10         46.452         46.289         46.687
RSF_QRY                         W20        186.518        190.347        187.431
RSF_QRY                         W30        422.698        439.848        428.745
RSF_TMP                         W10           .193           .164           .162
RSF_TMP                         W20           .337           .409           .322
RSF_TMP                         W30            .53           .514           .512

elapsed_time_SLICE
==================
Run Type                        D10            D20            D30
MOD_QRY                        .252           .236            .28
MTH_QRY                        .055            .04           .041
RSF_QRY                     422.698        439.848        428.745
RSF_TMP                         .53           .514           .512

elapsed_time_RATIO
==================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10           1.26           4.26           6.38
MOD_QRY                         W20           4.46           5.13           6.27
MOD_QRY                         W30           4.58            5.9           6.83
MTH_QRY                         W10              1              1              1
MTH_QRY                         W20              1              1              1
MTH_QRY                         W30              1              1              1
RSF_QRY                         W10         673.22        2436.26        2917.94
RSF_QRY                         W20        5041.03        5948.34        7208.88
RSF_QRY                         W30        7685.42        10996.2        10457.2
RSF_TMP                         W10            2.8           8.63          10.13
RSF_TMP                         W20           9.11          12.78          12.38
RSF_TMP                         W30           9.64          12.85          12.49

elapsed_time_SLICE_RATIO
========================
Run Type                        D10            D20            D30
MOD_QRY                        4.58            5.9           6.83
MTH_QRY                           1              1              1
RSF_QRY                     7685.42        10996.2        10457.2
RSF_TMP                        9.64          12.85          12.49

memory_used
===========
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10        1197056        1192960        1167360
MOD_QRY                         W20        2134016        2137088        2136064
MOD_QRY                         W30        3046400        3036160        3027968
MTH_QRY                         W10         692224         692224         692224
MTH_QRY                         W20        1272832        1272832        1272832
MTH_QRY                         W30        1917952        1917952        1917952
RSF_QRY                         W10        1014784        1014784        1014784
RSF_QRY                         W20        1982464        1982464        1982464
RSF_QRY                         W30        2950144        2950144        2950144
RSF_TMP                         W10        1014784        1014784        1014784
RSF_TMP                         W20        1982464        1982464        1982464
RSF_TMP                         W30        2950144        2950144        2950144

memory_used_SLICE
=================
Run Type                        D10            D20            D30
MOD_QRY                     3046400        3036160        3027968
MTH_QRY                     1917952        1917952        1917952
RSF_QRY                     2950144        2950144        2950144
RSF_TMP                     2950144        2950144        2950144

memory_used_RATIO
=================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10           1.73           1.72           1.69
MOD_QRY                         W20           1.68           1.68           1.68
MOD_QRY                         W30           1.59           1.58           1.58
MTH_QRY                         W10              1              1              1
MTH_QRY                         W20              1              1              1
MTH_QRY                         W30              1              1              1
RSF_QRY                         W10           1.47           1.47           1.47
RSF_QRY                         W20           1.56           1.56           1.56
RSF_QRY                         W30           1.54           1.54           1.54
RSF_TMP                         W10           1.47           1.47           1.47
RSF_TMP                         W20           1.56           1.56           1.56
RSF_TMP                         W30           1.54           1.54           1.54

memory_used_SLICE_RATIO
=======================
Run Type                        D10            D20            D30
MOD_QRY                        1.59           1.58           1.58
MTH_QRY                           1              1              1
RSF_QRY                        1.54           1.54           1.54
RSF_TMP                        1.54           1.54           1.54

buffers
=======
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10             84             84             84
MOD_QRY                         W20            191            191            191
MOD_QRY                         W30            248            248            248
MTH_QRY                         W10             84             84             84
MTH_QRY                         W20            191            191            191
MTH_QRY                         W30            248            248            248
RSF_QRY                         W10         435302         435302         435302
RSF_QRY                         W20        1952152        1952152        1952152
RSF_QRY                         W30        3790638        3790638        3790638
RSF_TMP                         W10          35601          35601          35601
RSF_TMP                         W20          82728          82705          82728
RSF_TMP                         W30         131534         131569         131532

buffers_SLICE
=============
Run Type                        D10            D20            D30
MOD_QRY                         248            248            248
MTH_QRY                         248            248            248
RSF_QRY                     3790638        3790638        3790638
RSF_TMP                      131534         131569         131532

buffers_RATIO
=============
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10              1              1              1
MOD_QRY                         W20              1              1              1
MOD_QRY                         W30              1              1              1
MTH_QRY                         W10              1              1              1
MTH_QRY                         W20              1              1              1
MTH_QRY                         W30              1              1              1
RSF_QRY                         W10        5182.17        5182.17        5182.17
RSF_QRY                         W20       10220.69       10220.69       10220.69
RSF_QRY                         W30       15284.83       15284.83       15284.83
RSF_TMP                         W10         423.82         423.82         423.82
RSF_TMP                         W20         433.13         433.01         433.13
RSF_TMP                         W30         530.38         530.52         530.37

buffers_SLICE_RATIO
===================
Run Type                        D10            D20            D30
MOD_QRY                           1              1              1
MTH_QRY                           1              1              1
RSF_QRY                    15284.83       15284.83       15284.83
RSF_TMP                      530.38         530.52         530.37

disk_reads
==========
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10              0              0              0
MOD_QRY                         W20              0              0              0
MOD_QRY                         W30              0              0              0
MTH_QRY                         W10              0              0              0
MTH_QRY                         W20              0              0              0
MTH_QRY                         W30              0              0              0
RSF_QRY                         W10              0              0              0
RSF_QRY                         W20              0              0              0
RSF_QRY                         W30              0              0              0
RSF_TMP                         W10              0              0              0
RSF_TMP                         W20              0              0              0
RSF_TMP                         W30              0              0              0

disk_reads_SLICE
================
Run Type                        D10            D20            D30
MOD_QRY                           0              0              0
MTH_QRY                           0              0              0
RSF_QRY                           0              0              0
RSF_TMP                           0              0              0

disk_reads_RATIO
================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10              0              0              0
MOD_QRY                         W20              0              0              0
MOD_QRY                         W30              0              0              0
MTH_QRY                         W10              0              0              0
MTH_QRY                         W20              0              0              0
MTH_QRY                         W30              0              0              0
RSF_QRY                         W10              0              0              0
RSF_QRY                         W20              0              0              0
RSF_QRY                         W30              0              0              0
RSF_TMP                         W10              0              0              0
RSF_TMP                         W20              0              0              0
RSF_TMP                         W30              0              0              0

disk_reads_SLICE_RATIO
======================
Run Type                        D10            D20            D30
MOD_QRY                           0              0              0
MTH_QRY                           0              0              0
RSF_QRY                           0              0              0
RSF_TMP                           0              0              0

disk_writes
===========
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10              0              0              0
MOD_QRY                         W20              0              0              0
MOD_QRY                         W30              0              0              0
MTH_QRY                         W10              0              0              0
MTH_QRY                         W20              0              0              0
MTH_QRY                         W30              0              0              0
RSF_QRY                         W10              0              0              0
RSF_QRY                         W20              0              0              0
RSF_QRY                         W30              0              0              0
RSF_TMP                         W10              0              0              0
RSF_TMP                         W20              0              0              0
RSF_TMP                         W30              0              0              0

disk_writes_SLICE
=================
Run Type                        D10            D20            D30
MOD_QRY                           0              0              0
MTH_QRY                           0              0              0
RSF_QRY                           0              0              0
RSF_TMP                           0              0              0

disk_writes_RATIO
=================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10              0              0              0
MOD_QRY                         W20              0              0              0
MOD_QRY                         W30              0              0              0
MTH_QRY                         W10              0              0              0
MTH_QRY                         W20              0              0              0
MTH_QRY                         W30              0              0              0
RSF_QRY                         W10              0              0              0
RSF_QRY                         W20              0              0              0
RSF_QRY                         W30              0              0              0
RSF_TMP                         W10              0              0              0
RSF_TMP                         W20              0              0              0
RSF_TMP                         W30              0              0              0

disk_writes_SLICE_RATIO
=======================
Run Type                        D10            D20            D30
MOD_QRY                           0              0              0
MTH_QRY                           0              0              0
RSF_QRY                           0              0              0
RSF_TMP                           0              0              0

tempseg_size
============
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10
MOD_QRY                         W20
MOD_QRY                         W30
MTH_QRY                         W10
MTH_QRY                         W20
MTH_QRY                         W30
RSF_QRY                         W10
RSF_QRY                         W20
RSF_QRY                         W30
RSF_TMP                         W10
RSF_TMP                         W20
RSF_TMP                         W30

tempseg_size_SLICE
==================
Run Type                        D10            D20            D30
MOD_QRY
MTH_QRY
RSF_QRY
RSF_TMP

tempseg_size_RATIO
==================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10
MOD_QRY                         W20
MOD_QRY                         W30
MTH_QRY                         W10
MTH_QRY                         W20
MTH_QRY                         W30
RSF_QRY                         W10
RSF_QRY                         W20
RSF_QRY                         W30
RSF_TMP                         W10
RSF_TMP                         W20
RSF_TMP                         W30

tempseg_size_SLICE_RATIO
========================
Run Type                        D10            D20            D30
MOD_QRY
MTH_QRY
RSF_QRY
RSF_TMP

cardinality
===========
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10          15000          15000          15000
MOD_QRY                         W20          30000          30000          30000
MOD_QRY                         W30          45000          45000          45000
MTH_QRY                         W10          15000          15000          15000
MTH_QRY                         W20          30000          30000          30000
MTH_QRY                         W30          45000          45000          45000
RSF_QRY                         W10          15000          15000          15000
RSF_QRY                         W20          30000          30000          30000
RSF_QRY                         W30          45000          45000          45000
RSF_TMP                         W10            150            150            150
RSF_TMP                         W20            242            290            242
RSF_TMP                         W30            466            460            466

cardinality_SLICE
=================
Run Type                        D10            D20            D30
MOD_QRY                       45000          45000          45000
MTH_QRY                       45000          45000          45000
RSF_QRY                       45000          45000          45000
RSF_TMP                         466            460            466

cardinality_RATIO
=================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10            100            100            100
MOD_QRY                         W20         123.97         103.45         123.97
MOD_QRY                         W30          96.57          97.83          96.57
MTH_QRY                         W10            100            100            100
MTH_QRY                         W20         123.97         103.45         123.97
MTH_QRY                         W30          96.57          97.83          96.57
RSF_QRY                         W10            100            100            100
RSF_QRY                         W20         123.97         103.45         123.97
RSF_QRY                         W30          96.57          97.83          96.57
RSF_TMP                         W10              1              1              1
RSF_TMP                         W20              1              1              1
RSF_TMP                         W30              1              1              1

cardinality_SLICE_RATIO
=======================
Run Type                        D10            D20            D30
MOD_QRY                       96.57          97.83          96.57
MTH_QRY                       96.57          97.83          96.57
RSF_QRY                       96.57          97.83          96.57
RSF_TMP                           1              1              1

output_rows
===========
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10          15000          15000          15000
MOD_QRY                         W20          30000          30000          30000
MOD_QRY                         W30          45000          45000          45000
MTH_QRY                         W10          15000          15000          15000
MTH_QRY                         W20          30000          30000          30000
MTH_QRY                         W30          45000          45000          45000
RSF_QRY                         W10       75000000       75000000       75000000
RSF_QRY                         W20      300000000      300000000      300000000
RSF_QRY                         W30      675000000      675000000      675000000
RSF_TMP                         W10          15000          15000          15000
RSF_TMP                         W20          30000          30000          30000
RSF_TMP                         W30          45000          45000          45000

output_rows_SLICE
=================
Run Type                        D10            D20            D30
MOD_QRY                       45000          45000          45000
MTH_QRY                       45000          45000          45000
RSF_QRY                   675000000      675000000      675000000
RSF_TMP                       45000          45000          45000

output_rows_RATIO
=================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10              1              1              1
MOD_QRY                         W20              1              1              1
MOD_QRY                         W30              1              1              1
MTH_QRY                         W10              1              1              1
MTH_QRY                         W20              1              1              1
MTH_QRY                         W30              1              1              1
RSF_QRY                         W10           5000           5000           5000
RSF_QRY                         W20          10000          10000          10000
RSF_QRY                         W30          15000          15000          15000
RSF_TMP                         W10              1              1              1
RSF_TMP                         W20              1              1              1
RSF_TMP                         W30              1              1              1

output_rows_SLICE_RATIO
=======================
Run Type                        D10            D20            D30
MOD_QRY                           1              1              1
MTH_QRY                           1              1              1
RSF_QRY                       15000          15000          15000
RSF_TMP                           1              1              1

cardinality_error
=================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10           8834          11049          12090
MOD_QRY                         W20          22290          25463          26801
MOD_QRY                         W30          36549          40229          41675
MTH_QRY                         W10           8834          11049          12090
MTH_QRY                         W20          22290          25463          26801
MTH_QRY                         W30          36549          40229          41675
RSF_QRY                         W10         235003         235003         235003
RSF_QRY                         W20         970003         970003         970003
RSF_QRY                         W30        2205003        2205003        2205003
RSF_TMP                         W10        2235003        2235003        2235003
RSF_TMP                         W20        7230003        8670003        7230003
RSF_TMP                         W30       20925003       20655003       20925003

cardinality_error_SLICE
=======================
Run Type                        D10            D20            D30
MOD_QRY                       36549          40229          41675
MTH_QRY                       36549          40229          41675
RSF_QRY                     2205003        2205003        2205003
RSF_TMP                    20925003       20655003       20925003

cardinality_error_RATIO
=======================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10              1              1              1
MOD_QRY                         W20              1              1              1
MOD_QRY                         W30              1              1              1
MTH_QRY                         W10              1              1              1
MTH_QRY                         W20              1              1              1
MTH_QRY                         W30              1              1              1
RSF_QRY                         W10           26.6          21.27          19.44
RSF_QRY                         W20          43.52          38.09          36.19
RSF_QRY                         W30          60.33          54.81          52.91
RSF_TMP                         W10            253         202.28         184.86
RSF_TMP                         W20         324.36         340.49         269.77
RSF_TMP                         W30         572.52         513.44          502.1

cardinality_error_SLICE_RATIO
=============================
Run Type                        D10            D20            D30
MOD_QRY                           1              1              1
MTH_QRY                           1              1              1
RSF_QRY                       60.33          54.81          52.91
RSF_TMP                      572.52         513.44          502.1
WITH wit AS (SELECT query_name, point_wide, size_wide, point_deep, stat_val f_real, Round (stat_val / Greatest (Min (stat_val) OVER (PARTITION BY point_deep, point_wide), 0.000001), 2) f_ratio FROM be
nch_run_v$stats_v WHERE stat_name = 'sorts (rows)' AND stat_type = 'STAT') SELECT text FROM (SELECT query_name, point_wide, '"' || query_name || '","W' || size_wide || '","' || Max (CASE point_deep WH
EN 1 THEN f_real END) || '","' || Max (CASE point_deep WHEN 2 THEN f_real END) || '","' || Max (CASE point_deep WHEN 3 THEN f_real END) || '"' text FROM wit GROUP BY query_name, point_wide, size_wide)
 ORDER BY query_name, point_wide


sorts (rows)
============
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10          33922          46742          30000
MOD_QRY                         W20          60000          60000          60000
MOD_QRY                         W30          90000          90000          90000
MTH_QRY                         W10          21166          18951          17910
MTH_QRY                         W20          37710          34537          33199
MTH_QRY                         W30          53451          49771          48325
RSF_QRY                         W10       75045000       75045000       75045000
RSF_QRY                         W20      300090000      300090000      300090000
RSF_QRY                         W30      675135000      675135000      675135000
RSF_TMP                         W10          75000          75000          75000
RSF_TMP                         W20         115398         120458         115398
RSF_TMP                         W30         168164         167772         168164

sorts (rows)_SLICE
==================
Run Type                        D10            D20            D30
MOD_QRY                       90000          90000          90000
MTH_QRY                       53451          49771          48325
RSF_QRY                   675135000      675135000      675135000
RSF_TMP                      168164         167772         168164

sorts (rows)_RATIO
==================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10            1.6           2.47           1.68
MOD_QRY                         W20           1.59           1.74           1.81
MOD_QRY                         W30           1.68           1.81           1.86
MTH_QRY                         W10              1              1              1
MTH_QRY                         W20              1              1              1
MTH_QRY                         W30              1              1              1
RSF_QRY                         W10        3545.54        3959.95        4190.12
RSF_QRY                         W20        7957.84        8688.94        9039.13
RSF_QRY                         W30       12630.91       13564.83       13970.72
RSF_TMP                         W10           3.54           3.96           4.19
RSF_TMP                         W20           3.06           3.49           3.48
RSF_TMP                         W30           3.15           3.37           3.48

sorts (rows)_SLICE_RATIO
========================
Run Type                        D10            D20            D30
MOD_QRY                        1.68           1.81           1.86
MTH_QRY                           1              1              1
RSF_QRY                    12630.91       13564.83       13970.72
RSF_TMP                        3.15           3.37           3.48

Top Stats
=========
WITH wit AS (SELECT query_name, point_wide, size_wide, point_deep, stat_val f_real, Round (stat_val / Greatest (Min (stat_val) OVER (PARTITION BY point_deep, point_wide), 0.000001), 2) f_ratio FROM be
nch_run_v$stats_v WHERE stat_name = 'temp space allocated (bytes)' AND stat_type = 'STAT') SELECT text FROM (SELECT query_name, point_wide, '"' || query_name || '","W' || size_wide || '","' || Max (CA
SE point_deep WHEN 1 THEN f_real END) || '","' || Max (CASE point_deep WHEN 2 THEN f_real END) || '","' || Max (CASE point_deep WHEN 3 THEN f_real END) || '"' text FROM wit GROUP BY query_name, point_
wide, size_wide) ORDER BY query_name, point_wide


temp space allocated (bytes)
============================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10              0              0              0
MOD_QRY                         W20              0              0              0
MOD_QRY                         W30              0              0              0
MTH_QRY                         W10              0              0              0
MTH_QRY                         W20              0              0              0
MTH_QRY                         W30              0              0              0
RSF_QRY                         W10              0              0              0
RSF_QRY                         W20              0              0              0
RSF_QRY                         W30              0              0              0
RSF_TMP                         W10        2097152        2097152        2097152
RSF_TMP                         W20        2097152        2097152        2097152
RSF_TMP                         W30        4194304        4194304        4194304

temp space allocated (bytes)_SLICE
==================================
Run Type                        D10            D20            D30
MOD_QRY                           0              0              0
MTH_QRY                           0              0              0
RSF_QRY                           0              0              0
RSF_TMP                     4194304        4194304        4194304

temp space allocated (bytes)_RATIO
==================================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10              0              0              0
MOD_QRY                         W20              0              0              0
MOD_QRY                         W30              0              0              0
MTH_QRY                         W10              0              0              0
MTH_QRY                         W20              0              0              0
MTH_QRY                         W30              0              0              0
RSF_QRY                         W10              0              0              0
RSF_QRY                         W20              0              0              0
RSF_QRY                         W30              0              0              0
RSF_TMP                         W10  2097152000000  2097152000000  2097152000000
RSF_TMP                         W20  2097152000000  2097152000000  2097152000000
RSF_TMP                         W30  4194304000000  4194304000000  4194304000000

temp space allocated (bytes)_SLICE_RATIO
========================================
Run Type                        D10            D20            D30
MOD_QRY                           0              0              0
MTH_QRY                           0              0              0
RSF_QRY                           0              0              0
RSF_TMP               4194304000000  4194304000000  4194304000000
WITH wit AS (SELECT query_name, point_wide, size_wide, point_deep, stat_val f_real, Round (stat_val / Greatest (Min (stat_val) OVER (PARTITION BY point_deep, point_wide), 0.000001), 2) f_ratio FROM be
nch_run_v$stats_v WHERE stat_name = 'process queue reference' AND stat_type = 'LATCH') SELECT text FROM (SELECT query_name, point_wide, '"' || query_name || '","W' || size_wide || '","' || Max (CASE p
oint_deep WHEN 1 THEN f_real END) || '","' || Max (CASE point_deep WHEN 2 THEN f_real END) || '","' || Max (CASE point_deep WHEN 3 THEN f_real END) || '"' text FROM wit GROUP BY query_name, point_wide
, size_wide) ORDER BY query_name, point_wide


process queue reference
=======================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10              1              1              1
MOD_QRY                         W20              1              1              1
MOD_QRY                         W30              1              1              1
MTH_QRY                         W10              1              1              1
MTH_QRY                         W20              1              1              1
MTH_QRY                         W30              1              1              1
RSF_QRY                         W10           3855           3538           1773
RSF_QRY                         W20          22678          11409          10782
RSF_QRY                         W30          26456          25671          64057
RSF_TMP                         W10              1              1              1
RSF_TMP                         W20              1              1              1
RSF_TMP                         W30              1              1              1

process queue reference_SLICE
=============================
Run Type                        D10            D20            D30
MOD_QRY                           1              1              1
MTH_QRY                           1              1              1
RSF_QRY                       26456          25671          64057
RSF_TMP                           1              1              1

process queue reference_RATIO
=============================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10              1              1              1
MOD_QRY                         W20              1              1              1
MOD_QRY                         W30              1              1              1
MTH_QRY                         W10              1              1              1
MTH_QRY                         W20              1              1              1
MTH_QRY                         W30              1              1              1
RSF_QRY                         W10           3855           3538           1773
RSF_QRY                         W20          22678          11409          10782
RSF_QRY                         W30          26456          25671          64057
RSF_TMP                         W10              1              1              1
RSF_TMP                         W20              1              1              1
RSF_TMP                         W30              1              1              1

process queue reference_SLICE_RATIO
===================================
Run Type                        D10            D20            D30
MOD_QRY                           1              1              1
MTH_QRY                           1              1              1
RSF_QRY                       26456          25671          64057
RSF_TMP                           1              1              1
WITH wit AS (SELECT query_name, point_wide, size_wide, point_deep, stat_val f_real, Round (stat_val / Greatest (Min (stat_val) OVER (PARTITION BY point_deep, point_wide), 0.000001), 2) f_ratio FROM be
nch_run_v$stats_v WHERE stat_name = 'table scan disk non-IMC rows gotten' AND stat_type = 'STAT') SELECT text FROM (SELECT query_name, point_wide, '"' || query_name || '","W' || size_wide || '","' ||
Max (CASE point_deep WHEN 1 THEN f_real END) || '","' || Max (CASE point_deep WHEN 2 THEN f_real END) || '","' || Max (CASE point_deep WHEN 3 THEN f_real END) || '"' text FROM wit GROUP BY query_name,
 point_wide, size_wide) ORDER BY query_name, point_wide


table scan disk non-IMC rows gotten
===================================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10          18922          15000          26835
MOD_QRY                         W20          30000          30000          30000
MOD_QRY                         W30          45000          45000          45000
MTH_QRY                         W10          15000          15000          15000
MTH_QRY                         W20          30000          30000          30000
MTH_QRY                         W30          56835          45000          45000
RSF_QRY                         W10       75015000       75015000       75015000
RSF_QRY                         W20      300030000      300030000      300030000
RSF_QRY                         W30      675045000      675045000      675045000
RSF_TMP                         W10          56832          45000          45000
RSF_TMP                         W20          41835          30000          30000
RSF_TMP                         W30          45000          45000          45000

table scan disk non-IMC rows gotten_SLICE
=========================================
Run Type                        D10            D20            D30
MOD_QRY                       45000          45000          45000
MTH_QRY                       56835          45000          45000
RSF_QRY                   675045000      675045000      675045000
RSF_TMP                       45000          45000          45000

table scan disk non-IMC rows gotten_RATIO
=========================================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10           1.26              1           1.79
MOD_QRY                         W20              1              1              1
MOD_QRY                         W30              1              1              1
MTH_QRY                         W10              1              1              1
MTH_QRY                         W20              1              1              1
MTH_QRY                         W30           1.26              1              1
RSF_QRY                         W10           5001           5001           5001
RSF_QRY                         W20          10001          10001          10001
RSF_QRY                         W30          15001          15001          15001
RSF_TMP                         W10           3.79              3              3
RSF_TMP                         W20           1.39              1              1
RSF_TMP                         W30              1              1              1

table scan disk non-IMC rows gotten_SLICE_RATIO
===============================================
Run Type                        D10            D20            D30
MOD_QRY                           1              1              1
MTH_QRY                        1.26              1              1
RSF_QRY                       15001          15001          15001
RSF_TMP                           1              1              1
WITH wit AS (SELECT query_name, point_wide, size_wide, point_deep, stat_val f_real, Round (stat_val / Greatest (Min (stat_val) OVER (PARTITION BY point_deep, point_wide), 0.000001), 2) f_ratio FROM be
nch_run_v$stats_v WHERE stat_name = 'sorts (rows)' AND stat_type = 'STAT') SELECT text FROM (SELECT query_name, point_wide, '"' || query_name || '","W' || size_wide || '","' || Max (CASE point_deep WH
EN 1 THEN f_real END) || '","' || Max (CASE point_deep WHEN 2 THEN f_real END) || '","' || Max (CASE point_deep WHEN 3 THEN f_real END) || '"' text FROM wit GROUP BY query_name, point_wide, size_wide)
 ORDER BY query_name, point_wide


sorts (rows)
============
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10          33922          46742          30000
MOD_QRY                         W20          60000          60000          60000
MOD_QRY                         W30          90000          90000          90000
MTH_QRY                         W10          21166          18951          17910
MTH_QRY                         W20          37710          34537          33199
MTH_QRY                         W30          53451          49771          48325
RSF_QRY                         W10       75045000       75045000       75045000
RSF_QRY                         W20      300090000      300090000      300090000
RSF_QRY                         W30      675135000      675135000      675135000
RSF_TMP                         W10          75000          75000          75000
RSF_TMP                         W20         115398         120458         115398
RSF_TMP                         W30         168164         167772         168164

sorts (rows)_SLICE
==================
Run Type                        D10            D20            D30
MOD_QRY                       90000          90000          90000
MTH_QRY                       53451          49771          48325
RSF_QRY                   675135000      675135000      675135000
RSF_TMP                      168164         167772         168164

sorts (rows)_RATIO
==================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10            1.6           2.47           1.68
MOD_QRY                         W20           1.59           1.74           1.81
MOD_QRY                         W30           1.68           1.81           1.86
MTH_QRY                         W10              1              1              1
MTH_QRY                         W20              1              1              1
MTH_QRY                         W30              1              1              1
RSF_QRY                         W10        3545.54        3959.95        4190.12
RSF_QRY                         W20        7957.84        8688.94        9039.13
RSF_QRY                         W30       12630.91       13564.83       13970.72
RSF_TMP                         W10           3.54           3.96           4.19
RSF_TMP                         W20           3.06           3.49           3.48
RSF_TMP                         W30           3.15           3.37           3.48

sorts (rows)_SLICE_RATIO
========================
Run Type                        D10            D20            D30
MOD_QRY                        1.68           1.81           1.86
MTH_QRY                           1              1              1
RSF_QRY                    12630.91       13564.83       13970.72
RSF_TMP                        3.15           3.37           3.48
WITH wit AS (SELECT query_name, point_wide, size_wide, point_deep, stat_val f_real, Round (stat_val / Greatest (Min (stat_val) OVER (PARTITION BY point_deep, point_wide), 0.000001), 2) f_ratio FROM be
nch_run_v$stats_v WHERE stat_name = 'cache buffers chains' AND stat_type = 'LATCH') SELECT text FROM (SELECT query_name, point_wide, '"' || query_name || '","W' || size_wide || '","' || Max (CASE poin
t_deep WHEN 1 THEN f_real END) || '","' || Max (CASE point_deep WHEN 2 THEN f_real END) || '","' || Max (CASE point_deep WHEN 3 THEN f_real END) || '"' text FROM wit GROUP BY query_name, point_wide, s
ize_wide) ORDER BY query_name, point_wide


cache buffers chains
====================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10          37599           1053           2012
MOD_QRY                         W20           1000            793            812
MOD_QRY                         W30            921           1252           1139
MTH_QRY                         W10          37051            757            596
MTH_QRY                         W20            810            893            959
MTH_QRY                         W30           1067            904            979
RSF_QRY                         W10         930433         898521         903548
RSF_QRY                         W20        3973087        4008414        3989563
RSF_QRY                         W30        7702896        7701731        7718058
RSF_TMP                         W10         134245          94775          94773
RSF_TMP                         W20         223370         223044         223276
RSF_TMP                         W30         356793         357197         356756

cache buffers chains_SLICE
==========================
Run Type                        D10            D20            D30
MOD_QRY                         921           1252           1139
MTH_QRY                        1067            904            979
RSF_QRY                     7702896        7701731        7718058
RSF_TMP                      356793         357197         356756

cache buffers chains_RATIO
==========================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10           1.01           1.39           3.38
MOD_QRY                         W20           1.23              1              1
MOD_QRY                         W30              1           1.38           1.16
MTH_QRY                         W10              1              1              1
MTH_QRY                         W20              1           1.13           1.18
MTH_QRY                         W30           1.16              1              1
RSF_QRY                         W10          25.11        1186.95        1516.02
RSF_QRY                         W20        4905.05        5054.75        4913.25
RSF_QRY                         W30        8363.62        8519.61        7883.61
RSF_TMP                         W10           3.62          125.2         159.02
RSF_TMP                         W20         275.77         281.27         274.97
RSF_TMP                         W30          387.4         395.13         364.41

cache buffers chains_SLICE_RATIO
================================
Run Type                        D10            D20            D30
MOD_QRY                           1           1.38           1.16
MTH_QRY                        1.16              1              1
RSF_QRY                     8363.62        8519.61        7883.61
RSF_TMP                       387.4         395.13         364.41
WITH wit AS (SELECT query_name, point_wide, size_wide, point_deep, stat_val f_real, Round (stat_val / Greatest (Min (stat_val) OVER (PARTITION BY point_deep, point_wide), 0.000001), 2) f_ratio FROM be
nch_run_v$stats_v WHERE stat_name = 'logical read bytes from cache' AND stat_type = 'STAT') SELECT text FROM (SELECT query_name, point_wide, '"' || query_name || '","W' || size_wide || '","' || Max (C
ASE point_deep WHEN 1 THEN f_real END) || '","' || Max (CASE point_deep WHEN 2 THEN f_real END) || '","' || Max (CASE point_deep WHEN 3 THEN f_real END) || '"' text FROM wit GROUP BY query_name, point
_wide, size_wide) ORDER BY query_name, point_wide


logical read bytes from cache
=============================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10        6004736        5971968        8241152
MOD_QRY                         W20        5611520        4546560        4194304
MOD_QRY                         W30        4636672        5742592        5267456
MTH_QRY                         W10        4964352        5734400        3866624
MTH_QRY                         W20        4530176        4374528        4997120
MTH_QRY                         W30        8970240        4423680        4579328
RSF_QRY                         W10     3569631232     3570081792     3569803264
RSF_QRY                         W20    15994675200    15994806272    15994773504
RSF_QRY                         W30    31055880192    31055937536    31055536128
RSF_TMP                         W10      324878336      313499648      313122816
RSF_TMP                         W20      719626240      714039296      715243520
RSF_TMP                         W30     1129111552     1133158400     1129496576

logical read bytes from cache_SLICE
===================================
Run Type                        D10            D20            D30
MOD_QRY                     4636672        5742592        5267456
MTH_QRY                     8970240        4423680        4579328
RSF_QRY                 31055880192    31055937536    31055536128
RSF_TMP                  1129111552     1133158400     1129496576

logical read bytes from cache_RATIO
===================================
Run Type                      Width            D10            D20            D30
MOD_QRY                         W10           1.21           1.04           2.13
MOD_QRY                         W20           1.24           1.04              1
MOD_QRY                         W30              1            1.3           1.15
MTH_QRY                         W10              1              1              1
MTH_QRY                         W20              1              1           1.19
MTH_QRY                         W30           1.93              1              1
RSF_QRY                         W10         719.05         622.57         923.24
RSF_QRY                         W20         3530.7        3656.35        3813.45
RSF_QRY                         W30        6697.88        7020.39        6781.68
RSF_TMP                         W10          65.44          54.67          80.98
RSF_TMP                         W20         158.85         163.23         170.53
RSF_TMP                         W30         243.52         256.16         246.65

logical read bytes from cache_SLICE_RATIO
=========================================
Run Type                        D10            D20            D30
MOD_QRY                           1            1.3           1.15
MTH_QRY                        1.93              1              1
RSF_QRY                     6697.88        7020.39        6781.68
RSF_TMP                      243.52         256.16         246.65

Timer Set: File Writer, Constructed at 06 Nov 2016 14:45:12, written at 14:45:16
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000014), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.00        0.00             1        0.00000        0.00000
(Other)        4.45        2.26             1        4.45200        2.26000
-------  ----------  ----------  ------------  -------------  -------------
Total          4.45        2.26             2        2.22600        1.13000
-------  ----------  ----------  ------------  -------------  -------------
WITH wit AS (SELECT query_name, point_deep, size_deep, point_wide, FACT f_real, Round (FACT / Greatest (Min (FACT) OVER (PARTITION BY point_deep, point_wide), 0.000001), 2) f_ratio FROM bench_v$sql_pl
an_stats_all_v) SELECT text FROM (SELECT query_name, point_deep, '"' || query_name || '","D' || size_deep || '","' || Max (CASE point_wide WHEN 1 THEN f_real END) || '","' || Max (CASE point_wide WHEN
 2 THEN f_real END) || '","' || Max (CASE point_wide WHEN 3 THEN f_real END) || '"' text FROM wit GROUP BY query_name, point_deep, size_deep) ORDER BY query_name, point_deep


Distinct Plans
==============
MOD_QRY: 3/3 (1 of 1)
SQL_ID  3z698sr8q2xag, child number 0
-------------------------------------
/* MOD_QRY */ WITH all_rows AS ( SELECT person_id, start_date,
end_date, group_start FROM activity MODEL PARTITION BY (person_id)
DIMENSION BY (Row_Number() OVER (PARTITION BY person_id ORDER BY
start_date) rn) MEASURES (start_date, end_date, start_date group_start)
RULES ( group_start[rn = 1] = start_date[cv()], group_start[rn > 1] =
CASE WHEN start_date[cv()] - group_start[cv()-1] >
Sys_Context('bench_ctx', 'deep') THEN start_date[cv()] ELSE
group_start[cv()-1] END ) ) SELECT /*+ GATHER_PLAN_STATISTICS */ '"' ||
person_id || '","' || group_start || '","' || MAX(end_date) || '","' ||
COUNT(*) || '","4507"' FROM all_rows GROUP BY person_id, group_start
ORDER BY person_id, group_start

Plan hash value: 2323700320

-----------------------------------------------------------------------------------------------------------------------
| Id  | Operation             | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-----------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |          |      1 |        |   3325 |00:00:00.27 |     248 |       |       |          |
|   1 |  SORT GROUP BY        |          |      1 |  45000 |   3325 |00:00:00.27 |     248 |   267K|   267K|  237K (0)|
|   2 |   VIEW                |          |      1 |  45000 |  45000 |00:00:00.13 |     248 |       |       |          |
|   3 |    SQL MODEL ORDERED  |          |      1 |  45000 |  45000 |00:00:00.12 |     248 |  4279K|  1428K| 2957K (0)|
|   4 |     WINDOW SORT       |          |      1 |  45000 |  45000 |00:00:00.03 |     248 |  2108K|   682K| 1873K (0)|
|   5 |      TABLE ACCESS FULL| ACTIVITY |      1 |  45000 |  45000 |00:00:00.01 |     248 |       |       |          |
-----------------------------------------------------------------------------------------------------------------------

MTH_QRY: 3/3 (1 of 1)
SQL_ID  byvj7frb0w34f, child number 0
-------------------------------------
/* MTH_QRY */ SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id ||
'","' || group_start || '","' || group_end || '","' || num_rows ||
'","5630"' FROM activity MATCH_RECOGNIZE ( PARTITION BY person_id ORDER
BY start_date MEASURES FIRST (start_date) group_start, FINAL MAX
(end_date) group_end, COUNT(*) num_rows ONE ROW PER MATCH PATTERN (strt
sm*) DEFINE sm AS sm.start_date <= strt.start_date +
Sys_Context('bench_ctx', 'deep') ) m ORDER BY person_id, group_start

Plan hash value: 3670115155

--------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                        | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                                 |          |      1 |        |   3325 |00:00:00.04 |     248 |       |       |          |
|   1 |  SORT ORDER BY                                   |          |      1 |  45000 |   3325 |00:00:00.04 |     248 |   302K|   302K|  268K (0)|
|   2 |   VIEW                                           |          |      1 |  45000 |   3325 |00:00:00.03 |     248 |       |       |          |
|   3 |    MATCH RECOGNIZE SORT DETERMINISTIC FINITE AUTO|          |      1 |  45000 |   3325 |00:00:00.03 |     248 |  2108K|   682K| 1873K (0)|
|   4 |     TABLE ACCESS FULL                            | ACTIVITY |      1 |  45000 |  45000 |00:00:00.01 |     248 |       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------------

RSF_QRY: 3/3 (1 of 1)
SQL_ID  516g8wq4kzryp, child number 0
-------------------------------------
/* RSF_QRY */ WITH act AS ( SELECT person_id, start_date, end_date,
Row_Number() OVER (PARTITION BY person_id ORDER BY start_date) rn FROM
activity ), rsq (person_id, rn, start_date, end_date, group_start) AS (
SELECT person_id, rn, start_date, end_date, start_date FROM act WHERE
rn = 1 UNION ALL SELECT act.person_id, act.rn, act.start_date,
act.end_date, CASE WHEN act.start_date - rsq.group_start <=
Sys_Context('bench_ctx', 'deep') THEN rsq.group_start ELSE
act.start_date end FROM act JOIN rsq ON rsq.rn = act.rn - 1 AND
rsq.person_id = act.person_id ) SELECT /*+ GATHER_PLAN_STATISTICS */
'"' || person_id || '","' || group_start || '","' || Max (end_date) ||
'","' || COUNT(*) || '","6817"' FROM rsq GROUP BY person_id,
group_start ORDER BY person_id, group_start

Plan hash value: 941514960

--------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name     | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |          |      1 |        |   3325 |00:07:08.74 |    3790K|       |       |          |
|   1 |  SORT GROUP BY                             |          |      1 |    151 |   3325 |00:07:08.74 |    3790K|   302K|   302K|  268K (0)|
|   2 |   VIEW                                     |          |      1 |    151 |  45000 |00:07:08.09 |    3790K|       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|          |      1 |        |  45000 |00:07:08.07 |    3790K|  2048 |  2048 | 2881K (0)|
|*  4 |     VIEW                                   |          |      1 |      1 |      3 |00:00:00.06 |     248 |       |       |          |
|*  5 |      WINDOW SORT PUSHED RANK               |          |      1 |  45000 |      3 |00:00:00.06 |     248 |  2958K|   766K| 2629K (0)|
|   6 |       TABLE ACCESS FULL                    | ACTIVITY |      1 |  45000 |  45000 |00:00:00.01 |     248 |       |       |          |
|*  7 |     HASH JOIN                              |          |  15000 |    150 |  44997 |00:06:13.31 |    3720K|  1321K|  1321K|  683K (0)|
|   8 |      RECURSIVE WITH PUMP                   |          |  15000 |        |  45000 |00:00:00.03 |       0 |       |       |          |
|   9 |      VIEW                                  |          |  15000 |  45000 |    675M|00:07:56.72 |    3720K|       |       |          |
|  10 |       WINDOW SORT                          |          |  15000 |  45000 |    675M|00:06:20.44 |    3720K|  2108K|   682K| 1873K (0)|
|  11 |        TABLE ACCESS FULL                   | ACTIVITY |  15000 |  45000 |    675M|00:01:03.31 |    3720K|       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   4 - filter("RN"=1)
   5 - filter(ROW_NUMBER() OVER ( PARTITION BY "PERSON_ID" ORDER BY "START_DATE")<=1)
   7 - access("RSQ"."RN"="ACT"."RN"-1 AND "RSQ"."PERSON_ID"="ACT"."PERSON_ID")

RSF_TMP: 3/3 (1 of 1)
SQL_ID  466bfh0g14499, child number 0
-------------------------------------
/* RSF_TMP */ WITH rsq (person_id, rn, start_date, end_date,
group_start) AS ( SELECT person_id, act_rownum, start_date, end_date,
start_date FROM activity_tmp WHERE act_rownum = 1 UNION ALL SELECT
act.person_id, act.act_rownum, act.start_date, act.end_date, CASE WHEN
act.start_date - rsq.group_start <= Sys_Context('bench_ctx', 'deep')
THEN rsq.group_start ELSE act.start_date end FROM rsq JOIN activity_tmp
act ON act.act_rownum = rsq.rn + 1 AND act.person_id = rsq.person_id )
SELECT /*+ GATHER_PLAN_STATISTICS */ '"' || person_id || '","' ||
group_start || '","' || Max (end_date) || '","' || COUNT(*) ||
'","9144"' FROM rsq GROUP BY person_id, group_start ORDER BY person_id,
group_start

Plan hash value: 4212061972

---------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                  | Name            | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
---------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                           |                 |      1 |        |   3325 |00:00:00.42 |     131K|       |       |          |
|   1 |  SORT GROUP BY                             |                 |      1 |      6 |   3325 |00:00:00.42 |     131K|   302K|   302K|  268K (0)|
|   2 |   VIEW                                     |                 |      1 |      6 |  45000 |00:00:00.38 |     131K|       |       |          |
|   3 |    UNION ALL (RECURSIVE WITH) BREADTH FIRST|                 |      1 |        |  45000 |00:00:00.37 |     131K|  2048 |  2048 | 2881K (0)|
|   4 |     TABLE ACCESS BY INDEX ROWID BATCHED    | ACTIVITY_TMP    |      1 |      3 |      3 |00:00:00.01 |       5 |       |       |          |
|*  5 |      INDEX RANGE SCAN                      | ACTIVITY_TMP_N1 |      1 |      3 |      3 |00:00:00.01 |       2 |       |       |          |
|   6 |     NESTED LOOPS                           |                 |  15000 |      3 |  44997 |00:00:00.16 |   61137 |       |       |          |
|   7 |      RECURSIVE WITH PUMP                   |                 |  15000 |        |  45000 |00:00:00.01 |       0 |       |       |          |
|   8 |      TABLE ACCESS BY INDEX ROWID BATCHED   | ACTIVITY_TMP    |  45000 |      1 |  44997 |00:00:00.12 |   61137 |       |       |          |
|*  9 |       INDEX RANGE SCAN                     | ACTIVITY_TMP_N1 |  45000 |    466 |  44997 |00:00:00.05 |   16140 |       |       |          |
---------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   5 - access("ACT_ROWNUM"=1)
   9 - access("ACT"."ACT_ROWNUM"="RSQ"."RN"+1 AND "ACT"."PERSON_ID"="RSQ"."PERSON_ID")

Note
-----
   - dynamic statistics used: dynamic sampling (level=2)
   - this is an adaptive plan


Data Points
===========
Data Point:               size_wide      size_deep       cpu_time        elapsed       num_recs       per_part     group_size
Data Point                       10             10           1.42          2.433          15000           5000              3
Data Point                       10             20            .96          1.152          15000           5000              4
Data Point                       10             30            .97           .999          15000           5000              5
Data Point                       20             10           1.97          3.332          30000          10000              4
Data Point                       20             20           1.86          1.973          30000          10000              7
Data Point                       20             30           1.97          2.082          30000          10000             10
Data Point                       30             10           2.86          3.643          45000          15000              6
Data Point                       30             20           2.81          3.007          45000          15000             10
Data Point                       30             30           2.92          3.645          45000          15000             14

num_records_out
===============
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10           6166           7710           8451
MOD_QRY                         D20           3951           4537           4771
MOD_QRY                         D30           2910           3199           3325
MTH_QRY                         D10           6166           7710           8451
MTH_QRY                         D20           3951           4537           4771
MTH_QRY                         D30           2910           3199           3325
RSF_QRY                         D10           6166           7710           8451
RSF_QRY                         D20           3951           4537           4771
RSF_QRY                         D30           2910           3199           3325
RSF_TMP                         D10           6166           7710           8451
RSF_TMP                         D20           3951           4537           4771
RSF_TMP                         D30           2910           3199           3325

num_records_out_SLICE
=====================
Run Type                        W10            W20            W30
MOD_QRY                        2910           3199           3325
MTH_QRY                        2910           3199           3325
RSF_QRY                        2910           3199           3325
RSF_TMP                        2910           3199           3325

num_records_out_RATIO
=====================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10              1              1              1
MOD_QRY                         D20              1              1              1
MOD_QRY                         D30              1              1              1
MTH_QRY                         D10              1              1              1
MTH_QRY                         D20              1              1              1
MTH_QRY                         D30              1              1              1
RSF_QRY                         D10              1              1              1
RSF_QRY                         D20              1              1              1
RSF_QRY                         D30              1              1              1
RSF_TMP                         D10              1              1              1
RSF_TMP                         D20              1              1              1
RSF_TMP                         D30              1              1              1

num_records_out_SLICE_RATIO
===========================
Run Type                        W10            W20            W30
MOD_QRY                           1              1              1
MTH_QRY                           1              1              1
RSF_QRY                           1              1              1
RSF_TMP                           1              1              1

cpu_time
========
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10            .08            .18            .26
MOD_QRY                         D20            .08            .17            .25
MOD_QRY                         D30            .11            .17             .3
MTH_QRY                         D10            .03            .03            .06
MTH_QRY                         D20            .01            .03            .05
MTH_QRY                         D30            .02            .02            .05
RSF_QRY                         D10          46.41         186.42          422.6
RSF_QRY                         D20          46.28         190.24         439.31
RSF_QRY                         D30          46.67         187.33         428.47
RSF_TMP                         D10            .21            .33            .53
RSF_TMP                         D20            .16            .37            .52
RSF_TMP                         D30            .16            .32            .54

cpu_time_SLICE
==============
Run Type                        W10            W20            W30
MOD_QRY                         .11            .17             .3
MTH_QRY                         .02            .02            .05
RSF_QRY                       46.67         187.33         428.47
RSF_TMP                         .16            .32            .54

cpu_time_RATIO
==============
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10           2.67              6           4.33
MOD_QRY                         D20              8           5.67              5
MOD_QRY                         D30            5.5            8.5              6
MTH_QRY                         D10              1              1              1
MTH_QRY                         D20              1              1              1
MTH_QRY                         D30              1              1              1
RSF_QRY                         D10           1547           6214        7043.33
RSF_QRY                         D20           4628        6341.33         8786.2
RSF_QRY                         D30         2333.5         9366.5         8569.4
RSF_TMP                         D10              7             11           8.83
RSF_TMP                         D20             16          12.33           10.4
RSF_TMP                         D30              8             16           10.8

cpu_time_SLICE_RATIO
====================
Run Type                        W10            W20            W30
MOD_QRY                         5.5            8.5              6
MTH_QRY                           1              1              1
RSF_QRY                      2333.5         9366.5         8569.4
RSF_TMP                           8             16           10.8

elapsed_time
============
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10           .087           .165           .252
MOD_QRY                         D20           .081           .164           .236
MOD_QRY                         D30           .102           .163            .28
MTH_QRY                         D10           .069           .037           .055
MTH_QRY                         D20           .019           .032            .04
MTH_QRY                         D30           .016           .026           .041
RSF_QRY                         D10         46.452        186.518        422.698
RSF_QRY                         D20         46.289        190.347        439.848
RSF_QRY                         D30         46.687        187.431        428.745
RSF_TMP                         D10           .193           .337            .53
RSF_TMP                         D20           .164           .409           .514
RSF_TMP                         D30           .162           .322           .512

elapsed_time_SLICE
==================
Run Type                        W10            W20            W30
MOD_QRY                        .102           .163            .28
MTH_QRY                        .016           .026           .041
RSF_QRY                      46.687        187.431        428.745
RSF_TMP                        .162           .322           .512

elapsed_time_RATIO
==================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10           1.26           4.46           4.58
MOD_QRY                         D20           4.26           5.13            5.9
MOD_QRY                         D30           6.38           6.27           6.83
MTH_QRY                         D10              1              1              1
MTH_QRY                         D20              1              1              1
MTH_QRY                         D30              1              1              1
RSF_QRY                         D10         673.22        5041.03        7685.42
RSF_QRY                         D20        2436.26        5948.34        10996.2
RSF_QRY                         D30        2917.94        7208.88        10457.2
RSF_TMP                         D10            2.8           9.11           9.64
RSF_TMP                         D20           8.63          12.78          12.85
RSF_TMP                         D30          10.13          12.38          12.49

elapsed_time_SLICE_RATIO
========================
Run Type                        W10            W20            W30
MOD_QRY                        6.38           6.27           6.83
MTH_QRY                           1              1              1
RSF_QRY                     2917.94        7208.88        10457.2
RSF_TMP                       10.13          12.38          12.49

memory_used
===========
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10        1197056        2134016        3046400
MOD_QRY                         D20        1192960        2137088        3036160
MOD_QRY                         D30        1167360        2136064        3027968
MTH_QRY                         D10         692224        1272832        1917952
MTH_QRY                         D20         692224        1272832        1917952
MTH_QRY                         D30         692224        1272832        1917952
RSF_QRY                         D10        1014784        1982464        2950144
RSF_QRY                         D20        1014784        1982464        2950144
RSF_QRY                         D30        1014784        1982464        2950144
RSF_TMP                         D10        1014784        1982464        2950144
RSF_TMP                         D20        1014784        1982464        2950144
RSF_TMP                         D30        1014784        1982464        2950144

memory_used_SLICE
=================
Run Type                        W10            W20            W30
MOD_QRY                     1167360        2136064        3027968
MTH_QRY                      692224        1272832        1917952
RSF_QRY                     1014784        1982464        2950144
RSF_TMP                     1014784        1982464        2950144

memory_used_RATIO
=================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10           1.73           1.68           1.59
MOD_QRY                         D20           1.72           1.68           1.58
MOD_QRY                         D30           1.69           1.68           1.58
MTH_QRY                         D10              1              1              1
MTH_QRY                         D20              1              1              1
MTH_QRY                         D30              1              1              1
RSF_QRY                         D10           1.47           1.56           1.54
RSF_QRY                         D20           1.47           1.56           1.54
RSF_QRY                         D30           1.47           1.56           1.54
RSF_TMP                         D10           1.47           1.56           1.54
RSF_TMP                         D20           1.47           1.56           1.54
RSF_TMP                         D30           1.47           1.56           1.54

memory_used_SLICE_RATIO
=======================
Run Type                        W10            W20            W30
MOD_QRY                        1.69           1.68           1.58
MTH_QRY                           1              1              1
RSF_QRY                        1.47           1.56           1.54
RSF_TMP                        1.47           1.56           1.54

buffers
=======
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10             84            191            248
MOD_QRY                         D20             84            191            248
MOD_QRY                         D30             84            191            248
MTH_QRY                         D10             84            191            248
MTH_QRY                         D20             84            191            248
MTH_QRY                         D30             84            191            248
RSF_QRY                         D10         435302        1952152        3790638
RSF_QRY                         D20         435302        1952152        3790638
RSF_QRY                         D30         435302        1952152        3790638
RSF_TMP                         D10          35601          82728         131534
RSF_TMP                         D20          35601          82705         131569
RSF_TMP                         D30          35601          82728         131532

buffers_SLICE
=============
Run Type                        W10            W20            W30
MOD_QRY                          84            191            248
MTH_QRY                          84            191            248
RSF_QRY                      435302        1952152        3790638
RSF_TMP                       35601          82728         131532

buffers_RATIO
=============
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10              1              1              1
MOD_QRY                         D20              1              1              1
MOD_QRY                         D30              1              1              1
MTH_QRY                         D10              1              1              1
MTH_QRY                         D20              1              1              1
MTH_QRY                         D30              1              1              1
RSF_QRY                         D10        5182.17       10220.69       15284.83
RSF_QRY                         D20        5182.17       10220.69       15284.83
RSF_QRY                         D30        5182.17       10220.69       15284.83
RSF_TMP                         D10         423.82         433.13         530.38
RSF_TMP                         D20         423.82         433.01         530.52
RSF_TMP                         D30         423.82         433.13         530.37

buffers_SLICE_RATIO
===================
Run Type                        W10            W20            W30
MOD_QRY                           1              1              1
MTH_QRY                           1              1              1
RSF_QRY                     5182.17       10220.69       15284.83
RSF_TMP                      423.82         433.13         530.37

disk_reads
==========
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10              0              0              0
MOD_QRY                         D20              0              0              0
MOD_QRY                         D30              0              0              0
MTH_QRY                         D10              0              0              0
MTH_QRY                         D20              0              0              0
MTH_QRY                         D30              0              0              0
RSF_QRY                         D10              0              0              0
RSF_QRY                         D20              0              0              0
RSF_QRY                         D30              0              0              0
RSF_TMP                         D10              0              0              0
RSF_TMP                         D20              0              0              0
RSF_TMP                         D30              0              0              0

disk_reads_SLICE
================
Run Type                        W10            W20            W30
MOD_QRY                           0              0              0
MTH_QRY                           0              0              0
RSF_QRY                           0              0              0
RSF_TMP                           0              0              0

disk_reads_RATIO
================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10              0              0              0
MOD_QRY                         D20              0              0              0
MOD_QRY                         D30              0              0              0
MTH_QRY                         D10              0              0              0
MTH_QRY                         D20              0              0              0
MTH_QRY                         D30              0              0              0
RSF_QRY                         D10              0              0              0
RSF_QRY                         D20              0              0              0
RSF_QRY                         D30              0              0              0
RSF_TMP                         D10              0              0              0
RSF_TMP                         D20              0              0              0
RSF_TMP                         D30              0              0              0

disk_reads_SLICE_RATIO
======================
Run Type                        W10            W20            W30
MOD_QRY                           0              0              0
MTH_QRY                           0              0              0
RSF_QRY                           0              0              0
RSF_TMP                           0              0              0

disk_writes
===========
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10              0              0              0
MOD_QRY                         D20              0              0              0
MOD_QRY                         D30              0              0              0
MTH_QRY                         D10              0              0              0
MTH_QRY                         D20              0              0              0
MTH_QRY                         D30              0              0              0
RSF_QRY                         D10              0              0              0
RSF_QRY                         D20              0              0              0
RSF_QRY                         D30              0              0              0
RSF_TMP                         D10              0              0              0
RSF_TMP                         D20              0              0              0
RSF_TMP                         D30              0              0              0

disk_writes_SLICE
=================
Run Type                        W10            W20            W30
MOD_QRY                           0              0              0
MTH_QRY                           0              0              0
RSF_QRY                           0              0              0
RSF_TMP                           0              0              0

disk_writes_RATIO
=================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10              0              0              0
MOD_QRY                         D20              0              0              0
MOD_QRY                         D30              0              0              0
MTH_QRY                         D10              0              0              0
MTH_QRY                         D20              0              0              0
MTH_QRY                         D30              0              0              0
RSF_QRY                         D10              0              0              0
RSF_QRY                         D20              0              0              0
RSF_QRY                         D30              0              0              0
RSF_TMP                         D10              0              0              0
RSF_TMP                         D20              0              0              0
RSF_TMP                         D30              0              0              0

disk_writes_SLICE_RATIO
=======================
Run Type                        W10            W20            W30
MOD_QRY                           0              0              0
MTH_QRY                           0              0              0
RSF_QRY                           0              0              0
RSF_TMP                           0              0              0

tempseg_size
============
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10
MOD_QRY                         D20
MOD_QRY                         D30
MTH_QRY                         D10
MTH_QRY                         D20
MTH_QRY                         D30
RSF_QRY                         D10
RSF_QRY                         D20
RSF_QRY                         D30
RSF_TMP                         D10
RSF_TMP                         D20
RSF_TMP                         D30

tempseg_size_SLICE
==================
Run Type                        W10            W20            W30
MOD_QRY
MTH_QRY
RSF_QRY
RSF_TMP

tempseg_size_RATIO
==================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10
MOD_QRY                         D20
MOD_QRY                         D30
MTH_QRY                         D10
MTH_QRY                         D20
MTH_QRY                         D30
RSF_QRY                         D10
RSF_QRY                         D20
RSF_QRY                         D30
RSF_TMP                         D10
RSF_TMP                         D20
RSF_TMP                         D30

tempseg_size_SLICE_RATIO
========================
Run Type                        W10            W20            W30
MOD_QRY
MTH_QRY
RSF_QRY
RSF_TMP

cardinality
===========
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10          15000          30000          45000
MOD_QRY                         D20          15000          30000          45000
MOD_QRY                         D30          15000          30000          45000
MTH_QRY                         D10          15000          30000          45000
MTH_QRY                         D20          15000          30000          45000
MTH_QRY                         D30          15000          30000          45000
RSF_QRY                         D10          15000          30000          45000
RSF_QRY                         D20          15000          30000          45000
RSF_QRY                         D30          15000          30000          45000
RSF_TMP                         D10            150            242            466
RSF_TMP                         D20            150            290            460
RSF_TMP                         D30            150            242            466

cardinality_SLICE
=================
Run Type                        W10            W20            W30
MOD_QRY                       15000          30000          45000
MTH_QRY                       15000          30000          45000
RSF_QRY                       15000          30000          45000
RSF_TMP                         150            242            466

cardinality_RATIO
=================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10            100         123.97          96.57
MOD_QRY                         D20            100         103.45          97.83
MOD_QRY                         D30            100         123.97          96.57
MTH_QRY                         D10            100         123.97          96.57
MTH_QRY                         D20            100         103.45          97.83
MTH_QRY                         D30            100         123.97          96.57
RSF_QRY                         D10            100         123.97          96.57
RSF_QRY                         D20            100         103.45          97.83
RSF_QRY                         D30            100         123.97          96.57
RSF_TMP                         D10              1              1              1
RSF_TMP                         D20              1              1              1
RSF_TMP                         D30              1              1              1

cardinality_SLICE_RATIO
=======================
Run Type                        W10            W20            W30
MOD_QRY                         100         123.97          96.57
MTH_QRY                         100         123.97          96.57
RSF_QRY                         100         123.97          96.57
RSF_TMP                           1              1              1

output_rows
===========
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10          15000          30000          45000
MOD_QRY                         D20          15000          30000          45000
MOD_QRY                         D30          15000          30000          45000
MTH_QRY                         D10          15000          30000          45000
MTH_QRY                         D20          15000          30000          45000
MTH_QRY                         D30          15000          30000          45000
RSF_QRY                         D10       75000000      300000000      675000000
RSF_QRY                         D20       75000000      300000000      675000000
RSF_QRY                         D30       75000000      300000000      675000000
RSF_TMP                         D10          15000          30000          45000
RSF_TMP                         D20          15000          30000          45000
RSF_TMP                         D30          15000          30000          45000

output_rows_SLICE
=================
Run Type                        W10            W20            W30
MOD_QRY                       15000          30000          45000
MTH_QRY                       15000          30000          45000
RSF_QRY                    75000000      300000000      675000000
RSF_TMP                       15000          30000          45000

output_rows_RATIO
=================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10              1              1              1
MOD_QRY                         D20              1              1              1
MOD_QRY                         D30              1              1              1
MTH_QRY                         D10              1              1              1
MTH_QRY                         D20              1              1              1
MTH_QRY                         D30              1              1              1
RSF_QRY                         D10           5000          10000          15000
RSF_QRY                         D20           5000          10000          15000
RSF_QRY                         D30           5000          10000          15000
RSF_TMP                         D10              1              1              1
RSF_TMP                         D20              1              1              1
RSF_TMP                         D30              1              1              1

output_rows_SLICE_RATIO
=======================
Run Type                        W10            W20            W30
MOD_QRY                           1              1              1
MTH_QRY                           1              1              1
RSF_QRY                        5000          10000          15000
RSF_TMP                           1              1              1

cardinality_error
=================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10           8834          22290          36549
MOD_QRY                         D20          11049          25463          40229
MOD_QRY                         D30          12090          26801          41675
MTH_QRY                         D10           8834          22290          36549
MTH_QRY                         D20          11049          25463          40229
MTH_QRY                         D30          12090          26801          41675
RSF_QRY                         D10         235003         970003        2205003
RSF_QRY                         D20         235003         970003        2205003
RSF_QRY                         D30         235003         970003        2205003
RSF_TMP                         D10        2235003        7230003       20925003
RSF_TMP                         D20        2235003        8670003       20655003
RSF_TMP                         D30        2235003        7230003       20925003

cardinality_error_SLICE
=======================
Run Type                        W10            W20            W30
MOD_QRY                       12090          26801          41675
MTH_QRY                       12090          26801          41675
RSF_QRY                      235003         970003        2205003
RSF_TMP                     2235003        7230003       20925003

cardinality_error_RATIO
=======================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10              1              1              1
MOD_QRY                         D20              1              1              1
MOD_QRY                         D30              1              1              1
MTH_QRY                         D10              1              1              1
MTH_QRY                         D20              1              1              1
MTH_QRY                         D30              1              1              1
RSF_QRY                         D10           26.6          43.52          60.33
RSF_QRY                         D20          21.27          38.09          54.81
RSF_QRY                         D30          19.44          36.19          52.91
RSF_TMP                         D10            253         324.36         572.52
RSF_TMP                         D20         202.28         340.49         513.44
RSF_TMP                         D30         184.86         269.77          502.1

cardinality_error_SLICE_RATIO
=============================
Run Type                        W10            W20            W30
MOD_QRY                           1              1              1
MTH_QRY                           1              1              1
RSF_QRY                       19.44          36.19          52.91
RSF_TMP                      184.86         269.77          502.1
WITH wit AS (SELECT query_name, point_deep, size_deep, point_wide, stat_val f_real, Round (stat_val / Greatest (Min (stat_val) OVER (PARTITION BY point_deep, point_wide), 0.000001), 2) f_ratio FROM be
nch_run_v$stats_v WHERE stat_name = 'sorts (rows)' AND stat_type = 'STAT') SELECT text FROM (SELECT query_name, point_deep, '"' || query_name || '","D' || size_deep || '","' || Max (CASE point_wide WH
EN 1 THEN f_real END) || '","' || Max (CASE point_wide WHEN 2 THEN f_real END) || '","' || Max (CASE point_wide WHEN 3 THEN f_real END) || '"' text FROM wit GROUP BY query_name, point_deep, size_deep)
 ORDER BY query_name, point_deep


sorts (rows)
============
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10          33922          60000          90000
MOD_QRY                         D20          46742          60000          90000
MOD_QRY                         D30          30000          60000          90000
MTH_QRY                         D10          21166          37710          53451
MTH_QRY                         D20          18951          34537          49771
MTH_QRY                         D30          17910          33199          48325
RSF_QRY                         D10       75045000      300090000      675135000
RSF_QRY                         D20       75045000      300090000      675135000
RSF_QRY                         D30       75045000      300090000      675135000
RSF_TMP                         D10          75000         115398         168164
RSF_TMP                         D20          75000         120458         167772
RSF_TMP                         D30          75000         115398         168164

sorts (rows)_SLICE
==================
Run Type                        W10            W20            W30
MOD_QRY                       30000          60000          90000
MTH_QRY                       17910          33199          48325
RSF_QRY                    75045000      300090000      675135000
RSF_TMP                       75000         115398         168164

sorts (rows)_RATIO
==================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10            1.6           1.59           1.68
MOD_QRY                         D20           2.47           1.74           1.81
MOD_QRY                         D30           1.68           1.81           1.86
MTH_QRY                         D10              1              1              1
MTH_QRY                         D20              1              1              1
MTH_QRY                         D30              1              1              1
RSF_QRY                         D10        3545.54        7957.84       12630.91
RSF_QRY                         D20        3959.95        8688.94       13564.83
RSF_QRY                         D30        4190.12        9039.13       13970.72
RSF_TMP                         D10           3.54           3.06           3.15
RSF_TMP                         D20           3.96           3.49           3.37
RSF_TMP                         D30           4.19           3.48           3.48

sorts (rows)_SLICE_RATIO
========================
Run Type                        W10            W20            W30
MOD_QRY                        1.68           1.81           1.86
MTH_QRY                           1              1              1
RSF_QRY                     4190.12        9039.13       13970.72
RSF_TMP                        4.19           3.48           3.48

Top Stats
=========
WITH wit AS (SELECT query_name, point_deep, size_deep, point_wide, stat_val f_real, Round (stat_val / Greatest (Min (stat_val) OVER (PARTITION BY point_deep, point_wide), 0.000001), 2) f_ratio FROM be
nch_run_v$stats_v WHERE stat_name = 'temp space allocated (bytes)' AND stat_type = 'STAT') SELECT text FROM (SELECT query_name, point_deep, '"' || query_name || '","D' || size_deep || '","' || Max (CA
SE point_wide WHEN 1 THEN f_real END) || '","' || Max (CASE point_wide WHEN 2 THEN f_real END) || '","' || Max (CASE point_wide WHEN 3 THEN f_real END) || '"' text FROM wit GROUP BY query_name, point_
deep, size_deep) ORDER BY query_name, point_deep


temp space allocated (bytes)
============================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10              0              0              0
MOD_QRY                         D20              0              0              0
MOD_QRY                         D30              0              0              0
MTH_QRY                         D10              0              0              0
MTH_QRY                         D20              0              0              0
MTH_QRY                         D30              0              0              0
RSF_QRY                         D10              0              0              0
RSF_QRY                         D20              0              0              0
RSF_QRY                         D30              0              0              0
RSF_TMP                         D10        2097152        2097152        4194304
RSF_TMP                         D20        2097152        2097152        4194304
RSF_TMP                         D30        2097152        2097152        4194304

temp space allocated (bytes)_SLICE
==================================
Run Type                        W10            W20            W30
MOD_QRY                           0              0              0
MTH_QRY                           0              0              0
RSF_QRY                           0              0              0
RSF_TMP                     2097152        2097152        4194304

temp space allocated (bytes)_RATIO
==================================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10              0              0              0
MOD_QRY                         D20              0              0              0
MOD_QRY                         D30              0              0              0
MTH_QRY                         D10              0              0              0
MTH_QRY                         D20              0              0              0
MTH_QRY                         D30              0              0              0
RSF_QRY                         D10              0              0              0
RSF_QRY                         D20              0              0              0
RSF_QRY                         D30              0              0              0
RSF_TMP                         D10  2097152000000  2097152000000  4194304000000
RSF_TMP                         D20  2097152000000  2097152000000  4194304000000
RSF_TMP                         D30  2097152000000  2097152000000  4194304000000

temp space allocated (bytes)_SLICE_RATIO
========================================
Run Type                        W10            W20            W30
MOD_QRY                           0              0              0
MTH_QRY                           0              0              0
RSF_QRY                           0              0              0
RSF_TMP               2097152000000  2097152000000  4194304000000
WITH wit AS (SELECT query_name, point_deep, size_deep, point_wide, stat_val f_real, Round (stat_val / Greatest (Min (stat_val) OVER (PARTITION BY point_deep, point_wide), 0.000001), 2) f_ratio FROM be
nch_run_v$stats_v WHERE stat_name = 'process queue reference' AND stat_type = 'LATCH') SELECT text FROM (SELECT query_name, point_deep, '"' || query_name || '","D' || size_deep || '","' || Max (CASE p
oint_wide WHEN 1 THEN f_real END) || '","' || Max (CASE point_wide WHEN 2 THEN f_real END) || '","' || Max (CASE point_wide WHEN 3 THEN f_real END) || '"' text FROM wit GROUP BY query_name, point_deep
, size_deep) ORDER BY query_name, point_deep


process queue reference
=======================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10              1              1              1
MOD_QRY                         D20              1              1              1
MOD_QRY                         D30              1              1              1
MTH_QRY                         D10              1              1              1
MTH_QRY                         D20              1              1              1
MTH_QRY                         D30              1              1              1
RSF_QRY                         D10           3855          22678          26456
RSF_QRY                         D20           3538          11409          25671
RSF_QRY                         D30           1773          10782          64057
RSF_TMP                         D10              1              1              1
RSF_TMP                         D20              1              1              1
RSF_TMP                         D30              1              1              1

process queue reference_SLICE
=============================
Run Type                        W10            W20            W30
MOD_QRY                           1              1              1
MTH_QRY                           1              1              1
RSF_QRY                        1773          10782          64057
RSF_TMP                           1              1              1

process queue reference_RATIO
=============================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10              1              1              1
MOD_QRY                         D20              1              1              1
MOD_QRY                         D30              1              1              1
MTH_QRY                         D10              1              1              1
MTH_QRY                         D20              1              1              1
MTH_QRY                         D30              1              1              1
RSF_QRY                         D10           3855          22678          26456
RSF_QRY                         D20           3538          11409          25671
RSF_QRY                         D30           1773          10782          64057
RSF_TMP                         D10              1              1              1
RSF_TMP                         D20              1              1              1
RSF_TMP                         D30              1              1              1

process queue reference_SLICE_RATIO
===================================
Run Type                        W10            W20            W30
MOD_QRY                           1              1              1
MTH_QRY                           1              1              1
RSF_QRY                        1773          10782          64057
RSF_TMP                           1              1              1
WITH wit AS (SELECT query_name, point_deep, size_deep, point_wide, stat_val f_real, Round (stat_val / Greatest (Min (stat_val) OVER (PARTITION BY point_deep, point_wide), 0.000001), 2) f_ratio FROM be
nch_run_v$stats_v WHERE stat_name = 'table scan disk non-IMC rows gotten' AND stat_type = 'STAT') SELECT text FROM (SELECT query_name, point_deep, '"' || query_name || '","D' || size_deep || '","' ||
Max (CASE point_wide WHEN 1 THEN f_real END) || '","' || Max (CASE point_wide WHEN 2 THEN f_real END) || '","' || Max (CASE point_wide WHEN 3 THEN f_real END) || '"' text FROM wit GROUP BY query_name,
 point_deep, size_deep) ORDER BY query_name, point_deep


table scan disk non-IMC rows gotten
===================================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10          18922          30000          45000
MOD_QRY                         D20          15000          30000          45000
MOD_QRY                         D30          26835          30000          45000
MTH_QRY                         D10          15000          30000          56835
MTH_QRY                         D20          15000          30000          45000
MTH_QRY                         D30          15000          30000          45000
RSF_QRY                         D10       75015000      300030000      675045000
RSF_QRY                         D20       75015000      300030000      675045000
RSF_QRY                         D30       75015000      300030000      675045000
RSF_TMP                         D10          56832          41835          45000
RSF_TMP                         D20          45000          30000          45000
RSF_TMP                         D30          45000          30000          45000

table scan disk non-IMC rows gotten_SLICE
=========================================
Run Type                        W10            W20            W30
MOD_QRY                       26835          30000          45000
MTH_QRY                       15000          30000          45000
RSF_QRY                    75015000      300030000      675045000
RSF_TMP                       45000          30000          45000

table scan disk non-IMC rows gotten_RATIO
=========================================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10           1.26              1              1
MOD_QRY                         D20              1              1              1
MOD_QRY                         D30           1.79              1              1
MTH_QRY                         D10              1              1           1.26
MTH_QRY                         D20              1              1              1
MTH_QRY                         D30              1              1              1
RSF_QRY                         D10           5001          10001          15001
RSF_QRY                         D20           5001          10001          15001
RSF_QRY                         D30           5001          10001          15001
RSF_TMP                         D10           3.79           1.39              1
RSF_TMP                         D20              3              1              1
RSF_TMP                         D30              3              1              1

table scan disk non-IMC rows gotten_SLICE_RATIO
===============================================
Run Type                        W10            W20            W30
MOD_QRY                        1.79              1              1
MTH_QRY                           1              1              1
RSF_QRY                        5001          10001          15001
RSF_TMP                           3              1              1
WITH wit AS (SELECT query_name, point_deep, size_deep, point_wide, stat_val f_real, Round (stat_val / Greatest (Min (stat_val) OVER (PARTITION BY point_deep, point_wide), 0.000001), 2) f_ratio FROM be
nch_run_v$stats_v WHERE stat_name = 'sorts (rows)' AND stat_type = 'STAT') SELECT text FROM (SELECT query_name, point_deep, '"' || query_name || '","D' || size_deep || '","' || Max (CASE point_wide WH
EN 1 THEN f_real END) || '","' || Max (CASE point_wide WHEN 2 THEN f_real END) || '","' || Max (CASE point_wide WHEN 3 THEN f_real END) || '"' text FROM wit GROUP BY query_name, point_deep, size_deep)
 ORDER BY query_name, point_deep


sorts (rows)
============
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10          33922          60000          90000
MOD_QRY                         D20          46742          60000          90000
MOD_QRY                         D30          30000          60000          90000
MTH_QRY                         D10          21166          37710          53451
MTH_QRY                         D20          18951          34537          49771
MTH_QRY                         D30          17910          33199          48325
RSF_QRY                         D10       75045000      300090000      675135000
RSF_QRY                         D20       75045000      300090000      675135000
RSF_QRY                         D30       75045000      300090000      675135000
RSF_TMP                         D10          75000         115398         168164
RSF_TMP                         D20          75000         120458         167772
RSF_TMP                         D30          75000         115398         168164

sorts (rows)_SLICE
==================
Run Type                        W10            W20            W30
MOD_QRY                       30000          60000          90000
MTH_QRY                       17910          33199          48325
RSF_QRY                    75045000      300090000      675135000
RSF_TMP                       75000         115398         168164

sorts (rows)_RATIO
==================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10            1.6           1.59           1.68
MOD_QRY                         D20           2.47           1.74           1.81
MOD_QRY                         D30           1.68           1.81           1.86
MTH_QRY                         D10              1              1              1
MTH_QRY                         D20              1              1              1
MTH_QRY                         D30              1              1              1
RSF_QRY                         D10        3545.54        7957.84       12630.91
RSF_QRY                         D20        3959.95        8688.94       13564.83
RSF_QRY                         D30        4190.12        9039.13       13970.72
RSF_TMP                         D10           3.54           3.06           3.15
RSF_TMP                         D20           3.96           3.49           3.37
RSF_TMP                         D30           4.19           3.48           3.48

sorts (rows)_SLICE_RATIO
========================
Run Type                        W10            W20            W30
MOD_QRY                        1.68           1.81           1.86
MTH_QRY                           1              1              1
RSF_QRY                     4190.12        9039.13       13970.72
RSF_TMP                        4.19           3.48           3.48
WITH wit AS (SELECT query_name, point_deep, size_deep, point_wide, stat_val f_real, Round (stat_val / Greatest (Min (stat_val) OVER (PARTITION BY point_deep, point_wide), 0.000001), 2) f_ratio FROM be
nch_run_v$stats_v WHERE stat_name = 'cache buffers chains' AND stat_type = 'LATCH') SELECT text FROM (SELECT query_name, point_deep, '"' || query_name || '","D' || size_deep || '","' || Max (CASE poin
t_wide WHEN 1 THEN f_real END) || '","' || Max (CASE point_wide WHEN 2 THEN f_real END) || '","' || Max (CASE point_wide WHEN 3 THEN f_real END) || '"' text FROM wit GROUP BY query_name, point_deep, s
ize_deep) ORDER BY query_name, point_deep


cache buffers chains
====================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10          37599           1000            921
MOD_QRY                         D20           1053            793           1252
MOD_QRY                         D30           2012            812           1139
MTH_QRY                         D10          37051            810           1067
MTH_QRY                         D20            757            893            904
MTH_QRY                         D30            596            959            979
RSF_QRY                         D10         930433        3973087        7702896
RSF_QRY                         D20         898521        4008414        7701731
RSF_QRY                         D30         903548        3989563        7718058
RSF_TMP                         D10         134245         223370         356793
RSF_TMP                         D20          94775         223044         357197
RSF_TMP                         D30          94773         223276         356756

cache buffers chains_SLICE
==========================
Run Type                        W10            W20            W30
MOD_QRY                        2012            812           1139
MTH_QRY                         596            959            979
RSF_QRY                      903548        3989563        7718058
RSF_TMP                       94773         223276         356756

cache buffers chains_RATIO
==========================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10           1.01           1.23              1
MOD_QRY                         D20           1.39              1           1.38
MOD_QRY                         D30           3.38              1           1.16
MTH_QRY                         D10              1              1           1.16
MTH_QRY                         D20              1           1.13              1
MTH_QRY                         D30              1           1.18              1
RSF_QRY                         D10          25.11        4905.05        8363.62
RSF_QRY                         D20        1186.95        5054.75        8519.61
RSF_QRY                         D30        1516.02        4913.25        7883.61
RSF_TMP                         D10           3.62         275.77          387.4
RSF_TMP                         D20          125.2         281.27         395.13
RSF_TMP                         D30         159.02         274.97         364.41

cache buffers chains_SLICE_RATIO
================================
Run Type                        W10            W20            W30
MOD_QRY                        3.38              1           1.16
MTH_QRY                           1           1.18              1
RSF_QRY                     1516.02        4913.25        7883.61
RSF_TMP                      159.02         274.97         364.41
WITH wit AS (SELECT query_name, point_deep, size_deep, point_wide, stat_val f_real, Round (stat_val / Greatest (Min (stat_val) OVER (PARTITION BY point_deep, point_wide), 0.000001), 2) f_ratio FROM be
nch_run_v$stats_v WHERE stat_name = 'logical read bytes from cache' AND stat_type = 'STAT') SELECT text FROM (SELECT query_name, point_deep, '"' || query_name || '","D' || size_deep || '","' || Max (C
ASE point_wide WHEN 1 THEN f_real END) || '","' || Max (CASE point_wide WHEN 2 THEN f_real END) || '","' || Max (CASE point_wide WHEN 3 THEN f_real END) || '"' text FROM wit GROUP BY query_name, point
_deep, size_deep) ORDER BY query_name, point_deep


logical read bytes from cache
=============================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10        6004736        5611520        4636672
MOD_QRY                         D20        5971968        4546560        5742592
MOD_QRY                         D30        8241152        4194304        5267456
MTH_QRY                         D10        4964352        4530176        8970240
MTH_QRY                         D20        5734400        4374528        4423680
MTH_QRY                         D30        3866624        4997120        4579328
RSF_QRY                         D10     3569631232    15994675200    31055880192
RSF_QRY                         D20     3570081792    15994806272    31055937536
RSF_QRY                         D30     3569803264    15994773504    31055536128
RSF_TMP                         D10      324878336      719626240     1129111552
RSF_TMP                         D20      313499648      714039296     1133158400
RSF_TMP                         D30      313122816      715243520     1129496576

logical read bytes from cache_SLICE
===================================
Run Type                        W10            W20            W30
MOD_QRY                     8241152        4194304        5267456
MTH_QRY                     3866624        4997120        4579328
RSF_QRY                  3569803264    15994773504    31055536128
RSF_TMP                   313122816      715243520     1129496576

logical read bytes from cache_RATIO
===================================
Run Type                      Depth            W10            W20            W30
MOD_QRY                         D10           1.21           1.24              1
MOD_QRY                         D20           1.04           1.04            1.3
MOD_QRY                         D30           2.13              1           1.15
MTH_QRY                         D10              1              1           1.93
MTH_QRY                         D20              1              1              1
MTH_QRY                         D30              1           1.19              1
RSF_QRY                         D10         719.05         3530.7        6697.88
RSF_QRY                         D20         622.57        3656.35        7020.39
RSF_QRY                         D30         923.24        3813.45        6781.68
RSF_TMP                         D10          65.44         158.85         243.52
RSF_TMP                         D20          54.67         163.23         256.16
RSF_TMP                         D30          80.98         170.53         246.65

logical read bytes from cache_SLICE_RATIO
=========================================
Run Type                        W10            W20            W30
MOD_QRY                        2.13              1           1.15
MTH_QRY                           1           1.19              1
RSF_QRY                      923.24        3813.45        6781.68
RSF_TMP                       80.98         170.53         246.65

Timer Set: File Writer, Constructed at 06 Nov 2016 14:45:16, written at 14:45:21
================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000011), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Lines          0.00        0.00             1        0.00000        0.00000
(Other)        4.33        2.03             1        4.32500        2.03000
-------  ----------  ----------  ------------  -------------  -------------
Total          4.33        2.03             2        2.16250        1.01500
-------  ----------  ----------  ------------  -------------  -------------

Timer Set: Top, Constructed at 06 Nov 2016 14:11:20, written at 14:45:21
========================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000011), CPU (per call): 0.01 (0.000010), calls: 1000, '***' denotes corrected line below]

Timer          Elapsed         CPU         Calls       Ela/Call       CPU/Call
----------  ----------  ----------  ------------  -------------  -------------
Setup Data       22.31       17.74             9        2.47933        1.97111
Querying      2,009.94    2,004.31             9      223.32644      222.70111
(Other)           8.82        4.34             1        8.82300        4.34000
----------  ----------  ----------  ------------  -------------  -------------
Total         2,041.08    2,026.39            19      107.42500      106.65211
----------  ----------  ----------  ------------  -------------  -------------
Successfully completed

5041 rows selected.

Elapsed: 00:00:00.79
SQL> 
SQL> SELECT 'End: ' || To_Char(SYSDATE,'DD-MON-YYYY HH24:MI:SS') FROM DUAL
  2  /

'END:'||TO_CHAR(SYSDATE,'
-------------------------
End: 06-NOV-2016 14:45:22

Elapsed: 00:00:00.00
SQL> SPOOL OFF






A Framework for Dimensional Benchmarking of SQL Query Performance

A few years ago I wanted to investigate the performance of different SQL queries for the same problem, and wanted to include analysis of how the queries’ performance varied with problem size. In order to do this efficiently I wrote an Oracle framework consisting of tables, packages, types etc., and which I have now published here, dim_bench_sql_oracle on GitHub. As well as the obvious cpu and elapsed times, I included statistics contained in the execution plan tables, and also the differences in v$ view statistics that are gathered in the well known Runstats scripts, (originally developed by Tom Kyte, and for which there now seem to be lots of variations around, such as
Runstats utility
). My approach is to collect these statistics in tables keyed by both query and dimensions to allow for more elaborate reporting, and to easily detect unscaleable queries, for example that use resources at a rate that grows quadratically, or worse, with problem size, as in one of the demo queries. Output goes to both a text log file, and to summary csv files for importing to Excel.

This article has design information on the framework, and is best read in conjunction with the first article on its use for a specific problem, Dimensional Benchmarking of Oracle v10-v12 Queries for SQL Bursting Problems, which includes the output log produced. This problem is included in the GitHub project, so anyone interested can run it themselves fairly easily.

Update, 26 November 2016: A notes section has been added discussing design issues and features.

Here is one of the Scribd articles for which I originally developed the framework:

Loading...

Bench Data Model – ERD

bench-1-0-erd

Code Structure Diagram

bench-1-1-csd

Test_Queries Package Call Structure Table

Level 1 Level 2 Level 3 Package
Add_Query Test_Queries
Init_Statistics Test_Queries
Plan_Lines Test_Queries
Get_SQL_Id Utils
Display_Cursor DBMS_XPlan
Write_Plan_Statistics Test_Queries
Get_Queries Test_Queries
Write_Log Utils
Flush_Buf Test_Queries
Init_Time Timer_Set
Put_Line UTL_File
Increment_Time Timer_Set
Write_Line Test_Queries
Flush_Buf Test_Queries
Open_File Test_Queries
Construct Timer_Set
Fopen UTL_File
Close_File Test_Queries
Flush_Buf Test_Queries
FClose UTL_File
Write_Times Timer_Set
Outbound_Interface Test_Queries
Construct Timer_Set
Open_File Test_Queries
Write_Line Test_Queries
Process_Cursor Test_Queries
Write_Log Utils
Init_Statistics Test_Queries
Init_Time Timer_Set
Increment_Time Timer_Set
Write_Line Test_Queries
Flush_Buf Test_Queries
Write_Plan_Statistics Test_Queries
Write_Plan Utils
Write_Times Timer_Set
Get_Timer_Stats Timer_Set
Close_File Test_Queries
Write_Log Utils
Write_Size_list Test_Queries
Write_Log Utils
Write_Twice Test_Queries
Write_Line Test_Queries
Write_CSV_Fields Utils
Write_Data_Points Test_Queries
Heading Utils
Write_Line Test_Queries
Write_Twice Test_Queries
Write_Distinct_Plans Test_Queries
Heading Utils
Write_Log Utils
Write_Rows Test_Queries
Heading Utils
Write_Line Test_Queries
Write_Twice Test_Queries
Write_Rows Test_Queries
Write_Stat Test_Queries
Write_Log Utils
Write_Rows Test_Queries
Write_All_Facts Test_Queries
Write_Distinct_Plans Test_Queries
Write_Data_Points Test_Queries
Write_Rows Test_Queries
Write_Stat Test_Queries
Heading Utils
Close_File Test_Queries
Write_Stats Test_Queries
Open_File Test_Queries
Write_All_Facts Test_Queries
Write_Log Utils
Term_Run Test_Queries
Write_Times Timer_Set
Get_Run_Details Test_Queries
Construct Timer_Set
Create_Log Utils
Write_Log Utils
Heading Utils
Write_Size_list Test_Queries
Get_Queries Test_Queries
Set_Data_Point Test_Queries
Init_Time Timer_Set
Get_CPU_Time DBMS_Utility
Setup_Data Query_Test_Set
Increment_Time Timer_Set
Run_One Test_Queries
Construct Timer_Set
Outbound_Interface Test_Queries
Write_Log Utils
Write_Times Timer_Set
Create_Run Test_Queries
Write_Log Utils
Main Test_Queries
Main Test_Queries
Main Test_Queries
Get_Run_Details Test_Queries
Set_Data_Point Test_Queries
Run_One Test_Queries
Increment_Time Timer_Set
Write_Stats Test_Queries
Write_Log Utils
Write_Other_Error Utils

 
Outputs

out folder

The demo script Test_Bur.sql writes the log data to ..\out\Test_Bur.LST.

The program loops over each (W, D) data point included in the driving script lists, and outputs for each query in the group data including:

  • Full execution plan
  • CPU and elapsed timings of query execution steps, file writing and data setup

On completion of the loops, summary reports are written to both the main log and to summary csv files, mentioned below, with information including

  • Distinct execution plans (main log only)
  • Data point statistics including setup timings and records created
  • Numbers of output records from the queries
  • cpu and elapsed times for the queries
  • Execution plan statistics
  • Numerous v$ After-Before statistic differences (following the Run_Stats model)

Oracle directory: output_dir

For a query group and query with data points W-D, the results of running the query are written to:

<query_group>_<query>_<W>-<D>.csv

For example:

BURST_MTH_QRY_30-30

Two summary files are written, with the bench run id as part of the name:

<bench run id>_W.csv
<bench run id>_D.csv

These files contain all the detailed statistics in csv format, so that they can be imported into Excel and used to obtain graphs. _W has the width parameter as the row and depth as the column, and _D the other way round.

Notes

Query Timing

Obtaining reliable comparative timings of queries in a test environment is not as straightforward as it may seem. Some of the issues are considered in this article, for example, Timing an ALL_ROWS query. For ad hoc tests, running the query in SQL*Plus after ‘SET AUTOTRACE TRACEONLY’ is one of the better approaches. However, in this framework a different approach is taken in order to simulate the performance that might be obtained if the query records were fetched in batches to be processed, say as an outbound interface, where they may be written to a file on the server. To do this, the query select list is converted into CSV format and the records are written to a file, with care taken to separate the timings of the query operations from those of the file processing.

Hard Parsing

This framework is not intended for testing OLTP SQL but relatively long-running batch-type SQL, where the cost of parsing is generally negligible. As the dataset sizes vary it is possible that the execution plan may vary, so it is important that the SQL engine performs a hard-parse on each execution of a query to ensure plan re-calculation. A hard parse is ensured by appending a placeholder field into the select list CSV string of the transformed queries, which is then replaced before each execution by a random number: The SQL engine considers the queries then to be distinct and therefore re-parses them.

Code Timing

The processing within the framework is heavily instrumented using the author’s own code timing utility package Code Timing and Object Orientation and Zombies. This is very low footprint in terms both of code and of performance, operating entirely in memory with individual timers keyed by name, and (logically) object oriented so that multiple timer sets can be running at once. Timings are printed to log, and the cpu and elapsed times for the query executed are summed from the individual components for the query, together with the times for any pre-query step:

  • Pre SQL
  • Open cursor
  • First fetch
  • Remaining fetches

Benchmarking Non-Query SQL

The framework is centred around the concept of a group of queries that are run in turn against the same dataset for each dataset point. However, non-query SQL can also be benchmarked in two ways: First, the query can include database PL/SQL functions; and secondly, the query metadata record includes a clob field for pre-query SQL that can be a PL/SQL block, while the actual query could just be ‘select 1 from dual’.

Query Transformation by Regular Expression Processing

The query output is written to file in csv format, includes the hint GATHER_PLAN_STATISTICS, and has a placeholder for a random number. Rather than cluttering up the input queries with this formatting, it seemed better to have the framework do the formatting. To this end the input queries instead have a select list with individual expressions and (mandatory) aliases, which can be simple or can be in double-quotes. The aliases form the header line of the csv file. To facilitate formatting the main query select list has to be of the form:

SELECT 
/* SEL */
        expr_1          alias_1,
        expr_2          alias_2
/* SEL */

Each expression must be on a separate line, and the list must be delimited by comment lines /* SEL */ as shown. The query formatting is performed in a procedure Get_Queries using some fairly complex regular expression processing.

Statistic Output Formatting

The various kinds of statistic (basic timing, execution plan aggregates, v$ statistics) are generally output in matrix format, both WxD and DxW. First the base numbers are printed for the whole grid for each query; then the last row for each query is printed, the deep or wide ‘slice’; then the same two sets of output are printed for the ratios of each number compared to the smallest number at the same data point across all queries.

Execution Plan Aggregation

After executing a query the execution plan statistics are copied from the system view v$sql_plan_statistics_all into bench_run_v$sql_plan_stats_all, and the formatted plan is written to a nested varray in bench_run_statistics using DBMS_XPlan.Display_Cursor.

At the end useful statistics in the plans are printed in aggregate by query execution, including maximum values of memory used and disk reads and writes, etc.

Estimated vs Actual Cardinalities

Oracle’s Cost Based Optimizer (CBO) uses estimated cardinalities at each step to evaluate candidate execution plans, and using the hint GATHER_PLAN_STATISTICS causes the actual cardinalities to be collected. Differences between estimated and actuals are generally recognised as being an important factor in whether or not a ‘good’ plan is chosen, so the maximum difference is included in the aggregates printed.

V$ Statistics

The statistics in the system views v$mystat, v$latch, v$sess_time_model are written to bench_run_v$stats before query execution (value_before, wait_before) and after execution (value_after, wait_after).

At the end a selection of the (after – before) differences of these statistics is written to log and csv file in the same format as the other statistics, based on the variance across the queries at the highest data point. A simple heuristic is included in the reporting query to restrict the statistics written to those deemed of most interest in comparing the queries, but all of the statistics remain available in bench_run_v$stats for ad hoc querying if desired.

See Also…






A Note on Oracle Join Orders and Hints

I read an interesting article this week on a company internal blog (thanks, Deepak), which pointed out that many people seem to think that the hint USE_HASH needs two parameters to specify the hint, when in fact only the right table alias is required. Where more than one alias is given the hint is effectively treated as separate one-alias hints. Here is what the manual says, Oracle SQL Manual 12.1 – Hints – USE_HASH:

use_hash_hint

The USE_HASH hint instructs the optimizer to join each specified table with another row source using a hash join. For example:

SELECT /*+ USE_HASH(l h) */ *
FROM orders h, order_items l
WHERE l.order_id = h.order_id
AND l.order_id > 2400;

Observe that in the example given, with two tables, there can be only one join in the chosen plan but both aliases are given in the hint. Only one of the hints can take effect here, but which one? It depends on the join order chosen by the the Cost Based Optimizer (CBO). In the sections on USE_MERGE and USE_NL, the manual says:

Use of the USE_NL and USE_MERGE hints is recommended with the LEADING and ORDERED hints. The optimizer uses those hints when the referenced table is forced to be the inner table of a join. The hints are ignored if the referenced table is the outer table.

My colleague linked to an article by Jonathan Lewis that considers join order in relation to hash joins in some detail, Quiz Night.

You have NOT defined a hash join completely until you have specified which rowsource should be used as the build table and which as the probe table – so every time you supply the use_hash() hint for a table, you should also supply the swap_join_inputs() hint or the no_swap_join_inputs() hint.

In the article, JL asks how many execution plans are possible for a four-table query where he says he specifies both join order (leading hint) and join method for each of the three joins (use_hash). The answer is 8, which might be a surprise if you accept the specification at face value, as that would imply that a single plan has been fully specified. The explanation of the apparent paradox is of course given in the quote above. JL goes on to enumerate each possible plan, obtained by different combinations of the swap_join_inputs and no_swap_join_inputs hints. He then asserts:

Note the extreme change in shape and apparent order of tables in the plan. Despite this the join order really is t1 -> t2 -> t3 -> t4 in every case. I’ll give a quick description of the first and last plans to explain this.

The explanation seems plausible, but I can see a possible problem with it. It is possible to generate exactly the same plans using the hint leading (t2 t1 t3 t4) and different combinations of the swap hints. I could then equally plausibly assert that the join order really is t2 -> t1 -> t3 -> t4 in every case. Both assertions can’t be right can they? The explanation is that we need to consider two levels of ordering, and not just for hash joins. First, I will demonstrate how to get identical plans with different leading hints. I will use Oracle’s HR schema, and show the hints necessary to get all hash join plans (with current statistics – I am not fully specifying the plans in general):

SELECT *
  FROM employees e
  JOIN departments d
 USING (department_id)
  JOIN locations l
 USING (location_id)

You can see that hash joins are only possible between e and d, and between d and l (or rowsets that include the relevant keys).

We can use a notation x.y to mean hash-join y as the right table, using x to form the hash-table, and (x.y) to denote the resulting rowset. Then I believe there are exactly 8 possible hash-join permutations, each of which I was able to hint using leading, use_hash, swap_join_inputs and no_swap_join_input hints as follows:

1. leading (l) use_hash (d)
===========================
Combo              SJI
-------            ----
(l.d).e  
e.(l.d)            e
(d.l).e            d
e.(d.l)            d, e

2. leading (e)
==============
Combo              SJI    NSJI
-------            ----   ----
l.(e.d)
(e.d).l                   d
l.(d.e)            d
(d.e).l            d      l

Now, look at the following output where I have got exactly the same plan (the first combo above) using two different leading hints (putting in the first two aliases to be sure). The first has:

/*+ leading (l d)  use_hash (d) */

The second has:

/*+ leading (d l) use_hash (l e) swap_join_inputs (l) */

The plans that result, showing identical plan hash value of 2684174912 are:

SQL_ID  ds98jqmdbn9ym, child number 0
-------------------------------------
SELECT  /*+ leading (l d)  use_hash (d) GATHER_PLAN_STATISTICS
Lead_l_Hash_d */      *   FROM employees e   JOIN departments d  USING
(department_id)   JOIN locations l  USING (location_id)

Plan hash value: 2684174912

------------------------------------------------------------------------------------------------------------------------
| Id  | Operation           | Name        | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT    |             |      1 |        |    106 |00:00:00.01 |      25 |       |       |          |
|*  1 |  HASH JOIN          |             |      1 |    106 |    106 |00:00:00.01 |      25 |   796K|   796K| 1241K (0)|
|*  2 |   HASH JOIN         |             |      1 |     27 |     27 |00:00:00.01 |      12 |   835K|   835K| 1122K (0)|
|   3 |    TABLE ACCESS FULL| LOCATIONS   |      1 |     23 |     23 |00:00:00.01 |       6 |       |       |          |
|   4 |    TABLE ACCESS FULL| DEPARTMENTS |      1 |     27 |     27 |00:00:00.01 |       6 |       |       |          |
|   5 |   TABLE ACCESS FULL | EMPLOYEES   |      1 |    107 |    107 |00:00:00.01 |      13 |       |       |          |
------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - access("E"."DEPARTMENT_ID"="D"."DEPARTMENT_ID")
   2 - access("D"."LOCATION_ID"="L"."LOCATION_ID")

SQL_ID  fcbh8httjtpj3, child number 0
-------------------------------------
SELECT  /*+ leading (d l) use_hash (l e) swap_join_inputs (l)
GATHER_PLAN_STATISTICS Lead_d_Hash_l_e_SJI_l */      *   FROM employees
e   JOIN departments d  USING (department_id)   JOIN locations l  USING
(location_id)

Plan hash value: 2684174912

------------------------------------------------------------------------------------------------------------------------
| Id  | Operation           | Name        | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT    |             |      1 |        |    106 |00:00:00.01 |      25 |       |       |          |
|*  1 |  HASH JOIN          |             |      1 |    106 |    106 |00:00:00.01 |      25 |   796K|   796K| 1240K (0)|
|*  2 |   HASH JOIN         |             |      1 |     27 |     27 |00:00:00.01 |      12 |   835K|   835K| 1109K (0)|
|   3 |    TABLE ACCESS FULL| LOCATIONS   |      1 |     23 |     23 |00:00:00.01 |       6 |       |       |          |
|   4 |    TABLE ACCESS FULL| DEPARTMENTS |      1 |     27 |     27 |00:00:00.01 |       6 |       |       |          |
|   5 |   TABLE ACCESS FULL | EMPLOYEES   |      1 |    107 |    107 |00:00:00.01 |      13 |       |       |          |
------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - access("E"."DEPARTMENT_ID"="D"."DEPARTMENT_ID")
   2 - access("D"."LOCATION_ID"="L"."LOCATION_ID")

So, here we seem to have shown that join order l -> d -> e = join order d -> l -> e, since they have the same plan. I think that to understand this we need to separate out two levels of join order. In the two-table example I took from the manual I stated there could be only one join order in a given plan as there is only one join, meaning by join order which table appears on the left and which on the right.

Outer-level join order

This can be specified by a number assigned to each table matching the sequence number of the join in which it features. The first two tables therefore both have a sequence number of 1. Another way of looking at it can be found by considering my bracketing notation above. In general, the outer-level join sequence number for an n-table query, OS(i) = n – number of brackets enclosing table i – 1

For (l.d).e, l and d have OS = 1 and e has OS = 2. The same is true for (d.l).e.

It is in this sense of join order that JL’s queries all have the same join order, and that a single plan can arise from different outer-level join orders, once inner-join order is factored in.

Inner-level join order

This is simply the side on which a table is joined to a rowset in a given join, say 1 for the left side, and 2 for the right side in a hash join.

Note that the leading hint treats both levels of join order, but behaves differently between hash joins and other types of join.

Leading hint in hash join

  • Determines the outer-level join order
  • Defaults the inner-level join order
  • Swap_join_inputs operation overrides the inner-level default join order

Leading hint in other types of join

  • Determines the outer-level join order
  • Determines the inner-level join order on the first two tables
  • Inner-level order not applicable after first two tables

See also a later article I wrote: Benchmarking of Hash Join Options in SQL for Fixed-Depth Hierarchies






 

Code Timing and Object Orientation and Zombies

This is a Word document that I wrote initially in November 2010 and uploaded to Scribd, Code Timing and Object Orientation and Zombies, with a big update in September 2012, about code timing in several languages.

I am going to upload a number of articles to this blog shortly that make use of an updated version of the Oracle code-timing package, and I am aware that many work networks disallow Scribd access, so I thought I would put it here first, Code Timing and Object Orientation and Zombies. It’s also embedded below (if that is accessible).

Here is the introduction:

This article proposes an object-oriented design for simple CPU and elapsed timing of computer programs by individual code section or subroutine. The object data structure is first described using a diagram/tabulation approach first used in A Perl Object for Flattened Master-Detail Data in Excel, followed by a section describing method usage, and including a diagram showing a typical call structure.

The object class is then translated from the Ur-language of design into the programming languages of Oracle, Perl and Java (one might say that our class of class is instantiated into specific object classes for each language). In each case the code is listed, an example driving program is briefly described, the run results are listed, and any interesting features are highlighted.

Oracle’s implementation of object-orientation is rather different from other languages, and a section of the article discusses how one can best obtain the advantages of object orientation in Oracle, suggesting that it’s often better to bypass the ‘official’ object structures. Both approaches have been implemented here to help readers judge for themselves.

Finally, some notes are collated on differences between the languages.






 

Recursive SQL for Network Analysis, and Duality

In March 2013 I wrote an article on the use of SQL to group network-structured records into their distinct connected subnetworks, SQL for Network Grouping. I looked at two solution approaches commonly put forward on Oracle forums for these types of problem, using Oracle’s Connect By recursion, and the more recent recursive subquery factoring, and also put forward a new solution of my own using the Model clause. I noted however that SQL solutions are generally very inefficent compared with a good PL/SQL solution, such as I posted here, PL/SQL Pipelined Function for Network Analysis. For the first two methods, I noted:

  1. Non-hierarchical networks have no root nodes, so the traversal needs to be repeated from every node in the network set
  2. Hierarchical queries retrieve all possible routes through a network

I also noted that Connect By is more inefficient than recursive subquery factoring, but did not say why, promising a more detailed explanation at a later date. In this article I illustrate the behaviour of both recursive SQL methods through a series of five elementary networks, followed by a simple combination of the five. I then use the foreign key network from Oracle’s HR demo (v12 version, with OE and PM schemas included) as a final example.

In this article I consider traversal of a single connected network from a given root node (or several if each root node is specified).

It is shown that the behaviour of Connect By can be understood best by considering it to traverse all paths through a network that is dual to the original network.

Dual Networks

Dual network definition

The dual network consists of a set of nodes and links (d-nodes and d-links say) defined thus:

  • the d-nodes correspond to each link in the original network that is adjacent (via a node) to at least one other link, including itself if its start and end nodes are the same
  • the d-links correspond to each pair of adjacent links where the ‘from’ link identifier is alphabetically smaller than that of the ‘to’ link, except for the case of links that are adjacent to themselves where a single d-link has the same ‘from’ and ‘to’ link

Dual network SQL

The d-node identifiers are just the link identifiers, while the d-link identifiers use the adjacency-defining node identifiers with a sequential number (partitioned by node) attached.

WITH dist_links AS (
SELECT	DISTINCT CASE WHEN lin_2.node_fr IN (lin_1.node_fr, lin_1.node_to) THEN lin_2.node_fr ELSE lin_2.node_to END link_node,
        lin_1.id node_fr_d,
	lin_2.id node_to_d
  FROM links lin_1
  JOIN links lin_2
    ON lin_2.node_fr IN (lin_1.node_fr, lin_1.node_to)
    OR lin_2.node_to IN (lin_1.node_fr, lin_1.node_to)
 WHERE lin_2.id >= lin_1.id
   AND (lin_2.id != lin_1.id OR lin_2.node_fr = lin_1.node_to)
)
SELECT Substr (link_node, 1, Length (link_node)-1) || Row_Number () OVER (PARTITION BY link_node
                            ORDER BY node_fr_d, node_to_d) || '-' || Substr (link_node, -1),
       node_fr_d,
       node_to_d
  FROM dist_links

Dual network characteristics

Dual networks defined as above are generally larger than the original networks and are usually more heavily looped, which explains the inferior performance of Connect by compared with recursive subquery factor solutions. The PL/SQL solution mentioned above, while traversing the entire network, does not traverse all possible routes through it and its performance is thus not adversely affected by the degree of looping.

SQL Queries

The recursive SQL queries return all routes through the network from the roots supplied. In my attached script I also have versions that filter out repeated links. The pipelined function query returns a single, exhaustive route through the network, distinguishing a set of tree links from loop-closing links; it also returns all subnetworks without requiring input roots.

Pipelined Function Query (PLF)

See PL/SQL Pipelined Function for Network Analysis for the Pl/SQL function.

SELECT root_node_id             "Network",
       Count (DISTINCT link_id) OVER (PARTITION BY root_node_id) - 1 "#Links",
       Count (DISTINCT node_id) OVER (PARTITION BY root_node_id) "#Nodes",
       LPad (dirn || ' ', 2*node_level, ' ') || node_id || loop_flag "Node",
       link_id || CASE WHEN link_id = 'ROOT' THEN '_' || Substr (root_node_id, -1) END "Link",
       node_level               "Lev"
  FROM TABLE (Net_Pipe.All_Nets)
 ORDER BY line_no

Recursive Subquery Factor Query (RSF)

WITH rsf (node_id, prefix, id, lev) AS (
SELECT node_id, '', 'ROOT_' || Substr (node_id, 4, 1), 0
  FROM nodes_v
 WHERE Substr (node_id, 2, 1) = '1'
 UNION ALL
SELECT CASE WHEN l.node_id_to = r.node_id THEN l.node_id_fr ELSE l.node_id_to END,
       CASE WHEN l.node_id_fr = l.node_id_to THEN '= ' WHEN l.node_id_fr = r.node_id THEN '> ' ELSE '< ' END,
       l.link_id id, lev + 1
  FROM rsf r
  JOIN links_v l
    ON (l.node_id_fr = r.node_id OR l.node_id_to = r.node_id)
   AND l.link_id != Nvl (r.id, '0')
) SEARCH DEPTH FIRST BY node_id SET line_no
CYCLE node_id SET is_cycle TO '*' DEFAULT ' '
SELECT LPad (r.prefix || ' ', 2*r.lev) || r.node_id || is_cycle "Node",
        r.id "Link",
        line_no
  FROM rsf r
 ORDER BY line_no

Connect By Query (CBY)

SELECT node_id_fr || ' > ' || node_id_to  "Nodes",
       LPad (' ', 2 * (LEVEL-1)) || link_id || CASE WHEN CONNECT_BY_ISCYCLE = 1 THEN '*' ELSE ' ' END "Link Path"
  FROM links_v
CONNECT BY NOCYCLE ((node_id_fr = PRIOR node_id_to OR node_id_to = PRIOR node_id_fr OR
                     node_id_fr = PRIOR node_id_fr OR node_id_to = PRIOR node_id_to) /*AND link_id != PRIOR link_id*/)
 START WITH Substr (node_id_fr, 2, 1) = '1' AND Substr (node_id_to, 2, 1) = '2'
 ORDER SIBLINGS BY node_id_to

Five Elementary Networks

Oracle’s two forms of SQL recursion treat cycles differently

Connect By Cycles

The CONNECT_BY_ISCYCLE pseudocolumn returns 1 if the current row has a child which is also its ancestor. Otherwise it returns 0

Connect By queries do not return loop-closing nodes, and the prior node is marked as the cycle node.

Recursive Subquery Factor Cycles

A row is considered to form a cycle if one of its ancestor rows has the same values for the cycle columns.

Recursive Subquery Factor queries do return loop-closing nodes, and these nodes are marked as the cycle nodes.

We will see this differing behaviour clearly in the following examples. We will also see that the Connect By output on the original network has exactly the same structure as recursive subquery factor output on the dual network if the loop-closing rows are disregarded. Cycle nodes on both definitions are marked with a ‘*’ in the outputs below.

Network 1: 3 nodes in line

Dual Network, 1.3 - net-1

Network 2: Simple fork

Dual Network, 1.3 - net-2

Network 3: 2-node loop

Dual Network, 1.3 - net-3

Network 4: 3-node loop

Dual Network, 1.3 - net-4

Network 5: 2 nodes with a self-loop

Dual Network, 1.3 - net-5

Combination of Elementary Networks

Combination Network 6

Dual Network, 1.3 - net-6

This network has 10 links with 3 loops.

Combination Network 6: PLF Output

Node              Link
----------------- ----------
N1-6
> N2-6            L12-6
  = N2-6*         L22-6
  > N3-6          L23-6
    > N4-6        L34-6
      > N6-6      L46-6
        > N4-6*   L64-6
    > N5-6        L35-6
      > N7-6      L57-6
        > N8-6    L78-6
          < N5-6* L58-6

Combination Network 6: RSF Output

Node              Link
----------------- ----------
N1-6
> N2-6            L12-6
 =  N2-6*         L22-6
 >  N3-6          L23-6
   >  N4-6        L34-6
     <  N6-6      L64-6
       <  N4-6*   L46-6
     >  N6-6      L46-6
       >  N4-6*   L64-6
   >  N5-6        L35-6
     >  N7-6      L57-6
       >  N8-6    L78-6
         <  N5-6* L58-6
     >  N8-6      L58-6
       <  N7-6    L78-6
         <  N5-6* L57-6

Combination Network 6: CBY Output

Nodes           Link Path
--------------- --------------------
N1-6 > N2-6     L12-6*
N2-6 > N2-6       L22-6*
N2-6 > N3-6         L23-6*
N3-6 > N4-6           L34-6*
N6-6 > N4-6             L64-6*
N4-6 > N6-6               L46-6*
N3-6 > N5-6             L35-6*
N5-6 > N7-6               L57-6*
N5-6 > N8-6                 L58-6*
N7-6 > N8-6                   L78-6*
N7-6 > N8-6                 L78-6*
N5-6 > N8-6                   L58-6*
N5-6 > N8-6               L58-6*
N5-6 > N7-6                 L57-6*
N7-6 > N8-6                   L78-6*
N7-6 > N8-6                 L78-6*
N5-6 > N7-6                   L57-6*
N4-6 > N6-6             L46-6*
N6-6 > N4-6               L64-6*
N3-6 > N5-6           L35-6*
N3-6 > N4-6             L34-6*
N6-6 > N4-6               L64-6*
N4-6 > N6-6                 L46-6*
N4-6 > N6-6               L46-6*
N6-6 > N4-6                 L64-6*
N5-6 > N7-6             L57-6*
N5-6 > N8-6               L58-6*
N7-6 > N8-6                 L78-6*
N7-6 > N8-6               L78-6*
N5-6 > N8-6                 L58-6*
N5-6 > N8-6             L58-6*
N5-6 > N7-6               L57-6*
N7-6 > N8-6                 L78-6*
N7-6 > N8-6               L78-6*
N5-6 > N7-6                 L57-6*
N2-6 > N3-6       L23-6*
N2-6 > N2-6         L22-6*
N3-6 > N4-6         L34-6*
N6-6 > N4-6           L64-6*
N4-6 > N6-6             L46-6*
N3-6 > N5-6           L35-6*
N5-6 > N7-6             L57-6*
N5-6 > N8-6               L58-6*
N7-6 > N8-6                 L78-6*
N7-6 > N8-6               L78-6*
N5-6 > N8-6                 L58-6*
N5-6 > N8-6             L58-6*
N5-6 > N7-6               L57-6*
N7-6 > N8-6                 L78-6*
N7-6 > N8-6               L78-6*
N5-6 > N7-6                 L57-6*
N4-6 > N6-6           L46-6*
N6-6 > N4-6             L64-6*
N3-6 > N5-6         L35-6*
N3-6 > N4-6           L34-6*
N6-6 > N4-6             L64-6*
N4-6 > N6-6               L46-6*
N4-6 > N6-6             L46-6*
N6-6 > N4-6               L64-6*
N5-6 > N7-6           L57-6*
N5-6 > N8-6             L58-6*
N7-6 > N8-6               L78-6*
N7-6 > N8-6             L78-6*
N5-6 > N8-6               L58-6*
N5-6 > N8-6           L58-6*
N5-6 > N7-6             L57-6*
N7-6 > N8-6               L78-6*
N7-6 > N8-6             L78-6*
N5-6 > N7-6               L57-6*



Dual Combination Network 6

Dual Network, 1.3 - net-6-D

This network has 15 links with 6 loops, whereas the original had 10 links with 3 loops.

Dual Combination Network 6: PLF Output

Node                      Link
------------------------- ------
L12-6
> L22-6                   N2-1-6
  = L22-6*                N2-3-6
  > L23-6                 N2-4-6
    < L12-6*              N2-2-6
    > L34-6               N3-1-6
      > L35-6             N3-3-6
        < L23-6*          N3-2-6
        > L57-6           N5-1-6
          > L58-6         N5-3-6
            < L35-6*      N5-2-6
            > L78-6       N8-1-6
              < L57-6*    N7-1-6
      > L46-6             N4-1-6
        > L64-6           N6-1-6
          < L34-6*        N4-2-6

Dual Combination Network 6: RSF Output

Node                      Link
------------------------- ------
L12-6
> L22-6                   N2-1-6
 =  L22-6*                N2-3-6
 >  L23-6                 N2-4-6
   <  L12-6*              N2-2-6
   >  L34-6               N3-1-6
     >  L35-6             N3-3-6
       <  L23-6*          N3-2-6
       >  L57-6           N5-1-6
         >  L58-6         N5-3-6
           <  L35-6*      N5-2-6
           >  L78-6       N8-1-6
             <  L57-6*    N7-1-6
         >  L78-6         N7-1-6
           <  L58-6       N8-1-6
             <  L35-6*    N5-2-6
             <  L57-6*    N5-3-6
       >  L58-6           N5-2-6
         <  L57-6         N5-3-6
           <  L35-6*      N5-1-6
           >  L78-6       N7-1-6
             <  L58-6*    N8-1-6
         >  L78-6         N8-1-6
           <  L57-6       N7-1-6
             <  L35-6*    N5-1-6
             >  L58-6*    N5-3-6
     >  L46-6             N4-1-6
       >  L64-6           N6-1-6
         <  L34-6*        N4-2-6
     >  L64-6             N4-2-6
       <  L46-6           N6-1-6
         <  L34-6*        N4-1-6
   >  L35-6               N3-2-6
     <  L34-6             N3-3-6
       <  L23-6*          N3-1-6
       >  L46-6           N4-1-6
         >  L64-6         N6-1-6
           <  L34-6*      N4-2-6
       >  L64-6           N4-2-6
         <  L46-6         N6-1-6
           <  L34-6*      N4-1-6
     >  L57-6             N5-1-6
       >  L58-6           N5-3-6
         <  L35-6*        N5-2-6
         >  L78-6         N8-1-6
           <  L57-6*      N7-1-6
       >  L78-6           N7-1-6
         <  L58-6         N8-1-6
           <  L35-6*      N5-2-6
           <  L57-6*      N5-3-6
     >  L58-6             N5-2-6
       <  L57-6           N5-3-6
         <  L35-6*        N5-1-6
         >  L78-6         N7-1-6
           <  L58-6*      N8-1-6
       >  L78-6           N8-1-6
         <  L57-6         N7-1-6
           <  L35-6*      N5-1-6
           >  L58-6*      N5-3-6
> L23-6                   N2-2-6
 <  L22-6                 N2-4-6
   <  L12-6*              N2-1-6
   =  L22-6*              N2-3-6
 >  L34-6                 N3-1-6
   >  L35-6               N3-3-6
     <  L23-6*            N3-2-6
     >  L57-6             N5-1-6
       >  L58-6           N5-3-6
         <  L35-6*        N5-2-6
         >  L78-6         N8-1-6
           <  L57-6*      N7-1-6
       >  L78-6           N7-1-6
         <  L58-6         N8-1-6
           <  L35-6*      N5-2-6
           <  L57-6*      N5-3-6
     >  L58-6             N5-2-6
       <  L57-6           N5-3-6
         <  L35-6*        N5-1-6
         >  L78-6         N7-1-6
           <  L58-6*      N8-1-6
       >  L78-6           N8-1-6
         <  L57-6         N7-1-6
           <  L35-6*      N5-1-6
           >  L58-6*      N5-3-6
   >  L46-6               N4-1-6
     >  L64-6             N6-1-6
       <  L34-6*          N4-2-6
   >  L64-6               N4-2-6
     <  L46-6             N6-1-6
       <  L34-6*          N4-1-6
 >  L35-6                 N3-2-6
   <  L34-6               N3-3-6
     <  L23-6*            N3-1-6
     >  L46-6             N4-1-6
       >  L64-6           N6-1-6
         <  L34-6*        N4-2-6
     >  L64-6             N4-2-6
       <  L46-6           N6-1-6
         <  L34-6*        N4-1-6
   >  L57-6               N5-1-6
     >  L58-6             N5-3-6
       <  L35-6*          N5-2-6
       >  L78-6           N8-1-6
         <  L57-6*        N7-1-6
     >  L78-6             N7-1-6
       <  L58-6           N8-1-6
         <  L35-6*        N5-2-6
         <  L57-6*        N5-3-6
   >  L58-6               N5-2-6
     <  L57-6             N5-3-6
       <  L35-6*          N5-1-6
       >  L78-6           N7-1-6
         <  L58-6*        N8-1-6
     >  L78-6             N8-1-6
       <  L57-6           N7-1-6
         <  L35-6*        N5-1-6
         >  L58-6*        N5-3-6


Combination Network 6: CBY Original with RSF Dual Output

In the output below I deleted all the loop rows from the RSF output for the dual network and placed the result beside the output for CBY for the original network, using a column-wise copy and paste. It's easy to see then their equivalent structure. Both have 69 rows.

Network 6: CBY                         Dual Network 6: RSF with loop rows deleted
==============                         ==========================================
Nodes           Link Path              Node                      Link
--------------- --------------------   ------------------------- ------
N1-6 > N2-6     L12-6*                 L12-6
N2-6 > N2-6       L22-6*	       > L22-6                   N2-1-6
N2-6 > N3-6         L23-6*	        >  L23-6                 N2-4-6
N3-6 > N4-6           L34-6*	          >  L34-6               N3-1-6
N6-6 > N4-6             L64-6*	            >  L35-6             N3-3-6
N4-6 > N6-6               L46-6*              >  L57-6           N5-1-6
N3-6 > N5-6             L35-6*	                >  L58-6         N5-3-6
N5-6 > N7-6               L57-6*                  >  L78-6       N8-1-6
N5-6 > N8-6                 L58-6*              >  L78-6         N7-1-6
N7-6 > N8-6                   L78-6*              <  L58-6       N8-1-6
N7-6 > N8-6                 L78-6*            >  L58-6           N5-2-6
N5-6 > N8-6                   L58-6*            <  L57-6         N5-3-6
N5-6 > N8-6               L58-6*                  >  L78-6       N7-1-6
N5-6 > N7-6                 L57-6*              >  L78-6         N8-1-6
N7-6 > N8-6                   L78-6*              <  L57-6       N7-1-6
N7-6 > N8-6                 L78-6*          >  L46-6             N4-1-6
N5-6 > N7-6                   L57-6*          >  L64-6           N6-1-6
N4-6 > N6-6             L46-6*	            >  L64-6             N4-2-6
N6-6 > N4-6               L64-6*              <  L46-6           N6-1-6
N3-6 > N5-6           L35-6*	          >  L35-6               N3-2-6
N3-6 > N4-6             L34-6*	            <  L34-6             N3-3-6
N6-6 > N4-6               L64-6*              >  L46-6           N4-1-6
N4-6 > N6-6                 L46-6*              >  L64-6         N6-1-6
N4-6 > N6-6               L46-6*              >  L64-6           N4-2-6
N6-6 > N4-6                 L64-6*              <  L46-6         N6-1-6
N5-6 > N7-6             L57-6*	            >  L57-6             N5-1-6
N5-6 > N8-6               L58-6*              >  L58-6           N5-3-6
N7-6 > N8-6                 L78-6*              >  L78-6         N8-1-6
N7-6 > N8-6               L78-6*              >  L78-6           N7-1-6
N5-6 > N8-6                 L58-6*              <  L58-6         N8-1-6
N5-6 > N8-6             L58-6*	            >  L58-6             N5-2-6
N5-6 > N7-6               L57-6*              <  L57-6           N5-3-6
N7-6 > N8-6                 L78-6*              >  L78-6         N7-1-6
N7-6 > N8-6               L78-6*              >  L78-6           N8-1-6
N5-6 > N7-6                 L57-6*              <  L57-6         N7-1-6
N2-6 > N3-6       L23-6*	       > L23-6                   N2-2-6
N2-6 > N2-6         L22-6*	        <  L22-6                 N2-4-6
N3-6 > N4-6         L34-6*	        >  L34-6                 N3-1-6
N6-6 > N4-6           L64-6*	          >  L35-6               N3-3-6
N4-6 > N6-6             L46-6*	            >  L57-6             N5-1-6
N3-6 > N5-6           L35-6*	              >  L58-6           N5-3-6
N5-6 > N7-6             L57-6*	                >  L78-6         N8-1-6
N5-6 > N8-6               L58-6*              >  L78-6           N7-1-6
N7-6 > N8-6                 L78-6*              <  L58-6         N8-1-6
N7-6 > N8-6               L78-6*            >  L58-6             N5-2-6
N5-6 > N8-6                 L58-6*            <  L57-6           N5-3-6
N5-6 > N8-6             L58-6*	                >  L78-6         N7-1-6
N5-6 > N7-6               L57-6*              >  L78-6           N8-1-6
N7-6 > N8-6                 L78-6*              <  L57-6         N7-1-6
N7-6 > N8-6               L78-6*          >  L46-6               N4-1-6
N5-6 > N7-6                 L57-6*          >  L64-6             N6-1-6
N4-6 > N6-6           L46-6*	          >  L64-6               N4-2-6
N6-6 > N4-6             L64-6*	            <  L46-6             N6-1-6
N3-6 > N5-6         L35-6*	        >  L35-6                 N3-2-6
N3-6 > N4-6           L34-6*	          <  L34-6               N3-3-6
N6-6 > N4-6             L64-6*	            >  L46-6             N4-1-6
N4-6 > N6-6               L46-6*              >  L64-6           N6-1-6
N4-6 > N6-6             L46-6*	            >  L64-6             N4-2-6
N6-6 > N4-6               L64-6*              <  L46-6           N6-1-6
N5-6 > N7-6           L57-6*	          >  L57-6               N5-1-6
N5-6 > N8-6             L58-6*	            >  L58-6             N5-3-6
N7-6 > N8-6               L78-6*              >  L78-6           N8-1-6
N7-6 > N8-6             L78-6*	            >  L78-6             N7-1-6
N5-6 > N8-6               L58-6*              <  L58-6           N8-1-6
N5-6 > N8-6           L58-6*	          >  L58-6               N5-2-6
N5-6 > N7-6             L57-6*	            <  L57-6             N5-3-6
N7-6 > N8-6               L78-6*              >  L78-6           N7-1-6
N7-6 > N8-6             L78-6*	            >  L78-6             N8-1-6
N5-6 > N7-6               L57-6*              <  L57-6           N7-1-6


Dual Combination Network 6: CBY Output

34547 rows selected.

[See attached file if interested in detail.]

Oracle's HR/OE/PM Demo Network

Original Demo Network

Dual Network, 1.3 - HR

This network has 21 links with 6 loops.

Original Demo Network: PLF Output

Node                                          Link                                 Lev
--------------------------------------------- ----------------------------------- ----
COUNTRIES|HR                                  ROOT                                   0
< LOCATIONS|HR                                loc_c_id_fk|HR                         1
  < DEPARTMENTS|HR                            dept_loc_fk|HR                         2
    > EMPLOYEES|HR                            dept_mgr_fk|HR                         3
      < CUSTOMERS|OE                          customers_account_manager_fk|OE        4
        < ORDERS|OE                           orders_customer_id_fk|OE               5
          > EMPLOYEES|HR*                     orders_sales_rep_fk|OE                 6
          < ORDER_ITEMS|OE                    order_items_order_id_fk|OE             6
            > PRODUCT_INFORMATION|OE          order_items_product_id_fk|OE           7
              < INVENTORIES|OE                inventories_product_id_fk|OE           8
                > WAREHOUSES|OE               inventories_warehouses_fk|OE           9
                  > LOCATIONS|HR*             warehouses_location_fk|OE             10
              < ONLINE_MEDIA|PM               loc_c_id_fk|PM                         8
              < PRINT_MEDIA|PM                printmedia_fk|PM                       8
              < PRODUCT_DESCRIPTIONS|OE       pd_product_id_fk|OE                    8
      > DEPARTMENTS|HR*                       emp_dept_fk|HR                         4
      = EMPLOYEES|HR*                         emp_manager_fk|HR                      4
      > JOBS|HR                               emp_job_fk|HR                          4
        < JOB_HISTORY|HR                      jhist_job_fk|HR                        5
          > DEPARTMENTS|HR*                   jhist_dept_fk|HR                       6
          > EMPLOYEES|HR*                     jhist_emp_fk|HR                        6
> REGIONS|HR                                  countr_reg_fk|HR                       1

22 rows selected.

Elapsed: 00:00:00.15



Original Demo Network: RSF Output

Node                                          Link
--------------------------------------------- -----------------------------------
COUNTRIES|HR
< LOCATIONS|HR                                loc_c_id_fk|HR
  < DEPARTMENTS|HR                            dept_loc_fk|HR
    < EMPLOYEES|HR                            emp_dept_fk|HR
      < CUSTOMERS|OE                          customers_account_manager_fk|OE
        < ORDERS|OE                           orders_customer_id_fk|OE
          > EMPLOYEES|HR*                     orders_sales_rep_fk|OE
          < ORDER_ITEMS|OE                    order_items_order_id_fk|OE
            > PRODUCT_INFORMATION|OE          order_items_product_id_fk|OE
              < INVENTORIES|OE                inventories_product_id_fk|OE
                > WAREHOUSES|OE               inventories_warehouses_fk|OE
                  > LOCATIONS|HR*             warehouses_location_fk|OE
              < ONLINE_MEDIA|PM               loc_c_id_fk|PM
              < PRINT_MEDIA|PM                printmedia_fk|PM
              < PRODUCT_DESCRIPTIONS|OE       pd_product_id_fk|OE
      < DEPARTMENTS|HR*                       dept_mgr_fk|HR
      = EMPLOYEES|HR*                         emp_manager_fk|HR
      > JOBS|HR                               emp_job_fk|HR
        < JOB_HISTORY|HR                      jhist_job_fk|HR
          > DEPARTMENTS|HR*                   jhist_dept_fk|HR
          > EMPLOYEES|HR*                     jhist_emp_fk|HR
      < JOB_HISTORY|HR                        jhist_emp_fk|HR
        > DEPARTMENTS|HR*                     jhist_dept_fk|HR
        > JOBS|HR                             jhist_job_fk|HR
          < EMPLOYEES|HR*                     emp_job_fk|HR
      < ORDERS|OE                             orders_sales_rep_fk|OE
        > CUSTOMERS|OE                        orders_customer_id_fk|OE
          > EMPLOYEES|HR*                     customers_account_manager_fk|OE
        < ORDER_ITEMS|OE                      order_items_order_id_fk|OE
          > PRODUCT_INFORMATION|OE            order_items_product_id_fk|OE
            < INVENTORIES|OE                  inventories_product_id_fk|OE
              > WAREHOUSES|OE                 inventories_warehouses_fk|OE
                > LOCATIONS|HR*               warehouses_location_fk|OE
            < ONLINE_MEDIA|PM                 loc_c_id_fk|PM
            < PRINT_MEDIA|PM                  printmedia_fk|PM
            < PRODUCT_DESCRIPTIONS|OE         pd_product_id_fk|OE
    > EMPLOYEES|HR                            dept_mgr_fk|HR
      < CUSTOMERS|OE                          customers_account_manager_fk|OE
        < ORDERS|OE                           orders_customer_id_fk|OE
          > EMPLOYEES|HR*                     orders_sales_rep_fk|OE
          < ORDER_ITEMS|OE                    order_items_order_id_fk|OE
            > PRODUCT_INFORMATION|OE          order_items_product_id_fk|OE
              < INVENTORIES|OE                inventories_product_id_fk|OE
                > WAREHOUSES|OE               inventories_warehouses_fk|OE
                  > LOCATIONS|HR*             warehouses_location_fk|OE
              < ONLINE_MEDIA|PM               loc_c_id_fk|PM
              < PRINT_MEDIA|PM                printmedia_fk|PM
              < PRODUCT_DESCRIPTIONS|OE       pd_product_id_fk|OE
      > DEPARTMENTS|HR*                       emp_dept_fk|HR
      = EMPLOYEES|HR*                         emp_manager_fk|HR
      > JOBS|HR                               emp_job_fk|HR
        < JOB_HISTORY|HR                      jhist_job_fk|HR
          > DEPARTMENTS|HR*                   jhist_dept_fk|HR
          > EMPLOYEES|HR*                     jhist_emp_fk|HR
      < JOB_HISTORY|HR                        jhist_emp_fk|HR
        > DEPARTMENTS|HR*                     jhist_dept_fk|HR
        > JOBS|HR                             jhist_job_fk|HR
          < EMPLOYEES|HR*                     emp_job_fk|HR
      < ORDERS|OE                             orders_sales_rep_fk|OE
        > CUSTOMERS|OE                        orders_customer_id_fk|OE
          > EMPLOYEES|HR*                     customers_account_manager_fk|OE
        < ORDER_ITEMS|OE                      order_items_order_id_fk|OE
          > PRODUCT_INFORMATION|OE            order_items_product_id_fk|OE
            < INVENTORIES|OE                  inventories_product_id_fk|OE
              > WAREHOUSES|OE                 inventories_warehouses_fk|OE
                > LOCATIONS|HR*               warehouses_location_fk|OE
            < ONLINE_MEDIA|PM                 loc_c_id_fk|PM
            < PRINT_MEDIA|PM                  printmedia_fk|PM
            < PRODUCT_DESCRIPTIONS|OE         pd_product_id_fk|OE
    < JOB_HISTORY|HR                          jhist_dept_fk|HR
      > EMPLOYEES|HR                          jhist_emp_fk|HR
        < CUSTOMERS|OE                        customers_account_manager_fk|OE
          < ORDERS|OE                         orders_customer_id_fk|OE
            > EMPLOYEES|HR*                   orders_sales_rep_fk|OE
            < ORDER_ITEMS|OE                  order_items_order_id_fk|OE
              > PRODUCT_INFORMATION|OE        order_items_product_id_fk|OE
                < INVENTORIES|OE              inventories_product_id_fk|OE
                  > WAREHOUSES|OE             inventories_warehouses_fk|OE
                    > LOCATIONS|HR*           warehouses_location_fk|OE
                < ONLINE_MEDIA|PM             loc_c_id_fk|PM
                < PRINT_MEDIA|PM              printmedia_fk|PM
                < PRODUCT_DESCRIPTIONS|OE     pd_product_id_fk|OE
        < DEPARTMENTS|HR*                     dept_mgr_fk|HR
        > DEPARTMENTS|HR*                     emp_dept_fk|HR
        = EMPLOYEES|HR*                       emp_manager_fk|HR
        > JOBS|HR                             emp_job_fk|HR
          < JOB_HISTORY|HR*                   jhist_job_fk|HR
        < ORDERS|OE                           orders_sales_rep_fk|OE
          > CUSTOMERS|OE                      orders_customer_id_fk|OE
            > EMPLOYEES|HR*                   customers_account_manager_fk|OE
          < ORDER_ITEMS|OE                    order_items_order_id_fk|OE
            > PRODUCT_INFORMATION|OE          order_items_product_id_fk|OE
              < INVENTORIES|OE                inventories_product_id_fk|OE
                > WAREHOUSES|OE               inventories_warehouses_fk|OE
                  > LOCATIONS|HR*             warehouses_location_fk|OE
              < ONLINE_MEDIA|PM               loc_c_id_fk|PM
              < PRINT_MEDIA|PM                printmedia_fk|PM
              < PRODUCT_DESCRIPTIONS|OE       pd_product_id_fk|OE
      > JOBS|HR                               jhist_job_fk|HR
        < EMPLOYEES|HR                        emp_job_fk|HR
          < CUSTOMERS|OE                      customers_account_manager_fk|OE
            < ORDERS|OE                       orders_customer_id_fk|OE
              > EMPLOYEES|HR*                 orders_sales_rep_fk|OE
              < ORDER_ITEMS|OE                order_items_order_id_fk|OE
                > PRODUCT_INFORMATION|OE      order_items_product_id_fk|OE
                  < INVENTORIES|OE            inventories_product_id_fk|OE
                    > WAREHOUSES|OE           inventories_warehouses_fk|OE
                      > LOCATIONS|HR*         warehouses_location_fk|OE
                  < ONLINE_MEDIA|PM           loc_c_id_fk|PM
                  < PRINT_MEDIA|PM            printmedia_fk|PM
                  < PRODUCT_DESCRIPTIONS|OE   pd_product_id_fk|OE
          < DEPARTMENTS|HR*                   dept_mgr_fk|HR
          > DEPARTMENTS|HR*                   emp_dept_fk|HR
          = EMPLOYEES|HR*                     emp_manager_fk|HR
          < JOB_HISTORY|HR*                   jhist_emp_fk|HR
          < ORDERS|OE                         orders_sales_rep_fk|OE
            > CUSTOMERS|OE                    orders_customer_id_fk|OE
              > EMPLOYEES|HR*                 customers_account_manager_fk|OE
            < ORDER_ITEMS|OE                  order_items_order_id_fk|OE
              > PRODUCT_INFORMATION|OE        order_items_product_id_fk|OE
                < INVENTORIES|OE              inventories_product_id_fk|OE
                  > WAREHOUSES|OE             inventories_warehouses_fk|OE
                    > LOCATIONS|HR*           warehouses_location_fk|OE
                < ONLINE_MEDIA|PM             loc_c_id_fk|PM
                < PRINT_MEDIA|PM              printmedia_fk|PM
                < PRODUCT_DESCRIPTIONS|OE     pd_product_id_fk|OE
  < WAREHOUSES|OE                             warehouses_location_fk|OE
    < INVENTORIES|OE                          inventories_warehouses_fk|OE
      > PRODUCT_INFORMATION|OE                inventories_product_id_fk|OE
        < ONLINE_MEDIA|PM                     loc_c_id_fk|PM
        < ORDER_ITEMS|OE                      order_items_product_id_fk|OE
          > ORDERS|OE                         order_items_order_id_fk|OE
            > CUSTOMERS|OE                    orders_customer_id_fk|OE
              > EMPLOYEES|HR                  customers_account_manager_fk|OE
                < DEPARTMENTS|HR              dept_mgr_fk|HR
                  < EMPLOYEES|HR*             emp_dept_fk|HR
                  < JOB_HISTORY|HR            jhist_dept_fk|HR
                    > EMPLOYEES|HR*           jhist_emp_fk|HR
                    > JOBS|HR                 jhist_job_fk|HR
                      < EMPLOYEES|HR*         emp_job_fk|HR
                  > LOCATIONS|HR*             dept_loc_fk|HR
                > DEPARTMENTS|HR              emp_dept_fk|HR
                  > EMPLOYEES|HR*             dept_mgr_fk|HR
                  < JOB_HISTORY|HR            jhist_dept_fk|HR
                    > EMPLOYEES|HR*           jhist_emp_fk|HR
                    > JOBS|HR                 jhist_job_fk|HR
                      < EMPLOYEES|HR*         emp_job_fk|HR
                  > LOCATIONS|HR*             dept_loc_fk|HR
                = EMPLOYEES|HR*               emp_manager_fk|HR
                > JOBS|HR                     emp_job_fk|HR
                  < JOB_HISTORY|HR            jhist_job_fk|HR
                    > DEPARTMENTS|HR          jhist_dept_fk|HR
                      < EMPLOYEES|HR*         emp_dept_fk|HR
                      > EMPLOYEES|HR*         dept_mgr_fk|HR
                      > LOCATIONS|HR*         dept_loc_fk|HR
                    > EMPLOYEES|HR*           jhist_emp_fk|HR
                < JOB_HISTORY|HR              jhist_emp_fk|HR
                  > DEPARTMENTS|HR            jhist_dept_fk|HR
                    < EMPLOYEES|HR*           emp_dept_fk|HR
                    > EMPLOYEES|HR*           dept_mgr_fk|HR
                    > LOCATIONS|HR*           dept_loc_fk|HR
                  > JOBS|HR                   jhist_job_fk|HR
                    < EMPLOYEES|HR*           emp_job_fk|HR
                < ORDERS|OE*                  orders_sales_rep_fk|OE
            > EMPLOYEES|HR                    orders_sales_rep_fk|OE
              < CUSTOMERS|OE                  customers_account_manager_fk|OE
                < ORDERS|OE*                  orders_customer_id_fk|OE
              < DEPARTMENTS|HR                dept_mgr_fk|HR
                < EMPLOYEES|HR*               emp_dept_fk|HR
                < JOB_HISTORY|HR              jhist_dept_fk|HR
                  > EMPLOYEES|HR*             jhist_emp_fk|HR
                  > JOBS|HR                   jhist_job_fk|HR
                    < EMPLOYEES|HR*           emp_job_fk|HR
                > LOCATIONS|HR*               dept_loc_fk|HR
              > DEPARTMENTS|HR                emp_dept_fk|HR
                > EMPLOYEES|HR*               dept_mgr_fk|HR
                < JOB_HISTORY|HR              jhist_dept_fk|HR
                  > EMPLOYEES|HR*             jhist_emp_fk|HR
                  > JOBS|HR                   jhist_job_fk|HR
                    < EMPLOYEES|HR*           emp_job_fk|HR
                > LOCATIONS|HR*               dept_loc_fk|HR
              = EMPLOYEES|HR*                 emp_manager_fk|HR
              > JOBS|HR                       emp_job_fk|HR
                < JOB_HISTORY|HR              jhist_job_fk|HR
                  > DEPARTMENTS|HR            jhist_dept_fk|HR
                    < EMPLOYEES|HR*           emp_dept_fk|HR
                    > EMPLOYEES|HR*           dept_mgr_fk|HR
                    > LOCATIONS|HR*           dept_loc_fk|HR
                  > EMPLOYEES|HR*             jhist_emp_fk|HR
              < JOB_HISTORY|HR                jhist_emp_fk|HR
                > DEPARTMENTS|HR              jhist_dept_fk|HR
                  < EMPLOYEES|HR*             emp_dept_fk|HR
                  > EMPLOYEES|HR*             dept_mgr_fk|HR
                  > LOCATIONS|HR*             dept_loc_fk|HR
                > JOBS|HR                     jhist_job_fk|HR
                  < EMPLOYEES|HR*             emp_job_fk|HR
        < PRINT_MEDIA|PM                      printmedia_fk|PM
        < PRODUCT_DESCRIPTIONS|OE             pd_product_id_fk|OE
> REGIONS|HR                                  countr_reg_fk|HR

199 rows selected.

Elapsed: 00:00:00.30

The output above shows that RSF returned 199 rows unfiltered in 0.3s.

Original Demo Network: CBY Output

One tree by Connect By

Nodes                                              Link Path
-------------------------------------------------- ----------------------------------------------------------------------
COUNTRIES|HR > REGIONS|HR                          countr_reg_fk|HR*
LOCATIONS|HR > COUNTRIES|HR                          loc_c_id_fk|HR*
DEPARTMENTS|HR > LOCATIONS|HR                          dept_loc_fk|HR*
EMPLOYEES|HR > DEPARTMENTS|HR                            emp_dept_fk|HR*
JOB_HISTORY|HR > DEPARTMENTS|HR                            jhist_dept_fk|HR*
DEPARTMENTS|HR > EMPLOYEES|HR                                dept_mgr_fk|HR*
EMPLOYEES|HR > EMPLOYEES|HR                                    emp_manager_fk|HR*
CUSTOMERS|OE > EMPLOYEES|HR                                      customers_account_manager_fk|OE*
ORDERS|OE > CUSTOMERS|OE                                           orders_customer_id_fk|OE*
ORDERS|OE > EMPLOYEES|HR                                             orders_sales_rep_fk|OE*
JOB_HISTORY|HR > EMPLOYEES|HR                                          jhist_emp_fk|HR*
EMPLOYEES|HR > JOBS|HR                                                   emp_job_fk|HR*
JOB_HISTORY|HR > JOBS|HR                                                   jhist_job_fk|HR*
JOB_HISTORY|HR > JOBS|HR                                                 jhist_job_fk|HR*
EMPLOYEES|HR > JOBS|HR                                                     emp_job_fk|HR*
EMPLOYEES|HR > JOBS|HR                                                 emp_job_fk|HR*
JOB_HISTORY|HR > EMPLOYEES|HR                                            jhist_emp_fk|HR*
JOB_HISTORY|HR > JOBS|HR                                                   jhist_job_fk|HR*
JOB_HISTORY|HR > JOBS|HR                                                 jhist_job_fk|HR*
JOB_HISTORY|HR > EMPLOYEES|HR                                              jhist_emp_fk|HR*
ORDER_ITEMS|OE > ORDERS|OE                                             order_items_order_id_fk|OE*
ORDER_ITEMS|OE > PRODUCT_INFORMATION|OE                                  order_items_product_id_fk|OE*
INVENTORIES|OE > PRODUCT_INFORMATION|OE                                    inventories_product_id_fk|OE*
PRINT_MEDIA|PM > PRODUCT_INFORMATION|OE                                      printmedia_fk|PM*
.
.
.
ORDERS|OE > CUSTOMERS|OE                                                           orders_customer_id_fk|OE*
EMPLOYEES|HR > EMPLOYEES|HR                                                        emp_manager_fk|HR*
PRINT_MEDIA|PM > PRODUCT_INFORMATION|OE                        printmedia_fk|PM*
ONLINE_MEDIA|PM > PRODUCT_INFORMATION|OE                         loc_c_id_fk|PM*
PRODUCT_DESCRIPTIONS|OE > PRODUCT_INFORMATION|OE                   pd_product_id_fk|OE*
PRODUCT_DESCRIPTIONS|OE > PRODUCT_INFORMATION|OE                 pd_product_id_fk|OE*
ONLINE_MEDIA|PM > PRODUCT_INFORMATION|OE                           loc_c_id_fk|PM*
ONLINE_MEDIA|PM > PRODUCT_INFORMATION|OE                       loc_c_id_fk|PM*
PRINT_MEDIA|PM > PRODUCT_INFORMATION|OE                          printmedia_fk|PM*
PRODUCT_DESCRIPTIONS|OE > PRODUCT_INFORMATION|OE                   pd_product_id_fk|OE*
PRODUCT_DESCRIPTIONS|OE > PRODUCT_INFORMATION|OE                 pd_product_id_fk|OE*
PRINT_MEDIA|PM > PRODUCT_INFORMATION|OE                            printmedia_fk|PM*
PRODUCT_DESCRIPTIONS|OE > PRODUCT_INFORMATION|OE               pd_product_id_fk|OE*
PRINT_MEDIA|PM > PRODUCT_INFORMATION|OE                          printmedia_fk|PM*
ONLINE_MEDIA|PM > PRODUCT_INFORMATION|OE                           loc_c_id_fk|PM*
ONLINE_MEDIA|PM > PRODUCT_INFORMATION|OE                         loc_c_id_fk|PM*
PRINT_MEDIA|PM > PRODUCT_INFORMATION|OE                            printmedia_fk|PM*

4414420 rows selected.

Elapsed: 00:29:33.41

One tree by Connect By filtered

Nodes                                              Link Path                                                              LINK_COUNT
-------------------------------------------------- ---------------------------------------------------------------------- ----------
COUNTRIES|HR > REGIONS|HR                          countr_reg_fk|HR*                                                               1
LOCATIONS|HR > COUNTRIES|HR                          loc_c_id_fk|HR*                                                               1
DEPARTMENTS|HR > LOCATIONS|HR                          dept_loc_fk|HR*                                                        214178
EMPLOYEES|HR > DEPARTMENTS|HR                            emp_dept_fk|HR*                                                      169932
JOB_HISTORY|HR > DEPARTMENTS|HR                            jhist_dept_fk|HR*                                                  272162
DEPARTMENTS|HR > EMPLOYEES|HR                                dept_mgr_fk|HR*                                                  169932
EMPLOYEES|HR > EMPLOYEES|HR                                    emp_manager_fk|HR*                                             207910
CUSTOMERS|OE > EMPLOYEES|HR                                      customers_account_manager_fk|OE*                             132490
ORDERS|OE > CUSTOMERS|OE                                           orders_customer_id_fk|OE*                                   85298
ORDERS|OE > EMPLOYEES|HR                                             orders_sales_rep_fk|OE*                                   72234
JOB_HISTORY|HR > EMPLOYEES|HR                                          jhist_emp_fk|HR*                                       164660
EMPLOYEES|HR > JOBS|HR                                                   emp_job_fk|HR*                                       182784
JOB_HISTORY|HR > JOBS|HR                                                   jhist_job_fk|HR*                                   333192
ORDER_ITEMS|OE > ORDERS|OE                                             order_items_order_id_fk|OE*                             26804
ORDER_ITEMS|OE > PRODUCT_INFORMATION|OE                                  order_items_product_id_fk|OE*                         26804
INVENTORIES|OE > PRODUCT_INFORMATION|OE                                    inventories_product_id_fk|OE*                      428354
PRINT_MEDIA|PM > PRODUCT_INFORMATION|OE                                      printmedia_fk|PM*                                428384
ONLINE_MEDIA|PM > PRODUCT_INFORMATION|OE                                       loc_c_id_fk|PM*                                428384
PRODUCT_DESCRIPTIONS|OE > PRODUCT_INFORMATION|OE                                 pd_product_id_fk|OE*                         428384
INVENTORIES|OE > WAREHOUSES|OE                                               inventories_warehouses_fk|OE*                    428354
WAREHOUSES|OE > LOCATIONS|HR                                                   warehouses_location_fk|OE*                     214178

21 rows selected.

Elapsed: 00:03:03.16

The output above shows that CBY returned 4,414,420 rows unfiltered in 29m33s. Adding filtering reduced the time to 3m03s.

Dual Demo Network

Dual Network, 1.3 - HR-D

This network has 52 links with 32 loops, whereas the original had 21 links with 6 loops.

Dual Demo Network: PLF Output

Node                                                           Link
-------------------------------------------------------------- -------------------------
countr_reg_fk|HR                                               ROOT
> loc_c_id_fk|HR                                               COUNTRIES|HR-1
  < dept_loc_fk|HR                                             LOCATIONS|HR-1
    > dept_mgr_fk|HR                                           DEPARTMENTS|HR-1
      < customers_account_manager_fk|OE                        EMPLOYEES|HR-1
        > emp_dept_fk|HR                                       EMPLOYEES|HR-2
          < dept_loc_fk|HR*                                    DEPARTMENTS|HR-2
          < dept_mgr_fk|HR*                                    EMPLOYEES|HR-7
          > emp_job_fk|HR                                      EMPLOYEES|HR-12
            < customers_account_manager_fk|OE*                 EMPLOYEES|HR-3
            < dept_mgr_fk|HR*                                  EMPLOYEES|HR-8
            > emp_manager_fk|HR                                EMPLOYEES|HR-16
              < customers_account_manager_fk|OE*               EMPLOYEES|HR-4
              < dept_mgr_fk|HR*                                EMPLOYEES|HR-9
              < emp_dept_fk|HR*                                EMPLOYEES|HR-13
              = emp_manager_fk|HR*                             EMPLOYEES|HR-19
              > jhist_emp_fk|HR                                EMPLOYEES|HR-20
                < customers_account_manager_fk|OE*             EMPLOYEES|HR-5
                < dept_mgr_fk|HR*                              EMPLOYEES|HR-10
                < emp_dept_fk|HR*                              EMPLOYEES|HR-14
                < emp_job_fk|HR*                               EMPLOYEES|HR-17
                < jhist_dept_fk|HR                             JOB_HISTORY|HR-1
                  < dept_loc_fk|HR*                            DEPARTMENTS|HR-3
                  < dept_mgr_fk|HR*                            DEPARTMENTS|HR-4
                  < emp_dept_fk|HR*                            DEPARTMENTS|HR-5
                  > jhist_job_fk|HR                            JOB_HISTORY|HR-2
                    < emp_job_fk|HR*                           JOBS|HR-1
                    < jhist_emp_fk|HR*                         JOB_HISTORY|HR-3
                > orders_sales_rep_fk|OE                       EMPLOYEES|HR-22
                  < customers_account_manager_fk|OE*           EMPLOYEES|HR-6
                  < dept_mgr_fk|HR*                            EMPLOYEES|HR-11
                  < emp_dept_fk|HR*                            EMPLOYEES|HR-15
                  < emp_job_fk|HR*                             EMPLOYEES|HR-18
                  < emp_manager_fk|HR*                         EMPLOYEES|HR-21
                  < order_items_order_id_fk|OE                 ORDERS|OE-2
                    > order_items_product_id_fk|OE             ORDER_ITEMS|OE-1
                      < inventories_product_id_fk|OE           PRODUCT_INFORMATION|OE-2
                        > inventories_warehouses_fk|OE         INVENTORIES|OE-1
                          > warehouses_location_fk|OE          WAREHOUSES|OE-1
                            < dept_loc_fk|HR*                  LOCATIONS|HR-2
                            < loc_c_id_fk|HR*                  LOCATIONS|HR-3
                        > loc_c_id_fk|PM                       PRODUCT_INFORMATION|OE-1
                          > order_items_product_id_fk|OE*      PRODUCT_INFORMATION|OE-5
                          > pd_product_id_fk|OE                PRODUCT_INFORMATION|OE-6
                            < inventories_product_id_fk|OE*    PRODUCT_INFORMATION|OE-3
                            < order_items_product_id_fk|OE*    PRODUCT_INFORMATION|OE-8
                            > printmedia_fk|PM                 PRODUCT_INFORMATION|OE-10
                              < inventories_product_id_fk|OE*  PRODUCT_INFORMATION|OE-4
                              < loc_c_id_fk|PM*                PRODUCT_INFORMATION|OE-7
                              < order_items_product_id_fk|OE*  PRODUCT_INFORMATION|OE-9
                    > orders_customer_id_fk|OE                 ORDERS|OE-1
                      < customers_account_manager_fk|OE*       CUSTOMERS|OE-1
                      > orders_sales_rep_fk|OE*                ORDERS|OE-3

53 rows selected.

Elapsed: 00:00:00.27



Dual Demo Network: RSF and CBY Results

Neither of the two SQL recursion methods completed within a period of an hour and had to be terminated. The result for CBY on the original network suggests that RSF on the dual network should return somewhere above 4,414,420 rows.

Conclusions

  • We have shown by examples how network traversal by the Connect By (CBY) approach in SQL corresponds to traversal of all routes in a type of dual version of the original network
  • This dual version, which has forks converted to loops, tends to be larger and more heavily looped, resulting in worse performance compared with solution by recursive subquery factors (RSF)
  • The examples illustrate the different treatment of loop-closing links between the two types of SQL recursion
  • The RSF solutions on the dual network in the simpler examples where it completes is seen to be equivalent to the CBY solution on the original network, after allowing for the different treatment of loop-closing links
  • On the foreign key network for Oracle's HR/OE/PM demo, which has 21 links, RSF returns 199 rows while CBY returns 4,414,420 rows
  • On the dual version of the foreign key network for Oracle's HR/OE/PM demo, which has 52 links, RSF and CBY fail to complete in reasonable times
  • The pipelined function method returns the solution on both original and dual in a small fraction of a second

SQL files: SQL for network duality
Output files: Output for network duality

Oracle version used: Oracle Database 12c Enterprise Edition Release 12.1.0.1.0 - 64bit Production






SQL for Shortest Path Problems 2: A Branch and Bound Approach

I wrote an article a couple of weeks ago, SQL for Shortest Path Problems, in which analytic functions are used to truncate sub-optimal routes in SQL recursions for shortest paths through networks. The problem was posed by an OTN poster, How to use Recursive Subquery Factoring (RSF) to Implement Dijkstra’s shortest path algorithm?, who referenced a very simple test network, and included his own SQL to solve it, which turned out to be quite similar to my own effort. The solutions are guaranteed to be optimal if the algorithm terminates normally, which it does on the small test network, and will on any network unless resources such as memory or time are exhausted owing to problem size.

In that article I referenced two earlier articles that I had written (in June/July 2013) that used analytic functions for other combinatorial problems. The usage in those cases was similar syntactically, but pruned out routes that looked inferior to others at a given iteration, so that the final solutions were not guaranteed to be optimal. The motivation was to to be able to use the SQL for exact solutions on smaller problems and for good, maybe sub-optimal, solutions for problems too large to solve exactly.

I wondered how the SQL in the last article would perform on larger networks, and whether further tuning methods could be found, perhaps based on some form of search truncation, as in the earlier articles. The resulting solution methods can be considered as branch and bound algorithms in SQL.

Update, 19 November 2017: I have now put the code and the dataset installation onto GitHub: Brendan’s repo for interesting SQL

Test Problems

I took two test problems from this site: Stanford Large Network Dataset Collection.

Collaboration network of Arxiv General Relativity category
Friendship network of Brightkite users

The larger second data set has 428,156 arcs.

Both data sets are of the non-physical type, where there are no differential costs associated with links, and the problem therefore reduces to determining the minimum number of links between a node and other reachable nodes. These non-physical networks tend to be heavily looped, owing to the essentially zero cost of adding a new link. For that reason, I change my problem definition in this article to that of finding a single best path to each reachable node, rather than all, which reduces the solution set size considerably.

It is well known that in non-physical networks, such as social media networks like Linked-In and Facebook, the minimum paths between members tends to remain relatively small as the network size goes up. This will influence the type of algorithm that will be more efficient.

Approximation Methods: Simple truncation

The most obvious approximative approach would be to simple truncate the search after a certain depth (or level). This actually works quite well and gives good results for highly looped networks, where the minimum paths tend to be much shorter than the number of nodes. However there is no guarantee of optimality, and it will be less effective for less looped networks with longer minimum paths.

SQL for SP_RSFONE (simple truncation)

WITH paths (node, path, lev, rn) AS (
SELECT a.dst, To_Char(a.dst), 1, 1
  FROM arcs_v a
WHERE a.src = &SRC
 UNION ALL
SELECT  a.dst,
        p.path || ',' || a.dst,
        p.lev + 1,
        Row_Number () OVER (PARTITION BY a.dst ORDER BY a.dst)
  FROM paths p
  JOIN arcs_v a
    ON a.src = p.node
 WHERE p.rn = 1
   AND p.lev < &LEVMAX
)  SEARCH DEPTH FIRST BY node SET line_no
CYCLE node SET lp TO '*' DEFAULT ' '
SELECT Substr (LPad ('.', 1 + 2 * (Max (lev) KEEP (DENSE_RANK FIRST ORDER BY lev) - 1), '.') || node, 2) node,
       Max (lev) KEEP (DENSE_RANK FIRST ORDER BY lev) lev,
       Max (Max (lev) KEEP (DENSE_RANK FIRST ORDER BY lev)) OVER () maxlev,
       Max (lev) intnod,
       Max (Max (lev)) OVER () intmax,
       Max (path) KEEP (DENSE_RANK FIRST ORDER BY lev) path,
       Max (lp) KEEP (DENSE_RANK FIRST ORDER BY lev) lp
  FROM paths
 GROUP BY node
 ORDER BY Max (line_no) KEEP (DENSE_RANK FIRST ORDER BY lev)

Notes on SQL for SP_RSFONE (simple truncation)

  • Row_Number gives a single row with value 1 per partitioning node, so that we retain only one row per node for the previous iteration
  • The global pruning can be done without an additional subquery by grouping with KEEP, since we only want one optimal row per node
  • Note that in the double Max to get maxlev, the inner one is the grouping Max, while the outer is an analytic Max over the whole (grouped) result set
  • intnod obtains the maximum intermdiate value of lev for a given node
  • intmax obtains the maximum intermdiate value of lev over all nodes

Approximation Methods: Preliminary approximate subquery
A less obvious approach is based on the fact that during the recursion our path pruning can only take into account information available to the current iteration: Other than loops, we can prune out only paths to a given node that are longer than another at the same level. But what if we ran an approximate search in advance, in a prior subquery? Then we could outer-join the subquery by node and prune out any paths for which the subquery has found a better cost. This would potentially reduce the total searching without sacrificing guranteed optimality.

SQL for SP_RSFTWO (preliminary approximate subquery)

WITH paths_0 (node, path, lev, rn) AS (
SELECT a.dst, To_Char(a.dst), 1, 1
  FROM arcs_v a
 WHERE a.src = &SRC
 UNION ALL
SELECT a.dst,
       p.path || ',' || a.dst,
       p.lev + 1,
       Row_Number () OVER (PARTITION BY a.dst ORDER BY a.dst)
  FROM paths_0 p
  JOIN arcs_v a
    ON a.src = p.node
 WHERE p.rn = 1
   AND p.lev < &LEVMAX
) CYCLE node SET lp TO '*' DEFAULT ' '
, approx_best_paths AS (
SELECT node,
       Max (lev) KEEP (DENSE_RANK FIRST ORDER BY lev) lev
  FROM paths_0
 GROUP BY node
), paths (node, path, lev, rn) AS (
SELECT a.dst, To_Char(a.dst), 1, 1
  FROM arcs_v a
WHERE a.src = &SRC
 UNION ALL
SELECT a.dst,
        p.path || ',' || a.dst,
        p.lev + 1,
        Row_Number () OVER (PARTITION BY a.dst ORDER BY a.dst)
  FROM paths p
  JOIN arcs_v a
    ON a.src = p.node
  LEFT JOIN approx_best_paths b
    ON b.node = a.dst
 WHERE p.rn = 1
   AND p.lev < Nvl (b.lev, 1000000)
)  SEARCH DEPTH FIRST BY node SET line_no CYCLE node SET lp TO '*' DEFAULT ' '
SELECT Substr (LPad ('.', 1 + 2 * (Max (lev) KEEP (DENSE_RANK FIRST ORDER BY lev) - 1), '.') || node, 2) node,
       Max (lev) KEEP (DENSE_RANK FIRST ORDER BY lev) lev,
       Max (Max (lev) KEEP (DENSE_RANK FIRST ORDER BY lev)) OVER () maxlev,
       Max (lev) intnod,
       Max (Max (lev)) OVER () intmax,
       Max (path) KEEP (DENSE_RANK FIRST ORDER BY lev) path,
       Max (lp) KEEP (DENSE_RANK FIRST ORDER BY lev) lp
  FROM paths
 GROUP BY node
 ORDER BY Max (line_no) KEEP (DENSE_RANK FIRST ORDER BY lev)

Notes on SQL for SP_RSFTWO (preliminary approximate subquery)

  • This query has two recursive subquery factors
  • path_0 truncates after an input level is reached
  • approx_best_paths gets the global best paths found from the approximate recursion
  • paths now has an outer join to path_0 that is used to prune paths that are inferior to any path to the same node found in the prior subquery
  • the approximate recursion may not reach all reachable nodes, but the outer join ensures this does not cut off any such nodes incorrectly

Approximation Methods: Preliminary approximate subquery to GTT
We will see later that the second approach works quite well, but that the CBO does not process the preliminary query very efficiently. For this reason writing the query result instead to a temporary table may be more efficient overall. The table can be indexed, and dynamic sampling allows the CBO to estimate the cardinalities more accurately.

SQL for SP_GTTRSF_I and SP_GTTRSF_Q (preliminary approximate query to GTT)

PROMPT SP_GTTRSF_I
INSERT INTO approx_min_levs
WITH paths_0 (node, path, lev, rn) /* SP_GTTRSF_I */ AS (
SELECT a.dst, To_Char(a.dst), 1, 1
  FROM arcs_v a
WHERE a.src = &SRC
 UNION ALL
SELECT  a.dst,
        p.path || ',' || a.dst,
        p.lev + 1,
        Row_Number () OVER (PARTITION BY a.dst ORDER BY a.dst)
  FROM paths_0 p
  JOIN arcs_v a
    ON a.src = p.node
 WHERE p.rn = 1
   AND p.lev < &LEVMAX
) CYCLE node SET lp TO '*' DEFAULT ' '
SELECT node,
       Max (lev) KEEP (DENSE_RANK FIRST ORDER BY lev) lev
  FROM paths_0
 GROUP BY node
/
PROMPT SP_GTTRSF_Q
WITH paths (node, path, lev, rn) AS (
SELECT a.dst, To_Char(a.dst), 1, 1
  FROM arcs_v a
WHERE a.src = &SRC
 UNION ALL
SELECT a.dst,
        p.path || ',' || a.dst,
        p.lev + 1,
        Row_Number () OVER (PARTITION BY a.dst ORDER BY a.dst)
  FROM paths p
  JOIN arcs_v a
    ON a.src = p.node
  LEFT JOIN approx_min_levs b
    ON b.node = a.dst
 WHERE p.rn = 1
   AND p.lev < Nvl (b.lev, 1000000)
)  SEARCH DEPTH FIRST BY node SET line_no CYCLE node SET lp TO '*' DEFAULT ' '
SELECT Substr (LPad ('.', 1 + 2 * (Max (lev) KEEP (DENSE_RANK FIRST ORDER BY lev) - 1), '.') || node, 2) node,
       Max (lev) KEEP (DENSE_RANK FIRST ORDER BY lev) lev,
       Max (Max (lev) KEEP (DENSE_RANK FIRST ORDER BY lev)) OVER () maxlev,
       Max (lev) intnod,
       Max (Max (lev)) OVER () intmax,
       Max (path) KEEP (DENSE_RANK FIRST ORDER BY lev) path,
       Max (lp) KEEP (DENSE_RANK FIRST ORDER BY lev) lp
  FROM paths
 GROUP BY node
 ORDER BY Max (line_no) KEEP (DENSE_RANK FIRST ORDER BY lev)

Notes on SQL for preliminary approximate subquery to GTT

  • the SQL above consists of an insert of the approximate subquery into a temporary table, followed by the exact recursive query now referencing the table rather than a subquery factor

Results: Collaboration network of Arxiv General Relativity category
Collaboration network of Arxiv General Relativity category

Arxiv GR-QC (General Relativity and Quantum Cosmology) collaboration network is from the e-print arXiv and covers scientific collaborations between authors papers submitted to General Relativity and Quantum Cosmology category. If an author i co-authored a paper with author j, the graph contains a undirected edge from i to j. If the paper is co-authored by k authors this generates a completely connected (sub)graph on k nodes.

The data set comes with the reverse arcs already present, making a total of 28,980.

I took the first node in the first line in the data set file as the initial root node, 3466, and tested the three methods above for values of LEVMAX of 5, 10, 15, 20, 25 and 30. The complete results, including execution plans are in the attached file.

The exact solution has 4,158 nodes reached from the source node 3466, with a maximum level of 11. The listing below gives the output from SP_GTTRSF_Q for LEVMAX=5.

NODE                            LEV  MAXLEV  INTNOD  INTMAX PATH                                                                             LP
------------------------------ ---- ------- ------- ------- -------------------------------------------------------------------------------- --
937                               1      11       1      45 937
5233                              1      11       1      45 5233
8579                              1      11       1      45 8579
..4135                            2      11       2      45 937,4135
....1860                          3      11       3      45 8579,4135,1860
....16498                         3      11       3      45 8579,4135,16498
......19442                       4      11       4      45 8579,4135,16498,19442
..........9890                    6      11       6      45 8579,4135,16498,19442,6264,9890
......22826                       4      11       4      45 8579,4135,16498,22826
..........12260                   6      11       8      45 8579,4135,16498,22826,6804,12260
..........25491                   6      11       8      45 8579,4135,16498,22826,6804,25491
..........25844                   6      11       6      45 8579,4135,16498,22826,6804,25844
..............8037                8      11       9      45 8579,4135,16498,22826,13520,122,4825,8037
..............14621               8      11      11      45 8579,4135,16498,22826,13520,122,4825,14621
..............19608               8      11      10      45 8579,4135,16498,22826,13520,122,4825,19608
..............4836                8      11       9      45 8579,4135,16498,22826,13520,122,9593,4836
............4641                  7      11       9      45 8579,4135,16498,22826,13520,22224,4641
............17937                 7      11       9      45 8579,4135,16498,22826,13520,22224,17937
............21660                 7      11       7      45 8579,4135,16498,22826,13520,22224,21660
............22088                 7      11       7      45 8579,4135,16498,22826,13520,22224,22088
..........22224                   6      11       9      45 8579,4135,16498,22826,13520,22224
........17599                     5      11       5      45 8579,4135,16498,22826,17599
..16258                           2      11       2      45 8579,16258
....1356                          3      11       3      45 8579,16258,1356
....1727                          3      11       3      45 8579,16258,1727
......4241                        4      11       4      45 8579,16258,1727,4241
........5227                      5      11       5      45 8579,16258,1727,4241,5227
........7015                      5      11       5      45 8579,16258,1727,4241,7015
........10476                     5      11       5      45 8579,16258,1727,4241,10476
..............7854                8      11      10      45 8579,16258,1727,4241,10476,4875,11844,7854
............11844                 7      11      10      45 8579,16258,1727,4241,10476,4875,11844
.
. extracted
.
..23429                           2      11       2      45 17038,23429
....4781                          3      11       3      45 17038,23429,4781
....19697                         3      11       3      45 17038,23429,19697
......5519                        4      11       4      45 17038,23429,19697,5519
........26167                     5      11       5      45 17038,23429,19697,5519,26167
......17818                       4      11       4      45 17038,23429,19697,17818
......20260                       4      11       4      45 17038,23429,19697,20260
......23809                       4      11       4      45 17038,23429,19697,23809
........23219                     5      11       5      45 17038,23429,19697,5519,23219
..24578                           2      11       2      45 17038,24578
....18297                         3      11       3      45 17038,24578,18297
......5402                        4      11       4      45 17038,24578,18297,5402
......15947                       4      11       4      45 17038,24578,18297,15947
18720                             1      11       1      45 18720
19607                             1      11       1      45 19607
..3466                            2      11       2      45 937,3466

4158 rows selected.

Elapsed: 00:00:09.78

The embedded Excel file below summarises the results with relevant statistics from the query runs and the execution plans.

Results summary - SP_RSFONE (simple truncation)

  • SP_RSFONE ran in from 3 seconds to 60 seconds, and returned the exact solution from LEVMAX = 15 on
  • It continued iterating up to the maximum level of LEVMAX in each case, although all optimal path lengths are found by level 11

Results summary - SP_RSFTWO (preliminary approximate subquery)
This is the execution plan for LEVMAX=5

-----------------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                          | Name            | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-----------------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                                   |                 |      1 |        |   4158 |00:00:27.47 |    2716K|       |       |          |
|   1 |  WINDOW SORT                                       |                 |      1 |     39 |   4158 |00:00:27.47 |    2716K|   372K|   372K|  330K (0)|
|   2 |   SORT GROUP BY                                    |                 |      1 |     39 |   4158 |00:00:27.45 |    2716K|    19M|  6662K|   17M (0)|
|   3 |    VIEW                                            |                 |      1 |     39 |  87755 |00:00:27.27 |    2716K|       |       |          |
|   4 |     UNION ALL (RECURSIVE WITH) DEPTH FIRST         |                 |      1 |        |  87755 |00:00:27.17 |    2716K|    16M|  1524K|   14M (0)|
|*  5 |      INDEX RANGE SCAN                              | ARCS_CA_GRQC_PK |      1 |      6 |      8 |00:00:00.01 |       2 |       |       |          |
|   6 |      WINDOW SORT                                   |                 |     45 |     33 |  87747 |00:00:21.78 |    1664K|   832K|   511K|  739K (0)|
|*  7 |       FILTER                                       |                 |     45 |        |  87747 |00:00:21.27 |    1664K|       |       |          |
|*  8 |        HASH JOIN RIGHT OUTER                       |                 |     45 |     33 |    110K|00:00:21.38 |    1664K|  1817K|  1817K| 1565K (0)|
|   9 |         VIEW                                       |                 |     45 |     39 |    114K|00:00:21.02 |    1655K|       |       |          |
|  10 |          SORT GROUP BY                             |                 |     45 |     39 |    114K|00:00:20.96 |    1655K|   337K|   337K|  299K (0)|
|  11 |           VIEW                                     |                 |     45 |     39 |    689K|00:00:20.23 |    1655K|       |       |          |
|  12 |            UNION ALL (RECURSIVE WITH) BREADTH FIRST|                 |     45 |        |    689K|00:00:19.32 |    1655K|   903K|   523K|  802K (0)|
|* 13 |             INDEX RANGE SCAN                       | ARCS_CA_GRQC_PK |     45 |      6 |    360 |00:00:00.01 |      50 |       |       |          |
|  14 |             WINDOW SORT                            |                 |    225 |     33 |    688K|00:00:04.00 |   44865 |  1116K|   557K|  991K (0)|
|  15 |              NESTED LOOPS                          |                 |    225 |     33 |    688K|00:00:01.27 |   44865 |       |       |          |
|  16 |               RECURSIVE WITH PUMP                  |                 |    225 |        |  67635 |00:00:00.27 |       0 |       |       |          |
|* 17 |               INDEX RANGE SCAN                     | ARCS_CA_GRQC_PK |  67635 |      6 |    688K|00:00:00.57 |   44865 |       |       |          |
|  18 |         NESTED LOOPS                               |                 |     45 |     33 |    110K|00:00:00.21 |    8594 |       |       |          |
|  19 |          RECURSIVE WITH PUMP                       |                 |     45 |        |  10787 |00:00:00.03 |       0 |       |       |          |
|* 20 |          INDEX RANGE SCAN                          | ARCS_CA_GRQC_PK |  10787 |      6 |    110K|00:00:00.11 |    8594 |       |       |          |
-----------------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   5 - access("SRC"=3466)
   7 - filter("P"."LEV"<NVL("B"."LEV",1000000))
   8 - access("B"."NODE"="DST")
  13 - access("SRC"=3466)
  17 - access("SRC"="P"."NODE")
  20 - access("SRC"="P"."NODE")

  • SP_RSFTWO ran in from 27 seconds to 552 seconds, and returned the exact solution in all cases
  • From the intmax value (Excel file) we can see that only in the case of LEVMAX=5 did the second recursion iterate beyond the optimum level of 11 (in fact to a level of 45). This would be due the preliminary approximate subquery allowing it to discard sub-optimal paths in the second recursion
  • The execution plan above shows that Oracle CBO has chosen not to materialize the first recursive subquery, and essentially reruns it at each of the 45 outer iterations
  • A better approach for the CBO to have taken would appear to be to form a hash table in memory (where possible) of the first subquery, and run each iteration of the outer recursion outer-joining to that unchanging hash table; or alternatively, to materialize it and outer-join in any other way deemed appropriate
  • I tried hinting the subquery to get CBO to materialise or avoid the repetition of the first subquery, but without success, and so decided using a temproray table to materialise it myself would be a good idea

Results summary - SP_GTTRSF_I and SP_GTTRSF_Q (preliminary approximate query to GTT)

  • SP_GTTRSF_I and SP_GTTRSF_Q ran in from 5 seconds to 54 seconds combined
  • LEVMAX=10 gave slight the better result here: Evidently, the extra work in the insert compared with LEVMAX=5 was over-compensated by the benefit of a better approximate solution
  • Once LEVMAX is sufficiently large to give a good approximate solution it is most efficient not to increase it further
  • This method is almost as efficient as simply truncating at a given level, but guarantees optimality

Network analysis

I have my own network analysis program, implemented as a PL/SQL pipelined function. I thought this might be useful to help validate the results. The function returns all distinct subnetworks and is called three times to give different levels of detail. It runs against a view links_v that must be created for the data source containing the network links. Here is the output:

links_v based on net_CA_GrQc

View dropped.


View created.


  COUNT(*)
----------
     14484

Network detail

Network     #Links  #Nodes    Lev Node       Link
---------- ------- ------- ------ ---------- ----------
1000         13422    4158      0   1000     ROOT
                                1 > 1149     770
                                2 > 12016    4681
                                3 < 1000*    778
                                3 > 18271    7628
                                4 < 13702    3675
.
. Extracted
.
                               11 < 5400     14039
                                8 < 5241     5959
                                7 > 18145    8551
                                8 > 21799    13889
                                9 < 11557*   8553
                                6 > 18271*   14193
                                6 > 19978    14194
                                7 < 13702*   3676
                                7 < 18271*   3671
                                4 < 18152    12071
                                2 > 16234    4682
                                3 > 18373    4686
                                4 < 1149*    4684
                                4 > 19871    4687
                                5 > 25526    5590
                                6 < 18373*   4688
                                2 > 17251    4683
                                2 > 20557    4685
                                2 > 4189     4679
                                3 > 5829     13222
                                1 > 20667    785
10002            1       2      0   10002    ROOT
                                1 < 7468     8487
10056           11       6      0   10056    ROOT
                                1 < 2754     13119
                                2 > 5511     13116
                                3 > 10056*   13122
                                3 > 7265     13120
                                4 > 10056*   13115
                                4 < 2754*    13117
                                4 > 7479     13114
                                5 > 10056*   12036
                                5 > 13390    12037
                                5 < 2754*    13118
                                5 < 5511*    13121
1010             1       2      0   1010     ROOT
                                1 > 2749     13221
10115            2       3      0   10115    ROOT
                                1 > 10134    50
                                1 > 23916    51
1013             2       3      0   1013     ROOT
                                1 > 19011    9224
                                2 < 2123     12933
10133            1       2      0   10133    ROOT
                                1 > 18218    6369
10148            1       2      0   10148    ROOT
                                1 > 10847    7955
10154            5       4      0   10154    ROOT
                                1 > 16830    13630
                                2 < 11410    14133
                                3 < 9224     12381
                                4 > 10154*   12380
                                4 > 16830*   12382
10163           24       8      0   10163    ROOT
                                1 > 12551    7434
                                2 < 1281     7440
                                3 > 10163*   7439
                                3 > 18621    7441
                                4 < 10163*   7435
                                4 < 12551*   5987
                                4 < 17588    5984
                                5 < 12551*   5986
                                5 > 24207    5985
                                6 < 10163*   7436
                                6 < 12551*   5988
                                6 < 1281*    7442
                                6 < 18621*   5982
                                6 > 25287    5981
                                7 < 10163*   7437
                                7 < 12551*   5989
                                7 < 1281*    7443
                                7 < 18621*   5983
                                7 < 3653     7448
                                8 > 10163*   7444
                                8 > 12551*   7445
                                8 < 1281*    7438
                                8 > 18621*   7446
                                8 > 24207*   7447
10178            3       3      0   10178    ROOT
                                1 > 24133    10756
                                2 < 3744     14126
                                3 > 10178*   14125
10180            3       3      0   10180    ROOT
                                1 > 17587    13060
                                2 < 2334     13059
                                3 > 10180*   13058
10252            3       3      0   10252    ROOT
                                1 > 16820    6964
                                2 < 9630     6963
                                3 > 10252*   6962
10317            2       3      0   10317    ROOT
                                1 > 11816    4265
                                1 < 2259     4264
10338           14       7      0   10338    ROOT
                                1 > 12458    5220
                                2 > 12460    8958
                                3 < 10338*   5221
                                3 > 16651    13302
                                4 < 10338*   5223
                                4 < 12458*   8959
                                4 > 19378    13976
                                5 < 10338*   5224
                                5 < 12458*   8960
                                5 < 12460*   13303
                                5 < 7523     12926
                                6 > 10338*   12924
                                6 > 12458*   12925
                                1 > 14844    5222
10341            6       4      0   10341    ROOT
                                1 < 1292     10693
                                2 > 14840    10694
                                3 < 10341*   10695
                                3 < 6648     10697
                                4 > 10341*   10696
                                4 < 1292*    10692
10355            5       6      0   10355    ROOT
                                1 < 2054     3240
                                2 > 13741    3241
                                2 < 1552     13484
                                2 > 8719     3238
                                2 > 9760     3239
10356            1       2      0   10356    ROOT
                                1 > 19062    7274
10382            1       2      0   10382    ROOT
                                1 > 25482    12047
10407            1       2      0   10407    ROOT
                                1 < 6701     13278
10432            2       3      0   10432    ROOT
                                1 > 16891    7463
                                1 < 5774     13628
10433            1       2      0   10433    ROOT
                                1 < 2593     5143
1050             1       2      0   1050     ROOT
                                1 > 17120    4284
1051             3       3      0   1051     ROOT
                                1 > 25664    13897
                                2 < 4245     13898
                                3 < 1051*    13896
10513            2       3      0   10513    ROOT
                                1 > 25059    9437
                                1 > 25595    9438
10517            1       2      0   10517    ROOT
                                1 < 5119     9154
10522            1       2      0   10522    ROOT
                                1 > 10561    11775
10559            1       2      0   10559    ROOT
                                1 > 18245    8169
10564            6       5      0   10564    ROOT
                                1 > 15187    6266
                                2 < 8970     9824
                                3 > 10564*   9823
                                1 < 2984     6265
                                2 > 8731     6264
                                3 > 10564*   6294
10602            1       2      0   10602    ROOT
                                1 > 20805    13140
10637            4       4      0   10637    ROOT
                                1 > 21340    4094
                                2 < 8428     4093
                                3 > 10637*   4091
                                3 > 18603    4092
10638            1       2      0   10638    ROOT
                                1 < 8717     12974
10672            6       4      0   10672    ROOT
                                1 > 12512    11111
                                2 < 4630     11110
                                3 > 10672*   11109
                                3 > 9921     11108
                                4 > 10672*   13681
                                4 > 12512*   13682
10676            1       2      0   10676    ROOT
                                1 > 24961    1798
10677           29      14      0   10677    ROOT
                                1 > 17015    9130
                                2 > 20560    7465
                                3 < 309      7253
                                4 > 10677*   7250
                                4 > 17015*   7251
                                4 > 17453    7252
                                5 < 11030    10700
                                6 > 23946    10701
                                7 < 17453*   4282
                                7 > 25611    10703
                                8 < 11030*   10702
                                8 < 17453*   4283
                                8 < 6012     8987
                                9 > 11030*   8984
                                9 > 17453*   8985
                                9 > 23946*   8986
                                9 > 9591     8983
                               10 > 10677*   4275
                               10 > 11030*   4276
                               10 > 13704    4277
                               10 > 17015*   4278
                               10 > 17453*   4279
                               10 < 2136     4273
                               11 > 17453*   4274
                               10 < 2186     14089
                               10 > 23946*   4280
                               10 > 25611*   4281
                               10 < 309*     7249
                                2 > 21314    7466
10679            4       4      0   10679    ROOT
                                1 < 115      9941
                                2 > 5268     9940
                                3 > 10679*   9939
                                1 < 8671     9015
10682            4       4      0   10682    ROOT
                                1 < 2506     6022
                                2 > 9962     6021
                                3 > 10682*   5990
                                3 > 22428    5991
10792           11       7      0   10792    ROOT
                                1 > 15695    9866
                                2 > 20379    9647
                                2 > 21309    9648
                                3 < 20422    9661
                                4 < 2222     9642
                                5 > 10792*   9640
                                5 > 15695*   9641
                                5 > 21309*   9643
                                5 < 2215     9644
                                6 > 15695*   9645
                                6 > 21309*   9646
10818            3       3      0   10818    ROOT
                                1 > 11016    11965
                                2 > 25596    11967
                                3 < 10818*   11966
10872            3       3      0   10872    ROOT
                                1 > 24250    6959
                                2 < 2666     6961
                                3 > 10872*   6960
10884           10       7      0   10884    ROOT
                                1 > 16353    12670
                                2 < 4958     12669
                                3 > 10884*   12668
                                3 > 9606     12667
                                4 > 10884*   9663
                                4 > 12122    9664
                                5 < 5973     13438
                                6 > 9606*    13437
                                4 > 16353*   9665
                                4 < 2247     9662
10897            1       2      0   10897    ROOT
                                1 < 5548     7565
10904            7       7      0   10904    ROOT
                                1 > 12707    9216
                                2 < 5156     4083
                                3 > 10904*   4082
                                3 > 14282    4084
                                4 < 11035    4183
                                3 > 17933    4085
                                3 > 7483     4081
10906            5       6      0   10906    ROOT
                                1 < 1289     10560
                                2 > 1560     10558
                                2 > 4365     10559
                                1 < 8530     5023
                                2 > 21144    5024
1092             2       3      0   1092     ROOT
                                1 > 23226    5795
                                1 > 3196     5794
10936            3       4      0   10936    ROOT
                                1 > 19509    10723
                                1 > 19510    10724
                                1 > 23687    10725
11009           12       8      0   11009    ROOT
                                1 > 20157    7971
                                2 > 23471    7975
                                3 < 11009*   7974
                                1 > 21344    7972
                                2 < 11721    9753
                                3 > 12151    9751
                                4 > 15221    9756
                                5 < 11721*   9752
                                5 > 21344*   9754
                                4 > 21344*   9757
                                2 > 22990    9755
                                3 < 11009*   7973
11028            6       4      0   11028    ROOT
                                1 > 21171    9834
                                2 > 22730    9836
                                3 < 11028*   9835
                                3 < 5211     9833
                                4 > 11028*   9831
                                4 > 21171*   9832
11054            3       3      0   11054    ROOT
                                1 < 8395     14002
                                2 > 8725     14001
                                3 > 11054*   14003
1107             1       2      0   1107     ROOT
                                1 > 6973     6133
11120            3       4      0   11120    ROOT
                                1 > 16340    13294
                                1 > 17851    13295
                                1 > 20233    13296
11196            3       4      0   11196    ROOT
                                1 < 13       9182
                                2 > 19170    9183
                                2 > 7596     9181
11197            3       3      0   11197    ROOT
                                1 < 844      6408
                                2 > 890      6407
                                3 > 11197*   6409
11215            1       2      0   11215    ROOT
                                1 > 23156    13072
11216            2       3      0   11216    ROOT
                                1 > 19598    5564
                                2 < 13815    5565
11279            5       5      0   11279    ROOT
                                1 > 17750    5108
                                2 > 22976    5109
                                2 > 25609    5110
                                2 < 9832     6048
                                3 > 11279*   6047
11280            1       2      0   11280    ROOT
                                1 < 831      11119
11285            3       3      0   11285    ROOT
                                1 > 12193    7864
                                2 < 9618     7863
                                3 > 11285*   7862
11411            1       2      0   11411    ROOT
                                1 > 24242    13714
11418            5       5      0   11418    ROOT
                                1 < 161      5233
                                2 > 19583    5234
                                3 < 97       12273
                                4 > 161*     12272
                                2 > 3105     5232
11427            4       4      0   11427    ROOT
                                1 > 20414    6376
                                2 < 14170    7561
                                3 < 7632     6737
                                4 > 20414*   6738
11459            1       2      0   11459    ROOT
                                1 < 6706     4089
11462            1       2      0   11462    ROOT
                                1 > 17141    5708
11465            3       3      0   11465    ROOT
                                1 > 11577    12723
                                2 < 3239     5601
                                3 > 11465*   5600
11467            1       2      0   11467    ROOT
                                1 > 19575    13141
11539            7       5      0   11539    ROOT
                                1 > 15227    13103
                                2 > 16655    9932
                                3 < 11539*   13104
                                3 < 782      9931
                                4 > 11539*   9929
                                4 > 15227*   9930
                                2 > 18151    9933
1154             6       5      0   1154     ROOT
                                1 > 12017    4312
                                2 > 12930    4314
                                3 < 1154*    4313
                                3 > 17591    4315
                                4 < 8704     7088
                                5 > 12930*   7087
11561            6       6      0   11561    ROOT
                                1 < 9579     11992
                                2 > 16932    11993
                                3 > 19451    11991
                                4 < 9579*    11994
                                2 > 22381    11995
                                2 < 6534     12067
11566            3       3      0   11566    ROOT
                                1 > 11808    3143
                                2 > 18560    3145
                                3 < 11566*   3144
11579            1       2      0   11579    ROOT
                                1 > 15073    12917
11593           10      10      0   11593    ROOT
                                1 > 18415    9430
                                2 < 16818    8830
                                2 > 23648    3437
                                2 < 4633     3436
                                2 < 7194     886
                                3 > 15322    885
                                3 > 20960    887
                                4 < 6355     883
                                5 > 7194*    882
                                3 > 7542     884
11616           12       9      0   11616    ROOT
                                1 > 14149    5047
                                2 > 14662    5042
                                3 < 11616*   5048
                                2 > 16648    5043
                                2 > 19560    5044
                                3 > 23530    9159
                                4 < 14149*   5046
                                4 < 3750     11990
                                5 > 14149*   11988
                                5 > 19560*   11989
                                2 > 22199    5045
                                2 < 8147     13240
11622            5       5      0   11622    ROOT
                                1 < 3852     12250
                                2 > 7877     12249
                                3 > 11622*   6262
                                3 < 1378     6261
                                3 > 15422    6263
11623            1       2      0   11623    ROOT
                                1 > 23621    9950
11641            1       2      0   11641    ROOT
                                1 > 24462    11178
11642            1       2      0   11642    ROOT
                                1 > 25230    13233
11662           10       5      0   11662    ROOT
                                1 > 14094    9983
                                2 > 19014    9985
                                3 < 11662*   9984
                                3 < 5960     9979
                                4 > 11662*   9977
                                4 > 14094*   9978
                                4 > 8705     9976
                                5 > 11662*   9980
                                5 > 14094*   9981
                                5 > 19014*   9982
11718            1       2      0   11718    ROOT
                                1 > 20766    14024
11823           19       9      0   11823    ROOT
                                1 > 13628    13948
                                2 > 15246    13945
                                3 > 20332    13377
                                4 < 13628*   13946
                                4 < 6350     9193
                                5 > 11823*   9189
                                5 > 13628*   9190
                                5 > 15246*   9191
                                5 > 16014    9192
                                5 > 23710    9194
                                6 < 11823*   13949
                                6 < 13628*   13947
                                6 < 8372     13944
                                7 > 11823*   13940
                                7 > 13628*   13941
                                7 > 15246*   13942
                                7 > 20332*   13943
                                7 < 6350*    9188
                                5 < 4495     9195
11828            1       2      0   11828    ROOT
                                1 < 7807     7330
11842            5       5      0   11842    ROOT
                                1 < 1656     5766
                                2 > 21531    5767
                                3 < 5828     5768
                                4 < 1656*    5765
                                2 > 4040     5764
1187             1       2      0   1187     ROOT
                                1 > 6290     9841
11879            7       6      0   11879    ROOT
                                1 > 26092    11947
                                2 < 21187    10770
                                3 < 4051     7891
                                4 > 21313    7892
                                5 < 21310    13661
                                5 > 26092*   7894
                                4 > 26092*   7893
11893            3       3      0   11893    ROOT
                                1 > 25667    13467
                                2 < 8891     13036
                                3 > 11893*   13035
11911            1       2      0   11911    ROOT
                                1 < 9039     12102
1194             1       2      0   1194     ROOT
                                1 > 21858    1756
11965            3       4      0   11965    ROOT
                                1 < 1556     6619
                                2 > 14096    6620
                                2 > 23154    6621
11969            3       3      0   11969    ROOT
                                1 > 18996    10664
                                2 < 1967     10666
                                3 > 11969*   10665
11971            1       2      0   11971    ROOT
                                1 > 25211    11733
11991            1       2      0   11991    ROOT
                                1 < 3186     12664
12034           15       6      0   12034    ROOT
                                1 > 17935    14102
                                2 < 2116     14098
                                3 > 12034*   14097
                                3 > 9189     14094
                                4 > 12034*   14092
                                4 > 17935*   14093
                                4 > 9765     14090
                                5 > 12034*   14100
                                5 > 17935*   14101
                                5 < 2116*    14095
                                5 > 9774     14099
                                6 > 12034*   14103
                                6 > 17935*   14104
                                6 < 2116*    14096
                                6 < 9189*    14091
12041            1       2      0   12041    ROOT
                                1 > 14384    8493
12042           20      12      0   12042    ROOT
                                1 < 5738     3826
                                2 > 17252    3827
                                3 > 18142    12724
                                4 < 5738*    3828
                                4 < 6538     10717
                                5 > 16040    10715
                                5 > 17252*   10716
                                5 < 5478     13900
                                6 > 5738*    13899
                                6 > 8349     13901
                                7 < 1549     9651
                                8 > 22766    9652
                                9 > 23168    9655
                               10 < 1549*    9653
                               10 < 8349*    9650
                                9 < 8349*    9649
                                8 > 24732    9654
                                7 < 5738*    3825
                                7 < 6538*    10714
                                5 < 5738*    3824
12046            7       8      0   12046    ROOT
                                1 > 25957    7833
                                2 < 17724    4986
                                3 > 25958    4987
                                2 < 19126    9486
                                3 < 14135    13923
                                2 < 8263     3572
                                3 > 17882    3571
12050            1       2      0   12050    ROOT
                                1 < 5364     13463
12113            4       4      0   12113    ROOT
                                1 > 16886    12069
                                2 < 142      12755
                                3 > 18626    12756
                                4 < 16886*   12070
12161            1       2      0   12161    ROOT
                                1 > 19162    4316
12192            3       3      0   12192    ROOT
                                1 < 5839     9611
                                2 > 7026     9610
                                3 > 12192*   9612
12213           21       7      0   12213    ROOT
                                1 > 13558    13457
                                2 > 21710    12987
                                3 < 12213*   13458
                                3 > 22318    13461
                                4 < 12213*   13459
                                4 < 13558*   12988
                                4 > 24888    13456
                                5 < 12213*   13460
                                5 < 13558*   12989
                                5 < 21710*   13462
                                5 < 8669     12995
                                6 > 12213*   12991
                                6 > 13558*   12992
                                6 > 21710*   12993
                                6 > 22318*   12994
                                6 > 9038     12990

Network     #Links  #Nodes    Lev Node       Link
---------- ------- ------- ------ ---------- ----------
12213           21       7      7 > 12213*   13451
                                7 > 13558*   13452
                                7 > 21710*   13453
                                7 > 22318*   13454
                                7 > 24888*   13455
12248            1       2      0   12248    ROOT
                                1 < 98       14149
12252            2       3      0   12252    ROOT
                                1 > 22404    10336
                                2 < 9026     13358
12256            2       3      0   12256    ROOT
                                1 > 17237    6040
                                1 < 5081     6039
12290            2       3      0   12290    ROOT
                                1 > 17307    8012
                                1 > 20031    8013
12307            3       3      0   12307    ROOT
                                1 > 14175    12694
                                2 > 22980    12693
                                3 < 12307*   12695
12320            3       3      0   12320    ROOT
                                1 > 12321    6226
                                2 > 19222    6228
                                3 < 12320*   6227
12338            3       3      0   12338    ROOT
                                1 > 15800    13147
                                2 < 1878     13146
                                3 > 12338*   13145
12387            7       6      0   12387    ROOT
                                1 > 19520    7612
                                2 > 23084    7614
                                3 < 12387*   7613
                                3 < 19931    14057
                                3 > 23553    7616
                                3 > 23554    7617
                                4 < 19520*   7615
12414           13       8      0   12414    ROOT
                                1 > 14431    5783
                                2 > 24439    14022
                                3 < 12414*   5785
                                3 < 18562    5786
                                4 < 12414*   5784
                                4 < 3102     5781
                                5 > 12414*   5780
                                5 > 24439*   5782
                                3 < 20537    13299
                                4 > 20543    13298
                                5 > 21339    10744
                                6 > 24439*   10746
                                5 > 24439*   10745
12473            1       2      0   12473    ROOT
                                1 < 9831     13760
12504            1       2      0   12504    ROOT
                                1 < 9053     9044
12554            1       2      0   12554    ROOT
                                1 < 7636     11747
12616            3       3      0   12616    ROOT
                                1 > 16266    4164
                                2 < 4485     4166
                                3 > 12616*   4165
12617            2       3      0   12617    ROOT
                                1 > 17388    7631
                                2 < 6037     8024
12676            2       3      0   12676    ROOT
                                1 > 14302    9722
                                2 < 5432     13653
12689            6       4      0   12689    ROOT
                                1 > 17560    4479
                                2 > 21697    4477
                                3 < 12689*   4480
                                3 > 25116    4476
                                4 < 12689*   4481
                                4 < 17560*   4478
12703            2       3      0   12703    ROOT
                                1 < 1669     4747
                                1 < 5260     6438
12704            2       3      0   12704    ROOT
                                1 < 7861     7495
                                2 < 2355     7496
12751            1       2      0   12751    ROOT
                                1 < 6307     11094
12798            2       3      0   12798    ROOT
                                1 > 19507    6123
                                2 < 3199     7089
12801            4       4      0   12801    ROOT
                                1 > 15641    13864
                                2 > 19548    9870
                                3 < 12801*   13865
                                2 < 5466     9871
12863            1       2      0   12863    ROOT
                                1 > 18390    11997
12940            2       3      0   12940    ROOT
                                1 < 787      9633
                                2 > 20883    9634
13012            3       3      0   13012    ROOT
                                1 < 1983     12737
                                2 > 20943    12738
                                3 < 13012*   12739
13022            1       2      0   13022    ROOT
                                1 < 8077     8653
13031            4       4      0   13031    ROOT
                                1 > 13334    12391
                                2 < 8738     12997
                                3 > 13031*   12996
                                1 > 13620    12392
13167            3       3      0   13167    ROOT
                                1 > 15485    13919
                                2 < 800      7678
                                3 > 13167*   7677
13202            3       4      0   13202    ROOT
                                1 > 16703    8062
                                2 > 22253    3823
                                3 < 4128     5098
13325           14       8      0   13325    ROOT
                                1 > 14502    9507
                                2 > 15899    9510
                                3 < 13325*   9508
                                2 > 20926    9511
                                3 < 13325*   9509
                                3 < 6735     9505
                                4 > 13325*   9503
                                4 > 14502*   9504
                                4 > 23167    9506
                                5 < 3388     13311
                                6 > 3818     13309
                                7 > 23167*   9127
                                7 > 6735*    9126
                                6 > 6735*    13310
13357            4       4      0   13357    ROOT
                                1 > 25115    9305
                                2 < 8739     9304
                                3 > 13357*   9303
                                1 > 25852    9306
13413            1       2      0   13413    ROOT
                                1 < 9211     13312
13415            3       3      0   13415    ROOT
                                1 > 15386    12935
                                2 < 7585     12980
                                3 > 13415*   12979
1344             1       2      0   1344     ROOT
                                1 > 18126    10351
1346             1       2      0   1346     ROOT
                                1 > 6448     4271
13485            2       3      0   13485    ROOT
                                1 > 21530    5692
                                2 < 5059     1701
13486            3       3      0   13486    ROOT
                                1 > 18688    11102
                                2 < 4259     11104
                                3 > 13486*   11103
13621            1       2      0   13621    ROOT
                                1 > 25388    560
13675            1       2      0   13675    ROOT
                                1 < 4186     4163
13677            3       3      0   13677    ROOT
                                1 > 18288    9861
                                2 > 23206    9863
                                3 < 13677*   9862
13717            1       2      0   13717    ROOT
                                1 < 8558     12265
1376             1       2      0   1376     ROOT
                                1 > 4267     10556
13802            6       4      0   13802    ROOT
                                1 > 16823    14183
                                2 > 19553    13907
                                3 < 13802*   14184
                                3 < 5571     14182
                                4 > 13802*   14180
                                4 > 16823*   14181
1383            11       6      0   1383     ROOT
                                1 > 3377     13218
                                2 < 1660     11777
                                3 > 23068    11778
                                4 > 25631    11781
                                5 < 1660*    11779
                                5 > 25678    11776
                                6 < 1660*    11780
                                6 < 23068*   11782
                                6 < 3377*    11785
                                5 < 3377*    11784
                                4 < 3377*    11783
13932            4       4      0   13932    ROOT
                                1 < 6075     1618
                                2 > 14499    1619
                                3 > 20345    1621
                                4 < 6075*    1620
14               1       2      0   14       ROOT
                                1 > 14171    13498
14130            1       2      0   14130    ROOT
                                1 < 3599     9719
14131            1       2      0   14131    ROOT
                                1 < 372      12066
14132            1       2      0   14132    ROOT
                                1 > 15154    11120
14159            4       4      0   14159    ROOT
                                1 > 24852    6980
                                2 < 5144     10685
                                3 > 14159*   10684
                                2 < 8869     8832
14182            1       2      0   14182    ROOT
                                1 > 17537    12666
14338            1       2      0   14338    ROOT
                                1 > 22729    11180
14339            2       3      0   14339    ROOT
                                1 > 18608    13026
                                2 > 22816    13025
14353            6       5      0   14353    ROOT
                                1 > 14886    4074
                                2 < 2043     9914
                                3 > 6315     9913
                                4 > 14886*   5819
                                2 < 2455     4073
                                3 > 14353*   4072
14358            1       2      0   14358    ROOT
                                1 < 5697     12262
14543            4       4      0   14543    ROOT
                                1 > 21221    7497
                                2 > 25130    7499
                                3 < 14543*   7498
                                3 < 7958     6801
14560            3       3      0   14560    ROOT
                                1 > 24251    3804
                                2 < 2656     3803
                                3 > 14560*   3802
14763            1       2      0   14763    ROOT
                                1 < 4432     14004
14770            9       7      0   14770    ROOT
                                1 > 21713    11906
                                2 > 25470    12922
                                3 < 14770*   11908
                                1 > 23461    11907
                                2 < 3297     11746
                                3 > 17936    11745
                                3 > 5667     11744
                                4 > 14770*   9772
                                4 > 23461*   9773
14771            1       2      0   14771    ROOT
                                1 > 24127    4463
14842            2       3      0   14842    ROOT
                                1 > 24575    9988
                                2 < 8255     13350
14845            3       3      0   14845    ROOT
                                1 > 19521    13500
                                2 < 5232     13502
                                3 > 14845*   13501
14868            3       3      0   14868    ROOT
                                1 > 16226    9830
                                2 < 2201     9829
                                3 > 14868*   9828
14894            2       3      0   14894    ROOT
                                1 < 1670     9778
                                1 > 22927    9777
1490             1       2      0   1490     ROOT
                                1 > 20813    3849
14990            1       2      0   14990    ROOT
                                1 > 25975    13930
15181            1       2      0   15181    ROOT
                                1 < 2331     8932
15182           10       5      0   15182    ROOT
                                1 > 16728    12023
                                2 > 22319    12026
                                3 < 15182*   12024
                                3 > 23424    12028
                                4 < 15182*   12025
                                4 < 16728*   12027
                                4 < 8153     12022
                                5 > 15182*   12019
                                5 > 16728*   12020
                                5 > 22319*   12021
15188            1       2      0   15188    ROOT
                                1 < 6354     5992
15208            1       2      0   15208    ROOT
                                1 > 23759    9082
15218            1       2      0   15218    ROOT
                                1 > 17585    8869
15248            5       5      0   15248    ROOT
                                1 > 17595    13446
                                2 > 19018    8520
                                3 < 17076    4176
                                2 < 8443     13445
                                3 > 15248*   13444
15249            1       2      0   15249    ROOT
                                1 > 15624    3148
15259            2       3      0   15259    ROOT
                                1 > 25136    13139
                                2 < 22000    10613
15358            3       3      0   15358    ROOT
                                1 > 18036    12671
                                2 > 18338    12673
                                3 < 15358*   12672
15374            1       2      0   15374    ROOT
                                1 > 15553    14037
15387            1       2      0   15387    ROOT
                                1 > 15388    4994
15396            7       5      0   15396    ROOT
                                1 > 18238    11870
                                2 > 26180    11865
                                3 < 15396*   11871
                                3 < 4777     11869
                                4 > 15396*   11866
                                4 > 18238*   11867
                                4 > 19064    11868
15401            1       2      0   15401    ROOT
                                1 < 4196     13893
15415            3       4      0   15415    ROOT
                                1 > 24640    2865
                                2 < 24152    5206
                                2 < 4685     11740
15423            1       2      0   15423    ROOT
                                1 > 18144    9875
1551             2       3      0   1551     ROOT
                                1 > 8058     9269
                                2 < 2328     13800
15572            1       2      0   15572    ROOT
                                1 < 7356     7467
15583            4       4      0   15583    ROOT
                                1 > 17785    12058
                                2 > 18628    10047
                                2 > 24272    10048
                                3 < 15583*   12059
15609            1       2      0   15609    ROOT
                                1 > 21809    8705
15642            3       3      0   15642    ROOT
                                1 > 16783    14117
                                2 > 17563    10323
                                3 < 15642*   14118
15668            6       4      0   15668    ROOT
                                1 > 17293    10740
                                2 > 25614    10738
                                3 < 15668*   10741
                                3 > 26006    10743
                                4 < 15668*   10742
                                4 < 17293*   10739
15681            2       3      0   15681    ROOT
                                1 > 20793    8829
                                1 < 7482     8828
15688            1       2      0   15688    ROOT
                                1 > 22692    9551
15706            2       3      0   15706    ROOT
                                1 > 20776    6419
                                1 < 374      12104
15712            1       2      0   15712    ROOT
                                1 > 19596    10679
15824            1       2      0   15824    ROOT
                                1 > 22283    4049
15847            3       3      0   15847    ROOT
                                1 < 348      10620
                                2 > 5660     10619
                                3 > 15847*   10621
1589             1       2      0   1589     ROOT
                                1 > 7603     9073
15962            1       2      0   15962    ROOT
                                1 > 25447    13908
16015            1       2      0   16015    ROOT
                                1 > 22938    13260
16109            9       6      0   16109    ROOT
                                1 > 21808    6661
                                2 < 2784     6660
                                3 > 16109*   6659
                                3 > 5425     6658
                                4 > 16109*   2533
                                4 > 16224    2534
                                5 > 24161    2537
                                6 < 5425*    2536
                                4 > 21808*   2535
16124            3       3      0   16124    ROOT
                                1 > 20807    8756
                                2 > 24334    8758
                                3 < 16124*   8757
16129            3       3      0   16129    ROOT
                                1 < 2298     12973
                                2 < 74       12971
                                3 > 16129*   12972
1621             3       3      0   1621     ROOT
                                1 > 6576     11063
                                2 > 7109     11062
                                3 < 1621*    11064
16281            1       2      0   16281    ROOT
                                1 > 24728    4740
16312            1       2      0   16312    ROOT
                                1 > 16314    12399
16338            1       2      0   16338    ROOT
                                1 > 21390    9527
16358            3       3      0   16358    ROOT
                                1 < 822      11830
                                2 > 9518     11829
                                3 > 16358*   11831
16470            1       2      0   16470    ROOT
                                1 > 17822    1078
16484            1       2      0   16484    ROOT
                                1 < 8302     290
16523            2       3      0   16523    ROOT
                                1 < 4110     9867
                                2 > 17696    9868
16609            2       3      0   16609    ROOT
                                1 < 6170     12054
                                2 > 8881     12053
16620            8       6      0   16620    ROOT
                                1 < 1908     8034
                                2 > 16621    8035
                                3 < 2611     6945
                                4 > 16620*   6944
                                4 < 1908*    8033
                                4 < 376      6942
                                5 > 16620*   6943
                                2 > 17173    8036
16622            1       2      0   16622    ROOT
                                1 > 18454    12390
16643            1       2      0   16643    ROOT
                                1 > 20035    12052
16802            3       3      0   16802    ROOT
                                1 > 23757    9016
                                2 < 830      9018
                                3 > 16802*   9017
16892            3       3      0   16892    ROOT
                                1 > 19572    13495
                                2 < 3062     8588
                                3 > 16892*   8587
16922            1       2      0   16922    ROOT
                                1 > 20925    12923
1695             1       2      0   1695     ROOT
                                1 > 19380    7838
16957            2       3      0   16957    ROOT
                                1 < 3362     9779
                                2 < 3347     9780
16971            3       3      0   16971    ROOT
                                1 > 20170    13022
                                2 < 5228     13024
                                3 > 16971*   13023
17178            8       7      0   17178    ROOT
                                1 > 21024    9774
                                2 < 19712    8585
                                2 > 23215    8586
                                3 < 17178*   9775
                                2 < 8071     12245
                                1 < 2329     13300
                                2 > 24846    13301
                                3 < 17178*   9776
17179            3       3      0   17179    ROOT
                                1 > 24816    5256
                                2 < 9871     5255
                                3 > 17179*   5254
17276            3       3      0   17276    ROOT
                                1 > 18383    4020
                                2 < 9994     4019
                                3 > 17276*   4018
17280            7       5      0   17280    ROOT
                                1 > 19956    7470
                                2 < 2785     13505
                                3 > 17280*   13504
                                3 > 3682     13503
                                4 > 17280*   13506
                                4 > 19956*   13507
                                1 > 24597    7471
17291            3       3      0   17291    ROOT
                                1 < 4017     4627
                                2 > 7888     4626
                                3 > 17291*   4628
17346            3       3      0   17346    ROOT
                                1 > 20319    9991
                                2 < 9149     9916
                                3 > 17346*   9915
17461            3       3      0   17461    ROOT
                                1 < 188      7261
                                2 > 22920    7262
                                3 < 17461*   8965
17468            3       3      0   17468    ROOT
                                1 < 3200     9325
                                2 > 4264     9324
                                3 > 17468*   9326
17470            1       2      0   17470    ROOT
                                1 > 19221    12233
17471            1       2      0   17471    ROOT
                                1 < 3989     10774
17503            1       2      0   17503    ROOT
                                1 < 3748     13137
17690            1       2      0   17690    ROOT
                                1 < 5814     5763
17782           10       5      0   17782    ROOT
                                1 > 18231    10034
                                2 < 1989     10031
                                3 > 17782*   10030
                                3 > 4106     10028
                                4 > 17782*   13352
                                4 > 18231*   13353
                                4 > 7515     13351
                                5 > 17782*   10032
                                5 > 18231*   10033
                                5 < 1989*    10029
17865            3       4      0   17865    ROOT
                                1 > 24159    9131
                                2 < 4276     10554
                                2 < 717      9713
17951            1       2      0   17951    ROOT
                                1 < 833      8539
1798             3       3      0   1798     ROOT
                                1 > 4828     11136
                                2 > 5404     11138
                                3 < 1798*    11137
17992            1       2      0   17992    ROOT
                                1 < 4181     14179
18003            2       3      0   18003    ROOT
                                1 < 5545     8014
                                1 < 6709     3077
18034           18       8      0   18034    ROOT
                                1 < 1981     9113
                                2 > 19879    9114
                                3 < 18034*   9120
                                3 < 5468     9119
                                4 > 18034*   9118
                                4 < 1981*    9109
                                4 > 5668     9116
                                5 > 18034*   11977
                                5 < 1981*    9110
                                5 > 19879*   11978
                                5 > 8187     11976
                                6 > 18034*   9514
                                6 < 1981*    9112
                                6 > 19879*   9515
                                6 < 5468*    9117
                                2 > 25444    9115
                                3 < 6908     11813
                                4 < 1981*    9111
18098            1       2      0   18098    ROOT
                                1 < 3100     7819
18156            1       2      0   18156    ROOT
                                1 < 5387     12715
18171            2       3      0   18171    ROOT
                                1 < 5413     1730
                                1 < 85       7675
18183            1       2      0   18183    ROOT
                                1 < 4278     11748
18194            1       2      0   18194    ROOT
                                1 > 21949    12248
1821             3       3      0   1821     ROOT
                                1 < 187      6296
                                2 > 21386    6297
                                3 < 1821*    6298
18279            3       3      0   18279    ROOT
                                1 < 6389     8481
                                2 > 6914     8480
                                3 > 18279*   8482
1836             1       2      0   1836     ROOT
                                1 > 8400     12006
18388            1       2      0   18388    ROOT
                                1 > 20654    13869
18417            1       2      0   18417    ROOT
                                1 > 19892    13920
18544            3       3      0   18544    ROOT
                                1 > 21596    10321
                                2 < 2332     10320
                                3 > 18544*   10319
18581            1       2      0   18581    ROOT
                                1 < 2938     9797
18596            3       3      0   18596    ROOT
                                1 > 23771    12385
                                2 < 4144     12384
                                3 > 18596*   12383
18669            4       4      0   18669    ROOT
                                1 > 19866    10338
                                2 > 25545    10340
                                3 < 18669*   10339
                                3 < 8538     12898
18721            1       2      0   18721    ROOT
                                1 < 3067     6377
18895            1       2      0   18895    ROOT
                                1 < 7957     8872
18908            1       2      0   18908    ROOT
                                1 > 25531    13413
18970           10       5      0   18970    ROOT
                                1 < 2409     9807
                                2 > 3522     9804
                                3 > 18970*   9810
                                3 > 4286     9808
                                4 > 18970*   11115
                                4 < 2409*    9805
                                4 > 4288     11114
                                5 > 18970*   11116
                                5 < 2409*    9806
                                5 < 3522*    9809
18984            1       2      0   18984    ROOT
                                1 < 2476     6293
19015           10       5      0   19015    ROOT
                                1 > 19444    6633
                                2 > 25139    6635
                                3 < 19015*   6634
                                3 < 5212     6629
                                4 > 19015*   6627
                                4 > 19444*   6628
                                4 > 6628     6626
                                5 > 19015*   6630
                                5 > 19444*   6631
                                5 > 25139*   6632
19052            1       2      0   19052    ROOT
                                1 < 7713     289
19061            1       2      0   19061    ROOT
                                1 < 9094     1873
19145            1       2      0   19145    ROOT
                                1 > 23760    12719
1916             3       3      0   1916     ROOT
                                1 > 20953    6416
                                2 > 24463    6418
                                3 < 1916*    6417
19252            1       2      0   19252    ROOT
                                1 < 3195     6456
19257            3       3      0   19257    ROOT
                                1 > 22961    9462
                                2 < 7477     9461
                                3 > 19257*   9460
19314           15       6      0   19314    ROOT
                                1 > 19880    13363
                                2 > 25496    13371
                                3 < 19314*   13364
                                3 > 25543    13360
                                4 < 19314*   13365
                                4 < 19880*   13372
                                4 > 26019    13368
                                5 < 19314*   13366
                                5 < 19880*   13373
                                5 < 25496*   13361
                                5 > 26048    13370
                                6 < 19314*   13367
                                6 < 19880*   13374
                                6 < 25496*   13362
                                6 < 25543*   13369
194              1       2      0   194      ROOT
                                1 > 8628     7522
19466            3       3      0   19466    ROOT
                                1 > 24128    13695
                                2 < 7543     13697
                                3 > 19466*   13696
19473            1       2      0   19473    ROOT
                                1 > 23812    13340
19502            3       3      0   19502    ROOT
                                1 > 23970    13101
                                2 < 7718     13100
                                3 > 19502*   13099
19554            3       3      0   19554    ROOT
                                1 > 24878    7606
                                2 < 6159     7605
                                3 > 19554*   7604
1969             3       3      0   1969     ROOT
                                1 > 24141    13017
                                2 < 8472     13018
                                3 < 1969*    13016
1976             1       2      0   1976     ROOT
                                1 > 23672    14065
19906            1       2      0   19906    ROOT
                                1 > 26102    9469
19911            1       2      0   19911    ROOT
                                1 > 25487    7946
19932           12       7      0   19932    ROOT
                                1 > 19936    3994
                                2 < 2118     4090
                                2 > 25864    3996
                                3 < 19932*   3995
                                3 < 4199     3990
                                4 > 19932*   3988
                                4 > 19936*   3989
                                4 > 6443     3987
                                5 > 19932*   3991
                                5 > 19936*   3992
                                5 > 25864*   3993
                                2 > 26132    3997
19941            1       2      0   19941    ROOT
                                1 < 6079     9479
2004             1       2      0   2004     ROOT
                                1 > 21191    900
20084            1       2      0   20084    ROOT
                                1 > 22311    11060
20150            3       3      0   20150    ROOT
                                1 > 22312    9946
                                2 > 25226    9948
                                3 < 20150*   9947
20216            3       3      0   20216    ROOT
                                1 < 2223     12050
                                2 > 4266     12049
                                3 > 20216*   12051
20309            3       3      0   20309    ROOT
                                1 < 7267     13033
                                2 > 7280     13032
                                3 > 20309*   13031
20320            1       2      0   20320    ROOT
                                1 < 4643     13929
20333            1       2      0   20333    ROOT
                                1 < 4262     13275
20433            3       3      0   20433    ROOT
                                1 < 5446     11939
                                2 > 5632     11938
                                3 > 20433*   11940
20707            1       2      0   20707    ROOT
                                1 > 24820    13375
20803            2       3      0   20803    ROOT
                                1 > 25231    9268
                                1 < 6356     12964
20914            3       3      0   20914    ROOT
                                1 < 6008     6038
                                2 > 9959     6037
                                3 > 20914*   6036
21018            1       2      0   21018    ROOT
                                1 < 5479     8725
21028            1       2      0   21028    ROOT
                                1 < 8146     7558
2117             1       2      0   2117     ROOT
                                1 > 6300     8692
2119             1       2      0   2119     ROOT
                                1 > 7637     2066
2120             1       2      0   2120     ROOT
                                1 > 8157     288
21206            2       3      0   21206    ROOT
                                1 > 23175    1940
                                2 > 25662    1837
21288            3       4      0   21288    ROOT
                                1 < 8557     6253
                                2 > 26191    6254
                                2 < 8308     6255
21303            1       2      0   21303    ROOT
                                1 < 734      12168
21515            4       4      0   21515    ROOT
                                1 > 21523    9322
                                2 < 7916     8070
                                3 > 21515*   8069
                                3 < 28       8068
21579            1       2      0   21579    ROOT
                                1 < 373      8982
21593            1       2      0   21593    ROOT
                                1 > 22325    9803
21623            1       2      0   21623    ROOT
                                1 > 22605    12034
21684            6       5      0   21684    ROOT
                                1 > 22719    9328
                                2 < 21821    5235
                                2 > 22720    5236
                                3 < 21684*   9329
                                2 > 24169    5237
                                3 < 21684*   9330
22021            1       2      0   22021    ROOT
                                1 < 8811     10312
22110            1       2      0   22110    ROOT
                                1 < 5231     11035
22378            1       2      0   22378    ROOT
                                1 < 2762     4741
22435            1       2      0   22435    ROOT
                                1 < 5406     13288
2248             1       2      0   2248     ROOT
                                1 > 8409     12903
22827            3       3      0   22827    ROOT
                                1 < 5256     13257
                                2 > 5257     13256
                                3 > 22827*   13258
22891            1       2      0   22891    ROOT
                                1 < 25       8058
2304             6       4      0   2304     ROOT
                                1 < 360      11887
                                2 > 7602     11888
                                3 < 2304*    11890
                                3 > 8307     11892
                                4 < 2304*    11891
                                4 < 360*     11889
23094            1       2      0   23094    ROOT
                                1 < 2561     13015
2339             1       2      0   2339     ROOT
                                1 > 24594    3965
23416            1       2      0   23416    ROOT
                                1 < 3074     7925
23465            1       2      0   23465    ROOT
                                1 < 598      4505
23480            1       2      0   23480    ROOT
                                1 > 23652    5173
23772            1       2      0   23772    ROOT
                                1 < 735      12948
23776            1       2      0   23776    ROOT
                                1 < 8708     460
23811            3       3      0   23811    ROOT
                                1 < 4038     13143
                                2 > 7058     13142
                                3 > 23811*   13144
23856            2       3      0   23856    ROOT
                                1 > 24451    5693
                                2 < 4252     1759
23881            1       2      0   23881    ROOT
                                1 < 5577     7611
24202            1       2      0   24202    ROOT
                                1 < 2624     7464
24214            1       2      0   24214    ROOT
                                1 < 4116     13349
24464            1       2      0   24464    ROOT
                                1 < 8336     9272
24504            1       2      0   24504    ROOT
                                1 < 8054     12033
24733            1       2      0   24733    ROOT
                                1 < 6776     13049
24957            3       3      0   24957    ROOT
                                1 < 4019     6240
                                2 > 5626     6239
                                3 > 24957*   6241
25062            1       2      0   25062    ROOT
                                1 < 8735     12072
25095            1       2      0   25095    ROOT
                                1 < 9130     13214
254              1       2      0   254      ROOT
                                1 > 7572     9945
25492            9       6      0   25492    ROOT
                                1 > 25511    13407
                                2 < 8512     13406
                                3 > 25492*   13405
                                3 > 9715     13404
                                4 > 25492*   11133
                                4 > 25511*   11134
                                4 < 4034     11130
                                5 > 9717     11131
                                6 < 9715*    11132
25510            1       2      0   25510    ROOT
                                1 < 3279     9327
2557             1       2      0   2557     ROOT
                                1 > 4272     9656
25676            3       3      0   25676    ROOT
                                1 < 350      3528
                                2 > 951      3527
                                3 > 25676*   3529
2569             1       2      0   2569     ROOT
                                1 > 5546     1820
25853            1       2      0   25853    ROOT
                                1 < 8404     8057
26022            3       3      0   26022    ROOT
                                1 < 4021     8577
                                2 > 4826     8576
                                3 > 26022*   8575
294              1       2      0   294      ROOT
                                1 > 8626     4086
2981             1       2      0   2981     ROOT
                                1 > 4427     9683
3206             2       3      0   3206     ROOT
                                1 > 6535     7976
                                1 > 6579     7977
3844             1       2      0   3844     ROOT
                                1 < 82       9542
410              1       2      0   410      ROOT
                                1 > 4366     13307
4254             1       2      0   4254     ROOT
                                1 > 9337     2681
4954             1       2      0   4954     ROOT
                                1 > 4955     9567
5083             3       3      0   5083     ROOT
                                1 > 5084     3494
                                2 > 8711     3496
                                3 < 5083*    3495
5137             1       2      0   5137     ROOT
                                1 > 6884     9209
5261             1       2      0   5261     ROOT
                                1 > 6282     13379
5409             1       2      0   5409     ROOT
                                1 > 8623     9568
5486             1       2      0   5486     ROOT
                                1 > 8366     13376
5490             1       2      0   5490     ROOT
                                1 > 8474     14046
5492             1       2      0   5492     ROOT
                                1 > 5853     13722
6072             1       2      0   6072     ROOT
                                1 > 8887     914
6161             1       2      0   6161     ROOT
                                1 > 7055     8578
6229             2       3      0   6229     ROOT
                                1 > 6423     7947
                                1 > 7647     7948
6446             1       2      0   6446     ROOT
                                1 > 8036     9161
6669             1       2      0   6669     ROOT
                                1 > 9865     9691
6744             1       2      0   6744     ROOT
                                1 > 9595     4285
7534             1       2      0   7534     ROOT
                                1 > 7536     10346
7588             1       2      0   7588     ROOT
                                1 > 7590     9718
8534             1       2      0   8534     ROOT
                                1 > 8676     12343
8615             1       2      0   8615     ROOT
                                1 < 925      3541

14838 rows selected.

Elapsed: 00:00:10.56
Network summary 1 - by network

Network     #Links  #Nodes    Max Lev
---------- ------- ------- ----------
21593            2       2          1
21623            2       2          1
22021            2       2          1
22110            2       2          1
22378            2       2          1
22435            2       2          1
2248             2       2          1
22891            2       2          1
23094            2       2          1
2339             2       2          1
23416            2       2          1
23465            2       2          1
23480            2       2          1
23772            2       2          1
23776            2       2          1
23881            2       2          1
24202            2       2          1
24214            2       2          1
24464            2       2          1
24504            2       2          1
24733            2       2          1
25062            2       2          1
25095            2       2          1
254              2       2          1
25510            2       2          1
2557             2       2          1
2569             2       2          1
25853            2       2          1
294              2       2          1
2981             2       2          1
3844             2       2          1
410              2       2          1
4254             2       2          1
4954             2       2          1
5137             2       2          1
5261             2       2          1
5409             2       2          1
5486             2       2          1
5490             2       2          1
5492             2       2          1
6072             2       2          1
6161             2       2          1
6446             2       2          1
6669             2       2          1
6744             2       2          1
7534             2       2          1
7588             2       2          1
8534             2       2          1
8615             2       2          1
15208            2       2          1
15218            2       2          1
15249            2       2          1
15374            2       2          1
15387            2       2          1
15401            2       2          1
15423            2       2          1
15572            2       2          1
15609            2       2          1
15688            2       2          1
15712            2       2          1
15824            2       2          1
1589             2       2          1
15962            2       2          1
16015            2       2          1
16281            2       2          1
16312            2       2          1
16338            2       2          1
16470            2       2          1
16484            2       2          1
16622            2       2          1
16643            2       2          1
16922            2       2          1
1695             2       2          1
17470            2       2          1
17471            2       2          1
17503            2       2          1
17690            2       2          1
17951            2       2          1
17992            2       2          1
18098            2       2          1
18156            2       2          1
18183            2       2          1
18194            2       2          1
1836             2       2          1
18388            2       2          1
18417            2       2          1
18581            2       2          1
18721            2       2          1
18895            2       2          1
18908            2       2          1
18984            2       2          1
19052            2       2          1
19061            2       2          1
19145            2       2          1
19252            2       2          1
194              2       2          1
19473            2       2          1
1976             2       2          1
19906            2       2          1
19911            2       2          1
19941            2       2          1
2004             2       2          1
20084            2       2          1
20320            2       2          1
20333            2       2          1
20707            2       2          1
21018            2       2          1
21028            2       2          1
2117             2       2          1
2119             2       2          1
2120             2       2          1
21303            2       2          1
21579            2       2          1
10002            2       2          1
1010             2       2          1
10133            2       2          1
10148            2       2          1
10356            2       2          1
10382            2       2          1
10407            2       2          1
10433            2       2          1
1050             2       2          1
10517            2       2          1
10522            2       2          1
10559            2       2          1
10602            2       2          1
10638            2       2          1
10676            2       2          1
10897            2       2          1
1107             2       2          1
11215            2       2          1
11280            2       2          1
11411            2       2          1
11459            2       2          1
11462            2       2          1
11467            2       2          1
11579            2       2          1
11623            2       2          1
11641            2       2          1
11642            2       2          1
11718            2       2          1
11828            2       2          1
1187             2       2          1
11911            2       2          1
1194             2       2          1
11971            2       2          1
11991            2       2          1
12041            2       2          1
12050            2       2          1
12161            2       2          1
12248            2       2          1
12473            2       2          1
12504            2       2          1
12554            2       2          1
12751            2       2          1
12863            2       2          1
13022            2       2          1
13413            2       2          1
1344             2       2          1
1346             2       2          1
13621            2       2          1
13675            2       2          1
13717            2       2          1
1376             2       2          1
14               2       2          1
14130            2       2          1
14131            2       2          1
14132            2       2          1
14182            2       2          1
14338            2       2          1
14358            2       2          1
14763            2       2          1
14771            2       2          1
1490             2       2          1
14990            2       2          1
15181            2       2          1
15188            2       2          1
10115            3       3          1
1013             3       3          2
10317            3       3          1
10432            3       3          1
10513            3       3          1
1092             3       3          1
11216            3       3          2
12252            3       3          2
12256            3       3          1
12290            3       3          1
12617            3       3          2
12676            3       3          2
12703            3       3          1
12704            3       3          2
12798            3       3          2
12940            3       3          2
13485            3       3          2
14339            3       3          2
14842            3       3          2
14894            3       3          1
15259            3       3          2
1551             3       3          2
15681            3       3          1
15706            3       3          1
16523            3       3          2
16609            3       3          2
16957            3       3          2
18003            3       3          1
18171            3       3          1
20803            3       3          1
21206            3       3          2
23856            3       3          2
3206             3       3          1
6229             3       3          1
10178            4       3          3
10180            4       3          3
10252            4       3          3
1051             4       3          3
10818            4       3          3
10872            4       3          3
10936            4       4          1
11054            4       3          3
11120            4       4          1
11196            4       4          2
11197            4       3          3
11285            4       3          3
11465            4       3          3
11566            4       3          3
11893            4       3          3
11965            4       4          2
11969            4       3          3
12192            4       3          3
12307            4       3          3
12320            4       3          3
12338            4       3          3
12616            4       3          3
13012            4       3          3
13167            4       3          3
13202            4       4          3
13415            4       3          3
13486            4       3          3
13677            4       3          3
14560            4       3          3
14845            4       3          3
14868            4       3          3
15358            4       3          3
15415            4       4          2
15642            4       3          3
15847            4       3          3
16124            4       3          3
16129            4       3          3
1621             4       3          3
16358            4       3          3
16802            4       3          3
16892            4       3          3
16971            4       3          3
17179            4       3          3
17276            4       3          3
17291            4       3          3
17346            4       3          3
17461            4       3          3
17468            4       3          3
17865            4       4          2
1798             4       3          3
1821             4       3          3
18279            4       3          3
18544            4       3          3
18596            4       3          3
1916             4       3          3
19257            4       3          3
19466            4       3          3
19502            4       3          3
19554            4       3          3
1969             4       3          3
20150            4       3          3
20216            4       3          3
20309            4       3          3
20433            4       3          3
20914            4       3          3
21288            4       4          2
22827            4       3          3
23811            4       3          3
24957            4       3          3
25676            4       3          3
26022            4       3          3
5083             4       3          3
13031            5       4          3
12801            5       4          3
18669            5       4          3
14543            5       4          3
11427            5       4          4
10682            5       4          3
10679            5       4          3
15583            5       4          3
10637            5       4          3
21515            5       4          3
13357            5       4          3
12113            5       4          4
13932            5       4          4
14159            5       4          3
10154            6       4          4
11842            6       5          4
10906            6       6          2
15248            6       5          3
10355            6       6          2
11418            6       5          4
11279            6       5          3
11622            6       5          3
12689            7       4          4
11561            7       6          4
1154             7       5          5
11028            7       4          4
10672            7       4          4
10564            7       5          3
10341            7       4          4
2304             7       4          4
21684            7       5          3
15668            7       4          4
14353            7       5          4
13802            7       4          4
15396            8       5          4
11539            8       5          4
12046            8       8          3
10904            8       7          4
11879            8       6          5
12387            8       6          4
17280            8       5          4
17178            9       7          3
16620            9       6          5
16109           10       6          6
14770           10       7          4
25492           10       6          6
10884           11       7          6
11593           11      10          5
11662           11       5          5
15182           11       5          5
17782           11       5          5
18970           11       5          5
19015           11       5          5
1383            12       6          6
10792           12       7          6
10056           12       6          5
19932           13       7          5
11616           13       9          5
11009           13       8          5
12414           14       8          6
13325           15       8          7
10338           15       7          6
19314           16       6          6
12034           16       6          6
18034           19       8          6
11823           20       9          7
12042           21      12         10
12213           22       7          7
10163           25       8          8
10677           30      14         11
1000         13423    4158       1146

354 rows selected.

Elapsed: 00:00:01.75
Network summary 2 - grouped by numbers of nodes

 #Nodes #Networks
------- ---------
      2       177
      3        98
      4        30
      5        17
      6        12
      7         8
      8         6
      9         2
     10         1
     12         1
     14         1
   4158         1

12 rows selected.

Elapsed: 00:00:01.44

The results show that the data set contains 354 connected networks, with one much larger than the rest, having 4158 nodes. This (more or less) matches with the results we got from source 3466. Actually, we should get one fewer record back than the number of nodes in the network, but as in the earlier article the SQL returns the source node in one record - we can easily fix this, but it's not worthwhile my redoing all the results, so I leave it as is.

As another check, we can run against the second largest network, using 10677 as the source, which should give 14 records. Here is the result for SP_GTTRSF_Q, LEVMAX=10.

NODE                            LEV  MAXLEV  INTNOD  INTMAX PATH                                                                            
------------------------------ ---- ------- ------- ------- --------------------------------------------------------------------------------
309                               1       2       1       2 309
9591                              1       2       1       2 9591
..2136                            2       2       2       2 9591,2136
..2186                            2       2       2       2 9591,2186
..6012                            2       2       2       2 9591,6012
..11030                           2       2       2       2 9591,11030
..13704                           2       2       2       2 9591,13704
..17453                           2       2       2       2 9591,17453
..23946                           2       2       2       2 9591,23946
..25611                           2       2       2       2 9591,25611
17015                             1       2       1       2 17015
..10677                           2       2       2       2 9591,10677
..20560                           2       2       2       2 309,20560
..21314                           2       2       2       2 17015,21314

14 rows selected.

This is consistent with the network output with source node appearing once. The network output (usually I indent the records by level, but the level is very high in some networks here) is:

Network     #Links  #Nodes    Lev Node       Link
---------- ------- ------- ------ ---------- ----------
10677           29      14      0   10677    ROOT
                                1 > 17015    9130
                                2 > 20560    7465
                                3 < 309      7253
                                4 > 10677*   7250
                                4 > 17015*   7251
                                4 > 17453    7252
                                5 < 11030    10700
                                6 > 23946    10701
                                7 < 17453*   4282
                                7 > 25611    10703
                                8 < 11030*   10702
                                8 < 17453*   4283
                                8 < 6012     8987
                                9 > 11030*   8984
                                9 > 17453*   8985
                                9 > 23946*   8986
                                9 > 9591     8983
                               10 > 10677*   4275
                               10 > 11030*   4276
                               10 > 13704    4277
                               10 > 17015*   4278
                               10 > 17453*   4279
                               10 < 2136     4273
                               11 > 17453*   4274
                               10 < 2186     14089
                               10 > 23946*   4280
                               10 > 25611*   4281
                               10 < 309*     7249
                                2 > 21314    7466

Results: Friendship network of Brightkite users

Friendship network of Brightkite users

Brightkite was once a location-based social networking service provider where users shared their locations by checking-in. The friendship network was collected using their public API, and consists of 58,228 nodes and 214,078 edges. The network is originally directed but we have constructed a network with undirected edges when there is a friendship in both ways.

The data set comes with the reverse arcs already present, making a total of 428,156 arcs.

I took the first node in the first line in the data set file as the initial root node, 0, and tested only the method SP_GTTRSF_I/Q for values of LEVMAX of 5, 10. The complete results, including execution plans are in the attached file.

The exact solution has 56,739 nodes reached from the source node 0, with a maximum level of 10. The output is a bit large to embed, so attaching it in file, but here are the last few lines of the exact solution:

122                               1      10       1      13 122
..0                               2      10       2      13 99,0
..6534                            2      10       2      13 122,6534
....15726                         3      10       3      13 40,647,15726
......42871                       4      10       4      13 69,4994,12608,42871
......45149                       4      10       4      13 40,2886,15714,45149
......45850                       4      10       4      13 122,6534,15726,45850
......45851                       4      10       4      13 40,2886,22440,45851
......45852                       4      10       4      13 122,6534,15726,45852
......45853                       4      10       4      13 40,2886,26635,45853
......45854                       4      10       4      13 36,2625,15736,45854
......45855                       4      10       4      13 122,6534,15726,45855
......45856                       4      10       4      13 122,6534,15726,45856
....15744                         3      10       3      13 40,647,15744
....34944                         3      10       3      13 122,6534,34944
....34945                         3      10       3      13 122,6534,34945
....34946                         3      10       3      13 122,6534,34946

56739 rows selected.

Elapsed: 00:01:32.49

In summary, as shown in the embedded Excel file, the exact solution is found in a total of 105 seconds and 344 seconds (based on Xplan timings) for LEVMAX=5 and 10 respectively.

I ran my network analysis program on this network too, and here is the final grouped results, showing consistency with the largest connected network of 56,739 nodes.

Network summary 2 - grouped by numbers of nodes

 #Nodes #Networks
------- ---------
      2       362
      3       103
      4        40
      5        21
      6         9
      7         3
      8         2
      9         1
     10         2
     11         2
     49         1
  56739         1

12 rows selected.

Elapsed: 00:00:24.17

We can do a further test by using a source from a smaller network. 51944 is a root of the network of size 49 nodes (as the full output shows). Here is the result of sourcing from that, again consistent witht he network analysis program that uses a completely diffferent algorithm:

NODE                            LEV  MAXLEV  INTNOD  INTMAX PATH
------------------------------ ---- ------- ------- ------- --------------------------------------------------------------------------------
57077                             1       7       1       9 57077
..51944                           2       7       2       9 57077,51944
..57969                           2       7       2       9 57077,57969
....58151                         3       7       3       9 57077,57969,58151
......58195                       4       7       4       9 57077,57969,58151,58195
........58218                     5       7       5       9 57077,57969,58151,58195,58218
......58196                       4       7       4       9 57077,57969,58151,58196
......58197                       4       7       4       9 57077,57969,58151,58197
......58198                       4       7       4       9 57077,57969,58151,58198
......58199                       4       7       4       9 57077,57969,58151,58199
......58201                       4       7       4       9 57077,57969,58151,58201
......58202                       4       7       4       9 57077,57969,58151,58202
......58203                       4       7       4       9 57077,57969,58151,58203
....58152                         3       7       3       9 57077,57969,58152
......58205                       4       7       4       9 57077,57969,58152,58205
........58219                     5       7       5       9 57077,57969,58152,58205,58219
..........58224                   6       7       6       9 57077,57969,58152,58205,58219,58224
........58220                     5       7       5       9 57077,57969,58152,58205,58220
..........58226                   6       7       8       9 57077,57969,58152,58205,58220,58226
............58227                 7       7       8       9 57077,57969,58152,58205,58220,58225,58227
..........58225                   6       7       9       9 57077,57969,58152,58205,58220,58225
........58221                     5       7       5       9 57077,57969,58152,58205,58221
......58207                       4       7       4       9 57077,57969,58152,58207
....58153                         3       7       3       9 57077,57969,58153
....58154                         3       7       3       9 57077,57969,58154
......58208                       4       7       4       9 57077,57969,58154,58208
......58209                       4       7       4       9 57077,57969,58154,58209
....58156                         3       7       3       9 57077,57969,58156
....58159                         3       7       3       9 57077,57969,58159
......58200                       4       7       4       9 57077,57969,58159,58200
....58160                         3       7       3       9 57077,57969,58160
......58210                       4       7       4       9 57077,57969,58160,58210
........58222                     5       7       5       9 57077,57969,58160,58210,58222
......58211                       4       7       4       9 57077,57969,58160,58211
......58212                       4       7       4       9 57077,57969,58160,58212
........58223                     5       7       5       9 57077,57969,58160,58212,58223
....58161                         3       7       3       9 57077,57969,58161
......58204                       4       7       4       9 57077,57969,58161,58204
......58206                       4       7       4       9 57077,57969,58161,58206
..57970                           2       7       2       9 57077,57970
....58155                         3       7       3       9 57077,57970,58155
....58157                         3       7       3       9 57077,57970,58157
....58158                         3       7       3       9 57077,57970,58158
..57971                           2       7       2       9 57077,57971
..57972                           2       7       2       9 57077,57972
....58162                         3       7       3       9 57077,57972,58162
..57973                           2       7       2       9 57077,57973
..57974                           2       7       2       9 57077,57974
....58163                         3       7       3       9 57077,57974,58163

49 rows selected.

Elapsed: 00:00:00.21

[4 May 2015 - I will add attachments in the next few days after tidying up, including the network analysis package]
[11 May 2015: I added PL/SQL Pipelined Function for Network Analysis]






NoCOUG SQL Challenge 2014 Illustrated

An SQL challenge was posted recently on the blog of the Northern California Oracle user group, SQL Mini-challenge. A query was given against Oracle’s demo HR schema, with description:

It lists the locations containing a department that either contains an employee named Steven King or an employee who holds the title of President or an employee who has previously held the title of President.

The challenge was to rewrite the query avoiding the relatively expensive existence subqueries, and minimising the number of consistent gets reported on the small demo data set. Oracle’s Cost-Based Optimiser will itself transform queries within its parsing phase, but at a relatively low level; for example, an ‘OR’ condition might be changed to a union if the CBO thinks that will aid performance. The solutions to the challenge present a nice illustration of how more extensive query transfomations can improve performance and modularity characteristics.

In this article I will list four equivalent queries for the problem, three based on solutions provided on the blog, using Ansi syntax here for consistency. For each query I give the output from DBMS_XPlan, and include a query structure diagram following my own diagramming notation. The example query provided in the challenge is not in fact the most literal translation of the requirement into SQL, and I think it will be interesting to start with my idea of what that would be.

Update 28 October 2014: I noticed that in the ‘literal’ query I had omitted the location condition on the third subquery. I have fixed this and the execution plan is much worse. The results reported here were from version 11.2; running on v12.1 gives some extremely interesting differences, and I have added the v12.1 results at the end for the ‘literal’ query. They show a much improved plan, with departments ‘factorised’ out.

Query 1: Literal
This my attempt at the most literal translation of the stated requirement into SQL. The three conditions are all separately expressed as existence subqueries.

QSD Literal

NCOUG-Literal

Query Literal
Note that in an earlier version of this article, I had omitted the final ‘d.location_id = l.location_id’ condition.

SELECT l.location_id, l.city
  FROM locations l
 WHERE EXISTS
  (SELECT *
     FROM departments d
     JOIN employees e
       ON e.department_id = d.department_id
    WHERE d.location_id = l.location_id
      AND e.first_name = 'Steven' AND e.last_name = 'King'
  ) OR EXISTS
  (SELECT *
     FROM departments d
     JOIN employees e
       ON e.department_id = d.department_id
     JOIN jobs j
       ON j.job_id = e.job_id
    WHERE d.location_id = l.location_id
      AND j.job_title = 'President'
  ) OR EXISTS
  (SELECT *
     FROM departments d
     JOIN employees e
       ON e.department_id = d.department_id
     JOIN job_history h
       ON h.employee_id = e.employee_id
     JOIN jobs j2
       ON j2.job_id = h.job_id
    WHERE d.location_id = l.location_id
      AND j2.job_title   = 'President'
  )

XPlan Literal

-------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                        | Name              | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                 |                   |      1 |        |      1 |00:00:00.01 |     426 |       |       |          |
|*  1 |  FILTER                          |                   |      1 |        |      1 |00:00:00.01 |     426 |       |       |          |
|   2 |   VIEW                           | index$_join$_001  |      1 |     23 |     23 |00:00:00.01 |       7 |       |       |          |
|*  3 |    HASH JOIN                     |                   |      1 |        |     23 |00:00:00.01 |       7 |  1023K|  1023K| 1150K (0)|
|   4 |     INDEX FAST FULL SCAN         | LOC_CITY_IX       |      1 |     23 |     23 |00:00:00.01 |       3 |       |       |          |
|   5 |     INDEX FAST FULL SCAN         | LOC_ID_PK         |      1 |     23 |     23 |00:00:00.01 |       4 |       |       |          |
|   6 |   NESTED LOOPS                   |                   |     23 |        |      1 |00:00:00.01 |      92 |       |       |          |
|   7 |    NESTED LOOPS                  |                   |     23 |      1 |     23 |00:00:00.01 |      69 |       |       |          |
|   8 |     TABLE ACCESS BY INDEX ROWID  | EMPLOYEES         |     23 |      1 |     23 |00:00:00.01 |      46 |       |       |          |
|*  9 |      INDEX RANGE SCAN            | EMP_NAME_IX       |     23 |      1 |     23 |00:00:00.01 |      23 |       |       |          |
|* 10 |     INDEX UNIQUE SCAN            | DEPT_ID_PK        |     23 |      1 |     23 |00:00:00.01 |      23 |       |       |          |
|* 11 |    TABLE ACCESS BY INDEX ROWID   | DEPARTMENTS       |     23 |      1 |      1 |00:00:00.01 |      23 |       |       |          |
|  12 |   NESTED LOOPS                   |                   |     22 |        |      0 |00:00:00.01 |     173 |       |       |          |
|  13 |    NESTED LOOPS                  |                   |     22 |      1 |     88 |00:00:00.01 |     166 |       |       |          |
|  14 |     NESTED LOOPS                 |                   |     22 |      2 |      6 |00:00:00.01 |     160 |       |       |          |
|* 15 |      TABLE ACCESS FULL           | JOBS              |     22 |      1 |     22 |00:00:00.01 |     132 |       |       |          |
|  16 |      TABLE ACCESS BY INDEX ROWID | DEPARTMENTS       |     22 |      2 |      6 |00:00:00.01 |      28 |       |       |          |
|* 17 |       INDEX RANGE SCAN           | DEPT_LOCATION_IX  |     22 |      2 |      6 |00:00:00.01 |      22 |       |       |          |
|* 18 |     INDEX RANGE SCAN             | EMP_DEPARTMENT_IX |      6 |     10 |     88 |00:00:00.01 |       6 |       |       |          |
|* 19 |    TABLE ACCESS BY INDEX ROWID   | EMPLOYEES         |     88 |      1 |      0 |00:00:00.01 |       7 |       |       |          |
|  20 |   NESTED LOOPS                   |                   |     22 |        |      0 |00:00:00.01 |     154 |       |       |          |
|  21 |    NESTED LOOPS                  |                   |     22 |      1 |      0 |00:00:00.01 |     154 |       |       |          |
|  22 |     NESTED LOOPS                 |                   |     22 |      1 |      0 |00:00:00.01 |     154 |       |       |          |
|  23 |      NESTED LOOPS                |                   |     22 |      1 |      0 |00:00:00.01 |     154 |       |       |          |
|* 24 |       TABLE ACCESS FULL          | JOBS              |     22 |      1 |     22 |00:00:00.01 |     132 |       |       |          |
|  25 |       TABLE ACCESS BY INDEX ROWID| JOB_HISTORY       |     22 |      1 |      0 |00:00:00.01 |      22 |       |       |          |
|* 26 |        INDEX RANGE SCAN          | JHIST_JOB_IX      |     22 |      1 |      0 |00:00:00.01 |      22 |       |       |          |
|  27 |      TABLE ACCESS BY INDEX ROWID | EMPLOYEES         |      0 |      1 |      0 |00:00:00.01 |       0 |       |       |          |
|* 28 |       INDEX UNIQUE SCAN          | EMP_EMP_ID_PK     |      0 |      1 |      0 |00:00:00.01 |       0 |       |       |          |
|* 29 |     INDEX UNIQUE SCAN            | DEPT_ID_PK        |      0 |      1 |      0 |00:00:00.01 |       0 |       |       |          |
|* 30 |    TABLE ACCESS BY INDEX ROWID   | DEPARTMENTS       |      0 |      1 |      0 |00:00:00.01 |       0 |       |       |          |
-------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter(( IS NOT NULL OR  IS NOT NULL OR  IS NOT NULL))
   3 - access(ROWID=ROWID)
   9 - access("E"."LAST_NAME"='King' AND "E"."FIRST_NAME"='Steven')
  10 - access("E"."DEPARTMENT_ID"="D"."DEPARTMENT_ID")
  11 - filter("D"."LOCATION_ID"=:B1)
  15 - filter("J"."JOB_TITLE"='President')
  17 - access("D"."LOCATION_ID"=:B1)
  18 - access("E"."DEPARTMENT_ID"="D"."DEPARTMENT_ID")
  19 - filter("J"."JOB_ID"="E"."JOB_ID")
  24 - filter("J2"."JOB_TITLE"='President')
  26 - access("J2"."JOB_ID"="H"."JOB_ID")
  28 - access("H"."EMPLOYEE_ID"="E"."EMPLOYEE_ID")
  29 - access("E"."DEPARTMENT_ID"="D"."DEPARTMENT_ID")
  30 - filter("D"."LOCATION_ID"=:B1)

Query 2: NoCOUG Example
This is the example in the original challenge article, translated into Ansi syntax. It nests the job history existence subquery within an outer existence subquery, and references the departments and employees tables only once.

QSD NoCOUG Example

NCOUG-Example

Query NoCOUG Example

SELECT l.location_id, l.city
  FROM locations l
 WHERE EXISTS
  (SELECT *
     FROM departments d
     JOIN employees e
       ON e.department_id = d.department_id
     JOIN jobs j
       ON j.job_id = e.job_id
    WHERE d.location_id = l.location_id
      AND ( 
            (e.first_name = 'Steven' AND e.last_name = 'King')
         OR j.job_title = 'President'
         OR EXISTS
            (SELECT *
               FROM job_history h
               JOIN jobs j2
                 ON j2.job_id = h.job_id
              WHERE h.employee_id = e.employee_id
                AND j2.job_title   = 'President'
            ) 
          )
  )

XPlan NoCOUG Example

-------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                        | Name              | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                 |                   |      1 |        |      1 |00:00:00.01 |     152 |       |       |          |
|*  1 |  HASH JOIN SEMI                  |                   |      1 |      7 |      1 |00:00:00.01 |     152 |  1156K|  1156K| 1120K (0)|
|   2 |   VIEW                           | index$_join$_001  |      1 |     23 |     23 |00:00:00.01 |       6 |       |       |          |
|*  3 |    HASH JOIN                     |                   |      1 |        |     23 |00:00:00.01 |       6 |  1023K|  1023K| 1443K (0)|
|   4 |     INDEX FAST FULL SCAN         | LOC_CITY_IX       |      1 |     23 |     23 |00:00:00.01 |       3 |       |       |          |
|   5 |     INDEX FAST FULL SCAN         | LOC_ID_PK         |      1 |     23 |     23 |00:00:00.01 |       3 |       |       |          |
|   6 |   VIEW                           | VW_SQ_1           |      1 |     11 |      1 |00:00:00.01 |     146 |       |       |          |
|*  7 |    FILTER                        |                   |      1 |        |      1 |00:00:00.01 |     146 |       |       |          |
|*  8 |     HASH JOIN                    |                   |      1 |    106 |    106 |00:00:00.01 |      15 |   876K|   876K|  895K (0)|
|   9 |      MERGE JOIN                  |                   |      1 |    107 |    107 |00:00:00.01 |       8 |       |       |          |
|  10 |       TABLE ACCESS BY INDEX ROWID| JOBS              |      1 |     19 |     19 |00:00:00.01 |       2 |       |       |          |
|  11 |        INDEX FULL SCAN           | JOB_ID_PK         |      1 |     19 |     19 |00:00:00.01 |       1 |       |       |          |
|* 12 |       SORT JOIN                  |                   |     19 |    107 |    107 |00:00:00.01 |       6 | 15360 | 15360 |14336  (0)|
|  13 |        TABLE ACCESS FULL         | EMPLOYEES         |      1 |    107 |    107 |00:00:00.01 |       6 |       |       |          |
|  14 |      TABLE ACCESS FULL           | DEPARTMENTS       |      1 |     27 |     27 |00:00:00.01 |       7 |       |       |          |
|  15 |     NESTED LOOPS                 |                   |    105 |        |      0 |00:00:00.01 |     131 |       |       |          |
|  16 |      NESTED LOOPS                |                   |    105 |      1 |     10 |00:00:00.01 |     121 |       |       |          |
|  17 |       TABLE ACCESS BY INDEX ROWID| JOB_HISTORY       |    105 |      1 |     10 |00:00:00.01 |     112 |       |       |          |
|* 18 |        INDEX RANGE SCAN          | JHIST_EMPLOYEE_IX |    105 |      1 |     10 |00:00:00.01 |     105 |       |       |          |
|* 19 |       INDEX UNIQUE SCAN          | JOB_ID_PK         |     10 |      1 |     10 |00:00:00.01 |       9 |       |       |          |
|* 20 |      TABLE ACCESS BY INDEX ROWID | JOBS              |     10 |      1 |      0 |00:00:00.01 |      10 |       |       |          |
-------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - access("ITEM_1"="L"."LOCATION_ID")
   3 - access(ROWID=ROWID)
   7 - filter((("E"."FIRST_NAME"='Steven' AND "E"."LAST_NAME"='King') OR "J"."JOB_TITLE"='President' OR  IS NOT NULL))
   8 - access("E"."DEPARTMENT_ID"="D"."DEPARTMENT_ID")
  12 - access("J"."JOB_ID"="E"."JOB_ID")
       filter("J"."JOB_ID"="E"."JOB_ID")
  18 - access("H"."EMPLOYEE_ID"=:B1)
  19 - access("J2"."JOB_ID"="H"."JOB_ID")
  20 - filter("J2"."JOB_TITLE"='President')

Query 3: Subquery Factor Union
This converts the ‘OR’ conditions into a union of three driving subqueries that return the matching department ids from a subquery factor (which could equally be an inline view), and then joins departments and locations.

QSD Subquery Factor Union

NCOUG-SQF

Query Subquery Factor Union

WITH driving_union AS (
SELECT e.department_id
  FROM employees e
 WHERE (e.first_name = 'Steven' AND e.last_name = 'King')
 UNION
SELECT e.department_id
  FROM jobs j
  JOIN employees e
    ON e.job_id        = j.job_id
 WHERE j.job_title     = 'President'
 UNION
SELECT e.department_id
  FROM jobs j
  JOIN job_history h
    ON j.job_id        = h.job_id
  JOIN employees e
    ON e.employee_id    = h.employee_id
 WHERE j.job_title     = 'President'
)
SELECT DISTINCT l.location_id, l.city
  FROM driving_union u
  JOIN departments d
    ON d.department_id 	= u.department_id
  JOIN locations l
    ON l.location_id 	= d.location_id

XPlan Subquery Factor Union

----------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                            | Name             | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
----------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                     |                  |      1 |        |      1 |00:00:00.01 |      29 |       |       |          |
|   1 |  HASH UNIQUE                         |                  |      1 |      8 |      1 |00:00:00.01 |      29 |  1156K|  1156K|  464K (0)|
|*  2 |   HASH JOIN                          |                  |      1 |      8 |      1 |00:00:00.01 |      29 |  1517K|  1517K|  366K (0)|
|*  3 |    HASH JOIN                         |                  |      1 |      8 |      1 |00:00:00.01 |      23 |  1517K|  1517K|  382K (0)|
|   4 |     VIEW                             |                  |      1 |      8 |      1 |00:00:00.01 |      17 |       |       |          |
|   5 |      SORT UNIQUE                     |                  |      1 |      8 |      1 |00:00:00.01 |      17 |  2048 |  2048 | 2048  (0)|
|   6 |       UNION-ALL                      |                  |      1 |        |      2 |00:00:00.01 |      17 |       |       |          |
|   7 |        TABLE ACCESS BY INDEX ROWID   | EMPLOYEES        |      1 |      1 |      1 |00:00:00.01 |       2 |       |       |          |
|*  8 |         INDEX RANGE SCAN             | EMP_NAME_IX      |      1 |      1 |      1 |00:00:00.01 |       1 |       |       |          |
|   9 |        NESTED LOOPS                  |                  |      1 |        |      1 |00:00:00.01 |       8 |       |       |          |
|  10 |         NESTED LOOPS                 |                  |      1 |      6 |      1 |00:00:00.01 |       7 |       |       |          |
|* 11 |          TABLE ACCESS FULL           | JOBS             |      1 |      1 |      1 |00:00:00.01 |       6 |       |       |          |
|* 12 |          INDEX RANGE SCAN            | EMP_JOB_IX       |      1 |      6 |      1 |00:00:00.01 |       1 |       |       |          |
|  13 |         TABLE ACCESS BY INDEX ROWID  | EMPLOYEES        |      1 |      6 |      1 |00:00:00.01 |       1 |       |       |          |
|  14 |        NESTED LOOPS                  |                  |      1 |        |      0 |00:00:00.01 |       7 |       |       |          |
|  15 |         NESTED LOOPS                 |                  |      1 |      1 |      0 |00:00:00.01 |       7 |       |       |          |
|  16 |          NESTED LOOPS                |                  |      1 |      1 |      0 |00:00:00.01 |       7 |       |       |          |
|* 17 |           TABLE ACCESS FULL          | JOBS             |      1 |      1 |      1 |00:00:00.01 |       6 |       |       |          |
|  18 |           TABLE ACCESS BY INDEX ROWID| JOB_HISTORY      |      1 |      1 |      0 |00:00:00.01 |       1 |       |       |          |
|* 19 |            INDEX RANGE SCAN          | JHIST_JOB_IX     |      1 |      1 |      0 |00:00:00.01 |       1 |       |       |          |
|* 20 |          INDEX UNIQUE SCAN           | EMP_EMP_ID_PK    |      0 |      1 |      0 |00:00:00.01 |       0 |       |       |          |
|  21 |         TABLE ACCESS BY INDEX ROWID  | EMPLOYEES        |      0 |      1 |      0 |00:00:00.01 |       0 |       |       |          |
|  22 |     VIEW                             | index$_join$_011 |      1 |     27 |     27 |00:00:00.01 |       6 |       |       |          |
|* 23 |      HASH JOIN                       |                  |      1 |        |     27 |00:00:00.01 |       6 |  1096K|  1096K| 1547K (0)|
|  24 |       INDEX FAST FULL SCAN           | DEPT_ID_PK       |      1 |     27 |     27 |00:00:00.01 |       3 |       |       |          |
|  25 |       INDEX FAST FULL SCAN           | DEPT_LOCATION_IX |      1 |     27 |     27 |00:00:00.01 |       3 |       |       |          |
|  26 |    VIEW                              | index$_join$_013 |      1 |     23 |     23 |00:00:00.01 |       6 |       |       |          |
|* 27 |     HASH JOIN                        |                  |      1 |        |     23 |00:00:00.01 |       6 |  1023K|  1023K| 1426K (0)|
|  28 |      INDEX FAST FULL SCAN            | LOC_CITY_IX      |      1 |     23 |     23 |00:00:00.01 |       3 |       |       |          |
|  29 |      INDEX FAST FULL SCAN            | LOC_ID_PK        |      1 |     23 |     23 |00:00:00.01 |       3 |       |       |          |
----------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("L"."LOCATION_ID"="D"."LOCATION_ID")
   3 - access("D"."DEPARTMENT_ID"="U"."DEPARTMENT_ID")
   8 - access("E"."LAST_NAME"='King' AND "E"."FIRST_NAME"='Steven')
  11 - filter("J"."JOB_TITLE"='President')
  12 - access("E"."JOB_ID"="J"."JOB_ID")
  17 - filter("J"."JOB_TITLE"='President')
  19 - access("J"."JOB_ID"="H"."JOB_ID")
  20 - access("E"."EMPLOYEE_ID"="H"."EMPLOYEE_ID")
  23 - access(ROWID=ROWID)
  27 - access(ROWID=ROWID)

Query 4: Outer Joins
This avoids existence subqueries using the idea that an outer join with a constraint that the joined record is not null, with a distinct qualifier to eliminate duplicates, can serve as a logical equivalent.

QSD Outer Joins

NCOUG-OJ

Query Outer Joins

SELECT DISTINCT l.location_id, l.city
  FROM employees e
  LEFT JOIN jobs j
    ON j.job_id        	= e.job_id
   AND j.job_title      = 'President'  
  LEFT JOIN job_history h
    ON h.employee_id    = e.employee_id
  LEFT JOIN jobs j2
    ON j2.job_id        = h.job_id
   AND j2.job_title     = 'President' 
  JOIN departments d
    ON d.department_id 	= e.department_id
  JOIN locations l
    ON l.location_id 	= d.location_id
 WHERE (e.first_name = 'Steven' AND e.last_name = 'King')
    OR j.job_id IS NOT NULL
    OR j2.job_id IS NOT NULL

XPlan Outer Joins

----------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                     | Name              | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
----------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT              |                   |      1 |        |      1 |00:00:00.01 |      36 |       |       |          |
|   1 |  HASH UNIQUE                  |                   |      1 |    106 |      1 |00:00:00.01 |      36 |  1156K|  1156K|  464K (0)|
|*  2 |   FILTER                      |                   |      1 |        |      1 |00:00:00.01 |      36 |       |       |          |
|*  3 |    HASH JOIN RIGHT OUTER      |                   |      1 |    106 |    109 |00:00:00.01 |      36 |  1269K|  1269K|  369K (0)|
|*  4 |     TABLE ACCESS FULL         | JOBS              |      1 |      1 |      1 |00:00:00.01 |       6 |       |       |          |
|*  5 |     HASH JOIN RIGHT OUTER     |                   |      1 |    106 |    109 |00:00:00.01 |      30 |  1134K|  1134K|  751K (0)|
|   6 |      VIEW                     | index$_join$_004  |      1 |     10 |     10 |00:00:00.01 |       6 |       |       |          |
|*  7 |       HASH JOIN               |                   |      1 |        |     10 |00:00:00.01 |       6 |  1096K|  1096K| 1331K (0)|
|   8 |        INDEX FAST FULL SCAN   | JHIST_EMPLOYEE_IX |      1 |     10 |     10 |00:00:00.01 |       3 |       |       |          |
|   9 |        INDEX FAST FULL SCAN   | JHIST_JOB_IX      |      1 |     10 |     10 |00:00:00.01 |       3 |       |       |          |
|* 10 |      HASH JOIN OUTER          |                   |      1 |    106 |    106 |00:00:00.01 |      24 |   858K|   858K| 1270K (0)|
|* 11 |       HASH JOIN               |                   |      1 |    106 |    106 |00:00:00.01 |      18 |  1063K|  1063K| 1252K (0)|
|* 12 |        HASH JOIN              |                   |      1 |     27 |     27 |00:00:00.01 |      12 |  1156K|  1156K| 1133K (0)|
|  13 |         VIEW                  | index$_join$_010  |      1 |     23 |     23 |00:00:00.01 |       6 |       |       |          |
|* 14 |          HASH JOIN            |                   |      1 |        |     23 |00:00:00.01 |       6 |  1023K|  1023K| 1450K (0)|
|  15 |           INDEX FAST FULL SCAN| LOC_CITY_IX       |      1 |     23 |     23 |00:00:00.01 |       3 |       |       |          |
|  16 |           INDEX FAST FULL SCAN| LOC_ID_PK         |      1 |     23 |     23 |00:00:00.01 |       3 |       |       |          |
|  17 |         VIEW                  | index$_join$_008  |      1 |     27 |     27 |00:00:00.01 |       6 |       |       |          |
|* 18 |          HASH JOIN            |                   |      1 |        |     27 |00:00:00.01 |       6 |  1096K|  1096K| 1547K (0)|
|  19 |           INDEX FAST FULL SCAN| DEPT_ID_PK        |      1 |     27 |     27 |00:00:00.01 |       3 |       |       |          |
|  20 |           INDEX FAST FULL SCAN| DEPT_LOCATION_IX  |      1 |     27 |     27 |00:00:00.01 |       3 |       |       |          |
|  21 |        TABLE ACCESS FULL      | EMPLOYEES         |      1 |    107 |    107 |00:00:00.01 |       6 |       |       |          |
|* 22 |       TABLE ACCESS FULL       | JOBS              |      1 |      1 |      1 |00:00:00.01 |       6 |       |       |          |
----------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - filter((("E"."FIRST_NAME"='Steven' AND "E"."LAST_NAME"='King') OR "J"."JOB_ID" IS NOT NULL OR "J2"."JOB_ID" IS NOT NULL))
   3 - access("J2"."JOB_ID"="H"."JOB_ID")
   4 - filter("J2"."JOB_TITLE"='President')
   5 - access("H"."EMPLOYEE_ID"="E"."EMPLOYEE_ID")
   7 - access(ROWID=ROWID)
  10 - access("J"."JOB_ID"="E"."JOB_ID")
  11 - access("D"."DEPARTMENT_ID"="E"."DEPARTMENT_ID")
  12 - access("L"."LOCATION_ID"="D"."LOCATION_ID")
  14 - access(ROWID=ROWID)
  18 - access(ROWID=ROWID)
  22 - filter("J"."JOB_TITLE"='President')

Query Summary Table v11.2

Here is a summary of some statistics on the queries, run on an Oracle 11.2 XE instance. Query lines depends on formatting of course.

Query Buffers Table Instances XPlan Steps Query Lines
Literal 426 10 30 30
NoCOUG Example 152 6 20 23
Subquery Factor Union 29 6 29 25
Outer Joins 36 6 22 17

Oracle 12c

While the original version of this article, posted 25 August 2014, was based on Oracle 11.2, I later ran my script on Oracle 12.1, and noted that the ‘literal’ query now had a much-changed execution plan. In particular, the departments table had been ‘factorised’ out, appearing only once, and giving a much reduced buffer count of 31. It seems that this comes from an improvement in the transformation phase of query execution. The other queries did not show so much difference in plans, see the summary table below.

Execution Plan for Literal v12.1

-----------------------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                    | Name               | Starts | E-Rows | A-Rows |   A-Time   | Buffers | Reads  |  OMem |  1Mem | Used-Mem |
-----------------------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                             |                    |      1 |        |      1 |00:00:00.05 |      31 |      1 |       |       |          |
|*  1 |  HASH JOIN SEMI                              |                    |      1 |      7 |      1 |00:00:00.05 |      31 |      1 |  1645K|  1645K| 1432K (0)|
|   2 |   VIEW                                       | index$_join$_001   |      1 |     23 |     23 |00:00:00.01 |       8 |      0 |       |       |          |
|*  3 |    HASH JOIN                                 |                    |      1 |        |     23 |00:00:00.01 |       8 |      0 |  1368K|  1368K| 1566K (0)|
|   4 |     INDEX FAST FULL SCAN                     | LOC_CITY_IX        |      1 |     23 |     23 |00:00:00.01 |       4 |      0 |       |       |          |
|   5 |     INDEX FAST FULL SCAN                     | LOC_ID_PK          |      1 |     23 |     23 |00:00:00.01 |       4 |      0 |       |       |          |
|   6 |   VIEW                                       | VW_SQ_1            |      1 |      8 |      1 |00:00:00.05 |      23 |      1 |       |       |          |
|   7 |    MERGE JOIN SEMI                           |                    |      1 |      8 |      1 |00:00:00.05 |      23 |      1 |       |       |          |
|   8 |     TABLE ACCESS BY INDEX ROWID              | DEPARTMENTS        |      1 |     27 |     10 |00:00:00.01 |       4 |      0 |       |       |          |
|   9 |      INDEX FULL SCAN                         | DEPT_ID_PK         |      1 |     27 |     10 |00:00:00.01 |       2 |      0 |       |       |          |
|* 10 |     SORT UNIQUE                              |                    |     10 |      8 |      1 |00:00:00.05 |      19 |      1 |  2048 |  2048 | 2048  (0)|
|  11 |      VIEW                                    | VW_JF_SET$1236063A |      1 |      8 |      2 |00:00:00.05 |      19 |      1 |       |       |          |
|  12 |       UNION-ALL                              |                    |      1 |        |      2 |00:00:00.05 |      19 |      1 |       |       |          |
|  13 |        NESTED LOOPS                          |                    |      1 |        |      1 |00:00:00.05 |       9 |      1 |       |       |          |
|  14 |         NESTED LOOPS                         |                    |      1 |      6 |      1 |00:00:00.05 |       8 |      1 |       |       |          |
|* 15 |          TABLE ACCESS FULL                   | JOBS               |      1 |      1 |      1 |00:00:00.01 |       7 |      0 |       |       |          |
|* 16 |          INDEX RANGE SCAN                    | EMP_JOB_IX         |      1 |      6 |      1 |00:00:00.05 |       1 |      1 |       |       |          |
|  17 |         TABLE ACCESS BY INDEX ROWID          | EMPLOYEES          |      1 |      6 |      1 |00:00:00.01 |       1 |      0 |       |       |          |
|  18 |        TABLE ACCESS BY INDEX ROWID BATCHED   | EMPLOYEES          |      1 |      1 |      1 |00:00:00.01 |       2 |      0 |       |       |          |
|* 19 |         INDEX RANGE SCAN                     | EMP_NAME_IX        |      1 |      1 |      1 |00:00:00.01 |       1 |      0 |       |       |          |
|  20 |        NESTED LOOPS                          |                    |      1 |        |      0 |00:00:00.01 |       8 |      0 |       |       |          |
|  21 |         NESTED LOOPS                         |                    |      1 |      1 |      0 |00:00:00.01 |       8 |      0 |       |       |          |
|  22 |          NESTED LOOPS                        |                    |      1 |      1 |      0 |00:00:00.01 |       8 |      0 |       |       |          |
|* 23 |           TABLE ACCESS FULL                  | JOBS               |      1 |      1 |      1 |00:00:00.01 |       7 |      0 |       |       |          |
|  24 |           TABLE ACCESS BY INDEX ROWID BATCHED| JOB_HISTORY        |      1 |      1 |      0 |00:00:00.01 |       1 |      0 |       |       |          |
|* 25 |            INDEX RANGE SCAN                  | JHIST_JOB_IX       |      1 |      1 |      0 |00:00:00.01 |       1 |      0 |       |       |          |
|* 26 |          INDEX UNIQUE SCAN                   | EMP_EMP_ID_PK      |      0 |      1 |      0 |00:00:00.01 |       0 |      0 |       |       |          |
|  27 |         TABLE ACCESS BY INDEX ROWID          | EMPLOYEES          |      0 |      1 |      0 |00:00:00.01 |       0 |      0 |       |       |          |
-----------------------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - access("VW_COL_1"="L"."LOCATION_ID")
   3 - access(ROWID=ROWID)
  10 - access("ITEM_1"="D"."DEPARTMENT_ID")
       filter("ITEM_1"="D"."DEPARTMENT_ID")
  15 - filter("J"."JOB_TITLE"='President')
  16 - access("J"."JOB_ID"="E"."JOB_ID")
  19 - access("E"."LAST_NAME"='King' AND "E"."FIRST_NAME"='Steven')
  23 - filter("J2"."JOB_TITLE"='President')
  25 - access("J2"."JOB_ID"="H"."JOB_ID")
  26 - access("H"."EMPLOYEE_ID"="E"."EMPLOYEE_ID")

Note
-----
   - this is an adaptive plan

Query Summary Table v12.1

Query Buffers Table Instances XPlan Steps Query Lines
Literal 31 10 27 31
NoCOUG Example 156 6 19 23
Subquery Factor Union 29 6 28 25
Outer Joins 45 6 22 17

Here is the v12.1 output:

NCOUG-3-121






Low-Hanging Fruit: The Classic Performance Tuning Anti-pattern

The July/August 2014 edition of Oracle Magazine contains an interesting PL/SQL performance tuning article by Steve Feuerstein, The Joy of Low-Hanging Fruit.

Low-Hanging Fruit

Low-Hanging Cherries

The article is a case study in which SF finds a “cursor FOR loop that contained two nonquery DML statements” and which he calls a classic anti-pattern. As he says, “the inserts and updates are changing the tables on a row-by-row basis, which maximizes the number of context switches”. He also identifies an inefficiency in the code that is more problem-specific: An update process occurs within the loop that only needs to be performed at the end of the loop. (Although this is a generic kind of performance ‘bug’ I would resist the temptation to call it an anti-pattern, preferring to reserve the term for more deliberate strategies). The article goes on to replace the row-by-row DML using bulk processing, and to move the in-loop update outside the loop. SF claims a two to three-fold performance improvement in testing.

The performance improvement sounds good, but at the same time it occurs to me that the article itself could be seen as an illustration of the classic performance-tuning anti-pattern. This is when the tuner looks for things to optimise before he or she knows what is actually taking up the bulk of the time (and the article’s title summarises it nicely – so I will use it to name the anti-pattern 🙂 ). The main thrust of the article, as indicated in the subtitle, is the performance benefits of BULK COLLECT, but there is actually no indication that this is where the performance gains were made – it’s possible, likely even, that all significant gains came from the other, more problem-specific, improvement.

The first paragraph of the final section of the article reads:

“It might be lots of fun to completely reorganize one’s program in hopes of improving performance, but we can’t just assume that the resulting code actually does run quickly.”

This is exactly right, and is why the first step in any performance tuning process should be to identify the hot-spots. Tuning should then focus on those, ignoring areas where theoretical improvements will make no practical difference. If one might be permitted a second sylvan metaphor, it’s important to perceive wood as well as trees.

William Blake illustration of Dante's Divine Comedy

The Wood of the Self-Murderers, by William Blake

There are many ways to identify the hot-spots, and I would recommend Oracle’s PL/SQL profiling features, which I wrote about here, Notes on Profiling Oracle PL/SQL.

Notes on the Metaphors

Low-Hanging Fruit

For such a ubiquitous expression, this seems to be of surprisingly recent origin, according to: What Is the World’s Actual Lowest Hanging Fruit?.

The metaphorical usage doesn’t appear to have a very long history, though. According to Liberman, the Oxford English Dictionary’s first partial reference is from a 1968 Guardian article: “His rare images are picked aptly, easily, like low-hanging fruit.”

Not Seeing the Wood for the Trees

This expression is apparently much older, being traced back to (at least) 1546 here, Can’t see the Economist for the Trees, where it is attributed to “The Proverbs of John Heywood” and the lines:

Plentie is no deyntie. ye see not your owne ease.
I see, ye can not see the wood for trees.

The article is ostensibly about an incorrect usage of the expression by The Economist, but is really more interesting than that, and includes equivalents in other languages. For example, Americans say:

Can’t see the forest for the trees

while the French say:

L’arbre qui cache la forêt

.
The Wood of the Self-Murderers

This intriguing painting hangs at the Tate Gallery in London, and you can read more about it here, The Wood of the Self-Murderers: The Harpies and the Suicides

The work was completed between 1824 and 1827 and illustrates a passage from the Inferno canticle of the Divine Comedy by Dante Alighieri (1265–1321)

The passage concerned is:

Here the repellent harpies make their nests,
Who drove the Trojans from the Strophades
With dire announcements of the coming woe.
They have broad wings, a human neck and face,
Clawed feet and swollen, feathered bellies; they caw
Their lamentations in the eerie trees






Brendan’s 2-Page Oracle Programming Standards

I recently had some discussions on PL/SQL coding standards centred around some documents I’d come across on the internet, as well as some internal company standards documents.

Steve Feuerstein has a useful page PL/SQL Standards linking to his own document and to two others:

Steven’s Naming Conventions and Coding Standards, by Steve Feuerstein (12 page pdf).
PLSQL Standards Developed for the PLSQL Starter Framework-1.pdf, by Bill Coulam (34 page pdf).
Trivadis PL/SQL & SQL Coding Guidelines, by Roger Troller (50 page pdf).

Another interesting document is Naming and Coding Standards for SQL and PL/SQL by William Robertson (html), which emphasizes common sense in application of standards.

These are all valuable documents, but it was thought that many developers would not read and remain familiar with long documents of this kind, and a 2-page summary standards might be useful. Here is my attempt, as a Word document on Scribd:

Brendan’s 2-Page Oracle Programming Standards by Brendan Furey







SQL and Modularity: Patterns, Anti-Patterns and the Kitchen Sink

There’s a lot of importance placed on code re-use in the database development world. In traditional procedural programming languages, such as C or Fortran, the value of modular programming and its application to promoting code re-use is well known and understood. When SQL enters the picture, however, the situation becomes less clear, and there is less consensus on how best to apply the traditional concept of modularity.

This article will consider the concept of modularity, and how it may best be applied to SQL, from the perspective of ‘patterns’ and ‘anti-patterns’. Here is a definition of these terms from Wikipedia, Anti-pattern:

An anti-pattern (or antipattern) is a pattern used in social or business operations or software engineering that may be commonly used but is ineffective and/or counterproductive in practice.[1][2]

The term was coined in 1995 by Andrew Koenig,[3] inspired by Gang of Four’s book Design Patterns, which developed the concept of design patterns in the software field. The term was widely popularized three years later by the book AntiPatterns, which extended the use of the term beyond the field of software design and into general social interaction. According to the authors of the latter, there must be at least two key elements present to formally distinguish an actual anti-pattern from a simple bad habit, bad practice, or bad idea:

  • Some repeated pattern of action, process or structure that initially appears to be beneficial, but ultimately produces more bad consequences than beneficial results, and
  • An alternative solution exists that is clearly documented, proven in actual practice and repeatable

 

Procedural Modularity

Modularity starts from the idea that a complex design can generally be broken down into a set of less complex component modules that is easier to work with. In programming terms, a long main program would be broken down into smaller subroutines, with a much shorter main program that calls the subroutines.

From this starting point emerges the possibility of code re-use, whereby the decomposition into modules aims at identifying common logic that can be placed in generic modules and called in multiple places. A simple example of this would be an error-logging module in PL/SQL that would write any Oracle errors to a table along with call stack information, that could be called wherever such errors need to be trapped. This might be termed an error-logging pattern, and it’s clear that this kind of code re-use can lead to simpler and more maintainable systems.

SQL Modularity: Design Patterns

Transactional APIs

The concept of transactions is important for modular design within a database application.

The Oracle manual, Oracle Database Concepts, defines a transaction thus:
A transaction is a logical unit of work that contains one or more SQL statements. A transaction is an atomic unit. The effects of all the SQL statements in a transaction can be either all committed (applied to the database) or all rolled back (undone from the database).

When a transaction needs to be performed in more than one place, then the code can be placed in a PL/SQL module, sometimes called a ‘transactional API’. This is really just the database-specific version of standard modularity, and is obviously a good design pattern to follow.

Data Access Layers

Transactional APIs are often used to form a Data Access Layer (DAL) for front end applications written in languages such as Java. Where the front end requires a record set from the database, the APIs may return a reference cursor, which is essentially a pointer to the data, and avoids the overhead of passing the whole data set at once. The data access layer pattern has a number of important advantages:

  • performance is enhanced through reduced network traffic between application server and database
  • SQL operates in an efficient set-based fashion for retrieving data in batches
  • the PL/SQL language, highly integrated with SQL, is specifically designed for database processing
  • storing the database processing code in database packages promotes modularity and code re-use

It is considered best practice to use data access layers even for clients, such as Oracle Forms, that have an embedded PL/SQL engine.

Of course, in order to achieve these benefits the data access layer has to be correctly written, avoiding the anti-pattern pitfalls discussed later. In particular, ‘kitchen sink’ style APIs that return far more data than required, to promote re-use, must be avoided; different client programs requiring different data should have separate APIs.

Views

Database views have been available in Oracle SQL from the earliest versions and can be used to avoid duplicating a complex SQL query that might be needed in multiple places.

This approach could be seens as a special case of transactional modularity, where a single query is the transaction, and might be regarded as a design pattern for re-use of SQL statements.

Views may form an alternative kind of data access layer, typically used by reporting tools such as Business Objects, and may also be used in conjumction with an API-based layer, which is a common approach in Oracle Forms applications.

Within-SQL Modularity

SQL is essentially a declarative, rather than procedural language for retrieving (and updating etc.) data from relational databases. The original idea was that the programmer specifies the tables and columns where the data are stored, as well as how the tables are related through key values, but does not specify algorithms for retrieving the data: The retrieval algorithms are performed by the SQL engine ‘under the covers’. There might therefore seem to be little scope for modularity within a SQL select statement. However, this is not quite true for a couple of reasons: First, logical paths have to be specified between the tables, and the same path may need to be specified multiple times from different starting points; for example, the path to billing and shipping addresses on a sales order would typically involve the same sequence of steps from different id columns; second, as SQL has evolved, procedural capabilities have been added, such as analytic functions and recursion.

In Oracle in-line views were introduced in v7.2, and are in a sense a first step in modularising an SQL statement, followed in v9.2 by the ‘WITH’ clause for subquery factoring. Analytic functions were introduced in v8i.

Here is an example based on Oracle’s HR demo schema. Suppose we want a list of employees with their current and previous jobs (if any), the same for their manager, and a count of the number of subordinates they have. To get the previous jobs, we need to find the latest records in the job_history table for the employee and his manager separately. This can be done using subqueries, but that is inefficient and it is normally better to join to aggregation views that use the DENSE_RANK clause to allow the required previous records to be obtained in a single pass each. Similarly, the subordinate count could be done by a scalar subquery, but again performance would usually dictate the use of another aggregation view.

Here is a query using in-line views to achieve this:

SELECT emp.last_name || ', ' || emp.first_name name,
       job.job_title,
       job_p.job_title             job_title_prior,
       emp_m.last_name || ', ' || emp_m.first_name name_mgr,
       job_m.job_title             job_title_mgr,
       job_pm.job_title            job_title_mgr_prior,
       sub.n_sub
  FROM hr.employees                emp
  JOIN hr.jobs                     job
    ON job.job_id                  = emp.job_id
  LEFT JOIN (SELECT employee_id,
                    Max (job_id) KEEP (DENSE_RANK LAST ORDER BY end_date) job_id
               FROM hr.job_history
              GROUP BY employee_id
            )                      jhs
    ON jhs.employee_id             = emp.employee_id
  LEFT JOIN hr.jobs                job_p
    ON job_p.job_id                = jhs.job_id
  LEFT JOIN hr.employees           emp_m
    ON emp_m.employee_id           = emp.manager_id
  LEFT JOIN hr.jobs                job_m
    ON job_m.job_id                = emp_m.job_id
  LEFT JOIN (SELECT employee_id,
                    Max (job_id) KEEP (DENSE_RANK LAST ORDER BY end_date) job_id
               FROM hr.job_history
              GROUP BY employee_id
            )                      jhs_m
    ON jhs_m.employee_id           = emp.manager_id
  LEFT JOIN hr.jobs                job_pm
    ON job_pm.job_id               = jhs_m.job_id
  LEFT JOIN (SELECT manager_id,
                    Count(*)       n_sub
               FROM hr.employees
              GROUP BY manager_id
            )                      sub
    ON sub.manager_id              = emp.employee_id
 WHERE emp.department_id           = 30
 ORDER BY 1

Here is a query using subquery factors to achieve the same:

WITH jhs_f AS (
SELECT employee_id,
       Max (job_id) KEEP (DENSE_RANK LAST ORDER BY end_date) job_id
  FROM hr.job_history
 GROUP BY employee_id
), sub_f AS (
SELECT manager_id,
       Count(*)                    n_sub
  FROM hr.employees
 GROUP BY manager_id
)
SELECT emp.last_name || ', ' || emp.first_name name,
       job.job_title,
       job_p.job_title             job_title_prior,
       emp_m.last_name || ', ' || emp_m.first_name name_mgr,
       job_m.job_title             job_title_mgr,
       job_pm.job_title            job_title_mgr_prior,
       sub.n_sub
  FROM hr.employees                emp
  JOIN hr.jobs                     job
    ON job.job_id                  = emp.job_id
  LEFT JOIN jhs_f                  jhs
    ON jhs.employee_id             = emp.employee_id
  LEFT JOIN hr.jobs                job_p
    ON job_p.job_id                = jhs.job_id
  LEFT JOIN hr.employees           emp_m
    ON emp_m.employee_id           = emp.manager_id
  LEFT JOIN hr.jobs                job_m
    ON job_m.job_id                = emp_m.job_id
  LEFT JOIN jhs_f                  jhs_m
    ON jhs_m.employee_id           = emp.employee_id
  LEFT JOIN hr.jobs                job_pm
    ON job_pm.job_id               = jhs_m.job_id
  LEFT JOIN sub_f                  sub
    ON sub.manager_id              = emp.employee_id
 WHERE emp.department_id           = 30
 ORDER BY 1

The second query, although only a line shorter, could be said to be more modular in two ways:

  1. The more complex processing is placed at the beginning, prior to the main select, which now contains only simple joins. This might be said to parallel the procedural modularity practice of having a simple main program calling subroutines, and may help maintainability
  2. A single subquery factor replaces the two inline views for previous jobs, a more modular design, and one that may be more efficient for larger data sets since Oracle generally materialises subquery factors referenced multiple times

This approach might be regarded as a design pattern for modularity within individual SQL statements.

ANSI Join Syntax

The queries above are written using ANSI join syntax, introduced in v9. Oracle SQL originally used its own proprietary syntax, as shown below for the same query requirement:

WITH jhs_f AS (
SELECT employee_id,
       Max (job_id) KEEP (DENSE_RANK LAST ORDER BY end_date) job_id
  FROM hr.job_history
 GROUP BY employee_id
), sub_f AS (
SELECT manager_id,
       Count(*)                    n_sub
  FROM hr.employees
 GROUP BY manager_id
)
SELECT emp.last_name || ', ' || emp.first_name name,
       job.job_title,
       job_p.job_title             job_title_prior,
       emp_m.last_name || ', ' || emp_m.first_name name_mgr,
       job_m.job_title             job_title_mgr,
       job_pm.job_title            job_title_mgr_prior,
       sub.n_sub
  FROM hr.employees                emp,
       hr.jobs                     job,
       jhs_f                       jhs,
       hr.jobs                     job_p,
       hr.employees                emp_m,
       hr.jobs                     job_m,
       jhs_f                       jhs_m,
       hr.jobs                     job_pm,
       sub_f                       sub
 WHERE emp.department_id           = 30
   AND job.job_id                  = emp.job_id
   AND jhs.employee_id (+)         = emp.employee_id
   AND job_p.job_id (+)            = jhs.job_id
   AND emp_m.employee_id (+)       = emp.manager_id
   AND job_m.job_id (+)            = emp_m.job_id
   AND jhs_m.employee_id (+)       = emp.employee_id
   AND job_pm.job_id (+)           = jhs_m.job_id
   AND sub.manager_id (+)          = emp.employee_id
 ORDER BY 1

The tables are listed together, join clauses are in a single block not separated from constraints, and outer joins are specified using a (+) token against every column in the ‘left’ table. The outer join syntax leads to widespread bugs when developers miss the (+) from one of the columns, which silently converts the join to an inner join.

Some of the advantages of the newer syntax are:

  • Greater functionality is available, including full outer joining
  • Outer joining is much harder to get wrong
  • The syntax follows an ANSI standard
  • Locating the join conditions with the table being joined appears to be more modular and readable

ANSI join syntax might therefore be considered a good design pattern to follow.

SQL Modularity: Design Anti-patterns

everything-but-the-kitchen-sink-IDIOM

Here is a thread from Tom Kyte’s AskTom forum dealing with an SQL anti-pattern that is unfortunately common, and strongly opposed by Tom Kyte: Considering SQL as a Service. The idea behind the anti-pattern seems to be to avoid repeating even simple table joins in SQL by hiding them in a special type of data access layer designed to be called within individual SQL statements. This results in over-complex ‘kitchen-sink’ SQL within the layer itself and performance problems in the ‘client’ SQL. In addition, complex PL/SQL involving object types and arrays tends to be needed to glue it all together; the approach thus achieves the opposite of its intended purpose – simplification – in the manner of a classic anti-pattern.

We’ll illustrate the anti-pattern by extending the HR example used above and working through an example. First we’ll use the PL/SQL packaged procedure variant, then look at an older form based on views.

APIs as SQL Building Blocks Anti-pattern

Let’s suppose that we start from the idea that we should centralise the SQL for employee information in a re-useable API. We could take the SQL above and add in department name, address and manager information to make it more general. We might think initially of making the API a function taking an employee id as input and returning a record. But what if we needed the information for a list of employees? It would be inefficient to call a function for every record in the list, which might lead us to think of making the function take a list as input and return a list of records. We might therefore define object and array types, and a function with the following signature:

FUNCTION Emp_Info_List (p_emp_id_list SYS.ODCINumberList) RETURN emp_info_list_type;

[All code and output referenced is attached to this article.]

Now let’s consider a scenario in which we have to provide an API for a web front end following the design pattern of returning a reference cursor. The data required are the following details for all employees in a given department:

  • employee name
  • manager name
  • list of subordinates

The output for department 30 would be:

NAME                      NAME_MGR               NAME_SUB
------------------------- ---------------------- -------------------
Baida, Shelli             Raphaely, Den
Colmenares, Karen         Raphaely, Den
Himuro, Guy               Raphaely, Den
Khoo, Alexander           Raphaely, Den
Raphaely, Den             King, Steven           Baida, Shelli
Raphaely, Den             King, Steven           Colmenares, Karen
Raphaely, Den             King, Steven           Himuro, Guy
Raphaely, Den             King, Steven           Khoo, Alexander
Raphaely, Den             King, Steven           Tobias, Sigal
Tobias, Sigal             Raphaely, Den

10 rows selected.

Here is a possible procedure implementation:

PROCEDURE Get_Mgr_Subs_KS (p_dept_id PLS_INTEGER, x_mgr_sub_cur OUT SYS_REFCURSOR) IS
  l_emp_id_list SYS.ODCINumberList;
BEGIN

  SELECT employee_id
    BULK COLLECT INTO l_emp_id_list
    FROM hr.employees
   WHERE department_id = p_dept_id;

  OPEN x_mgr_sub_cur FOR
  SELECT t.name,
         t.name_mgr,
         e.last_name || ', ' || e.first_name
    FROM TABLE (KSink_Emp.Emp_Info_List (l_emp_id_list)) t
    LEFT JOIN hr.employees e
      ON e.manager_id = t.employee_id
   ORDER BY 1, 2, 3;

END Get_Mgr_Subs_KS;

The first step is to get the list of employees for the department, which we then pass into the API, wrapped in the TABLE key word, and join the employees table to get the subordinates. Three SQL select statements are executed. You might argue that I have over-complicated this by having the API take a list of employees rather than the department id, but remember that in this design anti-pattern the API can’t be designed for one specific caller, and the list input is more general. It is intended to cater for all calls for employee information so in practice such compromises will happen frequently.

We can compare this to an alternative implementation in which we simply join the tables required:

PROCEDURE Get_Mgr_Subs_SQL (p_dept_id PLS_INTEGER, x_mgr_sub_cur OUT SYS_REFCURSOR) IS
BEGIN

  OPEN x_mgr_sub_cur FOR
  SELECT e.last_name || ', ' || e.first_name,
         m.last_name || ', ' || m.first_name,
         s.last_name || ', ' || s.first_name
    FROM hr.employees e
    LEFT JOIN hr.employees m
      ON m.employee_id = e.manager_id
    LEFT JOIN hr.employees s
      ON s.manager_id = e.employee_id
   WHERE e.department_id = p_dept_id
   ORDER BY 1, 2, 3;

END Get_Mgr_Subs_SQL;

This joins three tables in one statement while the earlier procedure effectively makes a join through PL/SQL using an array, which is arguably slightly more complicated. In any case the real problems become apparent when you compare the execution plans. I have written a test driver program that calls each of the APIs and loops over the returned cursor.

Taking the plan for the straight SQL implementation first:

-------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                              | Name              | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                       |                   |      1 |        |     10 |00:00:00.01 |      14 |       |       |          |
|   1 |  SORT ORDER BY                         |                   |      1 |     35 |     10 |00:00:00.01 |      14 |  2048 |  2048 | 2048  (0)|
|   2 |   NESTED LOOPS OUTER                   |                   |      1 |     35 |     10 |00:00:00.01 |      14 |       |       |          |
|*  3 |    HASH JOIN OUTER                     |                   |      1 |      6 |      6 |00:00:00.01 |      10 |  1281K|  1281K|  544K (0)|
|   4 |     TABLE ACCESS BY INDEX ROWID BATCHED| EMPLOYEES         |      1 |      6 |      6 |00:00:00.01 |       2 |       |       |          |
|*  5 |      INDEX RANGE SCAN                  | EMP_DEPARTMENT_IX |      1 |      6 |      6 |00:00:00.01 |       1 |       |       |          |
|   6 |     VIEW                               | index$_join$_002  |      1 |    107 |    107 |00:00:00.01 |       8 |       |       |          |
|*  7 |      HASH JOIN                         |                   |      1 |        |    107 |00:00:00.01 |       8 |  1245K|  1245K| 1439K (0)|
|   8 |       INDEX FAST FULL SCAN             | EMP_NAME_IX       |      1 |    107 |    107 |00:00:00.01 |       4 |       |       |          |
|   9 |       INDEX FAST FULL SCAN             | EMP_EMP_ID_PK     |      1 |    107 |    107 |00:00:00.01 |       4 |       |       |          |
|  10 |    TABLE ACCESS BY INDEX ROWID BATCHED | EMPLOYEES         |      6 |      6 |      5 |00:00:00.01 |       4 |       |       |          |
|* 11 |     INDEX RANGE SCAN                   | EMP_MANAGER_IX    |      6 |      6 |      5 |00:00:00.01 |       3 |       |       |          |
-------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - access("M"."EMPLOYEE_ID"="E"."MANAGER_ID")
   5 - access("E"."DEPARTMENT_ID"=:B1)
   7 - access(ROWID=ROWID)
  11 - access("S"."MANAGER_ID"="E"."EMPLOYEE_ID")

This is a relatively simple plan for the single SQL statement, with 14 buffers read.

For the anti-pattern version there are thee SQL select statements, but we’ll ignore the plan for initial bulk collect SQL and consider the other two execution plans. First, the client API SQL:

---------------------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                           | Name             | Starts | E-Rows | A-Rows |   A-Time   | Buffers | Reads  | Writes |  OMem |  1Mem | Used-Mem |
---------------------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                    |                  |      1 |        |     10 |00:00:00.14 |    1195 |     41 |      1 |       |       |          |
|   1 |  SORT ORDER BY                      |                  |      1 |  48554 |     10 |00:00:00.14 |    1195 |     41 |      1 |  2048 |  2048 | 2048  (0)|
|*  2 |   HASH JOIN RIGHT OUTER             |                  |      1 |  48554 |     10 |00:00:00.14 |    1195 |     41 |      1 |  1368K|  1368K| 1322K (0)|
|   3 |    VIEW                             | index$_join$_002 |      1 |    107 |    106 |00:00:00.02 |       8 |     12 |      0 |       |       |          |
|*  4 |     HASH JOIN                       |                  |      1 |        |    106 |00:00:00.02 |       8 |     12 |      0 |  1519K|  1519K| 1575K (0)|
|   5 |      INDEX FAST FULL SCAN           | EMP_MANAGER_IX   |      1 |    107 |    106 |00:00:00.01 |       4 |      6 |      0 |       |       |          |
|   6 |      INDEX FAST FULL SCAN           | EMP_NAME_IX      |      1 |    107 |    107 |00:00:00.01 |       4 |      6 |      0 |       |       |          |
|   7 |    COLLECTION ITERATOR PICKLER FETCH| EMP_INFO_LIST    |      1 |   8168 |      6 |00:00:00.13 |    1187 |     29 |      1 |       |       |          |
---------------------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("E"."MANAGER_ID"=SYS_OP_ATG(VALUE(KOKBF$),1,2,2))
   4 - access(ROWID=ROWID)

Note the extreme inaccuracy of the cardinality estimates at steps 1 and 2, which originate in the step 7 estimate of 8168, which is a database-level default for an array function call. This is exposing the general problem that joining to arrays prevents accurate cardinality estimates. A total of 1195 buffers were read.

Next, the plan for the inner API SQL:

------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                       | Name                      | Starts | E-Rows | A-Rows |   A-Time   | Buffers | Reads  | Writes |  OMem |  1Mem | Used-Mem |
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                                |                           |      1 |        |      6 |00:00:00.01 |      94 |      1 |      1 |       |       |          |
|   1 |  TEMP TABLE TRANSFORMATION                      |                           |      1 |        |      6 |00:00:00.01 |      94 |      1 |      1 |       |       |          |
|   2 |   LOAD AS SELECT                                |                           |      1 |        |      0 |00:00:00.01 |       6 |      0 |      1 |  1036K|  1036K|          |
|   3 |    SORT GROUP BY NOSORT                         |                           |      1 |      7 |      7 |00:00:00.01 |       2 |      0 |      0 |       |       |          |
|   4 |     TABLE ACCESS BY INDEX ROWID                 | JOB_HISTORY               |      1 |     10 |     10 |00:00:00.01 |       2 |      0 |      0 |       |       |          |
|   5 |      INDEX FULL SCAN                            | JHIST_EMP_ID_ST_DATE_PK   |      1 |     10 |     10 |00:00:00.01 |       1 |      0 |      0 |       |       |          |
|*  6 |   HASH JOIN OUTER                               |                           |      1 |      6 |      6 |00:00:00.01 |      85 |      1 |      0 |   735K|   735K|  506K (0)|
|*  7 |    HASH JOIN OUTER                              |                           |      1 |      6 |      6 |00:00:00.01 |      78 |      1 |      0 |   736K|   736K|  891K (0)|
|*  8 |     HASH JOIN OUTER                             |                           |      1 |      6 |      6 |00:00:00.01 |      75 |      1 |      0 |   737K|   737K|  550K (0)|
|*  9 |      HASH JOIN OUTER                            |                           |      1 |      6 |      6 |00:00:00.01 |      68 |      1 |      0 |   739K|   739K|  883K (0)|
|* 10 |       HASH JOIN OUTER                           |                           |      1 |      6 |      6 |00:00:00.01 |      62 |      0 |      0 |   740K|   740K|  903K (0)|
|* 11 |        HASH JOIN OUTER                          |                           |      1 |      6 |      6 |00:00:00.01 |      55 |      0 |      0 |   746K|   746K|  541K (0)|
|* 12 |         HASH JOIN OUTER                         |                           |      1 |      6 |      6 |00:00:00.01 |      48 |      0 |      0 |   754K|   754K|  534K (0)|
|* 13 |          HASH JOIN OUTER                        |                           |      1 |      6 |      6 |00:00:00.01 |      41 |      0 |      0 |   766K|   766K|  418K (0)|
|* 14 |           HASH JOIN OUTER                       |                           |      1 |      6 |      6 |00:00:00.01 |      33 |      0 |      0 |   773K|   773K|  414K (0)|
|  15 |            NESTED LOOPS OUTER                   |                           |      1 |      6 |      6 |00:00:00.01 |      26 |      0 |      0 |       |       |          |
|* 16 |             HASH JOIN OUTER                     |                           |      1 |      6 |      6 |00:00:00.01 |      23 |      0 |      0 |   833K|   833K|  414K (0)|
|* 17 |              HASH JOIN OUTER                    |                           |      1 |      6 |      6 |00:00:00.01 |      16 |      0 |      0 |   876K|   876K|  415K (0)|
|* 18 |               HASH JOIN                         |                           |      1 |      6 |      6 |00:00:00.01 |       9 |      0 |      0 |   905K|   905K| 1259K (0)|
|  19 |                MERGE JOIN                       |                           |      1 |    107 |    107 |00:00:00.01 |       9 |      0 |      0 |       |       |          |
|  20 |                 TABLE ACCESS BY INDEX ROWID     | JOBS                      |      1 |     19 |     19 |00:00:00.01 |       2 |      0 |      0 |       |       |          |
|  21 |                  INDEX FULL SCAN                | JOB_ID_PK                 |      1 |     19 |     19 |00:00:00.01 |       1 |      0 |      0 |       |       |          |
|* 22 |                 SORT JOIN                       |                           |     19 |    107 |    107 |00:00:00.01 |       7 |      0 |      0 | 18432 | 18432 |16384  (0)|
|  23 |                  TABLE ACCESS FULL              | EMPLOYEES                 |      1 |    107 |    107 |00:00:00.01 |       7 |      0 |      0 |       |       |          |
|  24 |                COLLECTION ITERATOR PICKLER FETCH|                           |      1 |      6 |      6 |00:00:00.01 |       0 |      0 |      0 |       |       |          |
|  25 |               TABLE ACCESS FULL                 | DEPARTMENTS               |      1 |     27 |     27 |00:00:00.01 |       7 |      0 |      0 |       |       |          |
|  26 |              TABLE ACCESS FULL                  | LOCATIONS                 |      1 |     23 |     23 |00:00:00.01 |       7 |      0 |      0 |       |       |          |
|* 27 |             INDEX UNIQUE SCAN                   | COUNTRY_C_ID_PK           |      6 |      1 |      6 |00:00:00.01 |       3 |      0 |      0 |       |       |          |
|  28 |            TABLE ACCESS FULL                    | REGIONS                   |      1 |      4 |      4 |00:00:00.01 |       7 |      0 |      0 |       |       |          |
|  29 |           VIEW                                  | index$_join$_024          |      1 |    107 |    107 |00:00:00.01 |       8 |      0 |      0 |       |       |          |
|* 30 |            HASH JOIN                            |                           |      1 |        |    107 |00:00:00.01 |       8 |      0 |      0 |  1245K|  1245K| 1550K (0)|
|  31 |             INDEX FAST FULL SCAN                | EMP_NAME_IX               |      1 |    107 |    107 |00:00:00.01 |       4 |      0 |      0 |       |       |          |
|  32 |             INDEX FAST FULL SCAN                | EMP_EMP_ID_PK             |      1 |    107 |    107 |00:00:00.01 |       4 |      0 |      0 |       |       |          |
|  33 |          TABLE ACCESS FULL                      | EMPLOYEES                 |      1 |    107 |    107 |00:00:00.01 |       7 |      0 |      0 |       |       |          |
|  34 |         TABLE ACCESS FULL                       | JOBS                      |      1 |     19 |     19 |00:00:00.01 |       7 |      0 |      0 |       |       |          |
|  35 |        VIEW                                     |                           |      1 |     18 |     19 |00:00:00.01 |       7 |      0 |      0 |       |       |          |
|  36 |         HASH GROUP BY                           |                           |      1 |     18 |     19 |00:00:00.01 |       7 |      0 |      0 |  1558K|  1558K| 1185K (0)|
|  37 |          TABLE ACCESS FULL                      | EMPLOYEES                 |      1 |    107 |    107 |00:00:00.01 |       7 |      0 |      0 |       |       |          |
|  38 |       VIEW                                      |                           |      1 |      7 |      7 |00:00:00.01 |       6 |      1 |      0 |       |       |          |
|  39 |        TABLE ACCESS FULL                        | SYS_TEMP_0FD9D6604_5813E5 |      1 |      7 |      7 |00:00:00.01 |       6 |      1 |      0 |       |       |          |
|  40 |      TABLE ACCESS FULL                          | JOBS                      |      1 |     19 |     19 |00:00:00.01 |       7 |      0 |      0 |       |       |          |
|  41 |     VIEW                                        |                           |      1 |      7 |      7 |00:00:00.01 |       3 |      0 |      0 |       |       |          |
|  42 |      TABLE ACCESS FULL                          | SYS_TEMP_0FD9D6604_5813E5 |      1 |      7 |      7 |00:00:00.01 |       3 |      0 |      0 |       |       |          |
|  43 |    TABLE ACCESS FULL                            | JOBS                      |      1 |     19 |     19 |00:00:00.01 |       7 |      0 |      0 |       |       |          |
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   6 - access("JOB_P"."JOB_ID"="JHS"."JOB_ID")
   7 - access("JHS"."EMPLOYEE_ID"="EMP"."EMPLOYEE_ID")
   8 - access("JOB_MP"."JOB_ID"="JHS_M"."JOB_ID")
   9 - access("JHS_M"."EMPLOYEE_ID"="EMP"."EMPLOYEE_ID")
  10 - access("SUB"."MANAGER_ID"="EMP"."EMPLOYEE_ID")
  11 - access("JOB_M"."JOB_ID"="EMP_M"."JOB_ID")
  12 - access("EMP_M"."EMPLOYEE_ID"="EMP"."MANAGER_ID")
  13 - access("EMP_DM"."EMPLOYEE_ID"="DEP"."MANAGER_ID")
  14 - access("REG"."REGION_ID"="COU"."REGION_ID")
  16 - access("LOC"."LOCATION_ID"="DEP"."LOCATION_ID")
  17 - access("DEP"."DEPARTMENT_ID"="EMP"."DEPARTMENT_ID")
  18 - access("EMP"."EMPLOYEE_ID"=VALUE(KOKBF$))
  22 - access("JOB"."JOB_ID"="EMP"."JOB_ID")
       filter("JOB"."JOB_ID"="EMP"."JOB_ID")
  27 - access("COU"."COUNTRY_ID"="LOC"."COUNTRY_ID")
  30 - access(ROWID=ROWID)

This is pretty complex. We can’t pretend to do a real performance analysis on such a small database (107 employees), but the potential for performance problems in real cases is clear. It’s important to understand that any performance analysis on the client API has to take into account not just the client code, but the full complexity of the centralised SQL, so any apparent simplification from using it is to a great extent illusory.

Database Inter-Schema Data Access Layer Anti-pattern

There is a variant of the anti-pattern above in which data access layers are used to retrieve data across schema boundaries. This variant suffers from exactly the same problems as the first of course, and should equally be avoided.

Views as SQL Building Blocks Anti-Pattern

The same ideas as are behind the APIs as SQL Building Blocks Anti-Pattern can also be implemented through views, and in fact this variant form of the anti-pattern has been around longer I think. We can illustrate it on the same example, by creating a view instead of the central API cursor.

CREATE OR REPLACE VIEW emp_ks_v (
       employee_id,
       name,
       job_title,
       job_title_p,
       name_mgr,
       job_title_mgr,
       job_title_mgr_p,
       n_sub,
       department_id,
       department_name,
       name_d_mgr,
       street_address,
       country_name,
       region_name) AS
WITH jhs_f AS (
SELECT employee_id,
     Max (job_id) KEEP (DENSE_RANK LAST ORDER BY end_date) job_id
  FROM hr.job_history
 GROUP BY employee_id
), sub AS (
SELECT manager_id,
       Count(*)                  n_sub
  FROM hr.employees
 GROUP BY manager_id
)
SELECT emp.employee_id,
       emp.last_name || ', ' || emp.first_name,
       job.job_title,
       job_p.job_title,
       emp_m.last_name || ', ' || emp_m.first_name,
       job_m.job_title,
       job_mp.job_title,
       sub.n_sub,
       dep.department_id,
       dep.department_name,
       emp_dm.last_name || ', ' || emp_dm.first_name,
       loc.street_address,
       cou.country_name,
       reg.region_name
  FROM hr.employees              emp
  JOIN hr.jobs                   job
    ON job.job_id                = emp.job_id
  LEFT JOIN jhs_f                jhs
    ON jhs.employee_id           = emp.employee_id
  LEFT JOIN hr.jobs              job_p
    ON job_p.job_id              = jhs.job_id
  LEFT JOIN hr.employees         emp_m
    ON emp_m.employee_id         = emp.manager_id
  LEFT JOIN hr.jobs              job_m
    ON job_m.job_id              = emp_m.job_id
  LEFT JOIN jhs_f                jhs_m
    ON jhs_m.employee_id         = emp.employee_id
  LEFT JOIN hr.jobs              job_mp
    ON job_mp.job_id             = jhs_m.job_id
  LEFT JOIN sub
    ON sub.manager_id            = emp.employee_id
  LEFT JOIN hr.departments       dep
    ON dep.department_id         = emp.department_id
  LEFT JOIN hr.employees         emp_dm
    ON emp_dm.employee_id        = dep.manager_id
  LEFT JOIN hr.locations         loc
    ON loc.location_id           = dep.location_id
  LEFT JOIN hr.countries         cou
    ON cou.country_id            = loc.country_id
  LEFT JOIN hr.regions           reg
    ON reg.region_id             = cou.region_id

The view can then be called to get the employee details for example for a given department, thus:

SELECT t.name,
       t.name_mgr,
       CASE WHEN e.last_name IS NOT NULL THEN e.last_name || ', ' || e.first_name END name_sub
  FROM emp_ks_v t
  LEFT JOIN hr.employees e
    ON e.manager_id = t.employee_id
 WHERE t.department_id = 30
 ORDER BY 1, 2, 3

This is actually quite a lot better than the API-based approach as it’s much simpler, avoiding the need for object arrays, and allowing use simply by joining. Let’s look at the execution plan though (we’ll just run the query rather than put it into a client API returning a reference cursor):

---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                    | Name                      | Starts | E-Rows | A-Rows |   A-Time   | Buffers | Reads  | Writes |  OMem |  1Mem | Used-Mem |
---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                             |                           |      1 |        |     10 |00:00:00.01 |      42 |      1 |      1 |       |       |          |
|   1 |  SORT ORDER BY                               |                           |      1 |     35 |     10 |00:00:00.01 |      42 |      1 |      1 |  2048 |  2048 | 2048  (0)|
|   2 |   NESTED LOOPS OUTER                         |                           |      1 |     35 |     10 |00:00:00.01 |      42 |      1 |      1 |       |       |          |
|   3 |    VIEW                                      | EMP_KS_V                  |      1 |      6 |      6 |00:00:00.01 |      38 |      1 |      1 |       |       |          |
|   4 |     TEMP TABLE TRANSFORMATION                |                           |      1 |        |      6 |00:00:00.01 |      38 |      1 |      1 |       |       |          |
|   5 |      LOAD AS SELECT                          |                           |      1 |        |      0 |00:00:00.01 |       6 |      0 |      1 |  1036K|  1036K|          |
|   6 |       SORT GROUP BY NOSORT                   |                           |      1 |      7 |      7 |00:00:00.01 |       2 |      0 |      0 |       |       |          |
|   7 |        TABLE ACCESS BY INDEX ROWID           | JOB_HISTORY               |      1 |     10 |     10 |00:00:00.01 |       2 |      0 |      0 |       |       |          |
|   8 |         INDEX FULL SCAN                      | JHIST_EMP_ID_ST_DATE_PK   |      1 |     10 |     10 |00:00:00.01 |       1 |      0 |      0 |       |       |          |
|*  9 |      HASH JOIN OUTER                         |                           |      1 |      6 |      6 |00:00:00.01 |      29 |      1 |      0 |   883K|   883K|  517K (0)|
|* 10 |       HASH JOIN OUTER                        |                           |      1 |      6 |      6 |00:00:00.01 |      21 |      1 |      0 |   890K|   890K|  857K (0)|
|* 11 |        HASH JOIN OUTER                       |                           |      1 |      6 |      6 |00:00:00.01 |      14 |      1 |      0 |   895K|   895K|  886K (0)|
|* 12 |         HASH JOIN OUTER                      |                           |      1 |      6 |      6 |00:00:00.01 |      11 |      1 |      0 |   905K|   905K|  893K (0)|
|  13 |          NESTED LOOPS                        |                           |      1 |      6 |      6 |00:00:00.01 |       5 |      0 |      0 |       |       |          |
|  14 |           NESTED LOOPS OUTER                 |                           |      1 |      1 |      1 |00:00:00.01 |       3 |      0 |      0 |       |       |          |
|  15 |            TABLE ACCESS BY INDEX ROWID       | DEPARTMENTS               |      1 |      1 |      1 |00:00:00.01 |       2 |      0 |      0 |       |       |          |
|* 16 |             INDEX UNIQUE SCAN                | DEPT_ID_PK                |      1 |      1 |      1 |00:00:00.01 |       1 |      0 |      0 |       |       |          |
|* 17 |            INDEX UNIQUE SCAN                 | LOC_ID_PK                 |      1 |      1 |      1 |00:00:00.01 |       1 |      0 |      0 |       |       |          |
|  18 |           TABLE ACCESS BY INDEX ROWID BATCHED| EMPLOYEES                 |      1 |      6 |      6 |00:00:00.01 |       2 |      0 |      0 |       |       |          |
|* 19 |            INDEX RANGE SCAN                  | EMP_DEPARTMENT_IX         |      1 |      6 |      6 |00:00:00.01 |       1 |      0 |      0 |       |       |          |
|  20 |          VIEW                                |                           |      1 |      7 |      7 |00:00:00.01 |       6 |      1 |      0 |       |       |          |
|  21 |           TABLE ACCESS FULL                  | SYS_TEMP_0FD9D6606_5813E5 |      1 |      7 |      7 |00:00:00.01 |       6 |      1 |      0 |       |       |          |
|  22 |         VIEW                                 |                           |      1 |      7 |      7 |00:00:00.01 |       3 |      0 |      0 |       |       |          |
|  23 |          TABLE ACCESS FULL                   | SYS_TEMP_0FD9D6606_5813E5 |      1 |      7 |      7 |00:00:00.01 |       3 |      0 |      0 |       |       |          |
|  24 |        VIEW                                  |                           |      1 |     18 |     19 |00:00:00.01 |       7 |      0 |      0 |       |       |          |
|  25 |         HASH GROUP BY                        |                           |      1 |     18 |     19 |00:00:00.01 |       7 |      0 |      0 |  1558K|  1558K| 1211K (0)|
|  26 |          TABLE ACCESS FULL                   | EMPLOYEES                 |      1 |    107 |    107 |00:00:00.01 |       7 |      0 |      0 |       |       |          |
|  27 |       VIEW                                   | index$_join$_013          |      1 |    107 |    107 |00:00:00.01 |       8 |      0 |      0 |       |       |          |
|* 28 |        HASH JOIN                             |                           |      1 |        |    107 |00:00:00.01 |       8 |      0 |      0 |  1245K|  1245K| 1410K (0)|
|  29 |         INDEX FAST FULL SCAN                 | EMP_NAME_IX               |      1 |    107 |    107 |00:00:00.01 |       4 |      0 |      0 |       |       |          |
|  30 |         INDEX FAST FULL SCAN                 | EMP_EMP_ID_PK             |      1 |    107 |    107 |00:00:00.01 |       4 |      0 |      0 |       |       |          |
|  31 |    TABLE ACCESS BY INDEX ROWID BATCHED       | EMPLOYEES                 |      6 |      6 |      5 |00:00:00.01 |       4 |      0 |      0 |       |       |          |
|* 32 |     INDEX RANGE SCAN                         | EMP_MANAGER_IX            |      6 |      6 |      5 |00:00:00.01 |       3 |      0 |      0 |       |       |          |
---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   9 - access("EMP_M"."EMPLOYEE_ID"="EMP"."MANAGER_ID")
  10 - access("SUB"."MANAGER_ID"="EMP"."EMPLOYEE_ID")
  11 - access("JHS_M"."EMPLOYEE_ID"="EMP"."EMPLOYEE_ID")
  12 - access("JHS"."EMPLOYEE_ID"="EMP"."EMPLOYEE_ID")
  16 - access("DEP"."DEPARTMENT_ID"=30)
  17 - access("LOC"."LOCATION_ID"="DEP"."LOCATION_ID")
  19 - access("EMP"."DEPARTMENT_ID"=30)
  28 - access(ROWID=ROWID)
  32 - access("E"."MANAGER_ID"="T"."EMPLOYEE_ID")

There is only one SQL statement, and the plan is better too, with better cardinality estimates owing to the absence of array processing, and with 42 buffers read. It’s still a bad idea though because the client caller would be executing far more complex SQL than is required and as before performance analysis on the client requires the full complexity of the ‘centralised’ SQL to be included. Using complex views as SQL building blocks is generally considered to have poor performance characteristics.

SQL Modularity: Other Design Options

Splitting Up Long SQL Statements

Oracle’s Cost Based Optimiser (CBO) has been greatly enhanced since it’s introduction in v7, but remains imperfect. The combinatorial nature of the problem that it tries to solve suggests that there will always be larger queries where it makes a bad choice of plan. In some cases splitting a large query into smaller ones and using temporary tables to join them can give better performance. This may arise from new indexing options for the CBO, or by dynamic sampling capabilities on the temporary tables, or just from the CBO algorithms happening to work better on the divided queries.

It’s important to understand though that any such splitting should be done purely on performance grounds: the splitting increases the code complexity and breaking a sequence of declarative joins into several subsequences is not comparable with standard modularisation of programs into subprograms.

Long SQL statements are not necessarily problematic, but obviously should only be as long as necessary, and avoiding the design anti-patterns mentioned helps to ensure this.

Simple Views

Simple views, without joins, are often used in areas such as access control; for example Oracle Applications multi-org features (upto release 11) generally involve transactional tables being referenced by such simple views. These do not cause the performance problems seen with the complex building-block views anti-pattern.

Data Access Layers for Back-end Programs

It is quite possible to use a similar approach for database programs as for front-end programs in terms of a data access layer. One could adopt a standard that stand-alone database PL/SQL programs should access data through packaged APIs rather than directly. This obviously does not have the performance or language advantages of the design pattern in relation to Java front-ends for example, but it may in some circumstances be a preferred method of code organisation. It is therefore not an anti-pattern of the kind we have considered – as long as it is for stand-alone programs only.

Conclusions

The main aim of this article has been to distinguish between good approaches to modularity in SQL (patterns) and bad ones (anti-patterns) based on personal experience of seeing both types applied.

  • The Data Access Layer design pattern is an excellent approach for client applications developed in Java, .net etc. to access a database
  • Using Data Access Layers for internal access within a database is a classic anti-pattern leading to overcomplication and performance problems
  • A good design pattern used in an inappropriate context can become an anti-pattern

SQL Modularity Code