Oracle and JUnit Data Driven Testing: An Example

In Design Patterns for Database API Testing 1: Web Service Saving 2 - Code I identified a number of antipatterns commonly seen in database testing.

utPLSQL, originally developed by Steve Feuerstein around 15 years ago, may have been the first Oracle unit testing framework and seems to be the most widely used. Its new utPLSQL GitHub Page describes itself thus:

The official new home of utPLSQL, unit testing framework for PL/SQL, based on xUnit.

xUnit refers to the family of unit testing frameworks derived from Java's JUnit, and present in most object-oriented languages, such as Ruby, Python etc.

It has occurred to me that some of the problems with unit testing in the database world may arise from translating object-oriented ideas on testing too zealously into the database world, where they may not work so well. It could also impinge on the design of base code, in that in the object-oriented world any complexity in unit tests is usually seen as a 'code smell' indicating the base units are too complex; testability is seen as a key objective in OO module design. To gain some insight into the differences between database and object-oriented testing, it seemed like a good idea to try to test the same functionality in both Java and Oracle. This article gives the results of this experiment.

I have submitted an abstract for a presentation entitled "Database Functional Testing: Automation, Yes; xUnit-Style Micro-Testing, No" to one of the Oracle User Group conferences for Q1 2017, but it has not yet been approved or rejected.

Update, 10 May 2017: My abstract for the Ireland OUG in March 2017 was not accepted. I did present on a second abstract that was accepted: Dimensional Performance Benchmarking of SQL - IOUG Presentation

Testing Example

In Java unit testing one normally tries to test code in isolation, without database access or other dependencies, whereas in Oracle it is normally database operations that are being tested. As a compromise I chose to implement code that would read a single key column from a CSV file and store counts of the key values in memory, with methods to return these key-value pairs as lists either unordered, ordered by key, or ordered by value (then key).

The constructor method will take three parameters:

  • File name
  • Delimiter
  • Key column position

We'll use the same file name, which in Java will include the full path, whereas Oracle will assume the path from an Oracle directory object. There will be two scenarios that will test different values for the other two parameters simultaneously (as what I call sub-scenarios in Design Patterns for Database API Testing 1: Web Service Saving 1 - Design).

For the unordered method, we will validate only the scalar count of the records returned, while for the ordered methods we will validate the full ordered lists of tuples returned. For illustrative purposes one test method for each scenario will have a deliberate error in the expected values.

Test Scenario 1 - Tie-break/single-delimiter/interior column

Here the test file has four columns, with the key column being the third, and the delimiter a single character ','. The file contains lines:

0,1,Cc,3
00,1,A,9
000,1,B,27
0000,1,A,81

Note that keys 'Cc' and 'B' both occur once, and when ordered by value (then key) 'B' should appear before 'Cc'.

Test Scenario 2 - Two copies/double-delimiter/first column

Here the test file has three columns, with the key column being the first, and the delimiter two characters ';;'. The file contains two identical lines:

X;;1;;A
X;;1;;A

Java - JUnit

JUnit Code

package colgroup;
/***************************************************************************************************
Name:        TestColGroup.java

Description: Junit testing class for Col_Group class. Uses Parameterized.class to data-drive
                                                                               
Modification History
Who                  When        Which What
-------------------- ----------- ----- -------------------------------------------------------------
B. Furey             22-Oct-2016 1.0   Created                       

***************************************************************************************************/
import static org.junit.Assert.*;

import java.io.IOException;
import java.nio.charset.StandardCharsets;
import java.nio.file.Files;
import java.nio.file.Paths;
import java.util.AbstractMap;
import java.util.ArrayList;
import java.util.Arrays;
import java.util.Collection;
import java.util.List;
import java.util.Map;

import org.junit.After;
import org.junit.Before;
import org.junit.Test;
import org.junit.runner.RunWith;
import org.junit.runners.Parameterized.Parameters;
import org.junit.runners.Parameterized;

@RunWith(Parameterized.class)
public class TestColGroup {
/***************************************************************************************************

Private instance variables: 2 scenarios, input, and expected records declared here, initially in 
2-level generic arrays, but expected records transferred to List for assertion

***************************************************************************************************/
  private ColGroup colGroup = null;
  private String testFile = "H:/Script/Input/ut_group.csv";
  private String[][] testLines = new String[][] { 
      {"0,1,Cc,3", "00,1,A,9", "000,1,B,27", "0000,1,A,81"}, 
      {"X;;1;;A", "X;;1;;A"}
  };
  private String[] testDelim = new String[] {",", ";;"};
  private int[] testColnum = new int[] {2, 0};
  private List<String> lines;
  private String delim;
  private int colnum;

  private String[][] keysK = new String[][] { 
      {"A", "Bx", "Cc"}, 
      {"X"}
  };
  private int[][] valuesK = new int[][] { 
      {2, 1, 1}, 
      {2}
  };
  private String[][] keysV = new String[][] { 
      {"B", "Cc", "A"},
      {"X"}
  };
  private int[][] valuesV = new int[][] { 
      {1, 1, 2}, 
      {2}
  };
  private int expAsIs;
  private List<Map.Entry<String,Long>> expListK = null;
  private List<Map.Entry<String,Long>> expListV = null;

  private void addMap (int i, String strValK, int lonValK, String strValV, int lonValV) {
    expListK.add (i, new AbstractMap.SimpleEntry<String, Long> (strValK, (long) lonValK));
    expListV.add (i, new AbstractMap.SimpleEntry<String, Long> (strValV, (long) lonValV));
  }

  private int testNum;

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

  TestColGroup: Constructor function, which sets the instance variables for given scenario (testNum), and
                is called before each test with parameters passed via test_data (see end)

  ***************************************************************************************************/
  public TestColGroup (int   testNum,   // test scenario number
                  int   nGroups) { // number of groups

    System.out.println("Doing TestCG3 before test "+testNum+"...");
    this.lines = Arrays.asList (testLines[testNum]);
    this.delim = testDelim[testNum];
    this.colnum = testColnum[testNum];
    this.expAsIs = nGroups;
    this.testNum = testNum;
    int i = 0;
    expListK = new ArrayList<Map.Entry<String,Long>>(keysK[testNum].length);
    expListV = new ArrayList<Map.Entry<String,Long>>(keysV[testNum].length);
    for (String k : keysK[testNum]) {
      addMap (i, k, valuesK[testNum][i], keysV[testNum][i], valuesV[testNum][i]);
      i++;
    }
  }
  /***************************************************************************************************

  getGroup: Before each test method to write the test file and instantiate base object, using instance
            variables set for the scenario in TestCG3

  ***************************************************************************************************/
  @Before
  public void getGroup() {
    try {
      System.out.println("Doing setup before test "+this.testNum+"...");
      Files.write (Paths.get (testFile), lines, StandardCharsets.UTF_8);
      colGroup = new ColGroup (testFile, delim, colnum);
    } catch (IOException e) {
      e.printStackTrace();
    }
  }
  /***************************************************************************************************

  delFile: After each test method to delete the test file

  ***************************************************************************************************/
  @After
  public void delFile() {
    try {
      System.out.println("Doing teardown after test "+this.testNum+"...");
      Files.delete(Paths.get (testFile));
    } catch (IOException e) {
      e.printStackTrace();
    }
  }
  /***************************************************************************************************

  test*: Test method for each base method; each one is run once for each record defined in test_data
         in @Parameters

  ***************************************************************************************************/
  @Test
  public void testAsIs() {

    List<Map.Entry<String,Long>> actList = colGroup.listAsIs();
    assertEquals ("(as is)", expAsIs, actList.size());
    colGroup.prList("(as is)", actList);
  }
  @Test
  public void testKey() {

    List<Map.Entry<String,Long>> actList = colGroup.sortByKey();
    assertEquals ("keys", expListK, actList);
    colGroup.prList("keys", actList);
  }
  @Test
  public void testValue() {
    List<Map.Entry<String,Long>> actList = colGroup.sortByValue();
    assertEquals ("values", expListV, actList);
    colGroup.prList("values", actList);
  }
  /***************************************************************************************************

  test_data: @Parameters section allows passing of data into tests per scenario; neater to pass in a
             pointer to the instance arrays for most of the data

  ***************************************************************************************************/
  @Parameters
  public static Collection<Object[]> test_data() {
    Object[][] data = new Object[][] { {0, 3}, {1, 2} }; // 2 records, columns = scenario #, # groups
    return Arrays.asList(data);
  }
}

JUnit Output

Unit Test Results.

Designed for use with JUnit and Ant.

All Tests

Class Name Status Type Time(s)
TestColGroup testKey[0] Failure keys expected:<[A=2, Bx=1, Cc=1]> but was:<[A=2, B=1, Cc=1]>

junit.framework.AssertionFailedError: keys expected:<[A=2, Bx=1, Cc=1]> but was:<[A=2, B=1, Cc=1]>
at colgroup.TestColGroup.testKey(TestColGroup.java:150)

0.055
TestColGroup testValue[0] Success 0.004
TestColGroup testAsIs[0] Success 0.002
TestColGroup testKey[1] Success 0.004
TestColGroup testValue[1] Success 0.002
TestColGroup testAsIs[1] Failure (as is) expected:<2> but was:<1>

junit.framework.AssertionFailedError: (as is) expected:<2> but was:<1>
at colgroup.TestColGroup.testAsIs(TestColGroup.java:143)

0.002

JUnit Notes

  • JUnit first creates instances of the test class for each test method and starts running the tests after each instance is created
  • From JUnit 4 it is possible to data-drive testing by means of the @Parameters annotation, as implemented here, whereas I identified lack of data-driving as a common antipattern
  • Test methods are identifiable only by their method names rather than full descriptions
  • Scenarios are identifiable only by a number, which is even worse
  • Execution of a test method (instance) is aborted on failure of any assertion
  • Here there is only one test method per base method, but in general there could be several
  • JUnit aborting on assertion failure means that unit tests should have one or very few assertions, with additional unit tests being generated where necessary
  • Data-driving allows JUnit to generate additional unit tests from a single method at run-time for each scenario
  • A good approach is to start with a single parameterized scenario, then add new scenarios just by adding data records; this is how I usually proceed in Oracle
  • On assertion failure JUnit prints expected and actual values for both scalar and complex values passed to the assertion

Oracle - utPLSQL

utPLSQL Code

CREATE OR REPLACE PACKAGE BODY UT_Col_Group AS
/***************************************************************************************************

Description: utPLSQL unit testing for polyglot group-counting module, Col_Group
                                                                               
Modification History
Who                  When        Which What
-------------------- ----------- ----- -------------------------------------------------------------
Brendan Furey        30-Oct-2016 1.0   Created

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

c_proc_name_asis        CONSTANT VARCHAR2(60) := 'Col_Group.ut_AIP_List_Asis';
c_proc_name_key         CONSTANT VARCHAR2(60) := 'Col_Group.ut_AIP_Sort_By_Key';
c_proc_name_value       CONSTANT VARCHAR2(60) := 'Col_Group.ut_AIP_Sort_By_vALUE';

c_file_2lis             CONSTANT L2_chr_arr := L2_chr_arr (
                                      L1_chr_arr ('0,1,Cc,3', '00,1,A,9', '000,1,B,27', '0000,1,A,81'),
                                      L1_chr_arr ('X;;1;;A', 'X;;1;;A')
);
c_prms_2lis             CONSTANT L2_chr_arr := L2_chr_arr (
                                      L1_chr_arr ('lines.csv', ',', '3'), L1_chr_arr ('lines.csv', ';;', '1')
);
c_scenario_lis          CONSTANT L1_chr_arr := L1_chr_arr ('Tie-break/single-delimiter/interior column', 'Two copies/double-delimiter/first column');

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

ut_Setup, ut_Teardown: Mandatory procedures for utPLSQL but don't do anything here

***************************************************************************************************/
PROCEDURE ut_Setup IS
BEGIN
  NULL;
END ut_Setup;

PROCEDURE ut_Teardown IS
BEGIN
  NULL;
END ut_Teardown;

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

Do_Test: Main local procedure for utPLSQL unit testing Col_Group methods

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

PROCEDURE Do_Test (p_proc_name          VARCHAR2,      -- procedure name
                   p_exp_2lis           L2_chr_arr) IS -- expected values 2-d array

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

  Setup: Setup procedure for unit testing Col_Group package. Writes test file, then calls
         constructor API to store data in an array, line counts grouped by key

  ***************************************************************************************************/
  PROCEDURE Setup (p_file                 VARCHAR2,      -- file name
                   p_delim                VARCHAR2,      -- delimiter
                   p_colnum               PLS_INTEGER,   -- key column number in file
                   p_dat_lis              L1_chr_arr) IS -- lines to write to test file

  BEGIN

    Utils.Delete_File (p_file);
    Utils.Write_File (p_file, p_dat_lis);

    Col_Group.AIP_Load_File (p_file => p_file, p_delim => p_delim, p_colnum => p_colnum);

  END Setup;

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

  Call_Proc: Calls the base method according to calling procedure, and uses utPLSQL assert procedure
             to assert list counts, and for ordered methods, record lists in delimited form

  ***************************************************************************************************/
  PROCEDURE Call_Proc (p_exp_lis        L1_chr_arr,  -- expected values list (delimited records)
                       p_scenario       VARCHAR2) IS -- scenario description

    l_arr_lis           chr_int_arr;
  BEGIN

    l_arr_lis := CASE p_proc_name
                   WHEN c_proc_name_asis        THEN Col_Group.AIP_List_Asis
                   WHEN c_proc_name_key         THEN Col_Group.AIP_Sort_By_Key
                   WHEN c_proc_name_value       THEN Col_Group.AIP_Sort_By_Value
                 END;

    IF p_proc_name = c_proc_name_asis THEN

      utAssert.Eq (p_scenario || ': List count', l_arr_lis.COUNT, p_exp_lis(1), TRUE);

    ELSE

      utAssert.Eq (p_scenario || ': List count', l_arr_lis.COUNT, p_exp_lis.COUNT, TRUE);
      FOR i IN 1..LEAST (l_arr_lis.COUNT, p_exp_lis.COUNT) LOOP

        utAssert.Eq ('...Record', Utils.List_Delim (l_arr_lis(i).chr_field, l_arr_lis(i).int_field), p_exp_lis(i), TRUE);

      END LOOP;

    END IF;

  END Call_Proc;

BEGIN

  FOR i IN 1..c_file_2lis.COUNT LOOP

    Setup (p_file              => c_prms_2lis(i)(1),
           p_delim             => c_prms_2lis(i)(2),
           p_colnum            => c_prms_2lis(i)(3),
           p_dat_lis           => c_file_2lis(i));

    Call_Proc (p_exp_2lis(i), c_scenario_lis(i));

  END LOOP;

END Do_Test;

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

ut_AIP_List_Asis: Entry procedure for utPLSQL testing Col_Group.AIP_List_Asis

***************************************************************************************************/
PROCEDURE ut_AIP_List_Asis IS

  c_proc_name           CONSTANT VARCHAR2(61) := c_proc_name_asis;
  c_exp_2lis            CONSTANT L2_chr_arr := L2_chr_arr (L1_chr_arr('3'), L1_chr_arr('2'));

BEGIN

  Do_Test (c_proc_name, c_exp_2lis);

END ut_AIP_List_Asis;

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

ut_AIP_Sort_By_Key: Entry procedure for utPLSQL testing Col_Group.AIP_Sort_By_Key

***************************************************************************************************/
PROCEDURE ut_AIP_Sort_By_Key IS

  c_proc_name           CONSTANT VARCHAR2(61) := c_proc_name_key;
  c_exp_2lis            CONSTANT L2_chr_arr := L2_chr_arr (L1_chr_arr (Utils.List_Delim ('A','2'),
                                                                         Utils.List_Delim ('Bx','1'),
                                                                         Utils.List_Delim ('Cc','1')),
                                                             L1_chr_arr (Utils.List_Delim ('X','2'))
                                               );
BEGIN

  Do_Test (c_proc_name, c_exp_2lis);

END ut_AIP_Sort_By_Key;

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

ut_AIP_Sort_By_Value: Entry procedure for utPLSQL testing Col_Group.AIP_Sort_By_Value

***************************************************************************************************/
PROCEDURE ut_AIP_Sort_By_Value IS

  c_proc_name           CONSTANT VARCHAR2(61) := c_proc_name_value;
  c_exp_2lis            CONSTANT L2_chr_arr := L2_chr_arr (L1_chr_arr (Utils.List_Delim ('B','1'),
                                                                         Utils.List_Delim ('Cc','1'),
                                                                         Utils.List_Delim ('A','2')),
                                                             L1_chr_arr (Utils.List_Delim ('X','2'))
                                               );
BEGIN

  Do_Test (c_proc_name, c_exp_2lis);

END ut_AIP_Sort_By_Value;

END UT_Col_Group;
/

utPLSQL Output

.
>  FFFFFFF   AA     III  L      U     U RRRRR   EEEEEEE
>  F        A  A     I   L      U     U R    R  E
>  F       A    A    I   L      U     U R     R E
>  F      A      A   I   L      U     U R     R E
>  FFFF   A      A   I   L      U     U RRRRRR  EEEE
>  F      AAAAAAAA   I   L      U     U R   R   E
>  F      A      A   I   L      U     U R    R  E
>  F      A      A   I   L       U   U  R     R E
>  F      A      A  III  LLLLLLL  UUU   R     R EEEEEEE
.
 FAILURE: ".COL_GROUP"
.
> Individual Test Case Results:
>
SUCCESS - COL_GROUP.UT_AIP_LIST_ASIS: EQ "Tie-break/single-delimiter/interior column: List count" Expected "3" and got "3"
>
FAILURE - COL_GROUP.UT_AIP_LIST_ASIS: EQ "Two copies/double-delimiter/first column: List count" Expected "2" and got "1"
>
SUCCESS - COL_GROUP.UT_AIP_SORT_BY_KEY: EQ "Tie-break/single-delimiter/interior column: List count" Expected "3" and got "3"
>
SUCCESS - COL_GROUP.UT_AIP_SORT_BY_KEY: EQ "...Record" Expected "A|2" and got "A|2"
>
FAILURE - COL_GROUP.UT_AIP_SORT_BY_KEY: EQ "...Record" Expected "Bx|1" and got "B|1"
>
SUCCESS - COL_GROUP.UT_AIP_SORT_BY_KEY: EQ "...Record" Expected "Cc|1" and got "Cc|1"
>
SUCCESS - COL_GROUP.UT_AIP_SORT_BY_KEY: EQ "Two copies/double-delimiter/first column: List count" Expected "1" and got "1"
>
SUCCESS - COL_GROUP.UT_AIP_SORT_BY_KEY: EQ "...Record" Expected "X|2" and got "X|2"
>
SUCCESS - COL_GROUP.UT_AIP_SORT_BY_VALUE: EQ "Tie-break/single-delimiter/interior column: List count" Expected "3" and got "3"
>
SUCCESS - COL_GROUP.UT_AIP_SORT_BY_VALUE: EQ "...Record" Expected "B|1" and got "B|1"
>
SUCCESS - COL_GROUP.UT_AIP_SORT_BY_VALUE: EQ "...Record" Expected "Cc|1" and got "Cc|1"
>
SUCCESS - COL_GROUP.UT_AIP_SORT_BY_VALUE: EQ "...Record" Expected "A|2" and got "A|2"
>
SUCCESS - COL_GROUP.UT_AIP_SORT_BY_VALUE: EQ "Two copies/double-delimiter/first column: List count" Expected "1" and got "1"
>
SUCCESS - COL_GROUP.UT_AIP_SORT_BY_VALUE: EQ "...Record" Expected "X|2" and got "X|2"
>
>
> Errors recorded in utPLSQL Error Log:
>
> NONE FOUND

PL/SQL procedure successfully completed.

utPLSQL Notes

  • Code is shared between the three test methods by means of a common local procedure Do_Test
  • Data-driving is achieved by using generic arrays and looping over scenarios
  • Only the simple assertion procedure utAssert.Eq is used; from experience the complex utPLSQL assertions are rarely suitable, and I think it is conceptually simpler to avoid them altogether
  • In general the lists of actual and expected values may have different cardinalities, so looping over them I use the minimum cardinality as loop maximum, and explicitly assert the counts; this means you may not see the detail for the unmatched records - in my own TRAPIT framework I handle this case by adding null records to the smaller list
  • Delimited records are asserted to limit the number of assertions, which would matter more in realistic cases having larger number of columns
  • utPLSQL does not have any data model for scenarios or output groups, with just a single description field available within the assert call to describe the scenario/group/assertion; I recommend bundling scenario and group information into this message for want of anything better
  • utPLSQL allows only one test method per base method, unlike JUnit, so multiple assertions may be necessary; fortunately an assertion failure does not abort the test procedure
  • utPLSQL test procedures run sequentially, in alphabetical order, unlike JUnit

Oracle - TRAPIT

This is the framework I described in articles listed at TRAPIT - TRansactional API Testing in Oracle. I have renamed the framework, dropping the phrase 'unit testing' because it has connotations from JUnit of testing small, isolated pieces of code, which is not what it is intended for.

TRAPIT Code

CREATE OR REPLACE PACKAGE BODY TT_Col_Group AS
/***************************************************************************************************

Description: TRAPIT (TRansactional API Testing) package for Col_Group

Further details: 'TRAPIT - TRansactional API Testing in Oracle'
                 
TRAPIT - TRansactional API Testing in Oracle
Modification History Who When Which What -------------------- ----------- ----- ------------------------------------------------------------- Brendan Furey 22-Oct-2016 1.0 Created Brendan Furey 13-Nov-2016 1.1 Utils_TT -> Utils_TT ***************************************************************************************************/ c_ms_limit CONSTANT PLS_INTEGER := 2; c_proc_name_asis CONSTANT VARCHAR2(60) := 'Col_Group.tt_AIP_List_Asis'; c_proc_name_key CONSTANT VARCHAR2(60) := 'Col_Group.tt_AIP_Sort_By_Key'; c_proc_name_value CONSTANT VARCHAR2(60) := 'Col_Group.tt_AIP_Sort_By_vALUE'; c_file_2lis CONSTANT L2_chr_arr := L2_chr_arr ( L1_chr_arr ('0,1,Cc,3', '00,1,A,9', '000,1,B,27', '0000,1,A,81'), L1_chr_arr ('X;;1;;A', 'X;;1;;A') ); c_prms_2lis CONSTANT L2_chr_arr := L2_chr_arr ( L1_chr_arr ('lines.csv', ',', '3'), L1_chr_arr ('lines.csv', ';;', '1') ); c_scenario_lis CONSTANT L1_chr_arr := L1_chr_arr ('Tie-break/single-delimiter/interior column', 'Two copies/double-delimiter/first column'); c_inp_group_lis CONSTANT L1_chr_arr := L1_chr_arr ('Parameter', 'File'); c_inp_field_2lis CONSTANT L2_chr_arr := L2_chr_arr ( L1_chr_arr ('File Name', 'Delimiter', '*Column'), L1_chr_arr ('Line') ); c_out_group_lis CONSTANT L1_chr_arr := L1_chr_arr ('Sorted Array'); c_out_fields_2lis CONSTANT L2_chr_arr := L2_chr_arr (L1_chr_arr ('Key', '*Count')); /*************************************************************************************************** Do_Test: Main local procedure for TRAPIT testing Col_Group methods ***************************************************************************************************/ PROCEDURE Do_Test (p_proc_name VARCHAR2, p_exp_2lis L2_chr_arr, p_out_group_lis L1_chr_arr, p_out_fields_2lis L2_chr_arr) IS l_timer_set PLS_INTEGER; l_inp_3lis L3_chr_arr := L3_chr_arr(); l_act_2lis L2_chr_arr := L2_chr_arr(); /*************************************************************************************************** Setup: Setup procedure for TRAPIT testing Col_Group package. Writes test file, then calls constructor API to store data in an array, line counts grouped by key ***************************************************************************************************/ PROCEDURE Setup (p_file VARCHAR2, -- file name p_delim VARCHAR2, -- delimiter p_colnum PLS_INTEGER, -- key column number in file p_dat_lis L1_chr_arr, -- lines to write to test file x_inp_2lis OUT L2_chr_arr) IS -- generic inputs list BEGIN Utils.Delete_File (p_file); Utils.Write_File (p_file, p_dat_lis); x_inp_2lis := L2_chr_arr (L1_chr_arr (Utils.List_Delim (p_file, p_delim, p_colnum)), p_dat_lis); Col_Group.AIP_Load_File (p_file => p_file, p_delim => p_delim, p_colnum => p_colnum); END Setup; /*************************************************************************************************** Call_Proc: Calls the base method according to calling procedure, and converts record lists to delimited form, and populates the actual list for later checking ***************************************************************************************************/ PROCEDURE Call_Proc (x_act_lis OUT L1_chr_arr) IS -- actual values list (delimited records) l_arr_lis chr_int_arr; l_act_lis L1_chr_arr := L1_chr_arr(); BEGIN l_arr_lis := CASE p_proc_name WHEN c_proc_name_asis THEN Col_Group.AIP_List_Asis WHEN c_proc_name_key THEN Col_Group.AIP_Sort_By_Key WHEN c_proc_name_value THEN Col_Group.AIP_Sort_By_Value END; Timer_Set.Increment_Time (l_timer_set, Utils_TT.c_call_timer); l_act_lis.EXTEND (l_arr_lis.COUNT); FOR i IN 1..l_arr_lis.COUNT LOOP l_act_lis(i) := Utils.List_Delim (l_arr_lis(i).chr_field, l_arr_lis(i).int_field); END LOOP; x_act_lis := CASE p_proc_name WHEN c_proc_name_asis THEN L1_chr_arr(l_arr_lis.COUNT) ELSE l_act_lis END; END Call_Proc; BEGIN l_timer_set := Utils_TT.Init (p_proc_name); l_act_2lis.EXTEND (c_file_2lis.COUNT); l_inp_3lis.EXTEND (c_file_2lis.COUNT); FOR i IN 1..c_file_2lis.COUNT LOOP Setup (p_file => c_prms_2lis(i)(1), p_delim => c_prms_2lis(i)(2), p_colnum => c_prms_2lis(i)(3), p_dat_lis => c_file_2lis(i), -- data file inputs x_inp_2lis => l_inp_3lis(i)); Timer_Set.Increment_Time (l_timer_set, 'Setup'); Call_Proc (l_act_2lis(i)); END LOOP; Utils_TT.Check_TT_Results (p_proc_name, c_scenario_lis, l_inp_3lis, l_act_2lis, p_exp_2lis, l_timer_set, c_ms_limit, c_inp_group_lis, c_inp_field_2lis, p_out_group_lis, p_out_fields_2lis); END Do_Test; /*************************************************************************************************** tt_AIP_List_Asis: Entry procedure for TRAPIT testing Col_Group.AIP_List_Asis ***************************************************************************************************/ PROCEDURE tt_AIP_List_Asis IS c_proc_name CONSTANT VARCHAR2(61) := c_proc_name_asis; c_exp_2lis CONSTANT L2_chr_arr := L2_chr_arr (L1_chr_arr('3'), L1_chr_arr('2')); c_out_group_lis CONSTANT L1_chr_arr := L1_chr_arr ('Counts'); c_out_fields_2lis CONSTANT L2_chr_arr := L2_chr_arr (L1_chr_arr ('*#Records')); BEGIN Do_Test (c_proc_name, c_exp_2lis, c_out_group_lis, c_out_fields_2lis); END tt_AIP_List_Asis; /*************************************************************************************************** tt_AIP_Sort_By_Key: Entry procedure for TRAPIT testing Col_Group.AIP_Sort_By_Key ***************************************************************************************************/ PROCEDURE tt_AIP_Sort_By_Key IS c_proc_name CONSTANT VARCHAR2(61) := c_proc_name_key; c_exp_2lis CONSTANT L2_chr_arr := L2_chr_arr (L1_chr_arr (Utils.List_Delim ('A','2'), Utils.List_Delim ('Bx','1'), Utils.List_Delim ('Cc','1')), L1_chr_arr (Utils.List_Delim ('X','2')) ); BEGIN Do_Test (c_proc_name, c_exp_2lis, c_out_group_lis, c_out_fields_2lis); END tt_AIP_Sort_By_Key; /*************************************************************************************************** tt_AIP_Sort_By_Value: Entry procedure for TRAPIT testing Col_Group.AIP_Sort_By_Value ***************************************************************************************************/ PROCEDURE tt_AIP_Sort_By_Value IS c_proc_name CONSTANT VARCHAR2(61) := c_proc_name_value; c_exp_2lis CONSTANT L2_chr_arr := L2_chr_arr (L1_chr_arr (Utils.List_Delim ('B','1'), Utils.List_Delim ('Cc','1'), Utils.List_Delim ('A','2')), L1_chr_arr (Utils.List_Delim ('X','2')) ); BEGIN Do_Test (c_proc_name, c_exp_2lis, c_out_group_lis, c_out_fields_2lis); END tt_AIP_Sort_By_Value; END TT_Col_Group; /

TRAPIT Output


PL/SQL procedure successfully completed.


TEXT
----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------

TRAPIT TEST: Col_Group.tt_AIP_List_Asis
=======================================

SCENARIO 1: Tie-break/single-delimiter/interior column {
========================================================

    INPUTS
    ======

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

            File Name  Delimiter  Column
            ---------  ---------  ------
            lines.csv  ,               3

        }
        =

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

            Line
            -----------
            0,1,Cc,3
            00,1,A,9
            000,1,B,27
            0000,1,A,81

        }
        =

    OUTPUTS
    =======

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

            F?  #Records
            --  --------
                       3

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

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

SCENARIO 2: Two copies/double-delimiter/first column {
======================================================

    INPUTS
    ======

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

            File Name  Delimiter  Column
            ---------  ---------  ------
            lines.csv  ;;              1

        }
        =

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

            Line
            -------
            X;;1;;A
            X;;1;;A

        }
        =

    OUTPUTS
    =======

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

            F?  #Records
            --  --------
            F          1
            >          2

        } 1 failed, of 1: FAILURE
        =========================

} 1 failed, of 1: FAILURE
=========================

TIMING: Actual = 0, Expected <= 2: SUCCESS
==========================================

SUMMARY for Col_Group.tt_AIP_List_Asis
======================================

Scenario                                    # Failed  # Tests  Status
------------------------------------------  --------  -------  -------
Tie-break/single-delimiter/interior column         0        1  SUCCESS
Two copies/double-delimiter/first column           1        1  FAILURE
Timing                                             0        1  SUCCESS
------------------------------------------  --------  -------  -------
Total                                              1        3  FAILURE
------------------------------------------  --------  -------  -------

Timer Set: Col_Group.tt_AIP_List_Asis, Constructed at 13 Nov 2016 09:07:08, written at 09:07:08
===============================================================================================
[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
-------  ----------  ----------  ------------  -------------  -------------
Setup          0.07        0.03             2        0.03700        0.01500
Caller         0.00        0.00             2        0.00000        0.00000
(Other)        0.01        0.01             1        0.00900        0.01000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.08        0.04             5        0.01660        0.00800
-------  ----------  ----------  ------------  -------------  -------------

TRAPIT TEST: Col_Group.tt_AIP_Sort_By_Key
=========================================

SCENARIO 1: Tie-break/single-delimiter/interior column {
========================================================

    INPUTS
    ======

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

            File Name  Delimiter  Column
            ---------  ---------  ------
            lines.csv  ,               3

        }
        =

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

            Line
            -----------
            0,1,Cc,3
            00,1,A,9
            000,1,B,27
            0000,1,A,81

        }
        =

    OUTPUTS
    =======

        GROUP Sorted Array: Actual = 3, Expected = 3 {
        ==============================================

            F?  Key  Count
            --  ---  -----
                A        2
            F   B        1
            >   Bx       1
                Cc       1

        } 1 failed, of 3: FAILURE
        =========================

} 1 failed, of 3: FAILURE
=========================

SCENARIO 2: Two copies/double-delimiter/first column {
======================================================

    INPUTS
    ======

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

            File Name  Delimiter  Column
            ---------  ---------  ------
            lines.csv  ;;              1

        }
        =

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

            Line
            -------
            X;;1;;A
            X;;1;;A

        }
        =

    OUTPUTS
    =======

        GROUP Sorted Array: Actual = 1, Expected = 1 {
        ==============================================

            F?  Key  Count
            --  ---  -----
                X        2

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

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

TIMING: Actual = 2, Expected <= 2: SUCCESS
==========================================

SUMMARY for Col_Group.tt_AIP_Sort_By_Key
========================================

Scenario                                    # Failed  # Tests  Status
------------------------------------------  --------  -------  -------
Tie-break/single-delimiter/interior column         1        3  FAILURE
Two copies/double-delimiter/first column           0        1  SUCCESS
Timing                                             0        1  SUCCESS
------------------------------------------  --------  -------  -------
Total                                              1        5  FAILURE
------------------------------------------  --------  -------  -------

Timer Set: Col_Group.tt_AIP_Sort_By_Key, Constructed at 13 Nov 2016 09:07:08, written at 09:07:08
=================================================================================================
[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
-------  ----------  ----------  ------------  -------------  -------------
Setup          0.03        0.03             2        0.01400        0.01500
Caller         0.00        0.00             2        0.00150        0.00000
(Other)        0.01        0.02             1        0.01000        0.02000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.04        0.05             5        0.00820        0.01000
-------  ----------  ----------  ------------  -------------  -------------

TRAPIT TEST: Col_Group.tt_AIP_Sort_By_vALUE
===========================================

SCENARIO 1: Tie-break/single-delimiter/interior column {
========================================================

    INPUTS
    ======

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

            File Name  Delimiter  Column
            ---------  ---------  ------
            lines.csv  ,               3

        }
        =

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

            Line
            -----------
            0,1,Cc,3
            00,1,A,9
            000,1,B,27
            0000,1,A,81

        }
        =

    OUTPUTS
    =======

        GROUP Sorted Array: Actual = 3, Expected = 3 {
        ==============================================

            F?  Key  Count
            --  ---  -----
                B        1
                Cc       1
                A        2

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

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

SCENARIO 2: Two copies/double-delimiter/first column {
======================================================

    INPUTS
    ======

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

            File Name  Delimiter  Column
            ---------  ---------  ------
            lines.csv  ;;              1

        }
        =

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

            Line
            -------
            X;;1;;A
            X;;1;;A

        }
        =

    OUTPUTS
    =======

        GROUP Sorted Array: Actual = 1, Expected = 1 {
        ==============================================

            F?  Key  Count
            --  ---  -----
                X        2

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

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

TIMING: Actual = 1, Expected <= 2: SUCCESS
==========================================

SUMMARY for Col_Group.tt_AIP_Sort_By_vALUE
==========================================

Scenario                                    # Failed  # Tests  Status
------------------------------------------  --------  -------  -------
Tie-break/single-delimiter/interior column         0        3  SUCCESS
Two copies/double-delimiter/first column           0        1  SUCCESS
Timing                                             0        1  SUCCESS
------------------------------------------  --------  -------  -------
Total                                              0        5  SUCCESS
------------------------------------------  --------  -------  -------

Timer Set: Col_Group.tt_AIP_Sort_By_vALUE, Constructed at 13 Nov 2016 09:07:08, written at 09:07:08
===================================================================================================
[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
-------  ----------  ----------  ------------  -------------  -------------
Setup          0.03        0.03             2        0.01450        0.01500
Caller         0.00        0.00             2        0.00050        0.00000
(Other)        0.01        0.02             1        0.01100        0.02000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.04        0.05             5        0.00820        0.01000
-------  ----------  ----------  ------------  -------------  -------------

Suite Summary
=============

Package.Procedure               Tests  Fails         ELA         CPU
------------------------------  -----  -----  ----------  ----------
Col_Group.tt_AIP_List_Asis          3      1        0.08        0.04
Col_Group.tt_AIP_Sort_By_Key        5      1        0.04        0.05
Col_Group.tt_AIP_Sort_By_vALUE      5      0        0.04        0.05
------------------------------  -----  -----  ----------  ----------
Total                              13      2        0.17        0.14
------------------------------  -----  -----  ----------  ----------
Others error in (): ORA-20001: Suite BRENDAN returned error status: ORA-06512: at "LIB.UTILS_TT", line 152
ORA-06512: at "LIB.UTILS_TT", line 819
ORA-06512: at line 5


376 rows selected.

TRAPIT Notes

  • The approach to code-sharing and data-driving is similar to that used in the utPLSQL version
  • No assertions are made at all in the client code; the actual values are collected and passed to the library procedure for assertion
  • The famous 'arrange-act-assert' OO pattern is therefore not followed, with no ill effects
  • The output displays all inputs and outputs in 3-level format: Scenario/Group/Record with scenario descriptions, group names and column headings passed in

Oracle - SQL Developer Unit Test

I briefly tried to use this gui framework as well, but soon gave up when I could not see how to handle the object array return values.

Conclusions

  • Some significant differences in the functionality of the frameworks between utPLSQL and JUnit have been noted
  • Following design patterns for testing from the OO world may not always be advisable
  • It may be best to drop the term 'unit testing' for the database altogether, with the understanding that testing only transactional APIs such as web service procedures is a much more efficient approach
  • Consider using a data-driven approach to testing multiple scenarios, in testing both database and Java code, where applicable

All code and output can be seen on polyglot_group on GitHub, where Python, Ruby, Perl and Scala versions are also included.






 

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/db_unit_test, and includes both framework and design pattern examples.
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
  • The entire body section of the procedure is given below
    • Notice that c_scenario_ds_lis holds pointers to datasets to allow re-use for multiple scenarios (with different parameter data)
  l_timer_set := Utils_TT.Init (c_proc_name);
  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);

    Setup (c_scenario_ds_lis (i), l_inp_3lis (i)(1));

    l_inp_3lis (i)(2) := L1_chr_arr (c_dep_lis(i));
    Timer_Set.Increment_Time (l_timer_set, Utils_TT.c_setup_timer);

    Emp_WS.AIP_Get_Dept_Emps (p_dep_id  => c_dep_lis(i),
                              x_emp_csr => l_emp_csr);
    l_act_2lis(i) := 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 LOOP;

  Utils_TT.Check_TT_Results (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);

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

Level 1 Level 2 Package
List_Delim Utils
Init Utils_TT
Setup TT_Emp_WS
Heading Utils
Col_Headers Utils
Ins_Emp DML_API_TT_HR
Pr_List_As_Line Utils
Increment_Time Timer_Set
AIP_Get_Dept_Emps Emp_WS
Cursor_to_Array Utils_TT
List_or_Empty Utils_TT
Check_TT_Results Utils_TT
Write_Other_Error Utils

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
-------  ----------  ----------  ------------  -------------  -------------






 

A Note on Oracle Join Orders and Hints

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

use_hash_hint

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

The second has:

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

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

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

Plan hash value: 2684174912

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

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

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

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

Plan hash value: 2684174912

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

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

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

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

Outer-level join order

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

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

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

Inner-level join order

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

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

Leading hint in hash join

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

Leading hint in other types of join

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

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






 

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/db_unit_test, and includes both framework and design pattern examples.

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.

First a structure diagram shows how the PL/SQL packages relate to each other, and two call structure tables are given for both the main test procedure for the view and for the previous web service saving procedure. Sections of the code are listed with notes.

Package Structure Diagram

Call Structure Table - TT_Emp_WS.tt_AIP_Save_Emps

Level 1 Level 2 Level 3 Package
Init Utils_TT
Setup TT_Emp_WS
Increment_Time Timer_Set
Call_WS TT_Emp_WS
Do_Save TT_Emp_WS
Init_Time Timer_Set
AIP_Save_Emps TT_Emp_WS
Increment_Time Timer_Set
Get_Tab_Lis TT_Emp_WS
List_Delim Utils
Get_Arr_Lis TT_Emp_WS
List_Delim Utils
List_or_Empty Utils_TT
Check_TT_Results Utils_TT
Write_Other_Error Utils

Call Structure Table - TT_View_Drivers.tt_HR_Test_View_V

Level 1 Level 2 Package
Init Utils_TT
Setup TT_View_Drivers
Heading Utils
Col_Headers Utils
Ins_Emp DML_API_TT_HR
Increment_Time Timer_Set
Get_View Utils_TT
Check_TT_Results Utils_TT
Write_Other_Error Utils

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 (p_call_ind PLS_INTEGER, x_inp_lis OUT L1_chr_arr) IS -- scenario index

    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;

Notes on setup section

  • c_dataset_3lis contains the data for all data sets indexed by (data set, record, field)
  • Setup 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

Main section

BEGIN

  l_timer_set := Utils_TT.Init (c_proc_name);
  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);

    Setup (c_scenario_ds_lis (i), l_inp_3lis (i)(1));

    l_inp_3lis (i)(2) := L1_chr_arr (c_where_lis(i));
    Timer_Set.Increment_Time (l_timer_set, Utils_TT.c_setup_timer);
    l_act_2lis(i) := Utils_TT.Get_View (
                            p_view_name         => c_view_name,
                            p_sel_field_lis     => c_sel_lis,
                            p_where             => c_where_lis(i),
                            p_timer_set         => l_timer_set);

  END LOOP;

  Utils_TT.Check_TT_Results (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 🙂
  • Main section loops over the scenarios
  • Setup 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
  • Check_TT_Results is called to do all the assertions within nested loops, then print the results

Utils_TT - Test Utility Procedures

Check_TT_Results - to check results from testing

PROCEDURE Check_TT_Results (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/db_unit_test, 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 Check_TT_Results;

Notes on Check_TT_Results

  • This is the base version of Check_TT_Results with 3-level arrays of expected and actuals
  • The view testing procedure has only one output group, and an overloaded version is called that passes 1 record in the middle index to the base version
  • The 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 unit 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/db_unit_test, and includes both framework and design pattern examples.
In this 2-part article, I present a design pattern for unit 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 1 - Code.

When to Unit 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 unit 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 unit tests for the reasons given there.

Good examples of views that should be unit 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 unit tested.

How to Unit 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.

Unit 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 unit 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 (at least up to release 11), 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.
See SYS_CONTEXT) for information on the system context database feature, and Multiple Organizations in Oracle Applications for its use in Oracle ebusiness.

Partitioning Views for Unit Testing
We propose to use views in a similar way to the multi-org views, to restrict records to those created in the unit testing session, by means of a utid 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 unit testing utility package UT_Utils sets a context variable to the value 'UT' 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 utid field, and if not, leave it blank. The views use the following clause:

 WHERE (utid = SYS_Context ('userenv', 'sessionid') OR 
        Substr (Nvl (SYS_Context ('userenv', 'client_info'), 'XX'), 1, 2) != 'UT')

Both unit 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 unit testing, and bear in mind that the earlier, less general, approaches may suffice in many cases. In this design pattern demo I will use the general solution, and back-port it to the code for the database save procedure of the previous articles.

Schema Structure

In the earlier articles, the base code and unit 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 unit 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 unit 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. Unit 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 unit 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 Unit 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> DECLARE
  2  BEGIN
  3  
  4    Utils.Clear_Log;
  5    UT_Utils.Run_Suite (UT_Utils.c_ut_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
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------


UNIT TEST for 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
-------  ----------  ----------  ------------  -------------  -------------

Suite Summary
=============

Package.Procedure                  Tests  Fails         ELA         CPU
---------------------------------  -----  -----  ----------  ----------
TT_Emp_WS.tt_AIP_Save_Emps            17      3        1.71        0.07
TT_View_Drivers.tt_HR_Test_View_V      9      1        0.32        0.09
---------------------------------  -----  -----  ----------  ----------
Total                                 26      4        2.03        0.16
---------------------------------  -----  -----  ----------  ----------
Others error in (): ORA-20001: Suite BRENDAN returned error status: ORA-06512: at "DP_7.TT_UTILS", line 140
ORA-06512: at "DP_7.TT_UTILS", line 807
ORA-06512: at line 5


476 rows selected.

SQL> SPOOL OFF

Notes on results section

  • In a view test there is only one group, namely the selected data set
  • The output included testing of the web service procedure discussed in the earlier articles, but the details has been removed, leaving just the summary lines, as it's in the earlier article

The second part of the article is here: Design Patterns for Database Unit Testing 2: Views 2 - Code






 

Design Patterns for Database API Testing 1: Web Service Saving 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/db_unit_test, and includes both framework and design pattern examples.

In this first example, I present a design pattern for web service 'save' procedures by means of a conceptual discussion, together with a working example of base code and test code for a procedure to save new employees in Oracle's well-known HR demonstration schema.

Design patterns involve abstraction and conceptual separation of general features of a situation from the particular. Therefore we will start with a fairly abstract discussion of automated API testing for the database, before proceeding to discuss the use case in question, describe the test cases, and show the results. The code is presented in another article, Design Patterns for Database API Testing 1: Web Service Saving 2 - Code. That article lists various extremely common antipatterns in database unit testing, and how they may be avoided. The code itself centralises as much as possible in order to make specific test code as small as possible, and is structured very differently from most unit testing code that I have seen.

This is the first in a series of four design patterns, with the second described again in two parts, starting here, Design Patterns for Database API Testing 2: Views 1 - Design. For an overview of the testing framework see TRAPIT - TRansactional API Testing in Oracle.

General Discussion of Database Unit Testing

The underlying functionality for unit testing could be described logically as:

  • Given a list of test inputs, X and a list of expected outputs, E, for function F:
  • For each x in X, with e in E:
    • Apply y = F(x)
    • Assert y = e

As the Functional Programming community knows well, functions having well-defined parameter inputs, returning values as outputs, and with no 'side-effects', are the easiest to test reliably. The difficulty with database unit testing is that most use cases do not fall into that category; instead, database procedures can read from and write to the database as well as using input and output parameters. This means that theoretically the inputs and outputs could include the whole database (at least); furthermore the database is a shared resource, so other parties can alter the data we are dealing with. One important consequence of these facts is that much of the thinking on best practices for unit testing, coming as it does from the non-database world, is not applicable here. So what to do?

Pragmatic testing

To make progress, we note that our purpose with unit testing is not to formally prove that our programs work, but rather includes the following aims:

  • Improve code quality within a Test Driven Development (TDD) approach
  • Provide regression tests to allow safe code-refactoring
  • Detect quickly changes external to the code that cause it to fail, such as reference data changes

That being so, we can note the following guidelines:

  • Testing code is written, as part of TDD, by the developer of the base code, who can identify the relevant database inputs and outputs
  • Some, but not necessarily all, test data may be created in a setup step; static reference data that are required for the code to work usually should not be created in setup
  • Testing code should be instrumented and logged liberally
  • The base code should be timed and a time limit included in the testing; this will help to quickly identify issues such as necessary indexes being dropped
  • Consideration should be given to running the unit test suites in performance and other instances

Design Pattern Use Case for Web Service Save Procedure

  • Purpose of procedure is to save a set of new records to a database table
  • Surrogate primary key is generated
  • Input is an array of objects with the records to be saved
  • Output is an array of objects containing the new primary key plus a description
  • For records failing validation, zero is returned, plus the error message, and the valid records will still be saved

ERD of Input and Output Data Structures in Relation to Scenarios

Unit Testing - ERD

  • In the diagram, a scenario corresponds to a web service call with a set of input records
  • The result of the call can be described as a set of output groups, each having a set of records
  • In our case the output array and the base table form two output groups, with a global group for average call timing
  • The logical diagram in terms of sets of records can be translated into an array structure diagram

Unit Testing - ASD

If we follow a similarly generic approach at the coding level, it becomes very easy to extend a simple example by adding groups, fields and records as necessary.

General Unit Test Design Process

The design process involves two high level steps

  • Identify a good set of scenarios with corresponding input records
  • Identify the expected outputs for each output group identified, for each scenario (there will also be a global group, for timing)

Design Pattern Scenarios

Unit Testing - HR

The procedure inserts records in Oracle's HR employees table, and we identify four test scenarios:

  1. Passing a single valid record
  2. Passing a single invalid record
  3. Trying to pass a record with an invalid type
  4. Passing multiple valid records, and one invalid record

Design Pattern Output Groups

  • Records inserted into table employees
  • Records returned in output parameter array
  • Timing of average call

Test Results Output

The output below is for a failing run, where the time limit is breached, and I also have deliberately entered incorrect expected values for two records, to show the difference in formatting between success and failure output group records. I like to include the output tables on completion of development in my technical design document.

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
            --  -----------  ----  -----  -------  ------
                       1513  LN 1  EM 1   IT_PROG    1000

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

        GROUP Output array: Actual = 1, Expected = 1 {
        ==============================================

            F?  Employee id  Description
            --  -----------  ----------------------------------
                       1513  ONE THOUSAND FIVE HUNDRED THIRTEEN

        } 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          1515  LN 4  EM 4   IT_PROG    3000
            >          1515  LN 4  EM 4   IT_PROG    1000
                       1517  LN 6  EM 6   IT_PROG    5000
            F
            >          1517  LN 6  EM 6   IT_PROG    5000

        } 2 failed, of 3: FAILURE
        =========================

        GROUP Output array: Actual = 3, Expected = 3 {
        ==============================================

            F?  Employee id  Description
            --  -----------  -------------------------------------------------------------------
                       1515  ONE THOUSAND FIVE HUNDRED FIFTEEN
                          0  ORA-02291: integrity constraint (.) violated - parent key not found
                       1517  ONE THOUSAND FIVE HUNDRED SEVENTEEN

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

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

} 2 failed, of 7: FAILURE
=========================

TIMING: Actual = 222, Expected <= 2: FAILURE
============================================

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                                                          1        1  FAILURE
-------------------------------------------------------  --------  -------  -------
Total                                                           3       17  FAILURE
-------------------------------------------------------  --------  -------  -------

Timer Set: TT_Emp_WS.tt_AIP_Save_Emps, Constructed at 09 Jul 2016 13:32:40, 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.04        0.01             1        0.03700        0.01000
Caller         0.67        0.03             3        0.22200        0.01000
SELECT         0.60        0.00             3        0.19933        0.00000
(Other)        0.41        0.03             1        0.40500        0.03000
-------  ----------  ----------  ------------  -------------  -------------
Total          1.71        0.07             8        0.21325        0.00875
-------  ----------  ----------  ------------  -------------  -------------

Notes on output

  • In the event of the suite failing, as here, the utility code ensures that an Oracle error is generated. This can then be trapped by a calling Unix script from a scheduled Jenkins job to send out emails

Conclusions

  • A design pattern has been presented for database web service save procedures, with scenarios and output results
  • The implementation (presented in the part 2 article) was against an Oracle database publicly available demonstration schema, and used Brendan's database API testing framework
  • The main ideas could be applied with any database technology and any testing framework
  • It is suggested that any proposed alternative testing framework can be compared by implementing this design pattern, or similar
  • Three more design patterns are presented in further articles in this series, the second being for testing of views (Design Patterns for Database Unit Testing 2: Views 1 - Design)






 

Design Patterns for Database API Testing 1: Web Service Saving 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/db_unit_test, and includes both framework and design pattern examples.

In this first example, I present a design pattern for web service 'save' procedures by means of a conceptual discussion, together with a working example of base code and test code for a procedure to save new employees in Oracle's well-known HR demonstration schema.

In part 1, Design Patterns for Database API Testing 1: Web Service Saving 1 - Design I presented a design pattern for testing web service 'save' procedures, beginning with an abstract discussion, and progressing to an example based on Oracle's HR demo schema.

That article presented the test scenarios, logical data structures, and the example testing output. Here, I start by listing a number of extremely prevalent antipattern approaches to database API testing, and how to avoid them.

Following this, I list the code for the base procedure and the test package with notes against each section. There are three utility packages used, and I list the code for one procedure from those, that does all of the assertion and reporting from a single call. After the code listings, I provide some design material on the code packages used.

Design Patterns for Database API Testing 2: Views 1 - Design presents another design pattern following the same ideas.

API Testing Antipatterns

Automated unit testing of database APIs is often considered difficult and time-consuming. Unfortunately I believe it is made much worse by widespread following of antipattern approaches, some of which appear on popular database testing-related sites as examples to follow.

Here are a few antipatterns that I have identified, and which my code attached below avoids.

Test this then test this then...

Antipattern description

This occurs when the unit test code is written as a long sequence of method calls, each followed by assertions, and each usually having hard-coded data values in both method calls and assertions. It is a classic antipattern because it is widespread and developers often follow it thinking they are doing the right thing.

Antipattern consequence

The testing code becomes very long-winded and hard to follow, and tends to result in less rigorous testing.

Pattern alternative

Store all input data in arrays at the start, loop over the input scenarios array, accumulating the outputs in arrays, and loop over the output arrays for the assertions.

Method-based testing

Antipattern description

This occurs when the test suite is based on testing all the methods in a package, rather than units of behaviour, such as a procedure serving a web service.

Antipattern consequence

Ian Cooper explains very well in the video link below the adverse consequences of this antipattern from a Java perspective, but it applies equally to database testing.

  • It results in a great deal more testing code, with a lot of redundancy, which deters people from the whole concept of test-driven development
  • Re-factoring is more difficult because the unit test code tests the implementation
  • Shifting the focus of testing from the behavioural side is also unlikely to improve testing quality

TDD: Where Did It All Go Wrong?

Pattern alternative

Include in your test suite only tests of well-defined units of behaviour such as a web service entry point procedure, ignoring helper methods.

Field-level assertion

Antipattern description

This occurs when the individual fields written to the database or in output arrays have their own assertions.

Antipattern consequence

Real database applications often have tables with large numbers of fields, and the numbers of assertions can consequently become very large.

Pattern alternative

Assert at the record level by concatenating the fields in a record into one string.

Coupled tests

Antipattern description

This occurs when testing one scenario affects another; for example, when all the test data are created at once and not rolled back after each scenario and re-created as needed for the next.

This antipattern is strongly promoted by some popular testing frameworks, where package level setup and teardown are mandatory, at least by default. My own framework deliberately does not support these, preferring the test program to call its own private procedures as necessary at the appropriate level.

Antipattern consequence

The coding becomes more complex as it is necessary to distentangle what results from earlier test scenarios from that of the current scenario.

Pattern alternative

Set up test data at the scenario level, not at the procedure level, and roll it back at the end of the scenario testing.

Opaque output

Antipattern description

This occurs when the output does not show what was tested.

Antipattern consequence

It is harder to review the testing, especially when combined, as it usually is, with the Test this then test this then... antipattern. This results in lower quality.

Pattern alternative

Make the output self-documenting with clear scenario descriptions and listings of entities and fields that are being tested.

Emp_WS.AIP_Save_Emps - Base Procedure

PROCEDURE AIP_Save_Emps (p_emp_in_lis           ty_emp_in_arr,     -- list of employees to insert
                         x_emp_out_lis      OUT ty_emp_out_arr) IS -- list of employee results
 
  l_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_emp_in_lis.COUNT
    SAVE EXCEPTIONS
    INSERT INTO employees (
        employee_id,
        last_name,
        email,
        hire_date,
        job_id,
        salary
    ) VALUES (
        employees_seq.NEXTVAL,
        p_emp_in_lis(i).last_name,
        p_emp_in_lis(i).email,
        SYSDATE,
        p_emp_in_lis(i).job_id,
        p_emp_in_lis(i).salary
    )
    RETURNING ty_emp_out_obj (employee_id, To_Char(To_Date(employee_id,'J'),'JSP')) BULK COLLECT INTO x_emp_out_lis;

EXCEPTION
  WHEN bulk_errors THEN

    l_emp_out_lis := x_emp_out_lis;

    FOR i IN 1 .. sql%BULK_EXCEPTIONS.COUNT LOOP
      IF i > x_emp_out_lis.COUNT THEN
        x_emp_out_lis.Extend;
      END IF;
      x_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_emp_in_lis.COUNT LOOP
      IF i > x_emp_out_lis.COUNT THEN
        x_emp_out_lis.Extend;
      END IF;
      IF x_emp_out_lis(i).employee_id = 0 THEN
        n_err := n_err + 1;
      ELSE
        x_emp_out_lis(i) := l_emp_out_lis(i - n_err);
      END IF;
    END LOOP;

END AIP_Save_Emps;

Notes on base procedure

  • There is a FORALL statement to insert a record into employees for each record in the input list in one batch
  • The RETURNING clause uses a BULK COLLECT to return the new id and its value in words to the output list
  • SAVE EXCEPTIONS means valid records will be inserted, while invalid ones will fall to the EXCEPTION block
  • Invalid records cause a zero and the error message to be interpolated into the output array
  • I tried to follow a similar principle here to that in Connor McDonald's article, Assume the Best; Plan for the Worst - Oracle Magazine Article

TT_Emp_WS.tt_AIP_Save_Emps - Testing Package Procedure

Declaration section

PROCEDURE tt_AIP_Save_Emps IS

  c_proc_name CONSTANT  VARCHAR2(61) := 'TT_Emp_WS.tt_AIP_Save_Emps';

  c_ln_prefix             CONSTANT VARCHAR2(20) := 'LN ';
  c_em_prefix             CONSTANT VARCHAR2(20) := 'EM ';

  c_ln                    CONSTANT L1_chr_arr := L1_chr_arr (
        c_ln_prefix || '1', c_ln_prefix || '2', c_ln_prefix || '3', c_ln_prefix || '4', c_ln_prefix || '5', c_ln_prefix || '6');
  c_em                    CONSTANT L1_chr_arr := L1_chr_arr (
        c_em_prefix || '1', c_em_prefix || '2', c_em_prefix || '3', c_em_prefix || '4', c_em_prefix || '5', c_em_prefix || '6');
  c_job_id                CONSTANT VARCHAR2(20) := 'IT_PROG';
  c_job_id_invalid        CONSTANT VARCHAR2(20) := 'NON_JOB';

  c_salary                CONSTANT L1_chr_arr := L1_chr_arr ('1000', '1500', '2000x', '3000', '4000', '5000');

  c_params_3lis           CONSTANT L3_chr_arr := L3_chr_arr (
          L2_chr_arr (L1_chr_arr (c_ln (1),    c_em (1),        c_job_id,         c_salary (1))), -- valid
          L2_chr_arr (L1_chr_arr (c_ln (2),    c_em (2),        c_job_id_invalid, c_salary (2))), -- invalid
          L2_chr_arr (L1_chr_arr (c_ln (3),    c_em (3),        c_job_id,         c_salary (3))), -- invalid salary, nan
          L2_chr_arr (L1_chr_arr (c_ln (4),    c_em (4),        c_job_id,         c_salary (4)),  -- valid
                      L1_chr_arr (c_ln (5),    c_em (5),        c_job_id_invalid, c_salary (5)),  -- invalid job id
                      L1_chr_arr (c_ln (6),    c_em (6),        c_job_id,         c_salary (6)))  -- valid
  );
  g_ws_exp_3lis                   L3_chr_arr;

  c_ws_ms_limit           CONSTANT PLS_INTEGER := 2;
  c_scenario_lis         CONSTANT L1_chr_arr := L1_chr_arr (
                               '1 valid record',
                               '1 invalid job id',
                               '1 invalid number',
                               '2 valid records, 1 invalid job id (2 deliberate errors)'
  );
  c_inp_group_lis       CONSTANT L1_chr_arr := L1_chr_arr ('Employee');
  c_inp_field_2lis      CONSTANT L2_chr_arr := L2_chr_arr (
                                                        L1_chr_arr (
                                                                'Name',
                                                                'Email',
                                                                'Job',
                                                               '*Salary')
  );
  c_out_group_lis         CONSTANT L1_chr_arr := L1_chr_arr ('Employee', 'Output array', 'Exception');
  c_fields_2lis           CONSTANT L2_chr_arr :=  L2_chr_arr (
                                      L1_chr_arr ('*Employee id', 'Name', 'Email', 'Job', '*Salary'),
                                      L1_chr_arr ('*Employee id', 'Description'),
                                      L1_chr_arr ('Error message')
  );
  l_timer_set             PLS_INTEGER;
  l_inp_3lis              L3_chr_arr := L3_chr_arr();

  l_ws_act_3lis           L3_chr_arr := L3_chr_arr ();

Notes on declaration section

  • Observe that the declarations of l_inp_3lis and g_ws_exp_3lis as 3-level generic lists map directly to Scenario Inputs and Scenario Outputs in the array structure diagram in Design Patterns for Database Unit Testing 1: Web Service Saving
  • c_scenario_lis, as a generic list maps directly to Scenario Descriptions
  • Adding or subtracting fields in the input object means simply adding or subtracting fields in the inner level of the list
  • Adding test scenarios (i.e. calls) amounts to adding outer level records in each list
  • Using the program as a template for other unit test programs is therefore very easy
  • All inputs and outputs are now printed in the output, making the testing self-documenting

Setup

  PROCEDURE Setup IS
    l_last_seq_val         PLS_INTEGER;
  BEGIN

    SELECT employees_seq.NEXTVAL
      INTO l_last_seq_val
      FROM DUAL;

    g_ws_exp_3lis := L3_chr_arr ( -- each call results in a list of 2 output lists: first is the table records; second is the out array
                        L2_chr_arr (L1_chr_arr (Utils.List_Delim (To_Char(l_last_seq_val+1), c_ln (1), c_em (1), c_job_id, c_salary (1))), -- valid char, num pair
                                    L1_chr_arr (Utils.List_Delim (To_Char(l_last_seq_val+1), To_Char(To_Date(l_last_seq_val+1,'J'),'JSP'))),
                                    Utils_TT.c_empty_list
                        ),
                        L2_chr_arr (Utils_TT.c_empty_list,
                                    L1_chr_arr (Utils.List_Delim (0, 'ORA-02291: integrity constraint (.) violated - parent key not found')),
                                    L1_chr_arr (Utils.List_Delim (0, 'ORA-02291: integrity constraint (.) violated - parent key not found'))
                        ),
                        L2_chr_arr (Utils_TT.c_empty_list,
                                    Utils_TT.c_empty_list,
                                    L1_chr_arr ('ORA-06502: PL/SQL: numeric or value error: character to number conversion error')
                        ),
                        L2_chr_arr (L1_chr_arr (Utils.List_Delim (To_Char(l_last_seq_val+3), c_ln (4), c_em (4), c_job_id, c_salary (1)), -- c_salary (1) should be c_salary (4)
                                                Utils.List_Delim (To_Char(l_last_seq_val+5), c_ln (6), c_em (6), c_job_id, c_salary (6)),
                                                Utils.List_Delim (To_Char(l_last_seq_val+5), c_ln (6), c_em (6), c_job_id, c_salary (6))), -- duplicate record to generate error
                                    L1_chr_arr (Utils.List_Delim (To_Char(l_last_seq_val+3), To_Char(To_Date(l_last_seq_val+3,'J'),'JSP')),
                                                Utils.List_Delim (0, 'ORA-02291: integrity constraint (.) violated - parent key not found'),
                                                Utils.List_Delim (To_Char(l_last_seq_val+5), To_Char(To_Date(l_last_seq_val+5,'J'),'JSP'))),
                                    Utils_TT.c_empty_list
                        )
                     );

  END Setup;

Notes on Setup

  • Setup gets a value from the sequence in order to determine what values are expected in the outputs
  • Any concurrent calls could invalidate this expectation, but scheduling the test runs may avoid this; if not, one could change the expectation to a category, of say positive integer in a certain range
  • The example has two output groups, corresponding to a table and an output array
  • Observe how easy it would be to extend to extra tables or arrays, just by adding records in the middle level of the list
  • c_empty_list is a 1-record list containing a string 'EMPTY', which is used to simplify assertion of empty lists
  • Setup in this case has no need to create test data, as we have chosen to reference pre-existing departments
  • There is no teardown as the inserts from the procedure call are rolled back after each call
  • The call to Write_Times writes out the report from the package level timer set, including setup timings (if any)

Main testing procedure

  PROCEDURE Call_WS (p_ws_inp_2lis        L2_chr_arr,       -- input list of lists (record, field)
                     x_ws_out_2lis    OUT L2_chr_arr) IS    -- output list of lists (group, record)

    l_emp_out_lis       emp_out_arr;
    l_tab_lis           L1_chr_arr;
    l_arr_lis           L1_chr_arr;
    l_err_lis           L1_chr_arr;

    -- Do_Save makes the ws call and returns o/p array
    PROCEDURE Do_Save (x_emp_out_lis OUT emp_out_arr) IS
      l_emp_in_lis        emp_in_arr := emp_in_arr();
    BEGIN

      FOR i IN 1..p_ws_inp_2lis.COUNT LOOP
        l_emp_in_lis.EXTEND;
        l_emp_in_lis (l_emp_in_lis.COUNT) := emp_in_rec (p_ws_inp_2lis(i)(1), p_ws_inp_2lis(i)(2), p_ws_inp_2lis(i)(3), p_ws_inp_2lis(i)(4));
      END LOOP;

      Timer_Set.Init_Time (p_timer_set_ind => l_timer_set);
      Emp_WS.AIP_Save_Emps (
                p_emp_in_lis        => l_emp_in_lis,
                x_emp_out_lis       => x_emp_out_lis);
      Timer_Set.Increment_Time (p_timer_set_ind => l_timer_set, p_timer_name => Utils_TT.c_call_timer);

    END Do_Save;

    -- Get_Tab_Lis: gets the database records inserted into a generic list of strings
    PROCEDURE Get_Tab_Lis (x_tab_lis OUT L1_chr_arr) IS
    BEGIN

      SELECT Utils.List_Delim (employee_id, last_name, email, job_id, salary)
        BULK COLLECT INTO x_tab_lis
        FROM employees
       WHERE utid = Utils.c_session_id_if_TT
       ORDER BY employee_id;
      Timer_Set.Increment_Time (p_timer_set_ind => l_timer_set, p_timer_name => 'SELECT');

    EXCEPTION
      WHEN NO_DATA_FOUND THEN NULL;
    END Get_Tab_Lis;

    -- Get_Arr_Lis converts the ws output array into a generic list of strings
    PROCEDURE Get_Arr_Lis (p_emp_out_lis emp_out_arr, x_arr_lis OUT L1_chr_arr) IS
    BEGIN

      IF p_emp_out_lis IS NOT NULL THEN

        x_arr_lis := L1_chr_arr();
        x_arr_lis.EXTEND (p_emp_out_lis.COUNT);
        FOR i IN 1..p_emp_out_lis.COUNT LOOP

          x_arr_lis (i) := Utils.List_Delim (p_emp_out_lis(i).employee_id, p_emp_out_lis(i).description);

        END LOOP;

      END IF;

    END Get_Arr_Lis;

  BEGIN

    BEGIN

      Do_Save (x_emp_out_lis => l_emp_out_lis);
      Get_Tab_Lis (x_tab_lis => l_tab_lis);
      Get_Arr_Lis (p_emp_out_lis => l_emp_out_lis, x_arr_lis => l_arr_lis);

    EXCEPTION
      WHEN OTHERS THEN
        l_err_lis := L1_chr_arr (SQLERRM);
    END;

    x_ws_out_2lis := L2_chr_arr (Utils_TT.List_or_Empty (l_tab_lis), Utils_TT.List_or_Empty (l_arr_lis), Utils_TT.List_or_Empty (l_err_lis));

  END Call_WS;

BEGIN

  l_timer_set := Utils_TT.Init (c_proc_name);
  Setup;
  Timer_Set.Increment_Time (l_timer_set, 'Setup');
  l_ws_act_3lis.EXTEND (c_params_3lis.COUNT);
  l_inp_3lis.EXTEND (c_params_3lis.COUNT);

  FOR i IN 1..c_params_3lis.COUNT LOOP

    Call_WS (c_params_3lis(i), l_ws_act_3lis(i));
    l_inp_3lis(i) := L2_chr_arr();
    l_inp_3lis(i).EXTEND(1);
    l_inp_3lis(i)(1) := L1_chr_arr();
    l_inp_3lis(i)(1).EXTEND(c_params_3lis(i).COUNT);
    FOR j IN 1..c_params_3lis(i).COUNT LOOP

      l_inp_3lis(i)(1)(j) := Utils.List_Delim (c_params_3lis(i)(j)(1), c_params_3lis(i)(j)(2), c_params_3lis(i)(j)(3), c_params_3lis(i)(j)(4));

    END LOOP;
    ROLLBACK;

  END LOOP;

  Utils_TT.Check_TT_Results (c_proc_name, c_scenario_lis, l_inp_3lis, l_ws_act_3lis, g_ws_exp_3lis, l_timer_set, c_ws_ms_limit,
                             c_inp_group_lis, c_inp_field_2lis, c_out_group_lis, c_fields_2lis);

EXCEPTION
  WHEN OTHERS THEN
    Utils.Write_Other_Error;
    RAISE;
END tt_AIP_Save_Emps;

Notes on main testing procedure

  • The main section is very simple: a local procedure Call_WS is called for each input scenario followed by a ROLLBACK
  • The call converts the generic input data into the objects required by the base procedure, then calls the procedure and sets the resulting records for each output group
  • Check_TT_Results is a generic utility procedure that does all the assertions and calls the results reporting utility
  • This can be used without change for any number of output groups with any numbers of fields, of any types
  • Call_WS has a very simple main section that calls local procedures to split the logic into three sections
  • Its EXCEPTION clause captures the scenario where an invalid type conversion is attempted
  • Its output is a generic 2-level list that is mapped to a record in the outer-level output list
  • Empty lists are converted to c_empty_list, the 1-record list mentioned earlier

Utils_TT - API Test Utilities Package
We will include only one procedure from this package in the body of the article. See gitHub link for the full code.
Check_TT_Results - to check results from testing

PROCEDURE Check_TT_Results (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/db_unit_test, 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 Check_TT_Results;

Notes on Check_TT_Results

  • This is the base version of Check_TT_Results 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 unit 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 unit test outputs now become precise and accurate documents of what the program does

Package Usages Diagram

Call Structure Table - TT_Emp_WS.tt_AIP_Save_Emps

Level 1 Level 2 Level 3 Package
Init Utils_TT
Setup TT_Emp_WS
Increment_Time Timer_Set
Call_WS TT_Emp_WS
Do_Save TT_Emp_WS
Init_Time Timer_Set
AIP_Save_Emps TT_Emp_WS
Increment_Time Timer_Set
Get_Tab_Lis TT_Emp_WS
List_Delim Utils
Get_Arr_Lis TT_Emp_WS
List_Delim Utils
List_or_Empty Utils_TT
Check_TT_Results Utils_TT
Write_Other_Error Utils

Installation Instructions

See TRAPIT - TRansactional API Testing in Oracle for a link to the installation code for both the framework and the demo code on gitHub, and links to related articles.

Exercise
If you are interested in following a similar approach to testing, you might find this exercise an easy way to get going: Revise the base procedure to return error records as a second output array, with the first output returning only valid records. You do not need to define any new types for this. Update the  unit test code for the new signature.

Conclusions