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

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

- from Little Gidding by T.S. Eliot

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

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

See also Dimensional Benchmarking of General SQL Bursting Problems.

'Bursting' Problem Definition

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

ACTIVITY Table

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

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

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

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

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

18 rows selected.

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

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

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

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

9 rows selected.

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

Model Query

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

Plan hash value: 2323700320

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

Recursive Subquery Factors Query 1 - Direct

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

Plan hash value: 941514960

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

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

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

Recursive Subquery Factors Query 2 - With Temporary Table

Temporary Table Definition

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

SQL - Insert to temporary table

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

Query using temporary table

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

Plan hash value: 4212061972

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

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

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

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

Match Recognize Query

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

Plan hash value: 3670115155

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

Performance

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

Records Input and Output

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

Model Query (elapsed seconds)

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

Recursive Subquery Factors Query 1 - Direct (elapsed seconds)

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

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

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

Match Recognize Query (elapsed seconds)

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

Conclusions

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

Original Scribd Document

Loading...

Full Output Log

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

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

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

Session altered.

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

PL/SQL procedure successfully completed.

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

Plan hash value: 2323700320

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


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

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

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

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

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

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

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

Plan hash value: 941514960

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

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

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


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

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

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

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

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

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

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

Plan hash value: 4212061972

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

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

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

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


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

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

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

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

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

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

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

Plan hash value: 3670115155

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


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

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

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

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

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

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

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

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

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

Plan hash value: 2323700320

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


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

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

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

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

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

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

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

Plan hash value: 941514960

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

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

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


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

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

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

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

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

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

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

Plan hash value: 4212061972

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

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

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

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


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

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

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

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

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

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

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

Plan hash value: 3670115155

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


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

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

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

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

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

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

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

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

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

Plan hash value: 2323700320

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


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

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

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

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

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

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

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

Plan hash value: 941514960

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

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

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


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

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

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

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

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

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

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

Plan hash value: 4212061972

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

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

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

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


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

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

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

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

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

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

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

Plan hash value: 3670115155

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


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

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

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

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

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

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

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

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

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

Plan hash value: 2323700320

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


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

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

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

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

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

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

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

Plan hash value: 941514960

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

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

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


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

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

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

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

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

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

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

Plan hash value: 4212061972

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

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

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

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


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

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

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

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

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

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

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

Plan hash value: 3670115155

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


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

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

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

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

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

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

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

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

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

Plan hash value: 2323700320

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


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

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

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

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

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

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

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

Plan hash value: 941514960

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

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

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


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

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

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

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

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

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

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

Plan hash value: 4212061972

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

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

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

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


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

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

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

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

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

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

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

Plan hash value: 3670115155

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


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

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

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

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

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

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

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

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

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

Plan hash value: 2323700320

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


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

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

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

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

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

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

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

Plan hash value: 941514960

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

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

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


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

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

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

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

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

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

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

Plan hash value: 4212061972

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

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

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

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


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

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

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

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

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

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

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

Plan hash value: 3670115155

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


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

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

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

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

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

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

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

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

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

Plan hash value: 2323700320

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


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

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

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

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

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

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

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

Plan hash value: 941514960

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

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

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


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

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

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

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

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

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

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

Plan hash value: 4212061972

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

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

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

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


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

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

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

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

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

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

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

Plan hash value: 3670115155

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


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

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

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

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

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

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

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

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

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

Plan hash value: 2323700320

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


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

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

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

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

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

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

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

Plan hash value: 941514960

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

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

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


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

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

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

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

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

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

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

Plan hash value: 4212061972

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

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

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

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


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

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

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

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

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

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

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

Plan hash value: 3670115155

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


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

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

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

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

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

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

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

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

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

Plan hash value: 2323700320

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


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

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

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

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

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

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

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

Plan hash value: 941514960

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

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

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


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

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

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

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

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

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

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

Plan hash value: 4212061972

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

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

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

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


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

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

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

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

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

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

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

Plan hash value: 3670115155

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


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

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

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

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

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

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

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

Plan hash value: 2323700320

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

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

Plan hash value: 3670115155

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

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

Plan hash value: 941514960

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

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

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

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

Plan hash value: 4212061972

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

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

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

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


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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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


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

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

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

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

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


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

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

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

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


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

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

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

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


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

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

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

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


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

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

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

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


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

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

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

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


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

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

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

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

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

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


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

Plan hash value: 2323700320

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

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

Plan hash value: 3670115155

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

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

Plan hash value: 941514960

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

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

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

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

Plan hash value: 4212061972

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

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

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

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


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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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


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

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

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

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

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


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

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

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

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


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

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

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

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


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

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

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

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


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

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

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

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


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

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

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

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


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

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

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

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

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

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

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

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

5041 rows selected.

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

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

Elapsed: 00:00:00.00
SQL> SPOOL OFF






A Framework for Dimensional Benchmarking of SQL Query Performance

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

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

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

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

Loading...

Bench Data Model - ERD

bench-1-0-erd

Code Structure Diagram

bench-1-1-csd

Test_Queries Package Call Structure Table

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

 
Outputs

out folder

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

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

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

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

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

Oracle directory: output_dir

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

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

For example:

BURST_MTH_QRY_30-30

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

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

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

Notes

Query Timing

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

Hard Parsing

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

Code Timing

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

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

Benchmarking Non-Query SQL

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

Query Transformation by Regular Expression Processing

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

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

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

Statistic Output Formatting

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

Execution Plan Aggregation

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

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

Estimated vs Actual Cardinalities

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

V$ Statistics

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

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

See Also...






Design Patterns for Database API Testing 4: REF Cursor Getter

Last October I gave a presentation on database unit testing with utPLSQL, Oracle Unit Testing with utPLSQL. I mentioned design patterns as a way of reducing the effort of building unit tests and outlined some strategies for coding them effectively.

In the current set of articles, I develop the ideas further, starting from the idea that all database APIs can be considered in terms of the axes:

  • direction (i.e. getter or setter, noting that setters can also 'get')
  • mode (i.e. real time or batch)

For each cell in the implied matrix, I construct an example API (or view) with specified requirements against Oracle's HR demo schema, and use this example to construct a testing program with appropriate scenarios as a design pattern. Concepts and common patterns and anti-patterns in automated API testing are discussed throughout, and these are largely independent of testing framework used. However, the examples use my own lightweight independent framework that is designed to help avoid many API testing anti-patterns. The code is available on GitHub here, BrenPatF/trapit_oracle_tester, and includes both framework and design pattern examples.

Behind the four examples, there is an underlying design pattern that involves wrapping the API call in a 'pure' procedure, called once per scenario, with the output 'actuals' array including everything affected by the API, whether as output parameters, or on database tables, etc. The inputs are also extended from the API parameters to include any other effective inputs. Assertion takes place after all scenarios and is against the extended outputs, with extended inputs also listed. This concept of the 'pure' function, central to Functional Programming, has important advantages in automated testing. I explained the concepts involved in a presentation at the Oracle User Group Ireland Conference in March 2018:

The Database API Viewed As A Mathematical Function: Insights into Testing

The previous example is here: Design Patterns for Database API Testing 3: Batch Loading of Flat Files. This fourth example covers getting data in real time via a REF cursor, such as would often be used as the source for a web service.

Requirement Summary

Modern Oracle SQL is very powerful and can apply complex logic within a single statement, reducing the need for more complex procedural code. In order to show how to API test SQL that might be used in a batch getter module, we previously devised a test view, HR_Test_V, having a range of features that we might want to test in general. We can use similar SQL to demonstrate API testing of a real time getter procedure that might be used by a web service, where reference cursors are often used as output parameters. The following list of features to test is taken, in slightly modified form, from Design Patterns for Database API Testing 2: Views 1 - Design

  • Inner joins suppress driving records where there is no joining record
  • Outer joins return driving records where there is no joining record
  • Analytic functions that partition by some key, and return aggregates on the returned record set
  • Functions based on aggregates over records that include those not in the returned record set
  • Constraints based on aggregates over records that include those not in the returned record set
  • Constraints on column values

The SQL functionality can be described in words as:

  • Selected values
    • Employee name, department name, and salary
    • Manager's name
    • Ratio of employee's salary to the department average (returned employees only)
    • Ratio of employee's salary to the average salary of all employees
  • Constraints
    • Exclude employees in job 'AD_ASST'
    • Return employees for a department passed as a bind parameter
    • Do not return any records if the total salary of all employees is below 1600
  • Outer join
    • Include employees both with and without a manager

The REF cursor SQL is:

  WITH all_emps AS (
        SELECT Avg (salary) avg_sal, SUM (salary) sal_tot_g
          FROM employees e
)
SELECT e.last_name, d.department_name, m.last_name manager, e.salary,
       Round (e.salary / Avg (e.salary) OVER (PARTITION BY e.department_id), 2) sal_rat,
       Round (e.salary / a.avg_sal, 2) sal_rat_g
  FROM all_emps a
 CROSS JOIN employees e
  JOIN departments d
    ON d.department_id = e.department_id
  LEFT JOIN employees m
    ON m.employee_id = e.manager_id
 WHERE e.job_id != 'AD_ASST'
   AND a.sal_tot_g >= 1600
   AND d.department_id = :1

Notes on API Testing REF Cursor Procedures

  • A new utility function has been added to Utils_TT, Cursor_to_Array, that converts an open reference cursor to a delimited list of strings (created from an initial stand-alone procedure: A Utility for Reading REF Cursors into a List of Delimited Strings)
  • Using this utility, very little code needs to be written once the test data has been set up: One call to return the reference cursor, and a second to return the actual values in a list, to be passed at the end in a single call to the library results checker

ERD

unit-testing-three-erd_rc

Design Pattern Groups

The API testing framework is centred around the concept of input and output groups, representing the data sets that respectively form the inputs to, and outputs from, the program. The records in each group are printed by the framework with column headers for each scenario. These groups are identified by the developer, and in this case they are as noted below.

Input Groups

  • Employees Table
  • Department Parameter

Output Groups

  • Select results
  • Timing of average call

Test Scenarios

The scenario descriptions start with a data set code, followed by a verbal description.

  1. DS-1, testing inner, outer joins, analytic over dep, and global ratios with 1 dep (10) - pass dep 10
  2. DS-2, testing same as 1 but with extra emp in another dep (20) - pass dep 10
  3. DS-2, as second scenario, but - pass dep 20
  4. DS-2, as second scenario, but - pass null dep
  5. DS-3, Salaries total 1500 (< threshold of 1600, so return nothing) - pass dep 10

Package Structure Diagram

Call Structure Table - TT_Emp_WS.tt_AIP_Get_Dept_Emps

TT_Emp_WS.tt_AIP_Get_Dept_Emps - Emp REF Cursor Test Procedure

Declare section

PROCEDURE tt_AIP_Get_Dept_Emps IS

  c_proc_name           CONSTANT VARCHAR2(61) := 'TT_Emp_WS.tt_AIP_Get_Dept_Emps';
  c_dep_id_1            CONSTANT PLS_INTEGER := 10;
  c_dep_id_2            CONSTANT PLS_INTEGER := 20;
  c_dep_nm_1            CONSTANT VARCHAR2(100) := 'Administration';
  c_dep_nm_2            CONSTANT VARCHAR2(100) := 'Marketing';
  c_job_bad             CONSTANT VARCHAR2(100) := 'AD_ASST';
  c_job_good            CONSTANT VARCHAR2(100) := 'IT_PROG';
  c_base_sal            CONSTANT PLS_INTEGER := 1000;
  c_out_group_lis       CONSTANT L1_chr_arr := L1_chr_arr ('Select results');

  c_ln_pre              CONSTANT VARCHAR2(10) := DML_API_TT_HR.c_ln_pre;

  c_dep_lis             CONSTANT L1_chr_arr := L1_chr_arr (c_dep_id_1, c_dep_id_1, c_dep_id_2, NULL, c_dep_id_1);

  c_dataset_3lis        CONSTANT L3_chr_arr := L3_chr_arr (
                             L2_chr_arr (L1_chr_arr ('4 emps, 1 dep (10), emp-3 has no dep, emp-4 has bad job'),
--                                         dep           job          salary
                               L1_chr_arr (c_dep_id_1,   c_job_good,  '1000'),
                               L1_chr_arr (c_dep_id_1,   c_job_good,  '2000'),
                               L1_chr_arr (NULL,         c_job_good,  '3000'),
                               L1_chr_arr (c_dep_id_1,   c_job_bad,   '4000')
                                             ),
                             L2_chr_arr (L1_chr_arr ('As dataset 1 but with extra emp-5, in second dep (20)'),
                               L1_chr_arr (c_dep_id_1,   c_job_good,  '1000'),
                               L1_chr_arr (c_dep_id_1,   c_job_good,  '2000'),
                               L1_chr_arr (NULL,         c_job_good,  '3000'),
                               L1_chr_arr (c_dep_id_1,   c_job_bad,   '4000'),
                               L1_chr_arr (c_dep_id_2,   c_job_good,  '5000')
                                             ),
                             L2_chr_arr (L1_chr_arr ('As dataset 2 but with salaries * 0.1, total below reporting threshold of 1600'),
                               L1_chr_arr (c_dep_id_1,   c_job_good,  '100'),
                               L1_chr_arr (c_dep_id_1,   c_job_good,  '200'),
                               L1_chr_arr (NULL,         c_job_good,  '300'),
                               L1_chr_arr (c_dep_id_1,   c_job_bad,   '400'),
                               L1_chr_arr (c_dep_id_2,   c_job_good,  '500')
                                             )
                        );

  c_exp_2lis            CONSTANT L2_chr_arr := L2_chr_arr (
                                               L1_chr_arr (
                                       Utils.List_Delim (c_ln_pre || '1',   c_dep_nm_1, NULL,            '1000', '.67',   '.4'),
                                       Utils.List_Delim (c_ln_pre || '2',   c_dep_nm_1, c_ln_pre || '1', '2000',  '1.33', '.8')
                                               ),
                                               L1_chr_arr (
                                       Utils.List_Delim (c_ln_pre || '1',   c_dep_nm_1, NULL,            '1000', '.67',  '.33'),
                                       Utils.List_Delim (c_ln_pre || '2',   c_dep_nm_1, c_ln_pre || '1', '2000',  '1.33', '.67')
                                               ),
                                               L1_chr_arr (
                                       Utils.List_Delim (c_ln_pre || '5',   c_dep_nm_2, c_ln_pre || '1', '5000',  '1',    '1.67')
                                               ),
                                               Utils_TT.c_empty_list,
                                               Utils_TT.c_empty_list
                        );

  c_scenario_ds_lis     CONSTANT L1_num_arr := L1_num_arr (1, 2, 2, 2, 3);
  c_scenario_lis        CONSTANT L1_chr_arr := L1_chr_arr (
                               'DS-1, testing inner, outer joins, analytic over dep, and global ratios with 1 dep (10) - pass dep 10',
                               'DS-2, testing same as 1 but with extra emp in another dep (20) - pass dep 10',
                               'DS-2, as second scenario, but - pass dep 20',
                               'DS-2, as second scenario, but - pass null dep',
                               'DS-3, Salaries total 1500 (< threshold of 1600, so return nothing) - pass dep 10');

  c_inp_group_lis       CONSTANT L1_chr_arr := L1_chr_arr ('Employee', 'Department Parameter');
  c_inp_field_2lis      CONSTANT L2_chr_arr := L2_chr_arr (
                                                        L1_chr_arr (
                                                                '*Employee Id',
                                                                'Last Name',
                                                                'Email',
                                                                'Hire Date',
                                                                'Job',
                                                                '*Salary',
                                                                '*Manager Id',
                                                                '*Department Id',
                                                                'Updated'),
                                                        L1_chr_arr (
                                                                '*Department Id')
  );
  c_out_field_2lis      CONSTANT L2_chr_arr :=  L2_chr_arr ( L1_chr_arr (
                                'Name',
                                'Department',
                                'Manager',
                                '*Salary',
                                '*Salary Ratio (dep)',
                                '*Salary Ratio (overall)'));

  l_act_2lis                      L2_chr_arr := L2_chr_arr();
  c_ms_limit            CONSTANT PLS_INTEGER := 1;
  l_timer_set                    PLS_INTEGER;
  l_inp_3lis                     L3_chr_arr := L3_chr_arr();
  l_emp_csr                      SYS_REFCURSOR;

Notes on declare section

  • Data sets, scenarios, expected values etc. are stored in generic arrays, where:
    • L1_chr_arr is type of array of VARCHAR2(4000), same as standard type SYS.ODCIVarchar2List
    • L2_chr_arr is a type of array of L1_chr_arr
    • L3_chr_arr is a type of array of L2_chr_arr

Setup section

  PROCEDURE Setup_Array IS
  BEGIN

    l_act_2lis.EXTEND (c_exp_2lis.COUNT);
    l_inp_3lis.EXTEND (c_exp_2lis.COUNT);

    FOR i IN 1..c_exp_2lis.COUNT LOOP

      l_inp_3lis (i) := L2_chr_arr();
      l_inp_3lis (i).EXTEND(2);
      l_inp_3lis (i)(2) := L1_chr_arr (c_dep_lis(i));

    END LOOP;

  END Setup_Array;

  /***************************************************************************************************

  Setup_DB: Create test records for a given scenario for testing AIP_Get_Dept_Emps

  ***************************************************************************************************/
  PROCEDURE Setup_DB (p_call_ind           PLS_INTEGER,   -- index of input dataset
                      x_inp_lis        OUT L1_chr_arr) IS -- input list, employees

    l_emp_id            PLS_INTEGER;
    l_mgr_id            PLS_INTEGER;
    l_len_lis           L1_num_arr := L1_num_arr (1, -11, -13, -10, 10, -10);

  BEGIN

    Utils.Heading ('Employees created in setup: DS-' || p_call_ind || ' - ' || c_dataset_3lis (p_call_ind)(1)(1));
    Utils.Col_Headers (L1_chr_arr ('#', 'Employee id', 'Department id', 'Manager', 'Job id', 'Salary'), l_len_lis);
    x_inp_lis := L1_chr_arr();
    x_inp_lis.EXTEND (c_dataset_3lis (p_call_ind).COUNT - 1);
    FOR i IN 2..c_dataset_3lis (p_call_ind).COUNT LOOP

      l_emp_id := DML_API_TT_HR.Ins_Emp (
                            p_emp_ind  => i - 1,
                            p_dep_id   => c_dataset_3lis (p_call_ind)(i)(1),
                            p_mgr_id   => l_mgr_id,
                            p_job_id   => c_dataset_3lis (p_call_ind)(i)(2),
                            p_salary   => c_dataset_3lis (p_call_ind)(i)(3),
                            x_rec      => x_inp_lis(i - 1));
      Utils.Pr_List_As_Line (L1_chr_arr ((i-1), l_emp_id, Nvl (c_dataset_3lis (p_call_ind)(i)(1), ' '), Nvl (To_Char(l_mgr_id), ' '), c_dataset_3lis (p_call_ind)(i)(2), c_dataset_3lis (p_call_ind)(i)(3)), l_len_lis);
      IF i = 2 THEN
        l_mgr_id := l_emp_id;
      END IF;

    END LOOP;

  END Setup_DB;

Notes on setup section

  • c_dataset_3lis contains the data for all data sets indexed by (data set, record, field)
  • Setup_Array is called once to do some setup on the arrays
  • Setup_DB is called for a single data set at a time in each scenario
  • Description of the data set is contained in the array and printed out
  • Data set is printed out in tabular format. In the current version of the utility code, this is not strictly necessary, because all the input data is printed out before the outputs

'Pure' API wrapper procedure

  PROCEDURE Purely_Wrap_API (p_scenario_ds      PLS_INTEGER,   -- index of input dataset
                             p_dep_id           PLS_INTEGER,   -- input department id
                             x_inp_lis      OUT L1_chr_arr,    -- generic inputs list (for scenario)
                             x_act_lis      OUT L1_chr_arr) IS -- generic actual values list (for scenario)
  BEGIN

    Setup_DB (p_scenario_ds, x_inp_lis);
    Timer_Set.Increment_Time (l_timer_set, Utils_TT.c_setup_timer);

    Emp_WS.AIP_Get_Dept_Emps (p_dep_id  => p_dep_id,
                              x_emp_csr => l_emp_csr);
    x_act_lis := Utils_TT.List_or_Empty (Utils_TT.Cursor_to_Array (x_csr => l_emp_csr));
    Timer_Set.Increment_Time (l_timer_set, Utils_TT.c_call_timer);
    ROLLBACK;

  END Purely_Wrap_API;

Notes on 'Pure' API wrapper procedure

  • Setup_DB is called to create the data set for the scenario
  • Emp_WS.AIP_Get_Dept_Emps returns the ref cursor
  • Utils_TT.Cursor_to_Array gets the ref cursor result set into an array (which may be empty)

Main section

BEGIN
--
-- Every testing main section should be similar to this, with array setup, then loop over scenarios
-- making a 'pure'(-ish) call to specific, local Purely_Wrap_API, with single assertion call outside
-- the loop
--
  l_timer_set := Utils_TT.Init (c_proc_name);
  Setup_Array;

  FOR i IN 1..c_exp_2lis.COUNT LOOP

    Purely_Wrap_API (c_scenario_ds_lis(i), c_where_lis(i), l_inp_3lis(i)(1), l_act_2lis(i));

  END LOOP;

  Utils_TT.Is_Deeply (c_proc_name, c_scenario_lis, l_inp_3lis, l_act_2lis, c_exp_2lis, l_timer_set, c_ms_limit,
                      c_inp_group_lis, c_inp_field_2lis, c_out_group_lis, c_out_field_2lis);

EXCEPTION

  WHEN OTHERS THEN
    Utils.Write_Other_Error;
    RAISE;

END tt_AIP_Get_Dept_Emps;

Notes on main section

  • It's quite short isn't it 🙂
  • Setup is called to do array setup
  • Main section loops over the scenarios calling Purely_Wrap_API
  • Is_Deeply is called to do all the assertions within nested loops, then print the results

Test Output

TRAPIT TEST: TT_Emp_WS.tt_AIP_Get_Dept_Emps
===========================================

Employees created in setup: DS-1 - 4 emps, 1 dep (10), emp-3 has no dep, emp-4 has bad job
==========================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1658             10              IT_PROG           1000
2         1659             10        1658  IT_PROG           2000
3         1660                       1658  IT_PROG           3000
4         1661             10        1658  AD_ASST           4000

Employees created in setup: DS-2 - As dataset 1 but with extra emp-5, in second dep (20)
========================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1662             10              IT_PROG           1000
2         1663             10        1662  IT_PROG           2000
3         1664                       1662  IT_PROG           3000
4         1665             10        1662  AD_ASST           4000
5         1666             20        1662  IT_PROG           5000

Employees created in setup: DS-2 - As dataset 1 but with extra emp-5, in second dep (20)
========================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1667             10              IT_PROG           1000
2         1668             10        1667  IT_PROG           2000
3         1669                       1667  IT_PROG           3000
4         1670             10        1667  AD_ASST           4000
5         1671             20        1667  IT_PROG           5000

Employees created in setup: DS-2 - As dataset 1 but with extra emp-5, in second dep (20)
========================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1672             10              IT_PROG           1000
2         1673             10        1672  IT_PROG           2000
3         1674                       1672  IT_PROG           3000
4         1675             10        1672  AD_ASST           4000
5         1676             20        1672  IT_PROG           5000

Employees created in setup: DS-3 - As dataset 2 but with salaries * 0.1, total below reporting threshold of 1600
================================================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1677             10              IT_PROG            100
2         1678             10        1677  IT_PROG            200
3         1679                       1677  IT_PROG            300
4         1680             10        1677  AD_ASST            400
5         1681             20        1677  IT_PROG            500

SCENARIO 1: DS-1, testing inner, outer joins, analytic over dep, and global ratios with 1 dep (10) - pass dep 10 {
==================================================================================================================

    INPUTS
    ======

        GROUP Employee {
        ================

            Employee Id  Last Name  Email  Hire Date    Job      Salary  Manager Id  Department Id  Updated
            -----------  ---------  -----  -----------  -------  ------  ----------  -------------  -----------
                   1658  LN_1       EM_1   01-OCT-2016  IT_PROG    1000                         10  01-OCT-2016
                   1659  LN_2       EM_2   01-OCT-2016  IT_PROG    2000        1658             10  01-OCT-2016
                   1660  LN_3       EM_3   01-OCT-2016  IT_PROG    3000        1658                 01-OCT-2016
                   1661  LN_4       EM_4   01-OCT-2016  AD_ASST    4000        1658             10  01-OCT-2016

        }
        =

        GROUP Department Parameter {
        ============================

            Department Id
            -------------
                       10

        }
        =

    OUTPUTS
    =======

        GROUP Select results: Actual = 2, Expected = 2 {
        ================================================

            F?  Name  Department      Manager  Salary  Salary Ratio (dep)  Salary Ratio (overall)
            --  ----  --------------  -------  ------  ------------------  ----------------------
                LN_1  Administration             1000                 .67                      .4
                LN_2  Administration  LN_1       2000                1.33                      .8

        } 0 failed, of 2: SUCCESS
        =========================

} 0 failed, of 2: SUCCESS
=========================

SCENARIO 2: DS-2, testing same as 1 but with extra emp in another dep (20) - pass dep 10 {
==========================================================================================

    INPUTS
    ======

        GROUP Employee {
        ================

            Employee Id  Last Name  Email  Hire Date    Job      Salary  Manager Id  Department Id  Updated
            -----------  ---------  -----  -----------  -------  ------  ----------  -------------  -----------
                   1662  LN_1       EM_1   01-OCT-2016  IT_PROG    1000                         10  01-OCT-2016
                   1663  LN_2       EM_2   01-OCT-2016  IT_PROG    2000        1662             10  01-OCT-2016
                   1664  LN_3       EM_3   01-OCT-2016  IT_PROG    3000        1662                 01-OCT-2016
                   1665  LN_4       EM_4   01-OCT-2016  AD_ASST    4000        1662             10  01-OCT-2016
                   1666  LN_5       EM_5   01-OCT-2016  IT_PROG    5000        1662             20  01-OCT-2016

        }
        =

        GROUP Department Parameter {
        ============================

            Department Id
            -------------
                       10

        }
        =

    OUTPUTS
    =======

        GROUP Select results: Actual = 2, Expected = 2 {
        ================================================

            F?  Name  Department      Manager  Salary  Salary Ratio (dep)  Salary Ratio (overall)
            --  ----  --------------  -------  ------  ------------------  ----------------------
                LN_1  Administration             1000                 .67                     .33
                LN_2  Administration  LN_1       2000                1.33                     .67

        } 0 failed, of 2: SUCCESS
        =========================

} 0 failed, of 2: SUCCESS
=========================

SCENARIO 3: DS-2, as second scenario, but - pass dep 20 {
=========================================================

    INPUTS
    ======

        GROUP Employee {
        ================

            Employee Id  Last Name  Email  Hire Date    Job      Salary  Manager Id  Department Id  Updated
            -----------  ---------  -----  -----------  -------  ------  ----------  -------------  -----------
                   1667  LN_1       EM_1   01-OCT-2016  IT_PROG    1000                         10  01-OCT-2016
                   1668  LN_2       EM_2   01-OCT-2016  IT_PROG    2000        1667             10  01-OCT-2016
                   1669  LN_3       EM_3   01-OCT-2016  IT_PROG    3000        1667                 01-OCT-2016
                   1670  LN_4       EM_4   01-OCT-2016  AD_ASST    4000        1667             10  01-OCT-2016
                   1671  LN_5       EM_5   01-OCT-2016  IT_PROG    5000        1667             20  01-OCT-2016

        }
        =

        GROUP Department Parameter {
        ============================

            Department Id
            -------------
                       20

        }
        =

    OUTPUTS
    =======

        GROUP Select results: Actual = 1, Expected = 1 {
        ================================================

            F?  Name  Department  Manager  Salary  Salary Ratio (dep)  Salary Ratio (overall)
            --  ----  ----------  -------  ------  ------------------  ----------------------
                LN_5  Marketing   LN_1       5000                   1                    1.67

        } 0 failed, of 1: SUCCESS
        =========================

} 0 failed, of 1: SUCCESS
=========================

SCENARIO 4: DS-2, as second scenario, but - pass null dep {
===========================================================

    INPUTS
    ======

        GROUP Employee {
        ================

            Employee Id  Last Name  Email  Hire Date    Job      Salary  Manager Id  Department Id  Updated
            -----------  ---------  -----  -----------  -------  ------  ----------  -------------  -----------
                   1672  LN_1       EM_1   01-OCT-2016  IT_PROG    1000                         10  01-OCT-2016
                   1673  LN_2       EM_2   01-OCT-2016  IT_PROG    2000        1672             10  01-OCT-2016
                   1674  LN_3       EM_3   01-OCT-2016  IT_PROG    3000        1672                 01-OCT-2016
                   1675  LN_4       EM_4   01-OCT-2016  AD_ASST    4000        1672             10  01-OCT-2016
                   1676  LN_5       EM_5   01-OCT-2016  IT_PROG    5000        1672             20  01-OCT-2016

        }
        =

        GROUP Department Parameter {
        ============================

            Department Id
            -------------


        }
        =

    OUTPUTS
    =======

        GROUP Select results: Actual = 0, Expected = 0: SUCCESS
        =======================================================

} 0 failed, of 1: SUCCESS
=========================

SCENARIO 5: DS-3, Salaries total 1500 (< threshold of 1600, so return nothing) - pass dep 10 {
==============================================================================================

    INPUTS
    ======

        GROUP Employee {
        ================

            Employee Id  Last Name  Email  Hire Date    Job      Salary  Manager Id  Department Id  Updated
            -----------  ---------  -----  -----------  -------  ------  ----------  -------------  -----------
                   1677  LN_1       EM_1   01-OCT-2016  IT_PROG     100                         10  01-OCT-2016
                   1678  LN_2       EM_2   01-OCT-2016  IT_PROG     200        1677             10  01-OCT-2016
                   1679  LN_3       EM_3   01-OCT-2016  IT_PROG     300        1677                 01-OCT-2016
                   1680  LN_4       EM_4   01-OCT-2016  AD_ASST     400        1677             10  01-OCT-2016
                   1681  LN_5       EM_5   01-OCT-2016  IT_PROG     500        1677             20  01-OCT-2016

        }
        =

        GROUP Department Parameter {
        ============================

            Department Id
            -------------
                       10

        }
        =

    OUTPUTS
    =======

        GROUP Select results: Actual = 0, Expected = 0: SUCCESS
        =======================================================

} 0 failed, of 1: SUCCESS
=========================

TIMING: Actual = 7, Expected <= 1: FAILURE
==========================================

SUMMARY for TT_Emp_WS.tt_AIP_Get_Dept_Emps
==========================================

Scenario                                                                                              # Failed  # Tests  Status
----------------------------------------------------------------------------------------------------  --------  -------  -------
DS-1, testing inner, outer joins, analytic over dep, and global ratios with 1 dep (10) - pass dep 10         0        2  SUCCESS
DS-2, testing same as 1 but with extra emp in another dep (20) - pass dep 10                                 0        2  SUCCESS
DS-2, as second scenario, but - pass dep 20                                                                  0        1  SUCCESS
DS-2, as second scenario, but - pass null dep                                                                0        1  SUCCESS
DS-3, Salaries total 1500 (< threshold of 1600, so return nothing) - pass dep 10                             0        1  SUCCESS
Timing                                                                                                       1        1  FAILURE
----------------------------------------------------------------------------------------------------  --------  -------  -------
Total                                                                                                        1        8  FAILURE
----------------------------------------------------------------------------------------------------  --------  -------  -------

Timer Set: TT_Emp_WS.tt_AIP_Get_Dept_Emps, Constructed at 01 Oct 2016 09:14:12, written at 09:14:13
===================================================================================================
[Timer timed: Elapsed (per call): 0.03 (0.000034), CPU (per call): 0.03 (0.000030), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Setup          0.08        0.05             5        0.01660        0.01000
Caller         0.03        0.01             5        0.00680        0.00200
(Other)        0.10        0.10             1        0.09500        0.10000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.21        0.16            11        0.01927        0.01455
-------  ----------  ----------  ------------  -------------  -------------






 

Design Patterns for Database API Testing 3: Batch Loading of Flat Files

Last October I gave a presentation on database unit testing with utPLSQL, Oracle Unit Testing with utPLSQL. I mentioned design patterns as a way of reducing the effort of building unit tests and outlined some strategies for coding them effectively.

In the current set of articles, I develop the ideas further, starting from the idea that all database APIs can be considered in terms of the axes:

  • direction (i.e. getter or setter, noting that setters can also 'get')
  • mode (i.e. real time or batch)

For each cell in the implied matrix, I construct an example API (or view) with specified requirements against Oracle's HR demo schema, and use this example to construct a testing program with appropriate scenarios as a design pattern. Concepts and common patterns and anti-patterns in automated API testing are discussed throughout, and these are largely independent of testing framework used. However, the examples use my own lightweight independent framework that is designed to help avoid many API testing anti-patterns. The code is available on GitHub here, BrenPatF/trapit_oracle_tester, and includes both framework and design pattern examples.

Behind the four examples, there is an underlying design pattern that involves wrapping the API call in a 'pure' procedure, called once per scenario, with the output 'actuals' array including everything affected by the API, whether as output parameters, or on database tables, etc. The inputs are also extended from the API parameters to include any other effective inputs. Assertion takes place after all scenarios and is against the extended outputs, with extended inputs also listed. This concept of the 'pure' function, central to Functional Programming, has important advantages in automated testing. I explained the concepts involved in a presentation at the Oracle User Group Ireland Conference in March 2018:

The Database API Viewed As A Mathematical Function: Insights into Testing

The previous example, on views, has its second part here: Design Patterns for Database API Testing 2: Views 2 - Code. This third example covers batch loading of data into a database table from file by means of external tables. There are many possible variants of this kind of interface, and I tried to combine the features from past projects that seemed to work best. In particular:

  • The load procedure is assumed to be executed from an operating system script (normally Unix) that manages the input files, copying from source files into a single file for reading by the external table, looping over multiple files where necessary, and archiving processed files
    • It is possible to dynamically map the external table to multiple files, but that approach involves executing DDL and seems to be generally more complex
    • The idea is to do the different types of processing at the level most appropriate, so avoiding excessive file processing within the database
  • SQL operations are performed at set level, rather than within a loop, and the set concerned comprises the entire contents of the external table
    • This assumes that the Oracle internal working space requirements (such as size of TEMP tablespace) are not exceeded
    • The alternative approach of fetching batches of records into arrays for loading tends to be more complex, and less efficient
    • It may be preferable to restrict the size of the input files where necessary instead, either at the source end, or from the controlling operating system script
    • Where loading occurs from staging tables (which is not in scope here) the use of the DBMS_Parallel_Execute package to control transaction size looks an attractive modern approach (from v11, DBMS_PARALLEL_EXECUTE)
  • Metadata tables are used for specifying job control parameters, and for recording run statistics
    • Run statistics include job status and numbers of records succeeding and failing at both external table and database level
    • A percentage threshold is included in the job control table, that causes the job to fail if a higher percentage of records fails
  • Oracle's DML LOG ERRORS clause is used to divert failing records into an errors table, while processing the other records normally
    • While simpler than other approaches to error handling, prior to v12.1 this clause had a significant performance overhead, but from v12.1 this is no longer the case (see DML Error Logging in Oracle 10g Database Release 2 - it has a table of comparative timings up to v12.1 at the end)
    • The standard Oracle err$ table structure is used, with the addition of two columns, one to identify the associated job run, and the other the utid column used by the framework to identify test data
    • In a replication environment a unique identifier would be needed, but is not included here
    • The table is also used to capture records that fail custom validation (here when a record passed as an update does not match an existing record)

Requirement Summary

  • The procedure reads employee records from a single flat file
  • Employee id is an optional field, and if passed the record is treated as an update, otherwise it is an insert
  • A job statistics table is populated with a record on each run, and stores numbers of successful and failed records etc.
  • Records that fail at the database level are inserted into an errors table, extended from Oracle's err$ table format
  • The external table has all fields defined as 4000 bytes character fields to minimise records failing to be read from the external table
  • An audit date column is included, and is set to the current date if any change is made in a record; if an unchanged record is detected no update should be made
  • The load program takes two parameters that would be passed in by an operating system calling script:
    • An identifier for the file, that may be a timestamped original file name (but the external table file has a fixed name)
    • A line count for the file
  • The passed file identifier is saved in the job statistics table, and a repeat identifier will only be accepted if previous records all have failed status
  • A job control table stores an error percentage threshold, above which the run is considered unsuccessfull, and an exception is raised

Notes on Testing Flat File Loads

  • It is considered best practice to keep testing code as self-contained as possible, and in order to avoid dependence on external data files, Oracle's UTL_File package is used to delete and create the test files from arrays within the test code
    • The Utils package contains two wrapper procedures to facilitate this: Delete_File and Write_File

Extended ERD

unit-testing-two-ff-erd-h

Design Pattern Groups

The testing framework is centred around the concept of input and output groups, representing the data sets that respectively form the inputs to, and outputs from, the program. The records in each group are printed by the framework with column headers for each scenario. These groups are identified by the developer, and in this case they are as noted below.

Input Groups

  • Parameters
  • Input File
  • Batch Job Table
  • Job Statistics Table
  • Employees Table

Output Groups

  • Employees Table
  • Errors Table
  • Job Statistics Table
  • Exception
  • Timing of average call

Test Scenarios

Key
The scenario descriptions start with two sets of counts, followed by a verbal description. The first set is on the records coming in from file:

  • NV - new valid records
  • OV - old valid records
  • OU - old unchanged records
  • NI - new invalid records
  • OI - old valid records
  • EI - external table invalid records

The second set is on the existing records in job statistics and employees (other than are in the input file; these are counted as old records in the first set of counts):

  • J - job statistics records
  • E - employees records

Scenario List

  1. NV/OV/OU/NI/OI/EI: 1/0/0/0/0/0. Existing J/E: 0/0. [1 valid new record from scratch]
  2. NV/OV/OU/NI/OI/EI: 1/1/1/0/0/0. Existing J/E: 1/0. [3 valid records of each kind]
  3. NV/OV/OU/NI/OI/EI: 0/0/0/0/1/0. Existing J/E: 1/1. Uid not found [1 invalid old - exception]
  4. NV/OV/OU/NI/OI/EI: 0/0/0/1/0/0. Existing J/E: 1/1. Email too long [1 invalid new - exception]
  5. NV/OV/OU/NI/OI/EI: 1/0/0/0/1/0. Existing J/E: 1/1. Name too long [1 valid new, 1 invalid old - no exception]
  6. NV/OV/OU/NI/OI/EI: 0/0/0/1/0/0. Existing J/E: 1/1. Invalid job [1 invalid new - exception]
  7. NV/OV/OU/NI/OI/EI: 0/1/0/1/1/0. Existing J/E: 1/2. 2 invalid jobs [1 valid old, 2 invalid: old and new - no exception]
  8. NV/OV/OU/NI/OI/EI: 0/1/0/0/0/1. Existing J/E: 1/2. Name 4001ch [1 valid old, 1 invalid new for external table - no exception; also file had previously failed]
  9. NV/OV/OU/NI/OI/EI: 0/0/0/1/0/0. Existing J/E: 1/1. [File already processed - exception]

Package Structure Diagram

Call Structure Table - TT_Emp_Batch.tt_AIP_Load_Emps

Test Output

TRAPIT TEST for TT_Emp_Batch.tt_AIP_Load_Emps
=============================================
employees.dat was not present to delete!

SCENARIO 1: NV/OV/OU/NI/OI/EI: 1/0/0/0/0/0. Existing J/E: 0/0. [1 valid new record from scratch] {
==================================================================================================

    INPUTS
    ======

        GROUP Parameter {
        =================

            File Name               Count
            ----------------------  -----
            employees_20160801.dat      1

        }
        =

        GROUP File {
        ============

            Line
            ------------------------------------
            ,LN 1,EM 1,01-JAN-2010,IT_PROG,10000

        }
        =

        GROUP Batch Job Table {
        =======================

            Name       Fail Percent
            ---------  ------------
            LOAD_EMPS            70

        }
        =

        GROUP Statistics Table (No records)
        ===================================

        GROUP Employees Table (No records)
        ==================================

    OUTPUTS
    =======

        GROUP Employee: Actual = 1, Expected = 1 {
        ==========================================

            F?  Employee Id  Name  Email  Hired        Job      Salary  Updated
            --  -----------  ----  -----  -----------  -------  ------  -----------
                       1627  LN 1  EM 1   01-JAN-2010  IT_PROG  10000   11-SEP-2016

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Error: Actual = 0, Expected = 0: SUCCESS
        ==============================================

        GROUP Job Statistic: Actual = 1, Expected = 1 {
        ===============================================

            F?  Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            --  ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                               3  LOAD_EMPS     employees_20160801.dat               1                  0                  0  11-SEP-2016  11-SEP-2016  S

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Exception: Actual = 0, Expected = 0: SUCCESS
        ==================================================

} 0 failed, of 4: SUCCESS
=========================

SCENARIO 2: NV/OV/OU/NI/OI/EI: 1/1/1/0/0/0. Existing J/E: 1/0. [3 valid records of each kind] {
===============================================================================================

    INPUTS
    ======

        GROUP Parameter {
        =================

            File Name               Count
            ----------------------  -----
            employees_20160801.dat      3

        }
        =

        GROUP File {
        ============

            Line
            -----------------------------------------
            ,LN 1,EM 1,01-JAN-2010,IT_PROG,10000
            1629,LN 2,EM 2,01-JAN-2010,IT_PROG,20000
            1630,LN 3U,EM 3,01-JAN-2010,IT_PROG,30000

        }
        =

        GROUP Batch Job Table {
        =======================

            Name       Fail Percent
            ---------  ------------
            LOAD_EMPS            70

        }
        =

        GROUP Statistics Table {
        ========================

            Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                           5  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S

        }
        =

        GROUP Employees Table {
        =======================

            Employee Id  Name  Email  Hired        Job      Salary  Manager Id  Department Id  Updated
            -----------  ----  -----  -----------  -------  ------  ----------  -------------  -----------
                   1629  LN 2  EM 2   01-JAN-2010  IT_PROG   20000                             01-JAN-2010
                   1630  LN 3  EM 3   01-JAN-2010  IT_PROG   30000                             01-JAN-2010

        }
        =

    OUTPUTS
    =======

        GROUP Employee: Actual = 3, Expected = 3 {
        ==========================================

            F?  Employee Id  Name   Email  Hired        Job      Salary  Updated
            --  -----------  -----  -----  -----------  -------  ------  -----------
                       1629  LN 2   EM 2   01-JAN-2010  IT_PROG  20000   01-JAN-2010
                       1630  LN 3U  EM 3   01-JAN-2010  IT_PROG  30000   11-SEP-2016
                       1631  LN 1   EM 1   01-JAN-2010  IT_PROG  10000   11-SEP-2016

        } 0 failed, of 3: SUCCESS
        =========================

        GROUP Error: Actual = 0, Expected = 0: SUCCESS
        ==============================================

        GROUP Job Statistic: Actual = 2, Expected = 2 {
        ===============================================

            F?  Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            --  ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                               5  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S
                               6  LOAD_EMPS     employees_20160801.dat               2                  0                  0  11-SEP-2016  11-SEP-2016  S

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Exception: Actual = 0, Expected = 0: SUCCESS
        ==================================================

} 0 failed, of 7: SUCCESS
=========================

SCENARIO 3: NV/OV/OU/NI/OI/EI: 0/0/0/0/1/0. Existing J/E: 1/1. Uid not found [1 invalid old - exception] {
==========================================================================================================

    INPUTS
    ======

        GROUP Parameter {
        =================

            File Name               Count
            ----------------------  -----
            employees_20160801.dat      1

        }
        =

        GROUP File {
        ============

            Line
            --------------------------------------
            99,LN 1,EM 1,01-JAN-2010,IT_PROG,10000

        }
        =

        GROUP Batch Job Table {
        =======================

            Name       Fail Percent
            ---------  ------------
            LOAD_EMPS            70

        }
        =

        GROUP Statistics Table {
        ========================

            Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                           8  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S

        }
        =

        GROUP Employees Table {
        =======================

            Employee Id  Name  Email  Hired        Job      Salary  Manager Id  Department Id  Updated
            -----------  ----  -----  -----------  -------  ------  ----------  -------------  -----------
                   1633  LN 2  EM 2   01-JAN-2010  IT_PROG   20000                             01-JAN-2010

        }
        =

    OUTPUTS
    =======

        GROUP Employee: Actual = 1, Expected = 1 {
        ==========================================

            F?  Employee Id  Name  Email  Hired        Job      Salary  Updated
            --  -----------  ----  -----  -----------  -------  ------  -----------
                       1633  LN 2  EM 2   01-JAN-2010  IT_PROG  20000   01-JAN-2010

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Error: Actual = 1, Expected = 1 {
        =======================================

            F?  Job Statistic Id  ORA_ERR_TAG$  ORA_ERR_MESG$       ORA_ERR_OPTYP$  Employee Id  Name  Email  Hired        Job      Salary
            --  ----------------  ------------  ------------------  --------------  -----------  ----  -----  -----------  -------  ------
                               9                Employee not found  PK                       99  LN 1  EM 1   01-JAN-2010  IT_PROG  10000

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Job Statistic: Actual = 2, Expected = 2 {
        ===============================================

            F?  Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            --  ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                               8  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S
                               9  LOAD_EMPS     employees_20160801.dat               0                  0                  1  11-SEP-2016  11-SEP-2016  F

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Exception: Actual = 1, Expected = 1 {
        ===========================================

            F?  Message
            --  ------------------------------------------------------
                ORA-20001: Batch failed with too many invalid records!

        } 0 failed, of 1: SUCCESS
        =========================

} 0 failed, of 5: SUCCESS
=========================

SCENARIO 4: NV/OV/OU/NI/OI/EI: 0/0/0/1/0/0. Existing J/E: 1/1. Email too long [1 invalid new - exception] {
===========================================================================================================

    INPUTS
    ======

        GROUP Parameter {
        =================

            File Name               Count
            ----------------------  -----
            employees_20160801.dat      1

        }
        =

        GROUP File {
        ============

            Line
            ------------------------------------------------------------------
            ,LN 1,EM 1123456789012345678901234567890,01-JAN-2010,IT_PROG,10000

        }
        =

        GROUP Batch Job Table {
        =======================

            Name       Fail Percent
            ---------  ------------
            LOAD_EMPS            70

        }
        =

        GROUP Statistics Table {
        ========================

            Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                          11  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S

        }
        =

        GROUP Employees Table {
        =======================

            Employee Id  Name  Email  Hired        Job      Salary  Manager Id  Department Id  Updated
            -----------  ----  -----  -----------  -------  ------  ----------  -------------  -----------
                   1635  LN 2  EM 2   01-JAN-2010  IT_PROG   20000                             01-JAN-2010

        }
        =

    OUTPUTS
    =======

        GROUP Employee: Actual = 1, Expected = 1 {
        ==========================================

            F?  Employee Id  Name  Email  Hired        Job      Salary  Updated
            --  -----------  ----  -----  -----------  -------  ------  -----------
                       1635  LN 2  EM 2   01-JAN-2010  IT_PROG  20000   01-JAN-2010

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Error: Actual = 1, Expected = 1 {
        =======================================

            F?  Job Statistic Id  ORA_ERR_TAG$  ORA_ERR_MESG$                                                                             ORA_ERR_OPTYP$  Employee Id  Name  Email                               Hired        Job      Salary
            --  ----------------  ------------  ----------------------------------------------------------------------------------------  --------------  -----------  ----  ----------------------------------  -----------  -------  ------
                              12                ORA-12899: value too large for column "HR"."EMPLOYEES"."EMAIL" (actual: 34, maximum: 25)  I                      1636  LN 1  EM 1123456789012345678901234567890  01-JAN-2010  IT_PROG  10000

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Job Statistic: Actual = 2, Expected = 2 {
        ===============================================

            F?  Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            --  ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                              11  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S
                              12  LOAD_EMPS     employees_20160801.dat               0                  0                  1  11-SEP-2016  11-SEP-2016  F

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Exception: Actual = 1, Expected = 1 {
        ===========================================

            F?  Message
            --  ------------------------------------------------------
                ORA-20001: Batch failed with too many invalid records!

        } 0 failed, of 1: SUCCESS
        =========================

} 0 failed, of 5: SUCCESS
=========================

SCENARIO 5: NV/OV/OU/NI/OI/EI: 1/0/0/0/1/0. Existing J/E: 1/1. Name too long [1 valid new, 1 invalid old - no exception] {
==========================================================================================================================

    INPUTS
    ======

        GROUP Parameter {
        =================

            File Name               Count
            ----------------------  -----
            employees_20160801.dat      2

        }
        =

        GROUP File {
        ============

            Line
            ----------------------------------------------------------------------
            1638,LN 1123456789012345678901234567890,EM 1,01-JAN-2010,IT_PROG,10000
            ,LN 3,EM 3,01-JAN-2010,IT_PROG,30000

        }
        =

        GROUP Batch Job Table {
        =======================

            Name       Fail Percent
            ---------  ------------
            LOAD_EMPS            70

        }
        =

        GROUP Statistics Table {
        ========================

            Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                          14  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S

        }
        =

        GROUP Employees Table {
        =======================

            Employee Id  Name  Email  Hired        Job      Salary  Manager Id  Department Id  Updated
            -----------  ----  -----  -----------  -------  ------  ----------  -------------  -----------
                   1638  LN 2  EM 2   01-JAN-2010  IT_PROG   20000                             01-JAN-2010

        }
        =

    OUTPUTS
    =======

        GROUP Employee: Actual = 2, Expected = 2 {
        ==========================================

            F?  Employee Id  Name  Email  Hired        Job      Salary  Updated
            --  -----------  ----  -----  -----------  -------  ------  -----------
                       1638  LN 2  EM 2   01-JAN-2010  IT_PROG  20000   01-JAN-2010
                       1639  LN 3  EM 3   01-JAN-2010  IT_PROG  30000   11-SEP-2016

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Error: Actual = 1, Expected = 1 {
        =======================================

            F?  Job Statistic Id  ORA_ERR_TAG$  ORA_ERR_MESG$                                                                                 ORA_ERR_OPTYP$  Employee Id  Name                                Email  Hired        Job      Salary
            --  ----------------  ------------  --------------------------------------------------------------------------------------------  --------------  -----------  ----------------------------------  -----  -----------  -------  ------
                              15                ORA-12899: value too large for column "HR"."EMPLOYEES"."LAST_NAME" (actual: 34, maximum: 25)  U                      1638  LN 1123456789012345678901234567890  EM 1   01-JAN-2010  IT_PROG  10000

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Job Statistic: Actual = 2, Expected = 2 {
        ===============================================

            F?  Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            --  ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                              14  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S
                              15  LOAD_EMPS     employees_20160801.dat               1                  0                  1  11-SEP-2016  11-SEP-2016  S

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Exception: Actual = 0, Expected = 0: SUCCESS
        ==================================================

} 0 failed, of 6: SUCCESS
=========================

SCENARIO 6: NV/OV/OU/NI/OI/EI: 0/0/0/1/0/0. Existing J/E: 1/1. Invalid job [1 invalid new - exception] {
========================================================================================================

    INPUTS
    ======

        GROUP Parameter {
        =================

            File Name               Count
            ----------------------  -----
            employees_20160801.dat      1

        }
        =

        GROUP File {
        ============

            Line
            ------------------------------------
            ,LN 1,EM 1,01-JAN-2010,NON_JOB,10000

        }
        =

        GROUP Batch Job Table {
        =======================

            Name       Fail Percent
            ---------  ------------
            LOAD_EMPS            70

        }
        =

        GROUP Statistics Table {
        ========================

            Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                          17  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S

        }
        =

        GROUP Employees Table {
        =======================

            Employee Id  Name  Email  Hired        Job      Salary  Manager Id  Department Id  Updated
            -----------  ----  -----  -----------  -------  ------  ----------  -------------  -----------
                   1641  LN 2  EM 2   01-JAN-2010  IT_PROG   20000                             01-JAN-2010

        }
        =

    OUTPUTS
    =======

        GROUP Employee: Actual = 1, Expected = 1 {
        ==========================================

            F?  Employee Id  Name  Email  Hired        Job      Salary  Updated
            --  -----------  ----  -----  -----------  -------  ------  -----------
                       1641  LN 2  EM 2   01-JAN-2010  IT_PROG  20000   01-JAN-2010

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Error: Actual = 1, Expected = 1 {
        =======================================

            F?  Job Statistic Id  ORA_ERR_TAG$  ORA_ERR_MESG$                                                                    ORA_ERR_OPTYP$  Employee Id  Name  Email  Hired        Job      Salary
            --  ----------------  ------------  -------------------------------------------------------------------------------  --------------  -----------  ----  -----  -----------  -------  ------
                              18                ORA-02291: integrity constraint (HR.EMP_JOB_FK) violated - parent key not found  I                      1642  LN 1  EM 1   01-JAN-2010  NON_JOB  10000

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Job Statistic: Actual = 2, Expected = 2 {
        ===============================================

            F?  Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            --  ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                              17  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S
                              18  LOAD_EMPS     employees_20160801.dat               0                  0                  1  11-SEP-2016  11-SEP-2016  F

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Exception: Actual = 1, Expected = 1 {
        ===========================================

            F?  Message
            --  ------------------------------------------------------
                ORA-20001: Batch failed with too many invalid records!

        } 0 failed, of 1: SUCCESS
        =========================

} 0 failed, of 5: SUCCESS
=========================

SCENARIO 7: NV/OV/OU/NI/OI/EI: 0/1/0/1/1/0. Existing J/E: 1/2. 2 invalid jobs [1 valid old, 2 invalid: old and new - no exception] {
====================================================================================================================================

    INPUTS
    ======

        GROUP Parameter {
        =================

            File Name               Count
            ----------------------  -----
            employees_20160801.dat      3

        }
        =

        GROUP File {
        ============

            Line
            -----------------------------------------
            ,LN 1,EM 1,01-JAN-2010,NON_JOB,10000
            1644,LN 2,EM 2,01-JAN-2010,NON_JOB,20000
            1645,LN 3U,EM 3,01-JAN-2010,IT_PROG,30000

        }
        =

        GROUP Batch Job Table {
        =======================

            Name       Fail Percent
            ---------  ------------
            LOAD_EMPS            70

        }
        =

        GROUP Statistics Table {
        ========================

            Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                          20  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S

        }
        =

        GROUP Employees Table {
        =======================

            Employee Id  Name  Email  Hired        Job      Salary  Manager Id  Department Id  Updated
            -----------  ----  -----  -----------  -------  ------  ----------  -------------  -----------
                   1644  LN 2  EM 2   01-JAN-2010  IT_PROG   20000                             01-JAN-2010
                   1645  LN 3  EM 3   01-JAN-2010  IT_PROG   30000                             01-JAN-2010

        }
        =

    OUTPUTS
    =======

        GROUP Employee: Actual = 2, Expected = 2 {
        ==========================================

            F?  Employee Id  Name   Email  Hired        Job      Salary  Updated
            --  -----------  -----  -----  -----------  -------  ------  -----------
                       1644  LN 2   EM 2   01-JAN-2010  IT_PROG  20000   01-JAN-2010
                       1645  LN 3U  EM 3   01-JAN-2010  IT_PROG  30000   11-SEP-2016

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Error: Actual = 2, Expected = 2 {
        =======================================

            F?  Job Statistic Id  ORA_ERR_TAG$  ORA_ERR_MESG$                                                                    ORA_ERR_OPTYP$  Employee Id  Name  Email  Hired        Job      Salary
            --  ----------------  ------------  -------------------------------------------------------------------------------  --------------  -----------  ----  -----  -----------  -------  ------
                              21                ORA-02291: integrity constraint (HR.EMP_JOB_FK) violated - parent key not found  U                      1644  LN 2  EM 2   01-JAN-2010  NON_JOB  20000
                              21                ORA-02291: integrity constraint (HR.EMP_JOB_FK) violated - parent key not found  I                      1646  LN 1  EM 1   01-JAN-2010  NON_JOB  10000

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Job Statistic: Actual = 2, Expected = 2 {
        ===============================================

            F?  Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            --  ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                              20  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S
                              21  LOAD_EMPS     employees_20160801.dat               1                  0                  2  11-SEP-2016  11-SEP-2016  S

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Exception: Actual = 0, Expected = 0: SUCCESS
        ==================================================

} 0 failed, of 7: SUCCESS
=========================

SCENARIO 8: NV/OV/OU/NI/OI/EI: 0/1/0/0/0/1. Existing J/E: 1/2. Name 4001ch [1 valid old, 1 invalid new for external table - no exception; also file had previously failed] {
============================================================================================================================================================================

    INPUTS
    ======

        GROUP Parameter {
        =================

            File Name               Count
            ----------------------  -----
            employees_20160801.dat      2

        }
        =

        GROUP File {
        ============

            Line
            --------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
            ,123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567
            1649,LN 3U,EM 3,01-JAN-2010,IT_PROG,30000

        }
        =

        GROUP Batch Job Table {
        =======================

            Name       Fail Percent
            ---------  ------------
            LOAD_EMPS            70

        }
        =

        GROUP Statistics Table {
        ========================

            Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                          23  LOAD_EMPS     employees_20160801.dat               0                  0                  2  01-JAN-2010  01-JAN-2010  F

        }
        =

        GROUP Employees Table {
        =======================

            Employee Id  Name  Email  Hired        Job      Salary  Manager Id  Department Id  Updated
            -----------  ----  -----  -----------  -------  ------  ----------  -------------  -----------
                   1648  LN 2  EM 2   01-JAN-2010  IT_PROG   20000                             01-JAN-2010
                   1649  LN 3  EM 3   01-JAN-2010  IT_PROG   30000                             01-JAN-2010

        }
        =

    OUTPUTS
    =======

        GROUP Employee: Actual = 2, Expected = 2 {
        ==========================================

            F?  Employee Id  Name   Email  Hired        Job      Salary  Updated
            --  -----------  -----  -----  -----------  -------  ------  -----------
                       1648  LN 2   EM 2   01-JAN-2010  IT_PROG  20000   01-JAN-2010
                       1649  LN 3U  EM 3   01-JAN-2010  IT_PROG  30000   11-SEP-2016

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Error: Actual = 0, Expected = 0: SUCCESS
        ==============================================

        GROUP Job Statistic: Actual = 2, Expected = 2 {
        ===============================================

            F?  Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            --  ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                              23  LOAD_EMPS     employees_20160801.dat               0                  0                  2  01-JAN-2010  01-JAN-2010  F
                              24  LOAD_EMPS     employees_20160801.dat               1                  1                  0  11-SEP-2016  11-SEP-2016  S

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Exception: Actual = 0, Expected = 0: SUCCESS
        ==================================================

} 0 failed, of 6: SUCCESS
=========================

SCENARIO 9: NV/OV/OU/NI/OI/EI: 0/0/0/1/0/0. Existing J/E: 1/1. [File already processed - exception] {
=====================================================================================================

    INPUTS
    ======

        GROUP Parameter {
        =================

            File Name               Count
            ----------------------  -----
            employees_20160801.dat      1

        }
        =

        GROUP File {
        ============

            Line
            ------------------------------------
            ,LN 1,EM 1,01-JAN-2010,NON_JOB,10000

        }
        =

        GROUP Batch Job Table {
        =======================

            Name       Fail Percent
            ---------  ------------
            LOAD_EMPS            70

        }
        =

        GROUP Statistics Table {
        ========================

            Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                          26  LOAD_EMPS     employees_20160801.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S

        }
        =

        GROUP Employees Table {
        =======================

            Employee Id  Name  Email  Hired        Job      Salary  Manager Id  Department Id  Updated
            -----------  ----  -----  -----------  -------  ------  ----------  -------------  -----------
                   1651  LN 2  EM 2   01-JAN-2010  IT_PROG   20000                             01-JAN-2010

        }
        =

    OUTPUTS
    =======

        GROUP Employee: Actual = 1, Expected = 1 {
        ==========================================

            F?  Employee Id  Name  Email  Hired        Job      Salary  Updated
            --  -----------  ----  -----  -----------  -------  ------  -----------
                       1651  LN 2  EM 2   01-JAN-2010  IT_PROG  20000   01-JAN-2010

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Error: Actual = 0, Expected = 0: SUCCESS
        ==============================================

        GROUP Job Statistic: Actual = 1, Expected = 1 {
        ===============================================

            F?  Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            --  ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                              26  LOAD_EMPS     employees_20160801.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Exception: Actual = 1, Expected = 1 {
        ===========================================

            F?  Message
            --  --------------------------------------------------------
                ORA-20002: File has already been processed successfully!

        } 0 failed, of 1: SUCCESS
        =========================

} 0 failed, of 4: SUCCESS
=========================

TIMING: Actual = 306, Expected <= 2: FAILURE
============================================

SUMMARY for TT_Emp_Batch.tt_AIP_Load_Emps
=========================================

Scenario                                                                                                                                                        # Failed  # Tests  Status
--------------------------------------------------------------------------------------------------------------------------------------------------------------  --------  -------  -------
NV/OV/OU/NI/OI/EI: 1/0/0/0/0/0. Existing J/E: 0/0. [1 valid new record from scratch]                                                                                   0        4  SUCCESS
NV/OV/OU/NI/OI/EI: 1/1/1/0/0/0. Existing J/E: 1/0. [3 valid records of each kind]                                                                                      0        7  SUCCESS
NV/OV/OU/NI/OI/EI: 0/0/0/0/1/0. Existing J/E: 1/1. Uid not found [1 invalid old - exception]                                                                           0        5  SUCCESS
NV/OV/OU/NI/OI/EI: 0/0/0/1/0/0. Existing J/E: 1/1. Email too long [1 invalid new - exception]                                                                          0        5  SUCCESS
NV/OV/OU/NI/OI/EI: 1/0/0/0/1/0. Existing J/E: 1/1. Name too long [1 valid new, 1 invalid old - no exception]                                                           0        6  SUCCESS
NV/OV/OU/NI/OI/EI: 0/0/0/1/0/0. Existing J/E: 1/1. Invalid job [1 invalid new - exception]                                                                             0        5  SUCCESS
NV/OV/OU/NI/OI/EI: 0/1/0/1/1/0. Existing J/E: 1/2. 2 invalid jobs [1 valid old, 2 invalid: old and new - no exception]                                                 0        7  SUCCESS
NV/OV/OU/NI/OI/EI: 0/1/0/0/0/1. Existing J/E: 1/2. Name 4001ch [1 valid old, 1 invalid new for external table - no exception; also file had previously failed]         0        6  SUCCESS
NV/OV/OU/NI/OI/EI: 0/0/0/1/0/0. Existing J/E: 1/1. [File already processed - exception]                                                                                0        4  SUCCESS
Timing                                                                                                                                                                 1        1  FAILURE
--------------------------------------------------------------------------------------------------------------------------------------------------------------  --------  -------  -------
Total                                                                                                                                                                  1       50  FAILURE
--------------------------------------------------------------------------------------------------------------------------------------------------------------  --------  -------  -------

Timer Set: TT_Emp_Batch.tt_AIP_Load_Emps, Constructed at 11 Sep 2016 16:10:46, written at 16:10:49
==================================================================================================
[Timer timed: Elapsed (per call): 0.04 (0.000036), CPU (per call): 0.03 (0.000030), calls: 1000, '***' denotes corrected line below]

Timer           Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------  ----------  ----------  ------------  -------------  -------------
Setup              1.10        0.30             9        0.12189        0.03333
Caller             1.53        1.16             5        0.30560        0.23200
Get_Tab_Lis        0.75        0.49             9        0.08378        0.05444
Get_Err_Lis        0.02        0.03             9        0.00244        0.00333
Get_Jbs_Lis        0.00        0.00             9        0.00011        0.00000
(Other)            0.34        0.35             1        0.33500        0.35000
-----------  ----------  ----------  ------------  -------------  -------------
Total              3.74        2.33            42        0.08898        0.05548
-----------  ----------  ----------  ------------  -------------  -------------

Suite Summary
=============

Package.Procedure                  Tests  Fails         ELA         CPU
---------------------------------  -----  -----  ----------  ----------
TT_Emp_WS.tt_AIP_Save_Emps            17      3        0.10        0.09
TT_Emp_WS.tt_AIP_Get_Dept_Emps         7      1        0.11        0.12
TT_View_Drivers.tt_HR_Test_View_V      9      0        0.12        0.12
TT_Emp_Batch.tt_AIP_Load_Emps         50      1        3.74        2.33
---------------------------------  -----  -----  ----------  ----------
Total                                 83      5        4.07        2.66
---------------------------------  -----  -----  ----------  ----------
Others error in (): ORA-20001: Suite BRENDAN returned error status: ORA-06512: at "DP_1.UTILS_TT", line 151
ORA-06512: at "DP_1.UTILS_TT", line 818
ORA-06512: at line 5

The fourth and final article in this series is here: Design Patterns for Database API Testing 4: REF Cursor Getter.






 

A Utility for Reading REF Cursors into a List of Delimited Strings

This is a generic utility function that I wrote for use in unit testing web services that return REF cursors. It takes as input an open REF cursor and an optional filter string and returns the output as an array of delimited strings matching the filter. This can then be used to assert against expected output records.

The initial technical difficulty I had with making this generic was in getting the structure of the cursor. This is resolved by translating the REF cursor into a cursor that can be managed by the package DBMS_SQL, using DBMS_SQL.To_Cursor_Number.

As I am using it for unit testing the function does not need to be scalable. For other uses involving large volumes it could be made scalable by, for example, converting to a pipelined function.

Data Types

The cursor needs to return a flat projection, and columns accounted for currently are:

  • NUMBER
  • VARCHAR2
  • DATE
  • TIMESTAMP

Custom Dependencies

  • L1_chr_arr - custom array type, equivalent to SYS.ODCIVarchar2List
  • Utils.List_Delim - function that turns an array of strings into one delimited string, included in my unit test framework, Brendan's Database Unit Testing Framework

Code

The function wiil (shortly) be packaged within my unit testing package UT_Utils, but for demo purposes, here is a script that has a driving anonymous block with the function declared locally within that block.

DECLARE
  l_csr         SYS_REFCURSOR;
  l_res_lis     L1_chr_arr;
  c_query_1     CONSTANT VARCHAR2(4000) := 'SELECT * FROM employees ORDER BY employee_id';
 
  PROCEDURE Write_Log (p_line VARCHAR2) IS
  BEGIN
    DBMS_Output.Put_Line (p_line);
  END Write_Log;
 
FUNCTION Cursor_to_Array (p_csr IN OUT SYS_REFCURSOR, p_filter VARCHAR2 DEFAULT NULL) RETURN L1_chr_arr IS
 
  c_chr_type    CONSTANT PLS_INTEGER := 1; --DBMS_Types.TYPECODE_* do not seem to quite work
  c_num_type    CONSTANT PLS_INTEGER := 2;
  c_dat_type    CONSTANT PLS_INTEGER := 12;
  c_stp_type    CONSTANT PLS_INTEGER := 180;
  l_csr_id      PLS_INTEGER;
  l_n_cols      PLS_INTEGER;
  l_desctab     DBMS_SQL.DESC_TAB;
  l_chr_val     VARCHAR2(4000);
  l_num_val     NUMBER;
  l_dat_val     DATE;
  l_stp_val     TIMESTAMP;
  l_val_lis     L1_chr_arr;
  l_res_lis     L1_chr_arr := L1_chr_arr();
  l_rec         VARCHAR2(4000);
 
BEGIN
 
  l_csr_id := DBMS_SQL.To_Cursor_Number (p_csr);
  DBMS_SQL.Describe_Columns (l_csr_id, l_n_cols, l_desctab);
 
  FOR i IN 1..l_n_cols LOOP
 
    CASE l_desctab(i).col_type
 
      WHEN c_chr_type THEN
        DBMS_SQL.Define_Column (l_csr_id, i, l_chr_val, 4000);
      WHEN c_num_type THEN
        DBMS_SQL.Define_Column (l_csr_id, i, l_num_val);
      WHEN c_dat_type THEN
        DBMS_SQL.Define_Column (l_csr_id, i, l_dat_val);
      WHEN c_stp_type THEN
         DBMS_SQL.Define_Column (l_csr_id, i, l_stp_val);
     ELSE
        Write_Log ('Col type ' || l_desctab(i).col_type || ' not accounted for!');
 
    END CASE;
 
  END LOOP;
 
  WHILE DBMS_SQL.Fetch_Rows (l_csr_id) > 0 LOOP
 
    l_val_lis := L1_chr_arr();
    l_val_lis.EXTEND (l_n_cols);
    FOR i IN 1 .. l_n_cols LOOP
 
      CASE l_desctab(i).col_type
 
        WHEN c_chr_type THEN
          DBMS_SQL.Column_Value (l_csr_id, i, l_chr_val);
          l_val_lis(i) := l_chr_val;
        WHEN c_num_type THEN
          DBMS_SQL.Column_Value (l_csr_id, i, l_num_val);
          l_val_lis(i) := l_num_val;
        WHEN c_dat_type THEN
          DBMS_SQL.Column_Value (l_csr_id, i, l_dat_val);
          l_val_lis(i) := l_dat_val;
        WHEN c_stp_type THEN
          DBMS_SQL.Column_Value (l_csr_id, i, l_stp_val);
          l_val_lis(i) := l_stp_val;
 
      END CASE;
 
    END LOOP;
 
    l_rec := Utils.List_Delim (l_val_lis);
    IF l_rec LIKE '%' || p_filter || '%' THEN
      l_res_lis.EXTEND;
      l_res_lis (l_res_lis.COUNT) := l_rec;
    END IF;
 
  END LOOP;
 
  DBMS_SQL.Close_Cursor (l_csr_id);
  RETURN l_res_lis;
 
END Cursor_to_Array;
 
BEGIN
 
  OPEN l_csr FOR c_query_1;
 
  l_res_lis := Cursor_to_Array (l_csr, 'SA_REP');
 
  FOR i IN 1..l_res_lis.COUNT LOOP
    Write_Log (i || ': ' || l_res_lis(i));
  END LOOP;
 
END;
/

 
Output for Cursor against HR.employees

1: 150|Peter|Tucker|PTUCKER|011.44.1344.129268|30-JAN-05|SA_REP|10000|.3|145|80|
2: 151|David|Bernstein|DBERNSTE|011.44.1344.345268|24-MAR-05|SA_REP|9500|.25|145|80|
3: 152|Peter|Hall|PHALL|011.44.1344.478968|20-AUG-05|SA_REP|9000|.25|145|80|
4: 153|Christopher|Olsen|COLSEN|011.44.1344.498718|30-MAR-06|SA_REP|8000|.2|145|80|
5: 154|Nanette|Cambrault|NCAMBRAU|011.44.1344.987668|09-DEC-06|SA_REP|7500|.2|145|80|
6: 155|Oliver|Tuvault|OTUVAULT|011.44.1344.486508|23-NOV-07|SA_REP|7000|.15|145|80|
7: 156|Janette|King|JKING|011.44.1345.429268|30-JAN-04|SA_REP|10000|.35|146|80|
8: 157|Patrick|Sully|PSULLY|011.44.1345.929268|04-MAR-04|SA_REP|9500|.35|146|80|
9: 158|Allan|McEwen|AMCEWEN|011.44.1345.829268|01-AUG-04|SA_REP|9000|.35|146|80|
10: 159|Lindsey|Smith|LSMITH|011.44.1345.729268|10-MAR-05|SA_REP|8000|.3|146|80|
11: 160|Louise|Doran|LDORAN|011.44.1345.629268|15-DEC-05|SA_REP|7500|.3|146|80|
12: 161|Sarath|Sewall|SSEWALL|011.44.1345.529268|03-NOV-06|SA_REP|7000|.25|146|80|
13: 162|Clara|Vishney|CVISHNEY|011.44.1346.129268|11-NOV-05|SA_REP|10500|.25|147|80|
14: 163|Danielle|Greene|DGREENE|011.44.1346.229268|19-MAR-07|SA_REP|9500|.15|147|80|
15: 164|Mattea|Marvins|MMARVINS|011.44.1346.329268|24-JAN-08|SA_REP|7200|.1|147|80|
16: 165|David|Lee|DLEE|011.44.1346.529268|23-FEB-08|SA_REP|6800|.1|147|80|
17: 166|Sundar|Ande|SANDE|011.44.1346.629268|24-MAR-08|SA_REP|6400|.1|147|80|
18: 167|Amit|Banda|ABANDA|011.44.1346.729268|21-APR-08|SA_REP|6200|.1|147|80|
19: 168|Lisa|Ozer|LOZER|011.44.1343.929268|11-MAR-05|SA_REP|11500|.25|148|80|
20: 169|Harrison|Bloom|HBLOOM|011.44.1343.829268|23-MAR-06|SA_REP|10000|.2|148|80|
21: 170|Tayler|Fox|TFOX|011.44.1343.729268|24-JAN-06|SA_REP|9600|.2|148|80|
22: 171|William|Smith|WSMITH|011.44.1343.629268|23-FEB-07|SA_REP|7400|.15|148|80|
23: 172|Elizabeth|Bates|EBATES|011.44.1343.529268|24-MAR-07|SA_REP|7300|.15|148|80|
24: 173|Sundita|Kumar|SKUMAR|011.44.1343.329268|21-APR-08|SA_REP|6100|.1|148|80|
25: 174|Ellen|Abel|EABEL|011.44.1644.429267|11-MAY-04|SA_REP|11000|.3|149|80|
26: 175|Alyssa|Hutton|AHUTTON|011.44.1644.429266|19-MAR-05|SA_REP|8800|.25|149|80|
27: 176|Jonathon|Taylor|JTAYLOR|011.44.1644.429265|24-MAR-06|SA_REP|8600|.2|149|80|
28: 177|Jack|Livingston|JLIVINGS|011.44.1644.429264|23-APR-06|SA_REP|8400|.2|149|80|
29: 178|Kimberely|Grant|KGRANT|011.44.1644.429263|24-MAY-07|SA_REP|7000|.15|149||
30: 179|Charles|Johnson|CJOHNSON|011.44.1644.429262|04-JAN-08|SA_REP|6200|.1|149|80|
 
PL/SQL procedure successfully completed.






 

A Note on Dependencies and Database Unit Testing

Ideas on unit testing for the database are often heavily influenced by the world of object oriented programming (OOP), usually Java in practice. This is no doubt because much of modern thinking on development methodologies, including test driven development (TDD), originated in this world. Some of these ideas appear to translate very well into the database world, including that of TDD itself, with automated unit tests. However, some ideas may not translate so well, or even make sense, in database unit testing. For example, Roy Osherove (2011), Unit Test - Definition says:

A good unit test ... runs in memory (no DB or File access, for example)

One concept that appears very important in the OOP world is that of dependencies, and of isolation of the code under test from its dependencies. This gives rise to complex mechanisms of 'mocking' and 'dependency injection' to bring about said isolation. Osherove mentions isolation in the same article as a requirement of good unit testing, and his view appears to be widespread. It's worth mentioning though that not everyone in the OOP world shares his insistence. The influential Martin Fowler (2014) uses a nice terminology of 'sociable' tests (as opposed to 'isolated' tests) for tests that rely on other units to fulfill the behaviour under test, and he uses this approach himself when practicable, UnitTest.

In the case of database unit testing, it seems to me to make very little sense to think in terms of isolating code under test from its dependencies. The following two diagrams represent how I see the relationships between base code, dependencies and unit test code across two distinct phases.

Development Phase
UT Phases-dev

Regression Phase
UT Phases-reg

I would welcome any comments or opinions.






 

TRAPIT - TRansactional API Testing in Oracle

I recently wrote a number of articles on design patterns for database API testing, with code included for testing example procedures against Oracle's HR demo schema. There are now four examples, intended together to represent the whole range of database API testing requirements, as follows:

ModeSetterGetter
Real TimeWeb Service SavingWeb Service Getting by REF Cursor
BatchBatch Loading of Flat FilesViews

The testing code used my own framework utility packages, and originally called procedures from the well-known utPLSQL framework. However, the use of utPLSQL was always minimal, and I later removed it to form my own lightweight independent framework that is designed to help avoid many API testing anti-patterns, and provide better output formatting than utPLSQL.

The framework is based on the idea that all API testing programs can follow a universal design pattern for testing APIs, using the concept of a ‘pure’ function as a wrapper to manage the ‘impurity’ inherent in database APIs. I explained the concepts involved in a presentation at the Oracle User Group Ireland Conference in March 2018:

The Database API Viewed As A Mathematical Function: Insights into Testing

The framework lists all inputs and outputs at scenario level (see box below), meaning that the API test logs become precise and accurate documents of what the program does. All the output is printed by a central library procedure so that work by individual test programs is minimised.

The code is available on GitHub here, and includes both framework and design pattern examples: BrenPatF/trapit_oracle_tester

See also the following articles describing the four design patterns. The log from my demo suite is included below for the first example to illustrate the general format of the log.

Design Patterns for Database API Testing 1: Web Service Saving 1 - Design
Design Patterns for Database API Testing 1: Web Service Saving 2 - Code
Design Patterns for Database API Testing 2: Views 1 - Design
Design Patterns for Database API Testing 2: Views 2 - Code
Design Patterns for Database API Testing 3: Batch Loading of Flat Files
Design Patterns for Database API Testing 4: REF Cursor Getter

SQL> DECLARE
  2  BEGIN
  3  
  4    Utils.Clear_Log;
  5    Utils_TT.Run_Suite (Utils_TT.c_tt_suite_bren);
  6  
  7  EXCEPTION
  8    WHEN OTHERS THEN
  9      Utils.Write_Other_Error;
 10  END;
 11  /

PL/SQL procedure successfully completed.

SQL> @L_Log_Default

TEXT
----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------

TRAPIT TEST: TT_Emp_WS.tt_AIP_Save_Emps
=======================================

SCENARIO 1: 1 valid record {
============================

    INPUTS
    ======

        GROUP Employee {
        ================

            Name  Email  Job      Salary
            ----  -----  -------  ------
            LN 1  EM 1   IT_PROG    1000

        }
        =

    OUTPUTS
    =======

        GROUP Employee: Actual = 1, Expected = 1 {
        ==========================================

            F?  Employee id  Name  Email  Job      Salary
            --  -----------  ----  -----  -------  ------
                       1927  LN 1  EM 1   IT_PROG    1000

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Output array: Actual = 1, Expected = 1 {
        ==============================================

            F?  Employee id  Description
            --  -----------  --------------------------------------
                       1927  ONE THOUSAND NINE HUNDRED TWENTY-SEVEN

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Exception: Actual = 0, Expected = 0: SUCCESS
        ==================================================

} 0 failed, of 3: SUCCESS
=========================

SCENARIO 2: 1 invalid job id {
==============================

    INPUTS
    ======

        GROUP Employee {
        ================

            Name  Email  Job      Salary
            ----  -----  -------  ------
            LN 2  EM 2   NON_JOB    1500

        }
        =

    OUTPUTS
    =======

        GROUP Employee: Actual = 0, Expected = 0: SUCCESS
        =================================================

        GROUP Output array: Actual = 1, Expected = 1 {
        ==============================================

            F?  Employee id  Description
            --  -----------  -------------------------------------------------------------------
                          0  ORA-02291: integrity constraint (.) violated - parent key not found

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Exception: Actual = 0, Expected = 0: SUCCESS
        ==================================================

} 0 failed, of 3: SUCCESS
=========================

SCENARIO 3: 1 invalid number {
==============================

    INPUTS
    ======

        GROUP Employee {
        ================

            Name  Email  Job      Salary
            ----  -----  -------  ------
            LN 3  EM 3   IT_PROG   2000x

        }
        =

    OUTPUTS
    =======

        GROUP Employee: Actual = 0, Expected = 0: SUCCESS
        =================================================

        GROUP Output array: Actual = 0, Expected = 0: SUCCESS
        =====================================================

        GROUP Exception: Actual = 1, Expected = 1 {
        ===========================================

            F?  Error message
            --  -------------------------------------------------------------------------------
                ORA-06502: PL/SQL: numeric or value error: character to number conversion error

        } 0 failed, of 1: SUCCESS
        =========================

} 0 failed, of 3: SUCCESS
=========================

SCENARIO 4: 2 valid records, 1 invalid job id (2 deliberate errors) {
=====================================================================

    INPUTS
    ======

        GROUP Employee {
        ================

            Name  Email  Job      Salary
            ----  -----  -------  ------
            LN 4  EM 4   IT_PROG    3000
            LN 5  EM 5   NON_JOB    4000
            LN 6  EM 6   IT_PROG    5000

        }
        =

    OUTPUTS
    =======

        GROUP Employee: Actual = 2, Expected = 3 {
        ==========================================

            F?  Employee id  Name  Email  Job      Salary
            --  -----------  ----  -----  -------  ------
            F          1929  LN 4  EM 4   IT_PROG    3000
            >          1929  LN 4  EM 4   IT_PROG    1000
                       1931  LN 6  EM 6   IT_PROG    5000
            F
            >          1931  LN 6  EM 6   IT_PROG    5000

        } 2 failed, of 3: FAILURE
        =========================

        GROUP Output array: Actual = 3, Expected = 3 {
        ==============================================

            F?  Employee id  Description
            --  -----------  -------------------------------------------------------------------
                       1929  ONE THOUSAND NINE HUNDRED TWENTY-NINE
                          0  ORA-02291: integrity constraint (.) violated - parent key not found
                       1931  ONE THOUSAND NINE HUNDRED THIRTY-ONE

        } 0 failed, of 3: SUCCESS
        =========================

        GROUP Exception: Actual = 0, Expected = 0: SUCCESS
        ==================================================

} 2 failed, of 7: FAILURE
=========================

TIMING: Actual = 1, Expected <= 2: SUCCESS
==========================================

SUMMARY for TT_Emp_WS.tt_AIP_Save_Emps
======================================

Scenario                                                 # Failed  # Tests  Status
-------------------------------------------------------  --------  -------  -------
1 valid record                                                  0        3  SUCCESS
1 invalid job id                                                0        3  SUCCESS
1 invalid number                                                0        3  SUCCESS
2 valid records, 1 invalid job id (2 deliberate errors)         2        7  FAILURE
Timing                                                          0        1  SUCCESS
-------------------------------------------------------  --------  -------  -------
Total                                                           2       17  FAILURE
-------------------------------------------------------  --------  -------  -------

Timer Set: TT_Emp_WS.tt_AIP_Save_Emps, Constructed at 22 Oct 2016 15:05:16, written at 15:05:16
===============================================================================================
[Timer timed: Elapsed (per call): 0.03 (0.000034), CPU (per call): 0.05 (0.000050), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Setup          0.00        0.00             1        0.00300        0.00000
Caller         0.00        0.02             3        0.00133        0.00667
SELECT         0.00        0.00             3        0.00033        0.00000
(Other)        0.08        0.06             1        0.07700        0.06000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.09        0.08             8        0.01063        0.01000
-------  ----------  ----------  ------------  -------------  -------------

TRAPIT TEST: TT_Emp_WS.tt_AIP_Get_Dept_Emps
===========================================

Employees created in setup: DS-1 - 4 emps, 1 dep (10), emp-3 has no dep, emp-4 has bad job
==========================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1932             10              IT_PROG           1000
2         1933             10        1932  IT_PROG           2000
3         1934                       1932  IT_PROG           3000
4         1935             10        1932  AD_ASST           4000

Employees created in setup: DS-2 - As dataset 1 but with extra emp-5, in second dep (20)
========================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1936             10              IT_PROG           1000
2         1937             10        1936  IT_PROG           2000
3         1938                       1936  IT_PROG           3000
4         1939             10        1936  AD_ASST           4000
5         1940             20        1936  IT_PROG           5000

Employees created in setup: DS-2 - As dataset 1 but with extra emp-5, in second dep (20)
========================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1941             10              IT_PROG           1000
2         1942             10        1941  IT_PROG           2000
3         1943                       1941  IT_PROG           3000
4         1944             10        1941  AD_ASST           4000
5         1945             20        1941  IT_PROG           5000

Employees created in setup: DS-2 - As dataset 1 but with extra emp-5, in second dep (20)
========================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1946             10              IT_PROG           1000
2         1947             10        1946  IT_PROG           2000
3         1948                       1946  IT_PROG           3000
4         1949             10        1946  AD_ASST           4000
5         1950             20        1946  IT_PROG           5000

Employees created in setup: DS-3 - As dataset 2 but with salaries * 0.1, total below reporting threshold of 1600
================================================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1951             10              IT_PROG            100
2         1952             10        1951  IT_PROG            200
3         1953                       1951  IT_PROG            300
4         1954             10        1951  AD_ASST            400
5         1955             20        1951  IT_PROG            500

SCENARIO 1: DS-1, testing inner, outer joins, analytic over dep, and global ratios with 1 dep (10) - pass dep 10 {
==================================================================================================================

    INPUTS
    ======

        GROUP Employee {
        ================

            Employee Id  Last Name  Email  Hire Date    Job      Salary  Manager Id  Department Id  Updated
            -----------  ---------  -----  -----------  -------  ------  ----------  -------------  -----------
                   1932  LN_1       EM_1   22-OCT-2016  IT_PROG    1000                         10  22-OCT-2016
                   1933  LN_2       EM_2   22-OCT-2016  IT_PROG    2000        1932             10  22-OCT-2016
                   1934  LN_3       EM_3   22-OCT-2016  IT_PROG    3000        1932                 22-OCT-2016
                   1935  LN_4       EM_4   22-OCT-2016  AD_ASST    4000        1932             10  22-OCT-2016

        }
        =

        GROUP Department Parameter {
        ============================

            Department Id
            -------------
                       10

        }
        =

    OUTPUTS
    =======

        GROUP Select results: Actual = 2, Expected = 2 {
        ================================================

            F?  Name  Department      Manager  Salary  Salary Ratio (dep)  Salary Ratio (overall)
            --  ----  --------------  -------  ------  ------------------  ----------------------
                LN_1  Administration             1000                 .67                      .4
                LN_2  Administration  LN_1       2000                1.33                      .8

        } 0 failed, of 2: SUCCESS
        =========================

} 0 failed, of 2: SUCCESS
=========================

SCENARIO 2: DS-2, testing same as 1 but with extra emp in another dep (20) - pass dep 10 {
==========================================================================================

    INPUTS
    ======

        GROUP Employee {
        ================

            Employee Id  Last Name  Email  Hire Date    Job      Salary  Manager Id  Department Id  Updated
            -----------  ---------  -----  -----------  -------  ------  ----------  -------------  -----------
                   1936  LN_1       EM_1   22-OCT-2016  IT_PROG    1000                         10  22-OCT-2016
                   1937  LN_2       EM_2   22-OCT-2016  IT_PROG    2000        1936             10  22-OCT-2016
                   1938  LN_3       EM_3   22-OCT-2016  IT_PROG    3000        1936                 22-OCT-2016
                   1939  LN_4       EM_4   22-OCT-2016  AD_ASST    4000        1936             10  22-OCT-2016
                   1940  LN_5       EM_5   22-OCT-2016  IT_PROG    5000        1936             20  22-OCT-2016

        }
        =

        GROUP Department Parameter {
        ============================

            Department Id
            -------------
                       10

        }
        =

    OUTPUTS
    =======

        GROUP Select results: Actual = 2, Expected = 2 {
        ================================================

            F?  Name  Department      Manager  Salary  Salary Ratio (dep)  Salary Ratio (overall)
            --  ----  --------------  -------  ------  ------------------  ----------------------
                LN_1  Administration             1000                 .67                     .33
                LN_2  Administration  LN_1       2000                1.33                     .67

        } 0 failed, of 2: SUCCESS
        =========================

} 0 failed, of 2: SUCCESS
=========================

SCENARIO 3: DS-2, as second scenario, but - pass dep 20 {
=========================================================

    INPUTS
    ======

        GROUP Employee {
        ================

            Employee Id  Last Name  Email  Hire Date    Job      Salary  Manager Id  Department Id  Updated
            -----------  ---------  -----  -----------  -------  ------  ----------  -------------  -----------
                   1941  LN_1       EM_1   22-OCT-2016  IT_PROG    1000                         10  22-OCT-2016
                   1942  LN_2       EM_2   22-OCT-2016  IT_PROG    2000        1941             10  22-OCT-2016
                   1943  LN_3       EM_3   22-OCT-2016  IT_PROG    3000        1941                 22-OCT-2016
                   1944  LN_4       EM_4   22-OCT-2016  AD_ASST    4000        1941             10  22-OCT-2016
                   1945  LN_5       EM_5   22-OCT-2016  IT_PROG    5000        1941             20  22-OCT-2016

        }
        =

        GROUP Department Parameter {
        ============================

            Department Id
            -------------
                       20

        }
        =

    OUTPUTS
    =======

        GROUP Select results: Actual = 1, Expected = 1 {
        ================================================

            F?  Name  Department  Manager  Salary  Salary Ratio (dep)  Salary Ratio (overall)
            --  ----  ----------  -------  ------  ------------------  ----------------------
                LN_5  Marketing   LN_1       5000                   1                    1.67

        } 0 failed, of 1: SUCCESS
        =========================

} 0 failed, of 1: SUCCESS
=========================

SCENARIO 4: DS-2, as second scenario, but - pass null dep {
===========================================================

    INPUTS
    ======

        GROUP Employee {
        ================

            Employee Id  Last Name  Email  Hire Date    Job      Salary  Manager Id  Department Id  Updated
            -----------  ---------  -----  -----------  -------  ------  ----------  -------------  -----------
                   1946  LN_1       EM_1   22-OCT-2016  IT_PROG    1000                         10  22-OCT-2016
                   1947  LN_2       EM_2   22-OCT-2016  IT_PROG    2000        1946             10  22-OCT-2016
                   1948  LN_3       EM_3   22-OCT-2016  IT_PROG    3000        1946                 22-OCT-2016
                   1949  LN_4       EM_4   22-OCT-2016  AD_ASST    4000        1946             10  22-OCT-2016
                   1950  LN_5       EM_5   22-OCT-2016  IT_PROG    5000        1946             20  22-OCT-2016

        }
        =

        GROUP Department Parameter {
        ============================

            Department Id
            -------------


        }
        =

    OUTPUTS
    =======

        GROUP Select results: Actual = 0, Expected = 0: SUCCESS
        =======================================================

} 0 failed, of 1: SUCCESS
=========================

SCENARIO 5: DS-3, Salaries total 1500 (< threshold of 1600, so return nothing) - pass dep 10 {
==============================================================================================

    INPUTS
    ======

        GROUP Employee {
        ================

            Employee Id  Last Name  Email  Hire Date    Job      Salary  Manager Id  Department Id  Updated
            -----------  ---------  -----  -----------  -------  ------  ----------  -------------  -----------
                   1951  LN_1       EM_1   22-OCT-2016  IT_PROG     100                         10  22-OCT-2016
                   1952  LN_2       EM_2   22-OCT-2016  IT_PROG     200        1951             10  22-OCT-2016
                   1953  LN_3       EM_3   22-OCT-2016  IT_PROG     300        1951                 22-OCT-2016
                   1954  LN_4       EM_4   22-OCT-2016  AD_ASST     400        1951             10  22-OCT-2016
                   1955  LN_5       EM_5   22-OCT-2016  IT_PROG     500        1951             20  22-OCT-2016

        }
        =

        GROUP Department Parameter {
        ============================

            Department Id
            -------------
                       10

        }
        =

    OUTPUTS
    =======

        GROUP Select results: Actual = 0, Expected = 0: SUCCESS
        =======================================================

} 0 failed, of 1: SUCCESS
=========================

TIMING: Actual = 1, Expected <= 1: SUCCESS
==========================================

SUMMARY for TT_Emp_WS.tt_AIP_Get_Dept_Emps
==========================================

Scenario                                                                                              # Failed  # Tests  Status
----------------------------------------------------------------------------------------------------  --------  -------  -------
DS-1, testing inner, outer joins, analytic over dep, and global ratios with 1 dep (10) - pass dep 10         0        2  SUCCESS
DS-2, testing same as 1 but with extra emp in another dep (20) - pass dep 10                                 0        2  SUCCESS
DS-2, as second scenario, but - pass dep 20                                                                  0        1  SUCCESS
DS-2, as second scenario, but - pass null dep                                                                0        1  SUCCESS
DS-3, Salaries total 1500 (< threshold of 1600, so return nothing) - pass dep 10                             0        1  SUCCESS
Timing                                                                                                       0        1  SUCCESS
----------------------------------------------------------------------------------------------------  --------  -------  -------
Total                                                                                                        0        8  SUCCESS
----------------------------------------------------------------------------------------------------  --------  -------  -------

Timer Set: TT_Emp_WS.tt_AIP_Get_Dept_Emps, Constructed at 22 Oct 2016 15:05:16, written at 15:05:16
===================================================================================================
[Timer timed: Elapsed (per call): 0.04 (0.000035), CPU (per call): 0.03 (0.000030), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Setup          0.04        0.02             5        0.00840        0.00400
Caller         0.01        0.02             5        0.00140        0.00400
(Other)        0.09        0.10             1        0.09200        0.10000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.14        0.14            11        0.01282        0.01273
-------  ----------  ----------  ------------  -------------  -------------

TRAPIT TEST: TT_View_Drivers.tt_HR_Test_View_V
==============================================

Employees created in setup: DS-1 - 4 emps, 1 dep (10), emp-3 has no dep, emp-4 has bad job
==========================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1956             10              IT_PROG           1000
2         1957             10        1956  IT_PROG           2000
3         1958                       1956  IT_PROG           3000
4         1959             10        1956  AD_ASST           4000

Employees created in setup: DS-2 - As dataset 1 but with extra emp-5, in second dep (20)
========================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1960             10              IT_PROG           1000
2         1961             10        1960  IT_PROG           2000
3         1962                       1960  IT_PROG           3000
4         1963             10        1960  AD_ASST           4000
5         1964             20        1960  IT_PROG           5000

Employees created in setup: DS-2 - As dataset 1 but with extra emp-5, in second dep (20)
========================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1965             10              IT_PROG           1000
2         1966             10        1965  IT_PROG           2000
3         1967                       1965  IT_PROG           3000
4         1968             10        1965  AD_ASST           4000
5         1969             20        1965  IT_PROG           5000

Employees created in setup: DS-3 - As dataset 2 but with salaries * 0.1, total below reporting threshold of 1600
================================================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1970             10              IT_PROG            100
2         1971             10        1970  IT_PROG            200
3         1972                       1970  IT_PROG            300
4         1973             10        1970  AD_ASST            400
5         1974             20        1970  IT_PROG            500

SCENARIO 1: DS-1, testing inner, outer joins, analytic over dep, and global ratios with 1 dep {
===============================================================================================

    INPUTS
    ======

        GROUP Employee {
        ================

            Employee Id  Last Name  Email  Hire Date    Job      Salary  Manager Id  Department Id  Updated
            -----------  ---------  -----  -----------  -------  ------  ----------  -------------  -----------
                   1956  LN_1       EM_1   22-OCT-2016  IT_PROG    1000                         10  22-OCT-2016
                   1957  LN_2       EM_2   22-OCT-2016  IT_PROG    2000        1956             10  22-OCT-2016
                   1958  LN_3       EM_3   22-OCT-2016  IT_PROG    3000        1956                 22-OCT-2016
                   1959  LN_4       EM_4   22-OCT-2016  AD_ASST    4000        1956             10  22-OCT-2016

        }
        =

        GROUP Where {
        =============

            Where
            -----


        }
        =

    OUTPUTS
    =======

        GROUP Select results: Actual = 2, Expected = 2 {
        ================================================

            F?  Name  Department      Manager  Salary  Salary Ratio (dep)  Salary Ratio (overall)
            --  ----  --------------  -------  ------  ------------------  ----------------------
                LN_1  Administration             1000                 .67                      .4
                LN_2  Administration  LN_1       2000                1.33                      .8

        } 0 failed, of 2: SUCCESS
        =========================

} 0 failed, of 2: SUCCESS
=========================

SCENARIO 2: DS-2, testing same as 1 but with extra emp in another dep {
=======================================================================

    INPUTS
    ======

        GROUP Employee {
        ================

            Employee Id  Last Name  Email  Hire Date    Job      Salary  Manager Id  Department Id  Updated
            -----------  ---------  -----  -----------  -------  ------  ----------  -------------  -----------
                   1960  LN_1       EM_1   22-OCT-2016  IT_PROG    1000                         10  22-OCT-2016
                   1961  LN_2       EM_2   22-OCT-2016  IT_PROG    2000        1960             10  22-OCT-2016
                   1962  LN_3       EM_3   22-OCT-2016  IT_PROG    3000        1960                 22-OCT-2016
                   1963  LN_4       EM_4   22-OCT-2016  AD_ASST    4000        1960             10  22-OCT-2016
                   1964  LN_5       EM_5   22-OCT-2016  IT_PROG    5000        1960             20  22-OCT-2016

        }
        =

        GROUP Where {
        =============

            Where
            -----


        }
        =

    OUTPUTS
    =======

        GROUP Select results: Actual = 3, Expected = 3 {
        ================================================

            F?  Name  Department      Manager  Salary  Salary Ratio (dep)  Salary Ratio (overall)
            --  ----  --------------  -------  ------  ------------------  ----------------------
                LN_1  Administration             1000                 .67                     .33
                LN_2  Administration  LN_1       2000                1.33                     .67
                LN_5  Marketing       LN_1       5000                   1                    1.67

        } 0 failed, of 3: SUCCESS
        =========================

} 0 failed, of 3: SUCCESS
=========================

SCENARIO 3: DS-2, passing 'WHERE dep=10' {
==========================================

    INPUTS
    ======

        GROUP Employee {
        ================

            Employee Id  Last Name  Email  Hire Date    Job      Salary  Manager Id  Department Id  Updated
            -----------  ---------  -----  -----------  -------  ------  ----------  -------------  -----------
                   1965  LN_1       EM_1   22-OCT-2016  IT_PROG    1000                         10  22-OCT-2016
                   1966  LN_2       EM_2   22-OCT-2016  IT_PROG    2000        1965             10  22-OCT-2016
                   1967  LN_3       EM_3   22-OCT-2016  IT_PROG    3000        1965                 22-OCT-2016
                   1968  LN_4       EM_4   22-OCT-2016  AD_ASST    4000        1965             10  22-OCT-2016
                   1969  LN_5       EM_5   22-OCT-2016  IT_PROG    5000        1965             20  22-OCT-2016

        }
        =

        GROUP Where {
        =============

            Where
            --------------------------------
            department_name='Administration'

        }
        =

    OUTPUTS
    =======

        GROUP Select results: Actual = 2, Expected = 2 {
        ================================================

            F?  Name  Department      Manager  Salary  Salary Ratio (dep)  Salary Ratio (overall)
            --  ----  --------------  -------  ------  ------------------  ----------------------
                LN_1  Administration             1000                 .67                     .33
                LN_2  Administration  LN_1       2000                1.33                     .67

        } 0 failed, of 2: SUCCESS
        =========================

} 0 failed, of 2: SUCCESS
=========================

SCENARIO 4: DS-3, Salaries total 1500 (< threshold of 1600, so return nothing) {
================================================================================

    INPUTS
    ======

        GROUP Employee {
        ================

            Employee Id  Last Name  Email  Hire Date    Job      Salary  Manager Id  Department Id  Updated
            -----------  ---------  -----  -----------  -------  ------  ----------  -------------  -----------
                   1970  LN_1       EM_1   22-OCT-2016  IT_PROG     100                         10  22-OCT-2016
                   1971  LN_2       EM_2   22-OCT-2016  IT_PROG     200        1970             10  22-OCT-2016
                   1972  LN_3       EM_3   22-OCT-2016  IT_PROG     300        1970                 22-OCT-2016
                   1973  LN_4       EM_4   22-OCT-2016  AD_ASST     400        1970             10  22-OCT-2016
                   1974  LN_5       EM_5   22-OCT-2016  IT_PROG     500        1970             20  22-OCT-2016

        }
        =

        GROUP Where {
        =============

            Where
            -----


        }
        =

    OUTPUTS
    =======

        GROUP Select results: Actual = 0, Expected = 0: SUCCESS
        =======================================================

} 0 failed, of 1: SUCCESS
=========================

TIMING: Actual = 1, Expected <= 1: SUCCESS
==========================================

SUMMARY for TT_View_Drivers.tt_HR_Test_View_V
=============================================

Scenario                                                                           # Failed  # Tests  Status
---------------------------------------------------------------------------------  --------  -------  -------
DS-1, testing inner, outer joins, analytic over dep, and global ratios with 1 dep         0        2  SUCCESS
DS-2, testing same as 1 but with extra emp in another dep                                 0        3  SUCCESS
DS-2, passing 'WHERE dep=10'                                                              0        2  SUCCESS
DS-3, Salaries total 1500 (< threshold of 1600, so return nothing)                        0        1  SUCCESS
Timing                                                                                    0        1  SUCCESS
---------------------------------------------------------------------------------  --------  -------  -------
Total                                                                                     0        9  SUCCESS
---------------------------------------------------------------------------------  --------  -------  -------

Timer Set: TT_View_Drivers.tt_HR_Test_View_V, Constructed at 22 Oct 2016 15:05:16, written at 15:05:16
======================================================================================================
[Timer timed: Elapsed (per call): 0.03 (0.000033), CPU (per call): 0.03 (0.000030), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Setup          0.03        0.03             4        0.00825        0.00750
Caller         0.01        0.00             4        0.00125        0.00000
(Other)        0.07        0.08             1        0.07000        0.08000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.11        0.11             9        0.01200        0.01222
-------  ----------  ----------  ------------  -------------  -------------

TRAPIT TEST: TT_Emp_Batch.tt_AIP_Load_Emps
==========================================

SCENARIO 1: NV/OV/OU/NI/OI/EI: 1/0/0/0/0/0. Existing J/E: 0/0. [1 valid new record from scratch] {
==================================================================================================

    INPUTS
    ======

        GROUP Parameter {
        =================

            File Name               Count
            ----------------------  -----
            employees_20160801.dat      1

        }
        =

        GROUP File {
        ============

            Line
            ------------------------------------
            ,LN 1,EM 1,01-JAN-2010,IT_PROG,10000

        }
        =

        GROUP Batch Job Table {
        =======================

            Name       Fail Percent
            ---------  ------------
            LOAD_EMPS            70

        }
        =

        GROUP Statistics Table (No records)
        ===================================

        GROUP Employees Table (No records)
        ==================================

    OUTPUTS
    =======

        GROUP Employee: Actual = 1, Expected = 1 {
        ==========================================

            F?  Employee Id  Name  Email  Hired        Job      Salary  Updated
            --  -----------  ----  -----  -----------  -------  ------  -----------
                       1976  LN 1  EM 1   01-JAN-2010  IT_PROG  10000   22-OCT-2016

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Error: Actual = 0, Expected = 0: SUCCESS
        ==============================================

        GROUP Job Statistic: Actual = 1, Expected = 1 {
        ===============================================

            F?  Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            --  ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                              52  LOAD_EMPS     employees_20160801.dat               1                  0                  0  22-OCT-2016  22-OCT-2016  S

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Exception: Actual = 0, Expected = 0: SUCCESS
        ==================================================

} 0 failed, of 4: SUCCESS
=========================

SCENARIO 2: NV/OV/OU/NI/OI/EI: 1/1/1/0/0/0. Existing J/E: 1/0. [3 valid records of each kind] {
===============================================================================================

    INPUTS
    ======

        GROUP Parameter {
        =================

            File Name               Count
            ----------------------  -----
            employees_20160801.dat      3

        }
        =

        GROUP File {
        ============

            Line
            -----------------------------------------
            ,LN 1,EM 1,01-JAN-2010,IT_PROG,10000
            1978,LN 2,EM 2,01-JAN-2010,IT_PROG,20000
            1979,LN 3U,EM 3,01-JAN-2010,IT_PROG,30000

        }
        =

        GROUP Batch Job Table {
        =======================

            Name       Fail Percent
            ---------  ------------
            LOAD_EMPS            70

        }
        =

        GROUP Statistics Table {
        ========================

            Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                          54  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S

        }
        =

        GROUP Employees Table {
        =======================

            Employee Id  Name  Email  Hired        Job      Salary  Manager Id  Department Id  Updated
            -----------  ----  -----  -----------  -------  ------  ----------  -------------  -----------
                   1978  LN 2  EM 2   01-JAN-2010  IT_PROG   20000                             01-JAN-2010
                   1979  LN 3  EM 3   01-JAN-2010  IT_PROG   30000                             01-JAN-2010

        }
        =

    OUTPUTS
    =======

        GROUP Employee: Actual = 3, Expected = 3 {
        ==========================================

            F?  Employee Id  Name   Email  Hired        Job      Salary  Updated
            --  -----------  -----  -----  -----------  -------  ------  -----------
                       1978  LN 2   EM 2   01-JAN-2010  IT_PROG  20000   01-JAN-2010
                       1979  LN 3U  EM 3   01-JAN-2010  IT_PROG  30000   22-OCT-2016
                       1980  LN 1   EM 1   01-JAN-2010  IT_PROG  10000   22-OCT-2016

        } 0 failed, of 3: SUCCESS
        =========================

        GROUP Error: Actual = 0, Expected = 0: SUCCESS
        ==============================================

        GROUP Job Statistic: Actual = 2, Expected = 2 {
        ===============================================

            F?  Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            --  ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                              54  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S
                              55  LOAD_EMPS     employees_20160801.dat               2                  0                  0  22-OCT-2016  22-OCT-2016  S

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Exception: Actual = 0, Expected = 0: SUCCESS
        ==================================================

} 0 failed, of 7: SUCCESS
=========================

SCENARIO 3: NV/OV/OU/NI/OI/EI: 0/0/0/0/1/0. Existing J/E: 1/1. Uid not found [1 invalid old - exception] {
==========================================================================================================

    INPUTS
    ======

        GROUP Parameter {
        =================

            File Name               Count
            ----------------------  -----
            employees_20160801.dat      1

        }
        =

        GROUP File {
        ============

            Line
            --------------------------------------
            99,LN 1,EM 1,01-JAN-2010,IT_PROG,10000

        }
        =

        GROUP Batch Job Table {
        =======================

            Name       Fail Percent
            ---------  ------------
            LOAD_EMPS            70

        }
        =

        GROUP Statistics Table {
        ========================

            Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                          57  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S

        }
        =

        GROUP Employees Table {
        =======================

            Employee Id  Name  Email  Hired        Job      Salary  Manager Id  Department Id  Updated
            -----------  ----  -----  -----------  -------  ------  ----------  -------------  -----------
                   1982  LN 2  EM 2   01-JAN-2010  IT_PROG   20000                             01-JAN-2010

        }
        =

    OUTPUTS
    =======

        GROUP Employee: Actual = 1, Expected = 1 {
        ==========================================

            F?  Employee Id  Name  Email  Hired        Job      Salary  Updated
            --  -----------  ----  -----  -----------  -------  ------  -----------
                       1982  LN 2  EM 2   01-JAN-2010  IT_PROG  20000   01-JAN-2010

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Error: Actual = 1, Expected = 1 {
        =======================================

            F?  Job Statistic Id  ORA_ERR_TAG$  ORA_ERR_MESG$       ORA_ERR_OPTYP$  Employee Id  Name  Email  Hired        Job      Salary
            --  ----------------  ------------  ------------------  --------------  -----------  ----  -----  -----------  -------  ------
                              58                Employee not found  PK                       99  LN 1  EM 1   01-JAN-2010  IT_PROG  10000

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Job Statistic: Actual = 2, Expected = 2 {
        ===============================================

            F?  Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            --  ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                              57  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S
                              58  LOAD_EMPS     employees_20160801.dat               0                  0                  1  22-OCT-2016  22-OCT-2016  F

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Exception: Actual = 1, Expected = 1 {
        ===========================================

            F?  Message
            --  ------------------------------------------------------
                ORA-20001: Batch failed with too many invalid records!

        } 0 failed, of 1: SUCCESS
        =========================

} 0 failed, of 5: SUCCESS
=========================

SCENARIO 4: NV/OV/OU/NI/OI/EI: 0/0/0/1/0/0. Existing J/E: 1/1. Email too long [1 invalid new - exception] {
===========================================================================================================

    INPUTS
    ======

        GROUP Parameter {
        =================

            File Name               Count
            ----------------------  -----
            employees_20160801.dat      1

        }
        =

        GROUP File {
        ============

            Line
            ------------------------------------------------------------------
            ,LN 1,EM 1123456789012345678901234567890,01-JAN-2010,IT_PROG,10000

        }
        =

        GROUP Batch Job Table {
        =======================

            Name       Fail Percent
            ---------  ------------
            LOAD_EMPS            70

        }
        =

        GROUP Statistics Table {
        ========================

            Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                          60  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S

        }
        =

        GROUP Employees Table {
        =======================

            Employee Id  Name  Email  Hired        Job      Salary  Manager Id  Department Id  Updated
            -----------  ----  -----  -----------  -------  ------  ----------  -------------  -----------
                   1984  LN 2  EM 2   01-JAN-2010  IT_PROG   20000                             01-JAN-2010

        }
        =

    OUTPUTS
    =======

        GROUP Employee: Actual = 1, Expected = 1 {
        ==========================================

            F?  Employee Id  Name  Email  Hired        Job      Salary  Updated
            --  -----------  ----  -----  -----------  -------  ------  -----------
                       1984  LN 2  EM 2   01-JAN-2010  IT_PROG  20000   01-JAN-2010

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Error: Actual = 1, Expected = 1 {
        =======================================

            F?  Job Statistic Id  ORA_ERR_TAG$  ORA_ERR_MESG$                                                                             ORA_ERR_OPTYP$  Employee Id  Name  Email                               Hired        Job      Salary
            --  ----------------  ------------  ----------------------------------------------------------------------------------------  --------------  -----------  ----  ----------------------------------  -----------  -------  ------
                              61                ORA-12899: value too large for column "HR"."EMPLOYEES"."EMAIL" (actual: 34, maximum: 25)  I                      1985  LN 1  EM 1123456789012345678901234567890  01-JAN-2010  IT_PROG  10000

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Job Statistic: Actual = 2, Expected = 2 {
        ===============================================

            F?  Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            --  ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                              60  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S
                              61  LOAD_EMPS     employees_20160801.dat               0                  0                  1  22-OCT-2016  22-OCT-2016  F

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Exception: Actual = 1, Expected = 1 {
        ===========================================

            F?  Message
            --  ------------------------------------------------------
                ORA-20001: Batch failed with too many invalid records!

        } 0 failed, of 1: SUCCESS
        =========================

} 0 failed, of 5: SUCCESS
=========================

SCENARIO 5: NV/OV/OU/NI/OI/EI: 1/0/0/0/1/0. Existing J/E: 1/1. Name too long [1 valid new, 1 invalid old - no exception] {
==========================================================================================================================

    INPUTS
    ======

        GROUP Parameter {
        =================

            File Name               Count
            ----------------------  -----
            employees_20160801.dat      2

        }
        =

        GROUP File {
        ============

            Line
            ----------------------------------------------------------------------
            1987,LN 1123456789012345678901234567890,EM 1,01-JAN-2010,IT_PROG,10000
            ,LN 3,EM 3,01-JAN-2010,IT_PROG,30000

        }
        =

        GROUP Batch Job Table {
        =======================

            Name       Fail Percent
            ---------  ------------
            LOAD_EMPS            70

        }
        =

        GROUP Statistics Table {
        ========================

            Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                          63  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S

        }
        =

        GROUP Employees Table {
        =======================

            Employee Id  Name  Email  Hired        Job      Salary  Manager Id  Department Id  Updated
            -----------  ----  -----  -----------  -------  ------  ----------  -------------  -----------
                   1987  LN 2  EM 2   01-JAN-2010  IT_PROG   20000                             01-JAN-2010

        }
        =

    OUTPUTS
    =======

        GROUP Employee: Actual = 2, Expected = 2 {
        ==========================================

            F?  Employee Id  Name  Email  Hired        Job      Salary  Updated
            --  -----------  ----  -----  -----------  -------  ------  -----------
                       1987  LN 2  EM 2   01-JAN-2010  IT_PROG  20000   01-JAN-2010
                       1988  LN 3  EM 3   01-JAN-2010  IT_PROG  30000   22-OCT-2016

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Error: Actual = 1, Expected = 1 {
        =======================================

            F?  Job Statistic Id  ORA_ERR_TAG$  ORA_ERR_MESG$                                                                                 ORA_ERR_OPTYP$  Employee Id  Name                                Email  Hired        Job      Salary
            --  ----------------  ------------  --------------------------------------------------------------------------------------------  --------------  -----------  ----------------------------------  -----  -----------  -------  ------
                              64                ORA-12899: value too large for column "HR"."EMPLOYEES"."LAST_NAME" (actual: 34, maximum: 25)  U                      1987  LN 1123456789012345678901234567890  EM 1   01-JAN-2010  IT_PROG  10000

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Job Statistic: Actual = 2, Expected = 2 {
        ===============================================

            F?  Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            --  ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                              63  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S
                              64  LOAD_EMPS     employees_20160801.dat               1                  0                  1  22-OCT-2016  22-OCT-2016  S

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Exception: Actual = 0, Expected = 0: SUCCESS
        ==================================================

} 0 failed, of 6: SUCCESS
=========================

SCENARIO 6: NV/OV/OU/NI/OI/EI: 0/0/0/1/0/0. Existing J/E: 1/1. Invalid job [1 invalid new - exception] {
========================================================================================================

    INPUTS
    ======

        GROUP Parameter {
        =================

            File Name               Count
            ----------------------  -----
            employees_20160801.dat      1

        }
        =

        GROUP File {
        ============

            Line
            ------------------------------------
            ,LN 1,EM 1,01-JAN-2010,NON_JOB,10000

        }
        =

        GROUP Batch Job Table {
        =======================

            Name       Fail Percent
            ---------  ------------
            LOAD_EMPS            70

        }
        =

        GROUP Statistics Table {
        ========================

            Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                          66  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S

        }
        =

        GROUP Employees Table {
        =======================

            Employee Id  Name  Email  Hired        Job      Salary  Manager Id  Department Id  Updated
            -----------  ----  -----  -----------  -------  ------  ----------  -------------  -----------
                   1990  LN 2  EM 2   01-JAN-2010  IT_PROG   20000                             01-JAN-2010

        }
        =

    OUTPUTS
    =======

        GROUP Employee: Actual = 1, Expected = 1 {
        ==========================================

            F?  Employee Id  Name  Email  Hired        Job      Salary  Updated
            --  -----------  ----  -----  -----------  -------  ------  -----------
                       1990  LN 2  EM 2   01-JAN-2010  IT_PROG  20000   01-JAN-2010

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Error: Actual = 1, Expected = 1 {
        =======================================

            F?  Job Statistic Id  ORA_ERR_TAG$  ORA_ERR_MESG$                                                                    ORA_ERR_OPTYP$  Employee Id  Name  Email  Hired        Job      Salary
            --  ----------------  ------------  -------------------------------------------------------------------------------  --------------  -----------  ----  -----  -----------  -------  ------
                              67                ORA-02291: integrity constraint (HR.EMP_JOB_FK) violated - parent key not found  I                      1991  LN 1  EM 1   01-JAN-2010  NON_JOB  10000

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Job Statistic: Actual = 2, Expected = 2 {
        ===============================================

            F?  Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            --  ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                              66  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S
                              67  LOAD_EMPS     employees_20160801.dat               0                  0                  1  22-OCT-2016  22-OCT-2016  F

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Exception: Actual = 1, Expected = 1 {
        ===========================================

            F?  Message
            --  ------------------------------------------------------
                ORA-20001: Batch failed with too many invalid records!

        } 0 failed, of 1: SUCCESS
        =========================

} 0 failed, of 5: SUCCESS
=========================

SCENARIO 7: NV/OV/OU/NI/OI/EI: 0/1/0/1/1/0. Existing J/E: 1/2. 2 invalid jobs [1 valid old, 2 invalid: old and new - no exception] {
====================================================================================================================================

    INPUTS
    ======

        GROUP Parameter {
        =================

            File Name               Count
            ----------------------  -----
            employees_20160801.dat      3

        }
        =

        GROUP File {
        ============

            Line
            -----------------------------------------
            ,LN 1,EM 1,01-JAN-2010,NON_JOB,10000
            1993,LN 2,EM 2,01-JAN-2010,NON_JOB,20000
            1994,LN 3U,EM 3,01-JAN-2010,IT_PROG,30000

        }
        =

        GROUP Batch Job Table {
        =======================

            Name       Fail Percent
            ---------  ------------
            LOAD_EMPS            70

        }
        =

        GROUP Statistics Table {
        ========================

            Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                          69  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S

        }
        =

        GROUP Employees Table {
        =======================

            Employee Id  Name  Email  Hired        Job      Salary  Manager Id  Department Id  Updated
            -----------  ----  -----  -----------  -------  ------  ----------  -------------  -----------
                   1993  LN 2  EM 2   01-JAN-2010  IT_PROG   20000                             01-JAN-2010
                   1994  LN 3  EM 3   01-JAN-2010  IT_PROG   30000                             01-JAN-2010

        }
        =

    OUTPUTS
    =======

        GROUP Employee: Actual = 2, Expected = 2 {
        ==========================================

            F?  Employee Id  Name   Email  Hired        Job      Salary  Updated
            --  -----------  -----  -----  -----------  -------  ------  -----------
                       1993  LN 2   EM 2   01-JAN-2010  IT_PROG  20000   01-JAN-2010
                       1994  LN 3U  EM 3   01-JAN-2010  IT_PROG  30000   22-OCT-2016

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Error: Actual = 2, Expected = 2 {
        =======================================

            F?  Job Statistic Id  ORA_ERR_TAG$  ORA_ERR_MESG$                                                                    ORA_ERR_OPTYP$  Employee Id  Name  Email  Hired        Job      Salary
            --  ----------------  ------------  -------------------------------------------------------------------------------  --------------  -----------  ----  -----  -----------  -------  ------
                              70                ORA-02291: integrity constraint (HR.EMP_JOB_FK) violated - parent key not found  U                      1993  LN 2  EM 2   01-JAN-2010  NON_JOB  20000
                              70                ORA-02291: integrity constraint (HR.EMP_JOB_FK) violated - parent key not found  I                      1995  LN 1  EM 1   01-JAN-2010  NON_JOB  10000

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Job Statistic: Actual = 2, Expected = 2 {
        ===============================================

            F?  Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            --  ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                              69  LOAD_EMPS     employees_20160101.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S
                              70  LOAD_EMPS     employees_20160801.dat               1                  0                  2  22-OCT-2016  22-OCT-2016  S

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Exception: Actual = 0, Expected = 0: SUCCESS
        ==================================================

} 0 failed, of 7: SUCCESS
=========================

SCENARIO 8: NV/OV/OU/NI/OI/EI: 0/1/0/0/0/1. Existing J/E: 1/2. Name 4001ch [1 valid old, 1 invalid new for external table - no exception; also file had previously failed] {
============================================================================================================================================================================

    INPUTS
    ======

        GROUP Parameter {
        =================

            File Name               Count
            ----------------------  -----
            employees_20160801.dat      2

        }
        =

        GROUP File {
        ============

            Line
            --------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
            ,123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567890123456789012345678901234567
            1998,LN 3U,EM 3,01-JAN-2010,IT_PROG,30000

        }
        =

        GROUP Batch Job Table {
        =======================

            Name       Fail Percent
            ---------  ------------
            LOAD_EMPS            70

        }
        =

        GROUP Statistics Table {
        ========================

            Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                          72  LOAD_EMPS     employees_20160801.dat               0                  0                  2  01-JAN-2010  01-JAN-2010  F

        }
        =

        GROUP Employees Table {
        =======================

            Employee Id  Name  Email  Hired        Job      Salary  Manager Id  Department Id  Updated
            -----------  ----  -----  -----------  -------  ------  ----------  -------------  -----------
                   1997  LN 2  EM 2   01-JAN-2010  IT_PROG   20000                             01-JAN-2010
                   1998  LN 3  EM 3   01-JAN-2010  IT_PROG   30000                             01-JAN-2010

        }
        =

    OUTPUTS
    =======

        GROUP Employee: Actual = 2, Expected = 2 {
        ==========================================

            F?  Employee Id  Name   Email  Hired        Job      Salary  Updated
            --  -----------  -----  -----  -----------  -------  ------  -----------
                       1997  LN 2   EM 2   01-JAN-2010  IT_PROG  20000   01-JAN-2010
                       1998  LN 3U  EM 3   01-JAN-2010  IT_PROG  30000   22-OCT-2016

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Error: Actual = 0, Expected = 0: SUCCESS
        ==============================================

        GROUP Job Statistic: Actual = 2, Expected = 2 {
        ===============================================

            F?  Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            --  ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                              72  LOAD_EMPS     employees_20160801.dat               0                  0                  2  01-JAN-2010  01-JAN-2010  F
                              73  LOAD_EMPS     employees_20160801.dat               1                  1                  0  22-OCT-2016  22-OCT-2016  S

        } 0 failed, of 2: SUCCESS
        =========================

        GROUP Exception: Actual = 0, Expected = 0: SUCCESS
        ==================================================

} 0 failed, of 6: SUCCESS
=========================

SCENARIO 9: NV/OV/OU/NI/OI/EI: 0/0/0/1/0/0. Existing J/E: 1/1. [File already processed - exception] {
=====================================================================================================

    INPUTS
    ======

        GROUP Parameter {
        =================

            File Name               Count
            ----------------------  -----
            employees_20160801.dat      1

        }
        =

        GROUP File {
        ============

            Line
            ------------------------------------
            ,LN 1,EM 1,01-JAN-2010,NON_JOB,10000

        }
        =

        GROUP Batch Job Table {
        =======================

            Name       Fail Percent
            ---------  ------------
            LOAD_EMPS            70

        }
        =

        GROUP Statistics Table {
        ========================

            Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                          75  LOAD_EMPS     employees_20160801.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S

        }
        =

        GROUP Employees Table {
        =======================

            Employee Id  Name  Email  Hired        Job      Salary  Manager Id  Department Id  Updated
            -----------  ----  -----  -----------  -------  ------  ----------  -------------  -----------
                   2000  LN 2  EM 2   01-JAN-2010  IT_PROG   20000                             01-JAN-2010

        }
        =

    OUTPUTS
    =======

        GROUP Employee: Actual = 1, Expected = 1 {
        ==========================================

            F?  Employee Id  Name  Email  Hired        Job      Salary  Updated
            --  -----------  ----  -----  -----------  -------  ------  -----------
                       2000  LN 2  EM 2   01-JAN-2010  IT_PROG  20000   01-JAN-2010

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Error: Actual = 0, Expected = 0: SUCCESS
        ==============================================

        GROUP Job Statistic: Actual = 1, Expected = 1 {
        ===============================================

            F?  Job Statistic Id  Batch job Id  File Name               Records Loaded  Records Failed ET  Records Failed DB  Start Time   End Time     Status
            --  ----------------  ------------  ----------------------  --------------  -----------------  -----------------  -----------  -----------  ------
                              75  LOAD_EMPS     employees_20160801.dat              10                  0                  2  01-JAN-2010  01-JAN-2010  S

        } 0 failed, of 1: SUCCESS
        =========================

        GROUP Exception: Actual = 1, Expected = 1 {
        ===========================================

            F?  Message
            --  --------------------------------------------------------
                ORA-20002: File has already been processed successfully!

        } 0 failed, of 1: SUCCESS
        =========================

} 0 failed, of 4: SUCCESS
=========================

TIMING: Actual = 254, Expected <= 2: FAILURE
============================================

SUMMARY for TT_Emp_Batch.tt_AIP_Load_Emps
=========================================

Scenario                                                                                                                                                        # Failed  # Tests  Status
--------------------------------------------------------------------------------------------------------------------------------------------------------------  --------  -------  -------
NV/OV/OU/NI/OI/EI: 1/0/0/0/0/0. Existing J/E: 0/0. [1 valid new record from scratch]                                                                                   0        4  SUCCESS
NV/OV/OU/NI/OI/EI: 1/1/1/0/0/0. Existing J/E: 1/0. [3 valid records of each kind]                                                                                      0        7  SUCCESS
NV/OV/OU/NI/OI/EI: 0/0/0/0/1/0. Existing J/E: 1/1. Uid not found [1 invalid old - exception]                                                                           0        5  SUCCESS
NV/OV/OU/NI/OI/EI: 0/0/0/1/0/0. Existing J/E: 1/1. Email too long [1 invalid new - exception]                                                                          0        5  SUCCESS
NV/OV/OU/NI/OI/EI: 1/0/0/0/1/0. Existing J/E: 1/1. Name too long [1 valid new, 1 invalid old - no exception]                                                           0        6  SUCCESS
NV/OV/OU/NI/OI/EI: 0/0/0/1/0/0. Existing J/E: 1/1. Invalid job [1 invalid new - exception]                                                                             0        5  SUCCESS
NV/OV/OU/NI/OI/EI: 0/1/0/1/1/0. Existing J/E: 1/2. 2 invalid jobs [1 valid old, 2 invalid: old and new - no exception]                                                 0        7  SUCCESS
NV/OV/OU/NI/OI/EI: 0/1/0/0/0/1. Existing J/E: 1/2. Name 4001ch [1 valid old, 1 invalid new for external table - no exception; also file had previously failed]         0        6  SUCCESS
NV/OV/OU/NI/OI/EI: 0/0/0/1/0/0. Existing J/E: 1/1. [File already processed - exception]                                                                                0        4  SUCCESS
Timing                                                                                                                                                                 1        1  FAILURE
--------------------------------------------------------------------------------------------------------------------------------------------------------------  --------  -------  -------
Total                                                                                                                                                                  1       50  FAILURE
--------------------------------------------------------------------------------------------------------------------------------------------------------------  --------  -------  -------

Timer Set: TT_Emp_Batch.tt_AIP_Load_Emps, Constructed at 22 Oct 2016 15:05:16, written at 15:05:20
==================================================================================================
[Timer timed: Elapsed (per call): 0.03 (0.000033), CPU (per call): 0.03 (0.000030), calls: 1000, '***' denotes corrected line below]

Timer           Elapsed         CPU         Calls       Ela/Call       CPU/Call
-----------  ----------  ----------  ------------  -------------  -------------
Setup              0.97        0.23             9        0.10811        0.02556
Caller             1.27        0.99             5        0.25400        0.19800
Get_Tab_Lis        0.73        0.59             9        0.08122        0.06556
Get_Err_Lis        0.00        0.00             9        0.00011        0.00000
Get_Jbs_Lis        0.01        0.02             9        0.00056        0.00222
(Other)            0.34        0.35             1        0.34200        0.35000
-----------  ----------  ----------  ------------  -------------  -------------
Total              3.32        2.18            42        0.07910        0.05190
-----------  ----------  ----------  ------------  -------------  -------------

Suite Summary
=============

Package.Procedure                  Tests  Fails         ELA         CPU
---------------------------------  -----  -----  ----------  ----------
TT_Emp_WS.tt_AIP_Save_Emps            17      2        0.09        0.08
TT_Emp_WS.tt_AIP_Get_Dept_Emps         8      0        0.14        0.14
TT_View_Drivers.tt_HR_Test_View_V      9      0        0.11        0.11
TT_Emp_Batch.tt_AIP_Load_Emps         50      1        3.32        2.18
---------------------------------  -----  -----  ----------  ----------
Total                                 84      3        3.66        2.51
---------------------------------  -----  -----  ----------  ----------
Others error in (): ORA-20001: Suite BRENDAN returned error status: ORA-06512: at "DP_3.UTILS_TT", line 152
ORA-06512: at "DP_3.UTILS_TT", line 819
ORA-06512: at line 5


1687 rows selected.






 

Design Patterns for Database API Testing 2: Views 2 - Code

Last October I gave a presentation on database unit testing with utPLSQL, Oracle Unit Testing with utPLSQL. I mentioned design patterns as a way of reducing the effort of building unit tests and outlined some strategies for coding them effectively.

In the current set of articles, I develop the ideas further, starting from the idea that all database APIs can be considered in terms of the axes:

  • direction (i.e. getter or setter, noting that setters can also 'get')
  • mode (i.e. real time or batch)

For each cell in the implied matrix, I construct an example API (or view) with specified requirements against Oracle's HR demo schema, and use this example to construct a testing program with appropriate scenarios as a design pattern. Concepts and common patterns and anti-patterns in automated API testing are discussed throughout, and these are largely independent of testing framework used. However, the examples use my own lightweight independent framework that is designed to help avoid many API testing anti-patterns. The code is available on GitHub here, BrenPatF/trapit_oracle_tester, and includes both framework and design pattern examples.

Behind the four examples, there is an underlying design pattern that involves wrapping the API call in a 'pure' procedure, called once per scenario, with the output 'actuals' array including everything affected by the API, whether as output parameters, or on database tables, etc. The inputs are also extended from the API parameters to include any other effective inputs. Assertion takes place after all scenarios and is against the extended outputs, with extended inputs also listed. This concept of the 'pure' function, central to Functional Programming, has important advantages in automated testing. I explained the concepts involved in a presentation at the Oracle User Group Ireland Conference in March 2018:

The Database API Viewed As A Mathematical Function: Insights into Testing


In the first part of this two part article,Design Patterns for Database API Testing 2: Views 1 - Design I presented a design pattern for unit testing views, using an example based on Oracle's HR demo schema, and here I list the code for the main test procedure and a couple of the utility procedures, with notes.

A structure diagram shows how the PL/SQL packages relate to each other, and sections of the code are listed with notes.

Package Structure Diagram

Call Structure Table

TT_View_Drivers.tt_HR_Test_View_V - View Test Procedure

Declare section

PROCEDURE tt_HR_Test_View_V IS

  c_view_name           CONSTANT VARCHAR2(61) := 'HR_Test_View_V';
  c_proc_name           CONSTANT VARCHAR2(61) := 'TT_View_Drivers.tt_' || c_view_name;
  c_dep_id_1            CONSTANT PLS_INTEGER := 10;
  c_dep_id_2            CONSTANT PLS_INTEGER := 20;
  c_dep_nm_1            CONSTANT VARCHAR2(100) := 'Administration';
  c_dep_nm_2            CONSTANT VARCHAR2(100) := 'Marketing';
  c_job_bad             CONSTANT VARCHAR2(100) := 'AD_ASST';
  c_job_good            CONSTANT VARCHAR2(100) := 'IT_PROG';
  c_base_sal            CONSTANT PLS_INTEGER := 1000;

  c_ln_pre              CONSTANT VARCHAR2(10) := DML_API_TT_HR.c_ln_pre;

  c_sel_lis             CONSTANT L1_chr_arr := L1_chr_arr ('last_name', 'department_name', 'manager', 'salary', 'sal_rat', 'sal_rat_g');
  c_where_lis           CONSTANT L1_chr_arr := L1_chr_arr (NULL, NULL, 'department_name=''Administration''', NULL);

  c_dataset_3lis        CONSTANT L3_chr_arr := L3_chr_arr (
                             L2_chr_arr (L1_chr_arr ('4 emps, 1 dep (10), emp-3 has no dep, emp-4 has bad job'),
--                                         dep           job          salary
                               L1_chr_arr (c_dep_id_1,   c_job_good,  '1000'),
                               L1_chr_arr (c_dep_id_1,   c_job_good,  '2000'),
                               L1_chr_arr (NULL,         c_job_good,  '3000'),
                               L1_chr_arr (c_dep_id_1,   c_job_bad,   '4000')
                                             ),
                             L2_chr_arr (L1_chr_arr ('As dataset 1 but with extra emp-5, in second dep (20)'),
                               L1_chr_arr (c_dep_id_1,   c_job_good,  '1000'),
                               L1_chr_arr (c_dep_id_1,   c_job_good,  '2000'),
                               L1_chr_arr (NULL,         c_job_good,  '3000'),
                               L1_chr_arr (c_dep_id_1,   c_job_bad,   '4000'),
                               L1_chr_arr (c_dep_id_2,   c_job_good,  '5000')
                                             ),
                             L2_chr_arr (L1_chr_arr ('As dataset 2 but with salaries * 0.1, total below reporting threshold of 1600'),
                               L1_chr_arr (c_dep_id_1,   c_job_good,  '100'),
                               L1_chr_arr (c_dep_id_1,   c_job_good,  '200'),
                               L1_chr_arr (NULL,         c_job_good,  '300'),
                               L1_chr_arr (c_dep_id_1,   c_job_bad,   '400'),
                               L1_chr_arr (c_dep_id_2,   c_job_good,  '500')
                                             )
                        );

  c_exp_2lis            CONSTANT L2_chr_arr := L2_chr_arr (
                                               L1_chr_arr (
                                       Utils.List_Delim (c_ln_pre || '1',   c_dep_nm_1, NULL,            '1000', '.67',   '.4'),
                                       Utils.List_Delim (c_ln_pre || '2',   c_dep_nm_1, c_ln_pre || '1', '2000',  '1.33', '.8')
                                               ),
                                               L1_chr_arr (
                                       Utils.List_Delim (c_ln_pre || '1',   c_dep_nm_1, NULL,            '1000', '.67',  '.33'),
                                       Utils.List_Delim (c_ln_pre || '2',   c_dep_nm_1, c_ln_pre || '1', '2000',  '1.33', '.67'),
                                       Utils.List_Delim (c_ln_pre || '5',   c_dep_nm_2, c_ln_pre || '1', '5000',  '1',    '1.67')
                                               ),
                                               L1_chr_arr (
                                       Utils.List_Delim (c_ln_pre || '1',   c_dep_nm_1, NULL,            '1000', '.67',   '.33'),
                                       Utils.List_Delim (c_ln_pre || '2',   c_dep_nm_1, c_ln_pre || '1', '2000',  '1.33', '.67')
                                               ),
                                               tt_Utils.c_empty_list
                        );

  c_scenario_ds_lis     CONSTANT L1_num_arr := L1_num_arr (1, 2, 2, 3);
  c_scenario_lis        CONSTANT L1_chr_arr := L1_chr_arr (
                               'DS-1, testing inner, outer joins, analytic over dep, and global ratios with 1 dep',
                               'DS-2, testing same as 1 but with extra emp in another dep',
                               'DS-2, passing ''WHERE dep=10''',
                               'DS-3, Salaries total 1500 (< threshold of 1600)');

  c_inp_group_lis       CONSTANT L1_chr_arr := L1_chr_arr ('Employee', 'Where');
  c_inp_field_2lis      CONSTANT L2_chr_arr := L2_chr_arr (
                                                        L1_chr_arr (
                                                                '*Employee Id',
                                                                'Last Name',
                                                                'Email',
                                                                'Hire Date',
                                                                'Job',
                                                                '*Salary',
                                                                '*Manager Id',
                                                                '*department Id'),
                                                        L1_chr_arr (
                                                                'Where')
  );
  c_out_field_2lis      CONSTANT L2_chr_arr :=  L2_chr_arr ( L1_chr_arr (
                                'Name',
                                'Department',
                                'Manager',
                                '*Salary',
                                '*Salary Ratio (dep)',
                                '*Salary Ratio (overall)'));

  l_act_2lis                      L2_chr_arr := L2_chr_arr();
  c_ms_limit            CONSTANT PLS_INTEGER := 1;
  l_timer_set                    PLS_INTEGER;
  l_inp_3lis                     L3_chr_arr := L3_chr_arr();

Notes on declare section

  • Data sets, scenarios, expected values etc. are stored in generic arrays, where:
    • L1_chr_arr is type of array of VARCHAR2(4000), same as standard type SYS.ODCIVarchar2List
    • L2_chr_arr is a type of array of L1_chr_arr
    • L3_chr_arr is a type of array of L2_chr_arr

Setup section

  PROCEDURE Setup_Array IS
  BEGIN

    l_act_2lis.EXTEND (c_exp_2lis.COUNT);
    l_inp_3lis.EXTEND (c_exp_2lis.COUNT);

    FOR i IN 1..c_exp_2lis.COUNT LOOP

      l_inp_3lis (i) := L2_chr_arr();
      l_inp_3lis (i).EXTEND(2);
      l_inp_3lis(i)(2) := L1_chr_arr (c_where_lis(i));

    END LOOP;

  END Setup_Array;

  /***************************************************************************************************

  Setup_DB: Create test records for a given scenario for testing view

  ***************************************************************************************************/
  PROCEDURE Setup_DB (p_call_ind           PLS_INTEGER,   -- scenario index
                      x_inp_lis        OUT L1_chr_arr) IS -- input list, first group, employees

    l_emp_id            PLS_INTEGER;
    l_mgr_id            PLS_INTEGER;
    l_len_lis           L1_num_arr := L1_num_arr (1, -11, -13, -10, 10, -10);

  BEGIN

    Utils.Heading ('Employees created in setup: DS-' || p_call_ind || ' - ' || c_dataset_3lis (p_call_ind)(1)(1));
    Utils.Col_Headers (L1_chr_arr ('#', 'Employee id', 'Department id', 'Manager', 'Job id', 'Salary'), l_len_lis);
    x_inp_lis := L1_chr_arr();
    x_inp_lis.EXTEND (c_dataset_3lis (p_call_ind).COUNT - 1);
    FOR i IN 2..c_dataset_3lis (p_call_ind).COUNT LOOP

      l_emp_id := DML_API_TT_HR.Ins_Emp (
                            p_emp_ind  => i - 1,
                            p_dep_id   => c_dataset_3lis (p_call_ind)(i)(1),
                            p_mgr_id   => l_mgr_id,
                            p_job_id   => c_dataset_3lis (p_call_ind)(i)(2),
                            p_salary   => c_dataset_3lis (p_call_ind)(i)(3),
                            x_rec      => x_inp_lis(i - 1));
      Utils.Pr_List_As_Line (L1_chr_arr ((i-1), l_emp_id, Nvl (c_dataset_3lis (p_call_ind)(i)(1), ' '), Nvl (To_Char(l_mgr_id), ' '), c_dataset_3lis (p_call_ind)(i)(2), c_dataset_3lis (p_call_ind)(i)(3)), l_len_lis);
      IF i = 2 THEN
        l_mgr_id := l_emp_id;
      END IF;

    END LOOP;

  END Setup_DB;

Notes on setup section

  • c_dataset_3lis contains the data for all data sets indexed by (data set, record, field)
  • Setup_Array is called once to do some setup on the arrays
  • Setup_DB is called for a single data set at a time in each scenario
  • Description of the data set is contained in the array and printed out
  • Data set is printed out in tabular format. In the most recent version of the utility code, this is not strictly necessary, because all the input data is printed out before the outputs

'Pure' API wrapper procedure

  PROCEDURE Purely_Wrap_API (p_scenario_ds      VARCHAR2,      -- index of input dataset
                             p_where            VARCHAR2,      -- input where clause for
                             x_inp_lis_1    OUT L1_chr_arr,    -- first input group, employees
                             x_act_lis      OUT L1_chr_arr) IS -- generic actual values list (for scenario)
  BEGIN

    Setup_DB (p_scenario_ds, x_inp_lis_1);

    Timer_Set.Increment_Time (l_timer_set, Utils_TT.c_setup_timer);
 
    x_act_lis := Utils_TT.Get_View (
                            p_view_name         => c_view_name,
                            p_sel_field_lis     => c_sel_lis,
                            p_where             => p_where,
                            p_timer_set         => l_timer_set);
    ROLLBACK;

  END Purely_Wrap_API;

Notes on 'Pure' API wrapper procedure

  • Setup_DB is called to create the data set for the scenario
  • Get_View returns the results of the query on the view as 2-level array
  • Get_View rolls back after getting the results, so the inserted test records are removed from the database

Main section

BEGIN
--
-- Every testing main section should be similar to this, with array setup, then loop over scenarios
-- making a 'pure'(-ish) call to specific, local Purely_Wrap_API, with single assertion call outside
-- the loop
--
  l_timer_set := Utils_TT.Init (c_proc_name);
  Setup_Array;

  FOR i IN 1..c_exp_2lis.COUNT LOOP

    Purely_Wrap_API (c_scenario_ds_lis(i), c_where_lis(i), l_inp_3lis(i)(1), l_act_2lis(i));

  END LOOP;

  Utils_TT.Is_Deeply (c_proc_name, c_scenario_lis, l_inp_3lis, l_act_2lis, c_exp_2lis, l_timer_set, c_ms_limit,
                      c_inp_group_lis, c_inp_field_2lis, c_out_group_lis, c_out_field_2lis);

EXCEPTION

  WHEN OTHERS THEN
    Utils.Write_Other_Error;
    RAISE;

END tt_HR_Test_View_V;

Notes on main section

  • It's quite short isn't it 🙂
  • Setup is called to do array setup
  • Main section loops over the scenarios calling Purely_Wrap_API
  • Is_Deeply is called to do all the assertions within nested loops, then print the results

Utils_TT - Test Utility Procedures
We will include only one procedure from this package in the body of the article. See gitHub link for the full code.
Is_Deeply - to check results from testing

PROCEDURE Is_Deeply (p_proc_name                 VARCHAR2,      -- calling procedure
                     p_test_lis                  L1_chr_arr,    -- test descriptions
                     p_inp_3lis                  L3_chr_arr,    -- actual result strings
                     p_act_3lis                  L3_chr_arr,    -- actual result strings
                     p_exp_3lis                  L3_chr_arr,    -- expected result strings
                     p_timer_set                 PLS_INTEGER,   -- timer set index
                     p_ms_limit                  PLS_INTEGER,   -- call time limit in ms
                     p_inp_group_lis             L1_chr_arr,    -- input group names
                     p_inp_fields_2lis           L2_chr_arr,    -- input fields descriptions
                     p_out_group_lis             L1_chr_arr,    -- output group names
                     p_fields_2lis               L2_chr_arr) IS -- test fields descriptions

  l_num_fails_sce                L1_num_arr :=  L1_num_arr();
  l_num_tests_sce                L1_num_arr :=  L1_num_arr();
  l_tot_fails                    PLS_INTEGER := 0;
  l_tot_tests                    PLS_INTEGER := 0;

.
.
.
(private procedures - see gitHub project, https://github.com/BrenPatF/trapit_oracle_tester, for full code listings)
.
.
.
BEGIN

  Detail_Section (l_num_fails_sce, l_num_tests_sce);
  Summary_Section (l_num_fails_sce, l_num_tests_sce, l_tot_fails, l_tot_tests);
  Set_Global_Summary (l_tot_fails, l_tot_tests + 1);

END Is_Deeply;

Notes on Is_Deeply

  • This is the base version of Is_Deeply with 3-level arrays of expected and actuals
  • An inner loop asserts actual values (which are records) against expected
  • The final assertion is against average call time
  • It is expected that all assertion within a test procedure will be via a single call to one of the versions of this procedure, making a big reduction in code compared with traditional unit testing approaches
  • After final assertion a call is made to write out all the results, by scenario, with all inputs printed first, followed by actuals (and expected, where they differ); this means that the test outputs now become precise and accurate documents of what the program does

Get_View - run a query dynamically on a view and return result set as array of strings

FUNCTION Get_View (p_view_name         VARCHAR2,               -- name of view
                   p_sel_field_lis     L1_chr_arr,             -- list of fields to select
                   p_where             VARCHAR2 DEFAULT NULL,  -- optional where clause
                   p_timer_set         PLS_INTEGER)            -- timer set handle
                   RETURN              L1_chr_arr IS           -- list of delimited result records

  l_cur            SYS_REFCURSOR;
  l_sql_txt        VARCHAR2(32767) := 'SELECT Utils.List_Delim (L1_chr_arr (';
  l_result_lis     L1_chr_arr;
  l_len            PLS_INTEGER;

BEGIN

  FOR i IN 1..p_sel_field_lis.COUNT LOOP

    l_sql_txt := l_sql_txt || p_sel_field_lis(i) || ',';

  END LOOP;

  l_sql_txt := RTrim (l_sql_txt, ',') || ')) FROM ' || p_view_name || ' WHERE ' || Nvl (p_where, '1=1 ') || 'ORDER BY 1';

  OPEN l_cur FOR l_sql_txt;

  FETCH l_cur BULK COLLECT -- ut, small result set, hence no need for limit clause
   INTO l_result_lis;

  CLOSE l_cur;

  Timer_Set.Increment_Time (p_timer_set, Utils_TT.c_call_timer);
  ROLLBACK;
  RETURN tt_Utils.List_or_Empty (l_result_lis);

END Get_View;

Notes on Get_View

  • A query string is constructed from the input list of fields and optional where clause
  • The fields are concatenated with delimiters and returned into an array of strings
  • A rollback occurs to remove any test data created, so as not to interfere with any subsequent call
  • If no data was returned from the query, we return a default 1-record listing containing the string 'EMPTY'

Package block section

BEGIN

  DBMS_Application_Info.Set_Client_Info (client_info => 'TT');
  Utils.c_session_id_if_TT := SYS_Context ('userenv', 'sessionid');

END Utils_TT;

Notes on package block section

  • client_info is set to 'TT', meaning the session operates in test mode
  • The session id is stored in a package variable
  • This id is referenced in the testing views and in insertion of test records with utid column

Conclusions






 

Design Patterns for Database API Testing 2: Views 1 - Design

Last October I gave a presentation on database unit testing with utPLSQL, Oracle Unit Testing with utPLSQL. I mentioned design patterns as a way of reducing the effort of building unit tests and outlined some strategies for coding them effectively.

In the current set of articles, I develop the ideas further, starting from the idea that all database APIs can be considered in terms of the axes:

  • direction (i.e. getter or setter, noting that setters can also 'get')
  • mode (i.e. real time or batch)

For each cell in the implied matrix, I construct an example API (or view) with specified requirements against Oracle's HR demo schema, and use this example to construct a testing program with appropriate scenarios as a design pattern. Concepts and common patterns and anti-patterns in automated API testing are discussed throughout, and these are largely independent of testing framework used. However, the examples use my own lightweight independent framework that is designed to help avoid many API testing anti-patterns. The code is available on GitHub here, BrenPatF/trapit_oracle_tester, and includes both framework and design pattern examples.

Behind the four examples, there is an underlying design pattern that involves wrapping the API call in a 'pure' procedure, called once per scenario, with the output 'actuals' array including everything affected by the API, whether as output parameters, or on database tables, etc. The inputs are also extended from the API parameters to include any other effective inputs. Assertion takes place after all scenarios and is against the extended outputs, with extended inputs also listed. This concept of the 'pure' function, central to Functional Programming, has important advantages in automated testing. I explained the concepts involved in a presentation at the Oracle User Group Ireland Conference in March 2018:

The Database API Viewed As A Mathematical Function: Insights into Testing


In this 2-part article, I present a design pattern for testing views. I start by discussing when and how to test views. Unlike in the design paatern of the first article in the series, Design Patterns for Database API Testing 1: Web Service Saving - Design, test data has to be created during testing of views, and a very general approach to creating and selecting the test data is proposed. The use case for the design pattern is described, and scenarios and sub-scenarios are defined conceptually. Finally, the output from the testing is presented, with notes.

The second post provides some code extracts, with notes: Design Patterns for Database API Testing 2: Views 2 - Code.

When to Test Views

Views can be simple or complex, or, as I categorise them in Brendan's 2-Page Oracle Programming Standards, thin or thick, where thick views include table joins and thinviews don't. Thin views do not normally require testing while it may or may not be appropriate to test thick views.

As explained in the second part of the first article mentioned above, method-based testing is a bad idea, and occurs when the test suite is based on testing all the methods in a package, rather than units of (external) behaviour (often corresponding to procedures prefixed AIP in a common naming convention). Similarly, we can consider views in the same way as methods and ask whether they represent testable units of behaviour or are merely internal code structures, which should not normally have individual automated tests for the reasons given there.

Good examples of views that should be tested would be those that form the basis of complex data extraction to file, by ETL tools such as Informatica, or those that form the basis of reporting tools such as Business Objects. In fact, it is very good practice to place SQL for these tools into views precisely so that they can be tested.

How to Test Views Using a PL/SQL Testing Framework

In order to leverage a PL/SQL API testing framework to also test views, the API test package procedures call a library procedure passing the name of the relevant view: The library procedure returns the result of querying the view as an array of delimited strings, and the API test procedures then compare the results against their own expected results.

Each API test procedure will have its own setup local procedure to create test data, and we need to discuss the issue of distinguishing test data from pre-existing data.

Test Data

In the earlier article on database save procedures, we did not create any test data within the testing code itself, but the base procedure did create data, and those were queried back for assertion. In order to select only the data created by the procedure call a prefix was used in one of the string fields which was assumed not to exist already. This is a workable approach in some cases, but may not be possible in general. Let us consider the different types of database data that may affect our testing:

  • Data created by the base code being tested
  • Data created by test code to be read by the base code
  • Data not created by test code to be read by base code

In order to verify that the program calls are giving results as expected, the test code needs to know all the data that influence the results, not necessarily just directly created data. Our view testing use case described below has an example where the results depend on an aggregate of all the records on the database. This is a problem when we have a shared database, where we cannot freeze the data at the time of test development. In order to handle this problem, we propose to borrow a technique used in Oracle's ebusinees applications.

Partitioning Views with System Contexts
In Oracle ebusiness's multi-org implementations, transactions are partitioned by a numeric identifier for the organization owning the transaction. This org_id value is stored in a column in the base table on transaction creation. Within the application code the base table is not queried directly, but through a view that restricts records returned to those for the organization corresponding to the current role of the application user, which is stored in the userenv system context (this is true up to release 11.5, but the mechanism changed in release 12.1).

See SYS_CONTEXT for information on the system context database feature, and Oracle E-Business Suite Multiple Organizations Implementation Guide (12.1) for release 12.1 multi-org implementation in Oracle ebusiness.

Partitioning Views for Testing
We propose to use views in a similar way to the multi-org views, to restrict records to those created in the testing session, by means of a ttid column on the base table that will hold the session id. The new optional column is added to those tables where this approach is required, and view are created on the tables. Our testing utility package Utils_TT sets a context variable to the value 'TT' to signify testing mode, and the session id is set to a package variable in the general utilities package Utils.

Any base code that inserts data into the tables has to check for test mode, and if set, put the session id into the ttid field, and if not, leave it blank. The views use the following clause:

 WHERE (ttid = SYS_Context ('userenv', 'sessionid') OR 
        Substr (Nvl (SYS_Context ('userenv', 'client_info'), 'XX'), 1, 2) != 'TT')

Both test code and base code now query the views instead of the base tables. As the base code to write to the tables has to account for the new column, it is necessary for the column to be added in all instances including production. If this seems a little drastic, consider the importance that you attach to testing, and bear in mind that the earlier, less general, approaches may suffice in many cases. In these design pattern demos I use the general solution.

Schema Structure

In the earlier articles, the base code and test packages were created in the HR schema, with utility packages kept in the custom brendan schema. However, it is more common to use separate schemas for code and data, so we will now place all packages and supporting objects in the brendan schema, and create the testing views there.

Design Pattern Use Case for Testing Views

Modern Oracle SQL is very powerful and can apply complex logic within a single statement, reducing the need for more complex procedural code. In order to show how to test SQL, we will devise a test view, HR_Test_V, having a range of features that we might want to test in general:

  • Inner joins suppress driving records where there is no joining record
  • Outer joins return driving records where there is no joining record
  • Analytic functions that partition by some key, and return aggregates on the returned record set
  • Functions based on aggregates over records that include those not in the returned record set
  • Constraints based on aggregates over records that include those not in the returned record set
  • Constraints on column values

The view functionality can be described in words as:

  • Selected values
    • Employee name, department name, and salary
    • Manager's name
    • Ratio of employee's salary to the department average (returned employees only)
    • Ratio of employee's salary to the average salary of all employees
  • Constraints
    • Exclude employees in job 'AD_ASST'
    • Exclude employees without a department
    • Do not return any records if the total salary of all employees is below 1600
  • Outer join
    • Include employees both with and without a manager

The view SQL is:

CREATE OR REPLACE VIEW hr_test_view_v AS
WITH all_emps AS (
        SELECT Avg (salary) avg_sal, SUM (salary) sal_tot_g
          FROM employees e
)
SELECT e.last_name, d.department_name, m.last_name manager, e.salary,
       Round (e.salary / Avg (e.salary) OVER (PARTITION BY e.department_id), 2) sal_rat,
       Round (e.salary / a.avg_sal, 2) sal_rat_g
  FROM all_emps a
 CROSS JOIN employees e
  JOIN departments d
    ON d.department_id = e.department_id
  LEFT JOIN employees m
    ON m.employee_id = e.manager_id
 WHERE e.job_id != 'AD_ASST'
   AND a.sal_tot_g >= 1600

Scenarios and Sub-scenarios

Scenario definition
Following our earlier article, we may define a scenario as being the set of all relevant records, both on the database and passed as parameters, to a single program call. API or view testing involves creating one or more scenarios, calling the program (or executing the process) for each scenario, and verifying that the output records are as expected.

Good testing is achieved when the scenarios are chosen to validate as wide a range of behaviours as possible. It is not always, or usually, necessary to create a new scenario for each aspect of behaviour to be tested.

Sub-scenario definition
Often, several features can be tested in the same program call by setting up different records in the scenario that will independently test the different features. For example, in our use case above we can create employees with and without a department, and with and without a manager in the same scenario to test the different types of join.

It may be helpful to think of these separate records, or fields within a record, as corresponding to sub-scenarios, and try to construct scenarios as efficiently as possible without making more calls than necessary.

View Test Output

Data setup section

SCENARIO 1: DS-1, testing inner, outer joins, analytic over dep, and global ratios with 1 dep, Employees created in setup: DS-1 - 4 emps, 1 dep (10), emp-3 has no dep, emp-4 has bad job
=========================================================================================================================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1493             10              IT_PROG           1000
2         1494             10        1493  IT_PROG           2000
3         1495                       1493  IT_PROG           3000
4         1496             10        1493  AD_ASST           4000

SCENARIO 2: DS-2, testing same as 1 but with extra emp in another dep, Employees created in setup: DS-2 - As dataset 1 but with extra emp-5, in second dep (20)
===============================================================================================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1497             10              IT_PROG           1000
2         1498             10        1497  IT_PROG           2000
3         1499                       1497  IT_PROG           3000
4         1500             10        1497  AD_ASST           4000
5         1501             20        1497  IT_PROG           5000

SCENARIO 3: DS-2, passing 'WHERE dep=10', Employees created in setup: DS-2 - As dataset 1 but with extra emp-5, in second dep (20)
==================================================================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1502             10              IT_PROG           1000
2         1503             10        1502  IT_PROG           2000
3         1504                       1502  IT_PROG           3000
4         1505             10        1502  AD_ASST           4000
5         1506             20        1502  IT_PROG           5000

SCENARIO 4: DS-3, Salaries total 1500 (< threshold of 1600), Employees created in setup: DS-3 - As dataset 2 but with salaries * 0.1, total below reporting threshold of 1600
=============================================================================================================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1507             10              IT_PROG            100
2         1508             10        1507  IT_PROG            200
3         1509                       1507  IT_PROG            300
4         1510             10        1507  AD_ASST            400
5         1511             20        1507  IT_PROG            500

Notes on data setup section

  • There are three data sets, and four scenarios, each of which references a data set
  • The call to set up the data for a scenario writes out all the data created
  • A header provides a description of the features (or sub-scenarios) in the data set
  • In the output above scenarios 2 and 3 use the same data set, DS-2

Results section

SQL>BEGIN

  Utils.Clear_Log;
  Utils_TT.Run_Suite (Utils_TT.c_tt_suite_bren);

EXCEPTION
  WHEN OTHERS THEN
    Utils.Write_Other_Error;
END;
/
SQL> @L_Log_Default

TEXT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------


TRAPIT TEST: TT_View_Drivers.tt_HR_Test_View_V
==============================================

Employees created in setup: DS-1 - 4 emps, 1 dep (10), emp-3 has no dep, emp-4 has bad job
==========================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1518             10              IT_PROG           1000
2         1519             10        1518  IT_PROG           2000
3         1520                       1518  IT_PROG           3000
4         1521             10        1518  AD_ASST           4000

Employees created in setup: DS-2 - As dataset 1 but with extra emp-5, in second dep (20)
========================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1522             10              IT_PROG           1000
2         1523             10        1522  IT_PROG           2000
3         1524                       1522  IT_PROG           3000
4         1525             10        1522  AD_ASST           4000
5         1526             20        1522  IT_PROG           5000

Employees created in setup: DS-2 - As dataset 1 but with extra emp-5, in second dep (20)
========================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1527             10              IT_PROG           1000
2         1528             10        1527  IT_PROG           2000
3         1529                       1527  IT_PROG           3000
4         1530             10        1527  AD_ASST           4000
5         1531             20        1527  IT_PROG           5000

Employees created in setup: DS-3 - As dataset 2 but with salaries * 0.1, total below reporting threshold of 1600
================================================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1532             10              IT_PROG            100
2         1533             10        1532  IT_PROG            200
3         1534                       1532  IT_PROG            300
4         1535             10        1532  AD_ASST            400
5         1536             20        1532  IT_PROG            500

SCENARIO 1: DS-1, testing inner, outer joins, analytic over dep, and global ratios with 1 dep {
===============================================================================================

    INPUTS
    ======

        GROUP Employee {
        ================

            Employee Id  Last Name  Email  Hire Date  Job      Salary  Manager Id  department Id
            -----------  ---------  -----  ---------  -------  ------  ----------  -------------
                   1518  LN_1       EM_1   09-JUL-16  IT_PROG    1000                         10
                   1519  LN_2       EM_2   09-JUL-16  IT_PROG    2000        1518             10
                   1520  LN_3       EM_3   09-JUL-16  IT_PROG    3000        1518
                   1521  LN_4       EM_4   09-JUL-16  AD_ASST    4000        1518             10

        }
        =

        GROUP Where {
        =============

            Where
            -----


        }
        =

    OUTPUTS
    =======

        GROUP Select results: Actual = 2, Expected = 2 {
        ================================================

            F?  Name  Department      Manager  Salary  Salary Ratio (dep)  Salary Ratio (overall)
            --  ----  --------------  -------  ------  ------------------  ----------------------
                LN_1  Administration             1000                 .67                      .4
                LN_2  Administration  LN_1       2000                1.33                      .8

        } 0 failed, of 2: SUCCESS
        =========================

} 0 failed, of 2: SUCCESS
=========================

SCENARIO 2: DS-2, testing same as 1 but with extra emp in another dep {
=======================================================================

    INPUTS
    ======

        GROUP Employee {
        ================

            Employee Id  Last Name  Email  Hire Date  Job      Salary  Manager Id  department Id
            -----------  ---------  -----  ---------  -------  ------  ----------  -------------
                   1522  LN_1       EM_1   09-JUL-16  IT_PROG    1000                         10
                   1523  LN_2       EM_2   09-JUL-16  IT_PROG    2000        1522             10
                   1524  LN_3       EM_3   09-JUL-16  IT_PROG    3000        1522
                   1525  LN_4       EM_4   09-JUL-16  AD_ASST    4000        1522             10
                   1526  LN_5       EM_5   09-JUL-16  IT_PROG    5000        1522             20

        }
        =

        GROUP Where {
        =============

            Where
            -----


        }
        =

    OUTPUTS
    =======

        GROUP Select results: Actual = 3, Expected = 3 {
        ================================================

            F?  Name  Department      Manager  Salary  Salary Ratio (dep)  Salary Ratio (overall)
            --  ----  --------------  -------  ------  ------------------  ----------------------
                LN_1  Administration             1000                 .67                     .33
                LN_2  Administration  LN_1       2000                1.33                     .67
                LN_5  Marketing       LN_1       5000                   1                    1.67

        } 0 failed, of 3: SUCCESS
        =========================

} 0 failed, of 3: SUCCESS
=========================

SCENARIO 3: DS-2, passing 'WHERE dep=10' {
==========================================

    INPUTS
    ======

        GROUP Employee {
        ================

            Employee Id  Last Name  Email  Hire Date  Job      Salary  Manager Id  department Id
            -----------  ---------  -----  ---------  -------  ------  ----------  -------------
                   1527  LN_1       EM_1   09-JUL-16  IT_PROG    1000                         10
                   1528  LN_2       EM_2   09-JUL-16  IT_PROG    2000        1527             10
                   1529  LN_3       EM_3   09-JUL-16  IT_PROG    3000        1527
                   1530  LN_4       EM_4   09-JUL-16  AD_ASST    4000        1527             10
                   1531  LN_5       EM_5   09-JUL-16  IT_PROG    5000        1527             20

        }
        =

        GROUP Where {
        =============

            Where
            --------------------------------
            department_name='Administration'

        }
        =

    OUTPUTS
    =======

        GROUP Select results: Actual = 2, Expected = 2 {
        ================================================

            F?  Name  Department      Manager  Salary  Salary Ratio (dep)  Salary Ratio (overall)
            --  ----  --------------  -------  ------  ------------------  ----------------------
                LN_1  Administration             1000                 .67                     .33
                LN_2  Administration  LN_1       2000                1.33                     .67

        } 0 failed, of 2: SUCCESS
        =========================

} 0 failed, of 2: SUCCESS
=========================

SCENARIO 4: DS-3, Salaries total 1500 (< threshold of 1600) {
=============================================================

    INPUTS
    ======

        GROUP Employee {
        ================

            Employee Id  Last Name  Email  Hire Date  Job      Salary  Manager Id  department Id
            -----------  ---------  -----  ---------  -------  ------  ----------  -------------
                   1532  LN_1       EM_1   09-JUL-16  IT_PROG     100                         10
                   1533  LN_2       EM_2   09-JUL-16  IT_PROG     200        1532             10
                   1534  LN_3       EM_3   09-JUL-16  IT_PROG     300        1532
                   1535  LN_4       EM_4   09-JUL-16  AD_ASST     400        1532             10
                   1536  LN_5       EM_5   09-JUL-16  IT_PROG     500        1532             20

        }
        =

        GROUP Where {
        =============

            Where
            -----


        }
        =

    OUTPUTS
    =======

        GROUP Select results: Actual = 0, Expected = 0: SUCCESS
        =======================================================

} 0 failed, of 1: SUCCESS
=========================

TIMING: Actual = 48, Expected <= 1: FAILURE
===========================================

SUMMARY for TT_View_Drivers.tt_HR_Test_View_V
=============================================

Scenario                                                                           # Failed  # Tests  Status
---------------------------------------------------------------------------------  --------  -------  -------
DS-1, testing inner, outer joins, analytic over dep, and global ratios with 1 dep         0        2  SUCCESS
DS-2, testing same as 1 but with extra emp in another dep                                 0        3  SUCCESS
DS-2, passing 'WHERE dep=10'                                                              0        2  SUCCESS
DS-3, Salaries total 1500 (< threshold of 1600)                                           0        1  SUCCESS
Timing                                                                                    1        1  FAILURE
---------------------------------------------------------------------------------  --------  -------  -------
Total                                                                                     1        9  FAILURE
---------------------------------------------------------------------------------  --------  -------  -------

Timer Set: TT_View_Drivers.tt_HR_Test_View_V, Constructed at 09 Jul 2016 13:32:42, written at 13:32:42
======================================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000013), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Setup          0.11        0.00             4        0.02675        0.00000
Caller         0.19        0.06             4        0.04750        0.01500
(Other)        0.03        0.03             1        0.02700        0.03000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.32        0.09             9        0.03600        0.01000
-------  ----------  ----------  ------------  -------------  -------------

Notes on results section

  • In a view test there is only one group, namely the selected data set

The second part of the article is here: Design Patterns for Database Unit Testing 2: Views 2 - Code






 

A Template Script for JDBC Calling of Oracle Procedures with Object Array Parameters

Some time ago I wrote an Oracle database package for a web service. The Java developer for the service told me that it was throwing an error when called from Java, although I had unit tested it from PL/SQL. He gave me a small Java driver script to demonstrate the issue, and this allowed the issue to be quickly identified: As both Java and PL/SQL have boolean data types I had considered that a boolean parameter would make sense to pass a boolean value. However, it turns out that this does not work in JDBC, and so I replaced it with an integer parameter.

It occurred to me then that it would be nice if the database developer was able in general to test JDBC compatibility of his or her procedure as a final step after unit testing. To this end I created a more generic example script based on a simple procedure that I wrote against Oracle's HR demo schema, the same procedure that I used as an example of a unit testing design pattern Design Patterns for Database Unit Testing 2: Web Service Saving - Code

Update, 4 November 2017: I have made a self-contained project on GitHub with both Java and Oracle code, avoiding dependency on my testing project. JDBC Calling of Oracle Procedures with Object Array Parameters on GitHub. I have also added the Oracle code below.

The code below runs against any Oracle instance in which the standard Oracle HR demo schema has been installed. There is a video demonstration of how to install and run it at the end of this article. The procedure has one input and one output object array parameter, and can easily be extended as desired. It requires one jar file in the classpath, ojdbc6.jar, which is available in Oracle client or database installations, and can be run from an IDE such as Eclipse.

Java Code

package jdbcdemo;
/***************************************************************************************************
Name:        Driver.java
Description: This is a Java driver script for Brendan's HR demo web service procedure. It is
             designed to serve as a template for other web service procedures to allow a database
             developer to do a JDBC integration test easily, and can also be used as a starting point
             for Java development.

             The template procedure takes an input array of objects and has an output array of 
             objects. It is easy to update for any named object and array types, procedure and
             Oracle connection. Any other signature types would need additional changes.

	     See 'A Template Script for JDBC Calling of Oracle Procedures with Object Array Parameters'
             
A Template Script for JDBC Calling of Oracle Procedures with Object Array Parameters
Modification History Who When Which What -------------------- ----------- ----- ------------------------------------------------------------- Brendan Furey 14-May-2016 1.0 Created Brendan Furey 04-Nov-2017 1.1 Put into new GitHub project along with Oracle code ***************************************************************************************************/ import java.sql.DriverManager; import java.sql.SQLException; import java.sql.Array; import java.sql.Struct; import oracle.jdbc.OracleTypes; import oracle.jdbc.OracleCallableStatement; import oracle.jdbc.OracleConnection; public class Driver { // Change section 1/2: Replace these constants with your own values private static final String DB_CONNECTION = "jdbc:oracle:thin:hr/hr@localhost:1521/orclpdb"; private static final String TY_IN_OBJ = "TY_EMP_IN_OBJ"; private static final String TY_IN_ARR = "TY_EMP_IN_ARR"; private static final String TY_OUT_ARR = "TY_EMP_OUT_ARR"; private static final String PROC_NAME = "Emp_WS.AIP_Save_Emps"; private static OracleConnection conn; public static void main(String[] argv) { try { getDBConnection (); prOutArray (callProc (inArray ())); } catch (SQLException e) { System.out.println(e.getMessage()); } } private static Array inArray () throws SQLException { // Change section 2/2: Replace [2] with number of test records, and the arrays with their values Struct[] struct = new Struct[2]; struct[0] = conn.createStruct (TY_IN_OBJ, new Object[] {"LN 1", "EM 1", "IT_PROG", 1000}); struct[1] = conn.createStruct (TY_IN_OBJ, new Object[] {"LN 2", "EM 2", "IT_PROG", 2000}); return conn.createARRAY (TY_IN_ARR, struct); } private static Array callProc (Array objArray) throws SQLException { OracleCallableStatement ocs = (OracleCallableStatement) conn.prepareCall ("BEGIN "+PROC_NAME+"(:1, :2); END;"); ocs.setArray (1, objArray); ocs.registerOutParameter (2, OracleTypes.ARRAY, TY_OUT_ARR); ocs.execute (); return ocs.getARRAY (2); } private static void prOutArray (Array arr) throws SQLException { Object[] objArr = (Object[]) arr.getArray(); int j = 0; for (Object rec : objArr) { Object[] objLis = ((Struct)rec).getAttributes (); int i = 0; String recStr = ""; for (Object fld : objLis) { if (i++ > 0) recStr = recStr + '/'; recStr = recStr + fld.toString(); } System.out.println ("Record "+(++j)+": "+recStr); } } private static void getDBConnection () throws SQLException { conn = (OracleConnection) DriverManager.getConnection (DB_CONNECTION); conn.setAutoCommit (false); System.out.println ("Connected..."); } }

Example output

Connected...
Record 1: 239/TWO HUNDRED THIRTY-NINE
Record 2: 240/TWO HUNDRED FORTY

Google Java Style

Oracle Code

/***************************************************************************************************

Author:      Brendan Furey
Description: Script to create objects to demo JDBC procedure calls with object array parameters

         See 'A Template Script for JDBC Calling of Oracle Procedures with Object Array Parameters'
             
A Template Script for JDBC Calling of Oracle Procedures with Object Array Parameters
Modification History Who When Which What -------------------- ----------- ----- ------------------------------------------------------------- Brendan Furey 04-May-2016 1.0 Created Brendan Furey 04-Nov-2017 1.1 Extracted the JDBC demo code from the unit testing project, and put into new GitHub project along with Java code ***************************************************************************************************/ REM Run this script from Oracle's standard HR schema to create objects to demo JDBC procedure calls COLUMN "Database" FORMAT A20 COLUMN "Time" FORMAT A20 COLUMN "Version" FORMAT A30 COLUMN "Session" FORMAT 9999990 COLUMN "OS User" FORMAT A10 COLUMN "Machine" FORMAT A20 SELECT 'Start: ' || dbs.name "Database", To_Char (SYSDATE,'DD-MON-YYYY HH24:MI:SS') "Time", Replace (Substr(ver.banner, 1, Instr(ver.banner, '64')-4), 'Enterprise Edition Release ', '') "Version" FROM v$database dbs, v$version ver WHERE ver.banner LIKE 'Oracle%'; PROMPT Input types creation DROP TYPE ty_emp_in_arr / CREATE OR REPLACE TYPE ty_emp_in_obj AS OBJECT ( last_name VARCHAR2(25), email VARCHAR2(25), job_id VARCHAR2(10), salary NUMBER ) / CREATE TYPE ty_emp_in_arr AS TABLE OF ty_emp_in_obj / PROMPT Output types creation DROP TYPE ty_emp_out_arr / CREATE OR REPLACE TYPE ty_emp_out_obj AS OBJECT ( employee_id NUMBER, description VARCHAR2(500) ) / CREATE TYPE ty_emp_out_arr AS TABLE OF ty_emp_out_obj / CREATE OR REPLACE PACKAGE Emp_WS AS /*************************************************************************************************** Description: HR demo web service code. Procedure saves new employees list and returns primary key plus same in words, or zero plus error message in output list ***************************************************************************************************/ PROCEDURE AIP_Save_Emps (p_ty_emp_in_lis ty_emp_in_arr, x_ty_emp_out_lis OUT ty_emp_out_arr); END Emp_WS; / CREATE OR REPLACE PACKAGE BODY Emp_WS AS PROCEDURE AIP_Save_Emps (p_ty_emp_in_lis ty_emp_in_arr, -- list of employees to insert x_ty_emp_out_lis OUT ty_emp_out_arr) IS -- list of employee results l_ty_emp_out_lis ty_emp_out_arr; bulk_errors EXCEPTION; PRAGMA EXCEPTION_INIT (bulk_errors, -24381); n_err PLS_INTEGER := 0; BEGIN FORALL i IN 1..p_ty_emp_in_lis.COUNT SAVE EXCEPTIONS INSERT INTO employees ( employee_id, last_name, email, hire_date, job_id, salary ) VALUES ( employees_seq.NEXTVAL, p_ty_emp_in_lis(i).last_name, p_ty_emp_in_lis(i).email, SYSDATE, p_ty_emp_in_lis(i).job_id, p_ty_emp_in_lis(i).salary ) RETURNING ty_emp_out_obj (employee_id, To_Char(To_Date(employee_id,'J'),'JSP')) BULK COLLECT INTO x_ty_emp_out_lis; EXCEPTION WHEN bulk_errors THEN l_ty_emp_out_lis := x_ty_emp_out_lis; FOR i IN 1 .. sql%BULK_EXCEPTIONS.COUNT LOOP IF i > x_ty_emp_out_lis.COUNT THEN x_ty_emp_out_lis.Extend; END IF; x_ty_emp_out_lis (SQL%Bulk_Exceptions (i).Error_Index) := ty_emp_out_obj (0, SQLERRM (- (SQL%Bulk_Exceptions (i).Error_Code))); END LOOP; FOR i IN 1..p_ty_emp_in_lis.COUNT LOOP IF i > x_ty_emp_out_lis.COUNT THEN x_ty_emp_out_lis.Extend; END IF; IF x_ty_emp_out_lis(i).employee_id = 0 THEN n_err := n_err + 1; ELSE x_ty_emp_out_lis(i) := l_ty_emp_out_lis(i - n_err); END IF; END LOOP; END AIP_Save_Emps; END Emp_WS; /

Here is a demo of installing and running the code, Oracle and Java: