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






Leave a Reply

Your email address will not be published. Required fields are marked *

This site uses Akismet to reduce spam. Learn how your comment data is processed.