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

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

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

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

Requirement Summary

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

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

The SQL functionality can be described in words as:

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

The REF cursor SQL is:

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

Notes on API Testing REF Cursor Procedures

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

ERD

unit-testing-three-erd_rc

Design Pattern Groups

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

Input Groups

  • Employees Table
  • Department Parameter

Output Groups

  • Select results
  • Timing of average call

Test Scenarios

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

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

Package Structure Diagram

Call Structure Table - TT_Emp_WS.tt_AIP_Get_Dept_Emps

TT_Emp_WS.tt_AIP_Get_Dept_Emps - Emp REF Cursor Test Procedure

Declare section

PROCEDURE tt_AIP_Get_Dept_Emps IS

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

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

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

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

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

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

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

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

Notes on declare section

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

Setup section

  PROCEDURE Setup_Array IS
  BEGIN

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

    FOR i IN 1..c_exp_2lis.COUNT LOOP

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

    END LOOP;

  END Setup_Array;

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

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

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

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

  BEGIN

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

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

    END LOOP;

  END Setup_DB;

Notes on setup section

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

'Pure' API wrapper procedure

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

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

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

  END Purely_Wrap_API;

Notes on 'Pure' API wrapper procedure

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

Main section

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

  FOR i IN 1..c_exp_2lis.COUNT LOOP

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

  END LOOP;

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

EXCEPTION

  WHEN OTHERS THEN
    Utils.Write_Other_Error;
    RAISE;

END tt_AIP_Get_Dept_Emps;

Notes on main section

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

Test Output

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

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

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

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

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

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

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

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

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

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

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

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

    INPUTS
    ======

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

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

        }
        =

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

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

        }
        =

    OUTPUTS
    =======

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

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

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

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

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

    INPUTS
    ======

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

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

        }
        =

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

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

        }
        =

    OUTPUTS
    =======

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

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

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

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

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

    INPUTS
    ======

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

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

        }
        =

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

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

        }
        =

    OUTPUTS
    =======

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

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

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

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

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

    INPUTS
    ======

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

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

        }
        =

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

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


        }
        =

    OUTPUTS
    =======

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

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

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

    INPUTS
    ======

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

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

        }
        =

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

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

        }
        =

    OUTPUTS
    =======

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

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

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

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

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

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

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






 

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

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

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


In the first part of this two part article,Design Patterns for Database API Testing 2: Views 1 - Design I presented a design pattern for unit testing views, using an example based on Oracle's HR demo schema, and here I list the code for the main test procedure and a couple of the utility procedures, with notes.

A structure diagram shows how the PL/SQL packages relate to each other, and sections of the code are listed with notes.

Package Structure Diagram

Call Structure Table

TT_View_Drivers.tt_HR_Test_View_V - View Test Procedure

Declare section

PROCEDURE tt_HR_Test_View_V IS

  c_view_name           CONSTANT VARCHAR2(61) := 'HR_Test_View_V';
  c_proc_name           CONSTANT VARCHAR2(61) := 'TT_View_Drivers.tt_' || c_view_name;
  c_dep_id_1            CONSTANT PLS_INTEGER := 10;
  c_dep_id_2            CONSTANT PLS_INTEGER := 20;
  c_dep_nm_1            CONSTANT VARCHAR2(100) := 'Administration';
  c_dep_nm_2            CONSTANT VARCHAR2(100) := 'Marketing';
  c_job_bad             CONSTANT VARCHAR2(100) := 'AD_ASST';
  c_job_good            CONSTANT VARCHAR2(100) := 'IT_PROG';
  c_base_sal            CONSTANT PLS_INTEGER := 1000;

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

  c_sel_lis             CONSTANT L1_chr_arr := L1_chr_arr ('last_name', 'department_name', 'manager', 'salary', 'sal_rat', 'sal_rat_g');
  c_where_lis           CONSTANT L1_chr_arr := L1_chr_arr (NULL, NULL, 'department_name=''Administration''', NULL);

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

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

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

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

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

Notes on declare section

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

Setup section

  PROCEDURE Setup_Array IS
  BEGIN

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

    FOR i IN 1..c_exp_2lis.COUNT LOOP

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

    END LOOP;

  END Setup_Array;

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

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

  ***************************************************************************************************/
  PROCEDURE Setup_DB (p_call_ind           PLS_INTEGER,   -- scenario index
                      x_inp_lis        OUT L1_chr_arr) IS -- input list, first group, employees

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

  BEGIN

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

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

    END LOOP;

  END Setup_DB;

Notes on setup section

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

'Pure' API wrapper procedure

  PROCEDURE Purely_Wrap_API (p_scenario_ds      VARCHAR2,      -- index of input dataset
                             p_where            VARCHAR2,      -- input where clause for
                             x_inp_lis_1    OUT L1_chr_arr,    -- first input group, employees
                             x_act_lis      OUT L1_chr_arr) IS -- generic actual values list (for scenario)
  BEGIN

    Setup_DB (p_scenario_ds, x_inp_lis_1);

    Timer_Set.Increment_Time (l_timer_set, Utils_TT.c_setup_timer);
 
    x_act_lis := Utils_TT.Get_View (
                            p_view_name         => c_view_name,
                            p_sel_field_lis     => c_sel_lis,
                            p_where             => p_where,
                            p_timer_set         => l_timer_set);
    ROLLBACK;

  END Purely_Wrap_API;

Notes on 'Pure' API wrapper procedure

  • Setup_DB is called to create the data set for the scenario
  • Get_View returns the results of the query on the view as 2-level array
  • Get_View rolls back after getting the results, so the inserted test records are removed from the database

Main section

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

  FOR i IN 1..c_exp_2lis.COUNT LOOP

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

  END LOOP;

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

EXCEPTION

  WHEN OTHERS THEN
    Utils.Write_Other_Error;
    RAISE;

END tt_HR_Test_View_V;

Notes on main section

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

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

PROCEDURE Is_Deeply (p_proc_name                 VARCHAR2,      -- calling procedure
                     p_test_lis                  L1_chr_arr,    -- test descriptions
                     p_inp_3lis                  L3_chr_arr,    -- actual result strings
                     p_act_3lis                  L3_chr_arr,    -- actual result strings
                     p_exp_3lis                  L3_chr_arr,    -- expected result strings
                     p_timer_set                 PLS_INTEGER,   -- timer set index
                     p_ms_limit                  PLS_INTEGER,   -- call time limit in ms
                     p_inp_group_lis             L1_chr_arr,    -- input group names
                     p_inp_fields_2lis           L2_chr_arr,    -- input fields descriptions
                     p_out_group_lis             L1_chr_arr,    -- output group names
                     p_fields_2lis               L2_chr_arr) IS -- test fields descriptions

  l_num_fails_sce                L1_num_arr :=  L1_num_arr();
  l_num_tests_sce                L1_num_arr :=  L1_num_arr();
  l_tot_fails                    PLS_INTEGER := 0;
  l_tot_tests                    PLS_INTEGER := 0;

.
.
.
(private procedures - see gitHub project, https://github.com/BrenPatF/trapit_oracle_tester, for full code listings)
.
.
.
BEGIN

  Detail_Section (l_num_fails_sce, l_num_tests_sce);
  Summary_Section (l_num_fails_sce, l_num_tests_sce, l_tot_fails, l_tot_tests);
  Set_Global_Summary (l_tot_fails, l_tot_tests + 1);

END Is_Deeply;

Notes on Is_Deeply

  • This is the base version of Is_Deeply with 3-level arrays of expected and actuals
  • An inner loop asserts actual values (which are records) against expected
  • The final assertion is against average call time
  • It is expected that all assertion within a test procedure will be via a single call to one of the versions of this procedure, making a big reduction in code compared with traditional unit testing approaches
  • After final assertion a call is made to write out all the results, by scenario, with all inputs printed first, followed by actuals (and expected, where they differ); this means that the test outputs now become precise and accurate documents of what the program does

Get_View - run a query dynamically on a view and return result set as array of strings

FUNCTION Get_View (p_view_name         VARCHAR2,               -- name of view
                   p_sel_field_lis     L1_chr_arr,             -- list of fields to select
                   p_where             VARCHAR2 DEFAULT NULL,  -- optional where clause
                   p_timer_set         PLS_INTEGER)            -- timer set handle
                   RETURN              L1_chr_arr IS           -- list of delimited result records

  l_cur            SYS_REFCURSOR;
  l_sql_txt        VARCHAR2(32767) := 'SELECT Utils.List_Delim (L1_chr_arr (';
  l_result_lis     L1_chr_arr;
  l_len            PLS_INTEGER;

BEGIN

  FOR i IN 1..p_sel_field_lis.COUNT LOOP

    l_sql_txt := l_sql_txt || p_sel_field_lis(i) || ',';

  END LOOP;

  l_sql_txt := RTrim (l_sql_txt, ',') || ')) FROM ' || p_view_name || ' WHERE ' || Nvl (p_where, '1=1 ') || 'ORDER BY 1';

  OPEN l_cur FOR l_sql_txt;

  FETCH l_cur BULK COLLECT -- ut, small result set, hence no need for limit clause
   INTO l_result_lis;

  CLOSE l_cur;

  Timer_Set.Increment_Time (p_timer_set, Utils_TT.c_call_timer);
  ROLLBACK;
  RETURN tt_Utils.List_or_Empty (l_result_lis);

END Get_View;

Notes on Get_View

  • A query string is constructed from the input list of fields and optional where clause
  • The fields are concatenated with delimiters and returned into an array of strings
  • A rollback occurs to remove any test data created, so as not to interfere with any subsequent call
  • If no data was returned from the query, we return a default 1-record listing containing the string 'EMPTY'

Package block section

BEGIN

  DBMS_Application_Info.Set_Client_Info (client_info => 'TT');
  Utils.c_session_id_if_TT := SYS_Context ('userenv', 'sessionid');

END Utils_TT;

Notes on package block section

  • client_info is set to 'TT', meaning the session operates in test mode
  • The session id is stored in a package variable
  • This id is referenced in the testing views and in insertion of test records with utid column

Conclusions






 

Design Patterns for Database API Testing 2: Views 1 - Design

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

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

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

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

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

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


In this 2-part article, I present a design pattern for testing views. I start by discussing when and how to test views. Unlike in the design paatern of the first article in the series, Design Patterns for Database API Testing 1: Web Service Saving - Design, test data has to be created during testing of views, and a very general approach to creating and selecting the test data is proposed. The use case for the design pattern is described, and scenarios and sub-scenarios are defined conceptually. Finally, the output from the testing is presented, with notes.

The second post provides some code extracts, with notes: Design Patterns for Database API Testing 2: Views 2 - Code.

When to Test Views

Views can be simple or complex, or, as I categorise them in Brendan's 2-Page Oracle Programming Standards, thin or thick, where thick views include table joins and thinviews don't. Thin views do not normally require testing while it may or may not be appropriate to test thick views.

As explained in the second part of the first article mentioned above, method-based testing is a bad idea, and occurs when the test suite is based on testing all the methods in a package, rather than units of (external) behaviour (often corresponding to procedures prefixed AIP in a common naming convention). Similarly, we can consider views in the same way as methods and ask whether they represent testable units of behaviour or are merely internal code structures, which should not normally have individual automated tests for the reasons given there.

Good examples of views that should be tested would be those that form the basis of complex data extraction to file, by ETL tools such as Informatica, or those that form the basis of reporting tools such as Business Objects. In fact, it is very good practice to place SQL for these tools into views precisely so that they can be tested.

How to Test Views Using a PL/SQL Testing Framework

In order to leverage a PL/SQL API testing framework to also test views, the API test package procedures call a library procedure passing the name of the relevant view: The library procedure returns the result of querying the view as an array of delimited strings, and the API test procedures then compare the results against their own expected results.

Each API test procedure will have its own setup local procedure to create test data, and we need to discuss the issue of distinguishing test data from pre-existing data.

Test Data

In the earlier article on database save procedures, we did not create any test data within the testing code itself, but the base procedure did create data, and those were queried back for assertion. In order to select only the data created by the procedure call a prefix was used in one of the string fields which was assumed not to exist already. This is a workable approach in some cases, but may not be possible in general. Let us consider the different types of database data that may affect our testing:

  • Data created by the base code being tested
  • Data created by test code to be read by the base code
  • Data not created by test code to be read by base code

In order to verify that the program calls are giving results as expected, the test code needs to know all the data that influence the results, not necessarily just directly created data. Our view testing use case described below has an example where the results depend on an aggregate of all the records on the database. This is a problem when we have a shared database, where we cannot freeze the data at the time of test development. In order to handle this problem, we propose to borrow a technique used in Oracle's ebusinees applications.

Partitioning Views with System Contexts
In Oracle ebusiness's multi-org implementations, transactions are partitioned by a numeric identifier for the organization owning the transaction. This org_id value is stored in a column in the base table on transaction creation. Within the application code the base table is not queried directly, but through a view that restricts records returned to those for the organization corresponding to the current role of the application user, which is stored in the userenv system context (this is true up to release 11.5, but the mechanism changed in release 12.1).

See SYS_CONTEXT for information on the system context database feature, and Oracle E-Business Suite Multiple Organizations Implementation Guide (12.1) for release 12.1 multi-org implementation in Oracle ebusiness.

Partitioning Views for Testing
We propose to use views in a similar way to the multi-org views, to restrict records to those created in the testing session, by means of a ttid column on the base table that will hold the session id. The new optional column is added to those tables where this approach is required, and view are created on the tables. Our testing utility package Utils_TT sets a context variable to the value 'TT' to signify testing mode, and the session id is set to a package variable in the general utilities package Utils.

Any base code that inserts data into the tables has to check for test mode, and if set, put the session id into the ttid field, and if not, leave it blank. The views use the following clause:

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

Both test code and base code now query the views instead of the base tables. As the base code to write to the tables has to account for the new column, it is necessary for the column to be added in all instances including production. If this seems a little drastic, consider the importance that you attach to testing, and bear in mind that the earlier, less general, approaches may suffice in many cases. In these design pattern demos I use the general solution.

Schema Structure

In the earlier articles, the base code and test packages were created in the HR schema, with utility packages kept in the custom brendan schema. However, it is more common to use separate schemas for code and data, so we will now place all packages and supporting objects in the brendan schema, and create the testing views there.

Design Pattern Use Case for Testing Views

Modern Oracle SQL is very powerful and can apply complex logic within a single statement, reducing the need for more complex procedural code. In order to show how to test SQL, we will devise a test view, HR_Test_V, having a range of features that we might want to test in general:

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

The view functionality can be described in words as:

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

The view SQL is:

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

Scenarios and Sub-scenarios

Scenario definition
Following our earlier article, we may define a scenario as being the set of all relevant records, both on the database and passed as parameters, to a single program call. API or view testing involves creating one or more scenarios, calling the program (or executing the process) for each scenario, and verifying that the output records are as expected.

Good testing is achieved when the scenarios are chosen to validate as wide a range of behaviours as possible. It is not always, or usually, necessary to create a new scenario for each aspect of behaviour to be tested.

Sub-scenario definition
Often, several features can be tested in the same program call by setting up different records in the scenario that will independently test the different features. For example, in our use case above we can create employees with and without a department, and with and without a manager in the same scenario to test the different types of join.

It may be helpful to think of these separate records, or fields within a record, as corresponding to sub-scenarios, and try to construct scenarios as efficiently as possible without making more calls than necessary.

View Test Output

Data setup section

SCENARIO 1: DS-1, testing inner, outer joins, analytic over dep, and global ratios with 1 dep, Employees created in setup: DS-1 - 4 emps, 1 dep (10), emp-3 has no dep, emp-4 has bad job
=========================================================================================================================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1493             10              IT_PROG           1000
2         1494             10        1493  IT_PROG           2000
3         1495                       1493  IT_PROG           3000
4         1496             10        1493  AD_ASST           4000

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

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1497             10              IT_PROG           1000
2         1498             10        1497  IT_PROG           2000
3         1499                       1497  IT_PROG           3000
4         1500             10        1497  AD_ASST           4000
5         1501             20        1497  IT_PROG           5000

SCENARIO 3: DS-2, passing 'WHERE dep=10', Employees created in setup: DS-2 - As dataset 1 but with extra emp-5, in second dep (20)
==================================================================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1502             10              IT_PROG           1000
2         1503             10        1502  IT_PROG           2000
3         1504                       1502  IT_PROG           3000
4         1505             10        1502  AD_ASST           4000
5         1506             20        1502  IT_PROG           5000

SCENARIO 4: DS-3, Salaries total 1500 (< threshold of 1600), Employees created in setup: DS-3 - As dataset 2 but with salaries * 0.1, total below reporting threshold of 1600
=============================================================================================================================================================================

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1507             10              IT_PROG            100
2         1508             10        1507  IT_PROG            200
3         1509                       1507  IT_PROG            300
4         1510             10        1507  AD_ASST            400
5         1511             20        1507  IT_PROG            500

Notes on data setup section

  • There are three data sets, and four scenarios, each of which references a data set
  • The call to set up the data for a scenario writes out all the data created
  • A header provides a description of the features (or sub-scenarios) in the data set
  • In the output above scenarios 2 and 3 use the same data set, DS-2

Results section

SQL>BEGIN

  Utils.Clear_Log;
  Utils_TT.Run_Suite (Utils_TT.c_tt_suite_bren);

EXCEPTION
  WHEN OTHERS THEN
    Utils.Write_Other_Error;
END;
/
SQL> @L_Log_Default

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


TRAPIT TEST: TT_View_Drivers.tt_HR_Test_View_V
==============================================

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

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1518             10              IT_PROG           1000
2         1519             10        1518  IT_PROG           2000
3         1520                       1518  IT_PROG           3000
4         1521             10        1518  AD_ASST           4000

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

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1522             10              IT_PROG           1000
2         1523             10        1522  IT_PROG           2000
3         1524                       1522  IT_PROG           3000
4         1525             10        1522  AD_ASST           4000
5         1526             20        1522  IT_PROG           5000

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

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1527             10              IT_PROG           1000
2         1528             10        1527  IT_PROG           2000
3         1529                       1527  IT_PROG           3000
4         1530             10        1527  AD_ASST           4000
5         1531             20        1527  IT_PROG           5000

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

#  Employee id  Department id     Manager  Job id          Salary
-  -----------  -------------  ----------  ----------  ----------
1         1532             10              IT_PROG            100
2         1533             10        1532  IT_PROG            200
3         1534                       1532  IT_PROG            300
4         1535             10        1532  AD_ASST            400
5         1536             20        1532  IT_PROG            500

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

    INPUTS
    ======

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

            Employee Id  Last Name  Email  Hire Date  Job      Salary  Manager Id  department Id
            -----------  ---------  -----  ---------  -------  ------  ----------  -------------
                   1518  LN_1       EM_1   09-JUL-16  IT_PROG    1000                         10
                   1519  LN_2       EM_2   09-JUL-16  IT_PROG    2000        1518             10
                   1520  LN_3       EM_3   09-JUL-16  IT_PROG    3000        1518
                   1521  LN_4       EM_4   09-JUL-16  AD_ASST    4000        1518             10

        }
        =

        GROUP Where {
        =============

            Where
            -----


        }
        =

    OUTPUTS
    =======

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

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

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

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

SCENARIO 2: DS-2, testing same as 1 but with extra emp in another dep {
=======================================================================

    INPUTS
    ======

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

            Employee Id  Last Name  Email  Hire Date  Job      Salary  Manager Id  department Id
            -----------  ---------  -----  ---------  -------  ------  ----------  -------------
                   1522  LN_1       EM_1   09-JUL-16  IT_PROG    1000                         10
                   1523  LN_2       EM_2   09-JUL-16  IT_PROG    2000        1522             10
                   1524  LN_3       EM_3   09-JUL-16  IT_PROG    3000        1522
                   1525  LN_4       EM_4   09-JUL-16  AD_ASST    4000        1522             10
                   1526  LN_5       EM_5   09-JUL-16  IT_PROG    5000        1522             20

        }
        =

        GROUP Where {
        =============

            Where
            -----


        }
        =

    OUTPUTS
    =======

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

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

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

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

SCENARIO 3: DS-2, passing 'WHERE dep=10' {
==========================================

    INPUTS
    ======

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

            Employee Id  Last Name  Email  Hire Date  Job      Salary  Manager Id  department Id
            -----------  ---------  -----  ---------  -------  ------  ----------  -------------
                   1527  LN_1       EM_1   09-JUL-16  IT_PROG    1000                         10
                   1528  LN_2       EM_2   09-JUL-16  IT_PROG    2000        1527             10
                   1529  LN_3       EM_3   09-JUL-16  IT_PROG    3000        1527
                   1530  LN_4       EM_4   09-JUL-16  AD_ASST    4000        1527             10
                   1531  LN_5       EM_5   09-JUL-16  IT_PROG    5000        1527             20

        }
        =

        GROUP Where {
        =============

            Where
            --------------------------------
            department_name='Administration'

        }
        =

    OUTPUTS
    =======

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

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

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

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

SCENARIO 4: DS-3, Salaries total 1500 (< threshold of 1600) {
=============================================================

    INPUTS
    ======

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

            Employee Id  Last Name  Email  Hire Date  Job      Salary  Manager Id  department Id
            -----------  ---------  -----  ---------  -------  ------  ----------  -------------
                   1532  LN_1       EM_1   09-JUL-16  IT_PROG     100                         10
                   1533  LN_2       EM_2   09-JUL-16  IT_PROG     200        1532             10
                   1534  LN_3       EM_3   09-JUL-16  IT_PROG     300        1532
                   1535  LN_4       EM_4   09-JUL-16  AD_ASST     400        1532             10
                   1536  LN_5       EM_5   09-JUL-16  IT_PROG     500        1532             20

        }
        =

        GROUP Where {
        =============

            Where
            -----


        }
        =

    OUTPUTS
    =======

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

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

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

SUMMARY for TT_View_Drivers.tt_HR_Test_View_V
=============================================

Scenario                                                                           # Failed  # Tests  Status
---------------------------------------------------------------------------------  --------  -------  -------
DS-1, testing inner, outer joins, analytic over dep, and global ratios with 1 dep         0        2  SUCCESS
DS-2, testing same as 1 but with extra emp in another dep                                 0        3  SUCCESS
DS-2, passing 'WHERE dep=10'                                                              0        2  SUCCESS
DS-3, Salaries total 1500 (< threshold of 1600)                                           0        1  SUCCESS
Timing                                                                                    1        1  FAILURE
---------------------------------------------------------------------------------  --------  -------  -------
Total                                                                                     1        9  FAILURE
---------------------------------------------------------------------------------  --------  -------  -------

Timer Set: TT_View_Drivers.tt_HR_Test_View_V, Constructed at 09 Jul 2016 13:32:42, written at 13:32:42
======================================================================================================
[Timer timed: Elapsed (per call): 0.01 (0.000013), CPU (per call): 0.02 (0.000020), calls: 1000, '***' denotes corrected line below]

Timer       Elapsed         CPU         Calls       Ela/Call       CPU/Call
-------  ----------  ----------  ------------  -------------  -------------
Setup          0.11        0.00             4        0.02675        0.00000
Caller         0.19        0.06             4        0.04750        0.01500
(Other)        0.03        0.03             1        0.02700        0.03000
-------  ----------  ----------  ------------  -------------  -------------
Total          0.32        0.09             9        0.03600        0.01000
-------  ----------  ----------  ------------  -------------  -------------

Notes on results section

  • In a view test there is only one group, namely the selected data set

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






 

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

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

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


In this 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 began with an abstract discussion, and progressed 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_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_out_field_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_act_3lis         L3_chr_arr := L3_chr_arr();

Notes on declaration section

  • Observe that the declarations of l_inp_3lis and g_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 API Testing 1: Web Service Saving 1 - Design
  • 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 printed in the output, making the testing self-documenting

Setup

  PROCEDURE Setup_Array IS
    l_last_seq_val         PLS_INTEGER;
  BEGIN

    SELECT employees_seq.NEXTVAL
      INTO l_last_seq_val
      FROM DUAL;

    g_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')),
                                    Utils_TT.c_empty_list
                        ),
                        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
                        )
                     );

    l_act_3lis.EXTEND (c_params_3lis.COUNT);
    l_inp_3lis.EXTEND (c_params_3lis.COUNT);

    FOR i IN 1..c_params_3lis.COUNT LOOP

      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;

    END LOOP;

  END Setup_Array;

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)

'Pure' API wrapper procedure

  PROCEDURE Purely_Wrap_API (p_inp_2lis        L2_chr_arr,       -- input list of lists (record, field)
                             x_act_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_inp_2lis.COUNT LOOP
        l_emp_in_lis.EXTEND;
        l_emp_in_lis (l_emp_in_lis.COUNT) := emp_in_rec (p_inp_2lis(i)(1), p_inp_2lis(i)(2), p_inp_2lis(i)(3), p_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 ttid = 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_act_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));
    ROLLBACK;

  END Purely_Wrap_API;

Notes on main testing procedure

  • 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
  • Purely_Wrap_API 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
  • The procedure ends with a rollback

Main section

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

  FOR i IN 1..c_params_3lis.COUNT LOOP

    Purely_Wrap_API (c_params_3lis(i), l_act_3lis(i));

  END LOOP;

  Utils_TT.Is_Deeply (c_proc_name, c_scenario_lis, l_inp_3lis, l_act_3lis, g_exp_3lis, l_timer_set, c_ws_ms_limit,
                      c_inp_group_lis, c_inp_field_2lis, c_out_group_lis, c_out_field_2lis);

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

Notes on main section

  • The main section is very simple: a local procedure Purely_Wrap_API is called for each input scenario
  • 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
  • Is_Deeply 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

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.
Is_Deeply - to check results from testing

PROCEDURE Is_Deeply (p_proc_name                 VARCHAR2,      -- calling procedure
                     p_test_lis                  L1_chr_arr,    -- test descriptions
                     p_inp_3lis                  L3_chr_arr,    -- actual result strings
                     p_act_3lis                  L3_chr_arr,    -- actual result strings
                     p_exp_3lis                  L3_chr_arr,    -- expected result strings
                     p_timer_set                 PLS_INTEGER,   -- timer set index
                     p_ms_limit                  PLS_INTEGER,   -- call time limit in ms
                     p_inp_group_lis             L1_chr_arr,    -- input group names
                     p_inp_fields_2lis           L2_chr_arr,    -- input fields descriptions
                     p_out_group_lis             L1_chr_arr,    -- output group names
                     p_fields_2lis               L2_chr_arr) IS -- test fields descriptions

  l_num_fails_sce                L1_num_arr :=  L1_num_arr();
  l_num_tests_sce                L1_num_arr :=  L1_num_arr();
  l_tot_fails                    PLS_INTEGER := 0;
  l_tot_tests                    PLS_INTEGER := 0;

.
.
.
(private procedures - see gitHub project, https://github.com/BrenPatF/trapit_oracle_tester, for full code listings)
.
.
.
BEGIN

  Detail_Section (l_num_fails_sce, l_num_tests_sce);
  Summary_Section (l_num_fails_sce, l_num_tests_sce, l_tot_fails, l_tot_tests);
  Set_Global_Summary (l_tot_fails, l_tot_tests + 1);

END Is_Deeply;

Notes on Is_Deeply

  • This is the base version of Is_Deeply with 3-level arrays of expected and actuals
  • An inner loop asserts actual values (which are records) against expected
  • The final assertion is against average call time
  • It is expected that all assertion within a test procedure will be via a single call to one of the versions of this procedure, making a big reduction in code compared with traditional unit testing approaches
  • After final assertion a call is made to write out all the results, by scenario, with all inputs printed first, followed by actuals (and expected, where they differ); this means that the test outputs now become precise and accurate documents of what the program does

Package Usages Diagram

Call Structure Table - TT_Emp_WS.tt_AIP_Save_Emps
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






Recursive SQL for Network Analysis, and Duality

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

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

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

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

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

Dual Networks

Dual network definition

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

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

Dual network SQL

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

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

Dual network characteristics

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

SQL Queries

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

Pipelined Function Query (PLF)

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

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

Recursive Subquery Factor Query (RSF)

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

Connect By Query (CBY)

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

Five Elementary Networks

Oracle's two forms of SQL recursion treat cycles differently

Connect By Cycles

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

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

Recursive Subquery Factor Cycles

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

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

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

Network 1: 3 nodes in line

Dual Network, 1.3 - net-1

Network 2: Simple fork

Dual Network, 1.3 - net-2

Network 3: 2-node loop

Dual Network, 1.3 - net-3

Network 4: 3-node loop

Dual Network, 1.3 - net-4

Network 5: 2 nodes with a self-loop

Dual Network, 1.3 - net-5

Combination of Elementary Networks

Combination Network 6

Dual Network, 1.3 - net-6

This network has 10 links with 3 loops.

Combination Network 6: PLF Output

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

Combination Network 6: RSF Output

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

Combination Network 6: CBY Output

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



Dual Combination Network 6

Dual Network, 1.3 - net-6-D

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

Dual Combination Network 6: PLF Output

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

Dual Combination Network 6: RSF Output

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


Combination Network 6: CBY Original with RSF Dual Output

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

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


Dual Combination Network 6: CBY Output

34547 rows selected.

[See attached file if interested in detail.]

Oracle's HR/OE/PM Demo Network

Original Demo Network

Dual Network, 1.3 - HR

This network has 21 links with 6 loops.

Original Demo Network: PLF Output

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

22 rows selected.

Elapsed: 00:00:00.15



Original Demo Network: RSF Output

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

199 rows selected.

Elapsed: 00:00:00.30

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

Original Demo Network: CBY Output

One tree by Connect By

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

4414420 rows selected.

Elapsed: 00:29:33.41

One tree by Connect By filtered

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

21 rows selected.

Elapsed: 00:03:03.16

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

Dual Demo Network

Dual Network, 1.3 - HR-D

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

Dual Demo Network: PLF Output

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

53 rows selected.

Elapsed: 00:00:00.27



Dual Demo Network: RSF and CBY Results

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

Conclusions

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

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

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






PL/SQL Pipelined Function for Network Analysis

In March 2013 I wrote this SQL for Network Grouping, describing some options in SQL for solving a general class of network problems, while noting that these would have serious performance issues, and that the most efficient approach would involve PL/SQL. I had already published a Scribd article, in June 2010, on using PL/SQL to traverse a single connected network, An Oracle Network Traversal PL SQL Program, but had not at that time extended the approach to cover all networks.

Last weekend, I posted an article, SQL for Shortest Path Problems 2: A Branch and Bound Approach, that included results from my more general package for network analysis, so I thought it was time to post an article on that package, and this is it. GitHub: Brendan's network structural analysis Oracle package

PL/SQL Package
Code

CREATE OR REPLACE PACKAGE Net_Pipe AS
/**************************************************************************************************

Author:         Brendan Furey
Date:           10 May 2015
Description:    Brendan's network analysis PL/SQL package, (http://aprogrammerwrites.eu/?p=1426).
                Pipelined function returns a record for each link in all connected subnetworks 
		specified by the view links_v. The root_node_id field identifies the subnetwork that
		a link belongs to. Use SQL to list the network in detail, or at any desired level of
		aggregation. Here is an example call:

SQL
===
SELECT root_node_id             "Network",
       Count (DISTINCT link_id) OVER (PARTITION BY root_node_id) - 1 "#Links",
       Count (DISTINCT node_id) OVER (PARTITION BY root_node_id) "#Nodes",
       node_level "Lev",
       LPad (dirn || ' ', Least (2*node_level, 60), ' ') || node_id || loop_flag "Node",
       link_id                  "Link"
  FROM TABLE (Net_Pipe.All_Nets)
 ORDER BY line_no

Output sample for an Oracle v12.1 foreign key network
=====================================================
Network       #Links  #Nodes Lev  Node                                     Link
------------  ------  ------ ---  ---------------------------------------  -------------------------------
COUNTRIES|HR      21      16   0  COUNTRIES|HR                             ROOT
                               1  < LOCATIONS|HR                           loc_c_id_fk|hr
                               2    < DEPARTMENTS|HR                       dept_loc_fk|hr                                3      > EMPLOYEES|HR                       dept_mgr_fk|hr
                               4        < CUSTOMERS|OE                     customers_account_manager_fk|oe
                               5          < ORDERS|OE                      orders_customer_id_fk|oe                                6            > EMPLOYEES|HR*                orders_sales_rep_fk|oe
                               6            < ORDER_ITEMS|OE               order_items_order_id_fk|oe                                7              > PRODUCT_INFORMATION|OE     order_items_product_id_fk|oe
                               8                < INVENTORIES|OE           inventories_product_id_fk|oe                                9                  > WAREHOUSES|OE          inventories_warehouses_fk|oe
                              10                    > LOCATIONS|HR*        warehouses_location_fk|oe
                               8                < ONLINE_MEDIA|PM          loc_c_id_fk|pm
                               8                < PRINT_MEDIA|PM           printmedia_fk|pm
                               8                < PRODUCT_DESCRIPTIONS|OE  pd_product_id_fk|oe                                4        > DEPARTMENTS|HR*                  emp_dept_fk|hr
                               4        = EMPLOYEES|HR*                    emp_manager_fk|hr
                               4        > JOBS|HR                          emp_job_fk|hr
                               5          < JOB_HISTORY|HR                 jhist_job_fk|hr                                6            > DEPARTMENTS|HR*              jhist_dept_fk|hr
                               6            > EMPLOYEES|HR*                jhist_emp_fk|hr
                               1  > REGIONS|HR                             countr_reg_fk|hr

1 of 69 subnetworks is shown above
***************************************************************************************************/

TYPE net_rec_type IS RECORD (
		root_node_id				VARCHAR2(100),
		dirn					VARCHAR2(1),
		node_id					VARCHAR2(100),
		link_id					VARCHAR2(100),
                node_level                              NUMBER,
		loop_flag				VARCHAR2(1),
		line_no 				NUMBER
);
TYPE net_tab_type IS TABLE OF net_rec_type;

FUNCTION All_Nets RETURN net_tab_type PIPELINED;

END Net_Pipe;
/
SHO ERR
CREATE OR REPLACE PACKAGE BODY Net_Pipe AS
/**************************************************************************************************

Author:         Brendan Furey
Date:           10 May 2015
Description:    Brendan's network analysis PL/SQL package, (http://aprogrammerwrites.eu/?p=1426).
                Pipelined function returns a record for each link in all connected subnetworks 
		specified by the view links_v. The root_node_id field identifies the subnetwork that
		a link belongs to. Use SQL to list the network in detail, or at any desired level of
		aggregation. See spec for an example call.

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

c_root_link_id          CONSTANT VARCHAR2(100) := 'ROOT';
c_loop_flag             CONSTANT VARCHAR2(1) := '*';
c_dirn_fr               CONSTANT VARCHAR2(1) := '<'; c_dirn_to               CONSTANT VARCHAR2(1) := '>';
c_dirn_sj               CONSTANT VARCHAR2(1) := '=';

g_root_node_id                   VARCHAR2(100);
g_line_no                        NUMBER;

PROCEDURE Write_Log (p_line VARCHAR2) IS
BEGIN

  DBMS_Output.Put_Line (p_line);

END Write_Log;

FUNCTION All_Nets RETURN net_tab_type PIPELINED IS
  g_net_tab				net_tab_type;
  TYPE id_hash_type IS                  TABLE OF PLS_INTEGER INDEX BY VARCHAR2(61);
  g_node_hash                           id_hash_type;
  g_link_hash                           id_hash_type;

  l_is_loop                             BOOLEAN;

  PROCEDURE Init_Net IS
  BEGIN

    g_net_tab := net_tab_type ();
    g_link_hash.DELETE;

  END Init_net;

  PROCEDURE Add_Net (p_root_node_id     VARCHAR2,
                     p_dirn             VARCHAR2,
                     p_node_id          VARCHAR2,
                     p_link_id          VARCHAR2,
                     p_node_level       PLS_INTEGER,
                     x_is_loop          OUT BOOLEAN) IS

    l_net_rec				net_rec_type;

  BEGIN

--    IF p_link_id != c_root_link_id AND g_link_hash.EXISTS (p_link_id) THEN
    IF g_link_hash.EXISTS (p_link_id) THEN
      x_is_loop := TRUE;
      RETURN;
    ELSE
      g_link_hash (p_link_id) := 1;
    END IF;

    g_line_no                   := g_line_no + 1;
    l_net_rec.line_no           := g_line_no;
    l_net_rec.root_node_id      := p_root_node_id;
    l_net_rec.dirn              := p_dirn;
    l_net_rec.node_id           := p_node_id;
    l_net_rec.link_id           := p_link_id;
    l_net_rec.node_level        := p_node_level;

    x_is_loop := g_node_hash.EXISTS (p_node_id);
    IF x_is_loop THEN

      l_net_rec.loop_flag := c_loop_flag;

    ELSE

      g_node_hash (p_node_id) := 1;

    END IF;
    g_net_tab.EXTEND;
    g_net_tab (g_net_tab.COUNT)  := l_net_rec;

  END Add_Net;

  PROCEDURE Expand_Node (p_node_id VARCHAR2, p_link_id_prior VARCHAR2, p_node_level PLS_INTEGER) IS

    CURSOR lin_csr IS
    SELECT link_id, node_id_fr node_id, c_dirn_fr dirn
      FROM links_v
     WHERE node_id_to   = p_node_id
       AND node_id_to  != node_id_fr
       AND link_id     != p_link_id_prior
     UNION
    SELECT link_id, node_id_to, c_dirn_to
      FROM links_v
     WHERE node_id_fr   = p_node_id
       AND node_id_to  != node_id_fr
       AND link_id     != p_link_id_prior
     UNION
    SELECT link_id, node_id_to, c_dirn_sj
      FROM links_v
     WHERE node_id_fr   = p_node_id
       AND node_id_to   = node_id_fr
       AND link_id     != p_link_id_prior
     ORDER BY 2, 1;
    TYPE lin_tab_type IS TABLE OF lin_csr%ROWTYPE;
    l_lin_tab		lin_tab_type;

  BEGIN

    OPEN lin_csr;
    FETCH lin_csr BULK COLLECT -- avoids too many open cursors
     INTO l_lin_tab;
    CLOSE lin_csr;

    FOR i IN 1..l_lin_tab.COUNT LOOP

      Add_Net (g_root_node_id, l_lin_tab(i).dirn, l_lin_tab(i).node_id, l_lin_tab(i).link_id, p_node_level + 1, l_is_loop);
      IF NOT l_is_loop THEN

        Expand_Node (l_lin_tab(i).node_id, l_lin_tab(i).link_id, p_node_level + 1);

      END IF;

    END LOOP;

  END Expand_Node;

BEGIN

  g_line_no := 0;
  FOR r_nod IN (
          SELECT node_id_fr root_node_id
            FROM links_v
           UNION
          SELECT node_id_to
            FROM links_v) LOOP

    IF g_node_hash.EXISTS (r_nod.root_node_id) THEN CONTINUE; END IF;

    g_root_node_id := r_nod.root_node_id;
    Init_Net;
    Add_Net (g_root_node_id, ' ', g_root_node_id, c_root_link_id, 0, l_is_loop);

    Expand_Node (g_root_node_id, c_root_link_id, 0);

    FOR i IN 1..g_net_tab.COUNT LOOP

      PIPE ROW (g_net_tab(i));

    END LOOP;

  END LOOP;

END All_Nets;

END Net_Pipe;
/
SHO ERR

Array Structure Diagram

Networks - PLSQL, v1.0 - Arrays

Neighbour SQL Structure Diagram

Networks - PLSQL, v1.0 - Neighbour

Pseudocode - All_Nets

  • Loop over all nodes in the input links view
    • If the node has been visited continue to the next one
    • Initialise a new subnetwork with root node
    • Delete link hash array and output array
    • Call recursive procedure. Expand_Node, to expand the whole subnetwork connected to the current root node
    • Loop over the output array
      • Pipe the record out
    • End loop
  • End Loop

Pseudocode - Expand_Node

  • Fetch all neighbours of the input node into an array, except the node from the prior link
  • Loop over neighbours array
    • Call Add_Net to possibly add new node to the output array
      • If link has been visited then
        • Return with link loop flag set
      • Else
        • Set link visited hash
      • End if
      • Set the fields of the new output record
      • If node has been visited then
        • Set the loop flag in the output record
      • Else
        • Set node visited hash
      • End if
      • Add new record to the output array
    • End call
    • If link was not a loop then
      • Call Expand_Node recursively
    • End if
  • End loop

Notes on Code

  • The arrays are a limitation on scalability
  • The size of the arrays are determined by the largest subnetwork, except for the nodes hash array which will hold all nodes at the end
  • Temporary tables could be used in place of the arrays if necessary

SQL Calling Code

PROMPT Network detail
SELECT root_node_id             "Network",
       Count (DISTINCT link_id) OVER (PARTITION BY root_node_id) - 1 "#Links",
       Count (DISTINCT node_id) OVER (PARTITION BY root_node_id) "#Nodes",
       node_level "Lev",
       LPad (dirn || ' ', Least (2*node_level, 60), ' ') || node_id || loop_flag "Node",
       link_id                  "Link"
  FROM TABLE (Net_Pipe.All_Nets)
 ORDER BY line_no
/
PROMPT Network summary 1 - by network
SELECT root_node_id             "Network",
       Count (DISTINCT link_id) "#Links",
       Count (DISTINCT node_id) "#Nodes",
       Max (node_level) "Max Lev"
  FROM TABLE (Net_Pipe.All_Nets)
 GROUP BY root_node_id
 ORDER BY 2
/
PROMPT Network summary 2 - grouped by numbers of nodes
WITH network_counts AS (
SELECT root_node_id,
       Count (DISTINCT node_id) n_nodes
  FROM TABLE (Net_Pipe.All_Nets)
 GROUP BY root_node_id
)
SELECT n_nodes "#Nodes",
       COUNT(*) "#Networks"
  FROM network_counts
 GROUP BY n_nodes
 ORDER BY 1
/

Test Network 1: Oracle v12.1 Foreign Key Network

This network comes from Oracles foreign key constraints as specified in it's ALL_CONSTRAINTS view. I copied the constraints of type foreign key from the view into my own table, and created primary key and indexes that I deemed appropriate, and gathered statistics on the table.

Output for Foreign Key Network
The detailed output with 815 records took 1.5 seconds, while the two summary outputs took a fraction of a second each.

View links_v based on fk_link

View dropped.


View created.

Network detail

Network                                     #Links  #Nodes    Lev Node                                                                   Link
------------------------------------------ ------- ------- ------ ---------------------------------------------------------------------- ------------------------------------------
APEX$ARCHIVE_CONTENTS|APEX_040200                1       2      0 APEX$ARCHIVE_CONTENTS|APEX_040200                                      ROOT
                                                                1 > APEX$ARCHIVE_HEADER|APEX_040200                                      sys_c008573|apex_040200
APEX$_WS_FILES|APEX_040200                       4       5      0 APEX$_WS_FILES|APEX_040200                                             ROOT
                                                                1 > APEX$_WS_ROWS|APEX_040200                                            apex$_ws_files_fk|apex_040200
                                                                2   < APEX$_WS_LINKS|APEX_040200                                         apex$_ws_links_fk|apex_040200
                                                                2   < APEX$_WS_NOTES|APEX_040200                                         apex$_ws_notes_fk|apex_040200
                                                                2   < APEX$_WS_TAGS|APEX_040200                                          apex$_ws_tags_fk|apex_040200
AQ$_INTERNET_AGENTS|SYSTEM                       1       2      0 AQ$_INTERNET_AGENTS|SYSTEM                                             ROOT
                                                                1 < AQ$_INTERNET_AGENT_PRIVS|SYSTEM                                      agent_must_be_created|system ARCS|TEST                                        2       2      0 ARCS|TEST                                                              ROOT                                                                 1 > NODES|TEST                                                           arcs_fk1|test
                                                                2   < ARCS|TEST*                                                         arcs_fk2|test ATTRIBUTE_TRANSFORMATIONS$|SYS                   1       2      0 ATTRIBUTE_TRANSFORMATIONS$|SYS                                         ROOT                                                                 1 > TRANSFORMATIONS$|SYS                                                 attribute_transformations_fk|sys
BENCH_RUNS|BENCH                                 9       9      0 BENCH_RUNS|BENCH                                                       ROOT
                                                                1 < BENCH_RUN_DATA_POINTS|BENCH                                          rdp_rcn_fk|bench
                                                                2   < BENCH_RUN_STATISTICS|BENCH                                         brs_rdp_fk|bench
                                                                3     < BENCH_RUN_V$SQL_PLAN_STATS_ALL|BENCH                             rps_rst_fk|bench
                                                                3     < BENCH_RUN_V$STATS|BENCH                                          rvs_rst_fk|bench                                                                 3     > QUERIES|BENCH                                                    brs_qry_fk|bench
                                                                4       > QUERY_GROUPS|BENCH                                             qry_qgp_fk|bench
                                                                5         < BENCH_RUNS|BENCH*                                            brn_qgp_fk|bench                                                                 1 > LOG_HEADERS|BRENDAN                                                  brn_log_fk|bench
                                                                2   < LOG_LINES|BRENDAN                                                  lin_hdr_fk|brendan
BSLN_BASELINES|DBSNMP                            2       3      0 BSLN_BASELINES|DBSNMP                                                  ROOT
                                                                1 < BSLN_STATISTICS|DBSNMP                                               bsln_statistics_fk|dbsnmp
                                                                1 < BSLN_THRESHOLD_PARAMS|DBSNMP                                         bsln_thresholds_fk|dbsnmp
CHANNELS|SH                                     10       8      0 CHANNELS|SH                                                            ROOT
                                                                1 < COSTS|SH                                                             costs_channel_fk|sh                                                                 2   > PRODUCTS|SH                                                        costs_product_fk|sh
                                                                3     < SALES|SH                                                         sales_product_fk|sh                                                                 4       > CHANNELS|SH*                                                   sales_channel_fk|sh
                                                                4       > CUSTOMERS|SH                                                   sales_customer_fk|sh
                                                                5         > COUNTRIES|SH                                                 customers_country_fk|sh
                                                                4       > PROMOTIONS|SH                                                  sales_promo_fk|sh
                                                                5         < COSTS|SH*                                                    costs_promo_fk|sh                                                                 4       > TIMES|SH                                                       sales_time_fk|sh
                                                                5         < COSTS|SH*                                                    costs_time_fk|sh CLOUD|GSMADMIN_INTERNAL                          1       2      0 CLOUD|GSMADMIN_INTERNAL                                                ROOT                                                                 1 > GSM|GSMADMIN_INTERNAL                                                sys_c004716|gsmadmin_internal
CODE$|DVSYS                                     25      20      0 CODE$|DVSYS                                                            ROOT
                                                                1 < COMMAND_RULE$|DVSYS                                                  command_rule$_fk1|dvsys                                                                 2   > RULE_SET$|DVSYS                                                    command_rule$_fk|dvsys
                                                                3     < FACTOR$|DVSYS                                                    factor$_fk1|dvsys
                                                                4       < FACTOR_LINK$|DVSYS                                             factor_link$_fk1|dvsys                                                                 5         > FACTOR$|DVSYS*                                               factor_link$_fk|dvsys
                                                                5         < IDENTITY_MAP$|DVSYS                                          identity_map$_fk1|dvsys                                                                 6           > CODE$|DVSYS*                                               identity_map$_fk2|dvsys
                                                                6           > IDENTITY$|DVSYS                                            identity_map$_fk|dvsys
                                                                7             > FACTOR$|DVSYS*                                           identity$_fk|dvsys
                                                                7             < POLICY_LABEL$|DVSYS                                      identity_label$_fk|dvsys
                                                                4       < FACTOR_SCOPE$|DVSYS                                            factor_scope$_fk|dvsys                                                                 4       > FACTOR_TYPE$|DVSYS                                             factor$_fk|dvsys
                                                                4       < MAC_POLICY_FACTOR$|DVSYS                                       mac_policy_factor$_fk|dvsys                                                                 5         > MAC_POLICY$|DVSYS                                            mac_policy_factor$_fk1|dvsys
                                                                6           > CODE$|DVSYS*                                               mac_policy$_fk1|dvsys
                                                                3     < MONITOR_RULE$|DVSYS                                              monitor_rule$_fk1|dvsys
                                                                3     < REALM_AUTH$|DVSYS                                                realm_auth$_fk1|dvsys                                                                 4       > REALM$|DVSYS                                                   realm_auth$_fk|dvsys
                                                                5         < REALM_COMMAND_RULE$|DVSYS                                    realm_command_rule$_fk2|dvsys                                                                 6           > CODE$|DVSYS*                                               realm_command_rule$_fk1|dvsys
                                                                6           > RULE_SET$|DVSYS*                                           realm_command_rule$_fk|dvsys
                                                                5         < REALM_OBJECT$|DVSYS                                          realm_object$_fk|dvsys
                                                                3     < ROLE$|DVSYS                                                      role$_fk|dvsys
                                                                3     < RULE_SET_RULE$|DVSYS                                             rule_set_rule$_fk|dvsys                                                                 4       > RULE$|DVSYS                                                    rule_set_rule$_fk1|dvsys
COUNTRIES|HR                                    21      16      0 COUNTRIES|HR                                                           ROOT
                                                                1 < LOCATIONS|HR                                                         loc_c_id_fk|hr
                                                                2   < DEPARTMENTS|HR                                                     dept_loc_fk|hr                                                                 3     > EMPLOYEES|HR                                                     dept_mgr_fk|hr
                                                                4       < CUSTOMERS|OE                                                   customers_account_manager_fk|oe
                                                                5         < ORDERS|OE                                                    orders_customer_id_fk|oe                                                                 6           > EMPLOYEES|HR*                                              orders_sales_rep_fk|oe
                                                                6           < ORDER_ITEMS|OE                                             order_items_order_id_fk|oe                                                                 7             > PRODUCT_INFORMATION|OE                                   order_items_product_id_fk|oe
                                                                8               < INVENTORIES|OE                                         inventories_product_id_fk|oe                                                                 9                 > WAREHOUSES|OE                                        inventories_warehouses_fk|oe
                                                               10                   > LOCATIONS|HR*                                      warehouses_location_fk|oe
                                                                8               < ONLINE_MEDIA|PM                                        loc_c_id_fk|pm
                                                                8               < PRINT_MEDIA|PM                                         printmedia_fk|pm
                                                                8               < PRODUCT_DESCRIPTIONS|OE                                pd_product_id_fk|oe                                                                 4       > DEPARTMENTS|HR*                                                emp_dept_fk|hr
                                                                4       = EMPLOYEES|HR*                                                  emp_manager_fk|hr
                                                                4       > JOBS|HR                                                        emp_job_fk|hr
                                                                5         < JOB_HISTORY|HR                                               jhist_job_fk|hr                                                                 6           > DEPARTMENTS|HR*                                            jhist_dept_fk|hr
                                                                6           > EMPLOYEES|HR*                                              jhist_emp_fk|hr
                                                                1 > REGIONS|HR                                                           countr_reg_fk|hr
CSW_DOMAININFO$|MDSYS                            1       2      0 CSW_DOMAININFO$|MDSYS                                                  ROOT
                                                                1 > CSW_RECORD_TYPES$|MDSYS                                              sys_c006217|mdsys
DAM_CONFIG_PARAM$|SYS                            1       2      0 DAM_CONFIG_PARAM$|SYS                                                  ROOT
                                                                1 > DAM_PARAM_TAB$|SYS                                                   dam_config_param_fk1|sys
DATABASE_POOL_ADMIN|GSMADMIN_INTERNAL            6       5      0 DATABASE_POOL_ADMIN|GSMADMIN_INTERNAL                                  ROOT
                                                                1 > DATABASE_POOL|GSMADMIN_INTERNAL                                      sys_c004723|gsmadmin_internal
                                                                2   < DATABASE|GSMADMIN_INTERNAL                                         sys_c004731|gsmadmin_internal
                                                                3     < SERVICE_PREFERRED_AVAILABLE|GSMADMIN_INTERNAL                    sys_c004739|gsmadmin_internal                                                                 4       > DATABASE_POOL|GSMADMIN_INTERNAL*                               sys_c004738|gsmadmin_internal
                                                                4       > SERVICE|GSMADMIN_INTERNAL                                      sys_c004740|gsmadmin_internal
                                                                5         > DATABASE_POOL|GSMADMIN_INTERNAL*                             sys_c004736|gsmadmin_internal
DBFS$_MOUNTS|SYS                                 1       2      0 DBFS$_MOUNTS|SYS                                                       ROOT
                                                                1 > DBFS$_STORES|SYS                                                     sys_c003936|sys
DBFS_SFS$_FSTP|SYS                               1       2      0 DBFS_SFS$_FSTP|SYS                                                     ROOT
                                                                1 > DBFS_SFS$_FST|SYS                                                    sys_c004004|sys
DBFS_SFS$_FS|SYS                                 3       4      0 DBFS_SFS$_FS|SYS                                                       ROOT
                                                                1 > DBFS_SFS$_VOL|SYS                                                    sys_c003978|sys
                                                                2   < DBFS_SFS$_SNAP|SYS                                                 sys_c003970|sys                                                                 2   > DBFS_SFS$_TAB|SYS                                                  sys_c003961|sys
DBMSHP_FUNCTION_INFO|BENCH                       3       3      0 DBMSHP_FUNCTION_INFO|BENCH                                             ROOT
                                                                1 < DBMSHP_PARENT_CHILD_INFO|BENCH                                       sys_c0010218|bench                                                                 2   > DBMSHP_FUNCTION_INFO|BENCH*                                        sys_c0010219|bench
                                                                1 > DBMSHP_RUNS|BENCH                                                    sys_c0010217|bench
DBMS_PARALLEL_EXECUTE_CHUNKS$|SYS                1       2      0 DBMS_PARALLEL_EXECUTE_CHUNKS$|SYS                                      ROOT
                                                                1 > DBMS_PARALLEL_EXECUTE_TASK$|SYS                                      fk_dbms_parallel_execute_1|sys
DEF$_CALLDEST|SYSTEM                            14      14      0 DEF$_CALLDEST|SYSTEM                                                   ROOT
                                                                1 > DEF$_DESTINATION|SYSTEM                                              def$_call_destination|system
                                                                2   < REPCAT$_REPSCHEMA|SYSTEM                                           repcat$_repschema_dest|system                                                                 3     > REPCAT$_REPCAT|SYSTEM                                            repcat$_repschema_prnt|system
                                                                4       < REPCAT$_FLAVORS|SYSTEM                                         repcat$_flavors_fk1|system
                                                                4       < REPCAT$_FLAVOR_OBJECTS|SYSTEM                                  repcat$_flavor_objects_fk1|system
                                                                4       < REPCAT$_REPGROUP_PRIVS|SYSTEM                                  repcat$_repgroup_privs_fk|system
                                                                4       < REPCAT$_REPOBJECT|SYSTEM                                       repcat$_repobject_prnt|system
                                                                5         < REPCAT$_GENERATED|SYSTEM                                     repcat$_repgen_prnt2|system                                                                 6           > REPCAT$_REPOBJECT|SYSTEM*                                  repcat$_repgen_prnt|system
                                                                5         < REPCAT$_KEY_COLUMNS|SYSTEM                                   repcat$_key_columns_prnt|system
                                                                5         < REPCAT$_REPCOLUMN|SYSTEM                                     repcat$_repcolumn_fk|system
                                                                5         < REPCAT$_REPPROP|SYSTEM                                       repcat$_repprop_prnt|system
                                                                4       < REPCAT$_SITES_NEW|SYSTEM                                       repcat$_sites_new_fk2|system                                                                 5         > REPCAT$_EXTENSION|SYSTEM                                     repcat$_sites_new_fk1|system
DEPT|SCOTT                                       1       2      0 DEPT|SCOTT                                                             ROOT
                                                                1 < EMP|SCOTT                                                            fk_deptno|scott DR$THS_BT|CTXSYS                                 4       4      0 DR$THS_BT|CTXSYS                                                       ROOT                                                                 1 > DR$THS_PHRASE|CTXSYS                                                 sys_c005023|ctxsys
                                                                2   < DR$THS_BT|CTXSYS*                                                  sys_c005024|ctxsys
                                                                2   < DR$THS_FPHRASE|CTXSYS                                              sys_c005021|ctxsys                                                                 2   > DR$THS|CTXSYS                                                      sys_c005017|ctxsys
FLIGHTS|TEST                                     1       2      0 FLIGHTS|TEST                                                           ROOT
                                                                1 > SECTORS|TEST                                                         fli_sec_fk|test
HS$_BASE_CAPS|SYS                               11      10      0 HS$_BASE_CAPS|SYS                                                      ROOT
                                                                1 < HS$_CLASS_CAPS|SYS                                                   hs$_class_caps_fk2|sys                                                                 2   > HS$_FDS_CLASS|SYS                                                  hs$_class_caps_fk1|sys
                                                                3     < HS$_CLASS_DD|SYS                                                 hs$_class_dd_fk1|sys                                                                 4       > HS$_BASE_DD|SYS                                                hs$_class_dd_fk2|sys
                                                                5         < HS$_INST_DD|SYS                                              hs$_inst_dd_fk2|sys                                                                 6           > HS$_FDS_INST|SYS                                           hs$_inst_dd_fk1|sys
                                                                7             > HS$_FDS_CLASS|SYS*                                       hs$_fds_inst_fk1|sys
                                                                7             < HS$_INST_CAPS|SYS                                        hs$_inst_caps_fk1|sys                                                                 8               > HS$_BASE_CAPS|SYS*                                     hs$_inst_caps_fk2|sys
                                                                7             < HS$_INST_INIT|SYS                                        hs$_inst_init_fk1|sys
                                                                3     < HS$_CLASS_INIT|SYS                                               hs$_class_init_fk1|sys HS$_PARALLEL_HISTOGRAM_DATA|SYS                  3       4      0 HS$_PARALLEL_HISTOGRAM_DATA|SYS                                        ROOT                                                                 1 > HS$_PARALLEL_METADATA|SYS                                            hs_parallel_histogram_data_fk|sys
                                                                2   < HS$_PARALLEL_PARTITION_DATA|SYS                                    hs_parallel_partition_data_fk|sys
                                                                2   < HS$_PARALLEL_SAMPLE_DATA|SYS                                       hs_parallel_sample_data_fk|sys
MVIEW$_ADV_AJG|SYSTEM                           14      13      0 MVIEW$_ADV_AJG|SYSTEM                                                  ROOT
                                                                1 < MVIEW$_ADV_FJG|SYSTEM                                                mview$_adv_fjg_fk|system
                                                                2   < MVIEW$_ADV_GC|SYSTEM                                               mview$_adv_gc_fk|system                                                                 1 > MVIEW$_ADV_LOG|SYSTEM                                                mview$_adv_ajg_fk|system
                                                                2   < MVIEW$_ADV_CLIQUE|SYSTEM                                           mview$_adv_clique_fk|system
                                                                2   < MVIEW$_ADV_ELIGIBLE|SYSTEM                                         mview$_adv_eligible_fk|system
                                                                2   < MVIEW$_ADV_EXCEPTIONS|SYSTEM                                       mview$_adv_exception_fk|system
                                                                2   < MVIEW$_ADV_FILTERINSTANCE|SYSTEM                                   mview$_adv_filterinstance_fk|system
                                                                2   < MVIEW$_ADV_INFO|SYSTEM                                             mview$_adv_info_fk|system
                                                                2   < MVIEW$_ADV_JOURNAL|SYSTEM                                          mview$_adv_journal_fk|system
                                                                2   < MVIEW$_ADV_LEVEL|SYSTEM                                            mview$_adv_level_fk|system
                                                                3     < MVIEW$_ADV_ROLLUP|SYSTEM                                         mview$_adv_rollup_cfk|system                                                                 4       > MVIEW$_ADV_LEVEL|SYSTEM*                                       mview$_adv_rollup_pfk|system
                                                                4       > MVIEW$_ADV_LOG|SYSTEM*                                         mview$_adv_rollup_fk|system
                                                                2   < MVIEW$_ADV_OUTPUT|SYSTEM                                           mview$_adv_output_fk|system MVIEW$_ADV_BASETABLE|SYSTEM                      1       2      0 MVIEW$_ADV_BASETABLE|SYSTEM                                            ROOT                                                                 1 > MVIEW$_ADV_WORKLOAD|SYSTEM                                           mview$_adv_basetable_fk|system
OGIS_GEOMETRY_COLUMNS|MDSYS                      1       2      0 OGIS_GEOMETRY_COLUMNS|MDSYS                                            ROOT
                                                                1 > OGIS_SPATIAL_REFERENCE_SYSTEMS|MDSYS                                 fk_srid|mdsys
OLS$AUDIT|LBACSYS                               21      14      0 OLS$AUDIT|LBACSYS                                                      ROOT
                                                                1 > OLS$POL|LBACSYS                                                      sys_c006346|lbacsys
                                                                2   < OLS$COMPARTMENTS|LBACSYS                                           ols_comp_pol_fk|lbacsys
                                                                3     < OLS$USER_COMPARTMENTS|LBACSYS                                    ols_user_comp_fk|lbacsys                                                                 4       > OLS$USER_LEVELS|LBACSYS                                        ols_user_comp_level_fk|lbacsys
                                                                5         > OLS$LEVELS|LBACSYS                                           ols_user_def_fk|lbacsys
                                                                6           > OLS$POL|LBACSYS*                                           ols_level_pol_fk|lbacsys
                                                                6           < OLS$USER_LEVELS|LBACSYS*                                   ols_user_max_fk|lbacsys
                                                                6           < OLS$USER_LEVELS|LBACSYS*                                   ols_user_min_fk|lbacsys
                                                                6           < OLS$USER_LEVELS|LBACSYS*                                   ols_user_row_fk|lbacsys                                                                 5         > OLS$POL|LBACSYS*                                             ols_user_level_pol_fk|lbacsys
                                                                5         < OLS$USER_GROUPS|LBACSYS                                      ols_user_grp_level_fk|lbacsys                                                                 6           > OLS$GROUPS|LBACSYS                                         ols_user_grp_fk|lbacsys
                                                                7             = OLS$GROUPS|LBACSYS*                                      ols_group_parent|lbacsys
                                                                7             > OLS$POL|LBACSYS*                                         ols_group_pol_fk|lbacsys
                                                                2   < OLS$LAB|LBACSYS                                                    ols_label_policy_fk|lbacsys
                                                                2   < OLS$POLS|LBACSYS                                                   sys_c006243|lbacsys
                                                                2   < OLS$POLT|LBACSYS                                                   sys_c006248|lbacsys
                                                                2   < OLS$PROFILE|LBACSYS                                                sys_c006251|lbacsys
                                                                3     < OLS$USER|LBACSYS                                                 sys_c006257|lbacsys                                                                 4       > OLS$POL|LBACSYS*                                               sys_c006256|lbacsys
                                                                2   < OLS$PROG|LBACSYS                                                   sys_c006262|lbacsys OLS_DIR_BUSINESSES|MDSYS                         1       2      0 OLS_DIR_BUSINESSES|MDSYS                                               ROOT                                                                 1 > OLS_DIR_BUSINESS_CHAINS|MDSYS                                        olsfk3|mdsys
OLS_DIR_CATEGORIES|MDSYS                         3       3      0 OLS_DIR_CATEGORIES|MDSYS                                               ROOT
                                                                1 = OLS_DIR_CATEGORIES|MDSYS*                                            olsfk1|mdsys
                                                                1 < OLS_DIR_CATEGORIZATIONS|MDSYS                                        olsfk5|mdsys                                                                 1 > OLS_DIR_CATEGORY_TYPES|MDSYS                                         olsfk2|mdsys
ORDDCM_ANON_ACTION_TYPES|ORDDATA                69      47      0 ORDDCM_ANON_ACTION_TYPES|ORDDATA                                       ROOT
                                                                1 < ORDDCM_ANON_ATTRS_WRK|ORDDATA                                        orddcm_anon_attrs_w_fk3|orddata                                                                 2   > ORDDCM_DOCS_WRK|ORDDATA                                            orddcm_anon_attrs_w_fk1|orddata
                                                                3     < ORDDCM_ANON_RULES_WRK|ORDDATA                                    orddcm_anon_rules_w_fk1|orddata                                                                 4       > ORDDCM_ANON_ACTION_TYPES|ORDDATA*                              orddcm_anon_rules_w_fk3|orddata
                                                                4       > ORDDCM_ANON_RULE_TYPES|ORDDATA                                 orddcm_anon_rules_w_fk2|orddata
                                                                5         < ORDDCM_ANON_RULES|ORDDATA                                    orddcm_anon_rules_fk2|orddata                                                                 6           > ORDDCM_ANON_ACTION_TYPES|ORDDATA*                          orddcm_anon_rules_fk3|orddata
                                                                6           > ORDDCM_DOCS|ORDDATA                                        orddcm_anon_rules_fk1|orddata
                                                                7             < ORDDCM_ANON_ATTRS|ORDDATA                                orddcm_anon_attrs_fk1|orddata                                                                 8               > ORDDCM_ANON_ACTION_TYPES|ORDDATA*                      orddcm_anon_attrs_fk3|orddata
                                                                7             < ORDDCM_CT_DAREFS|ORDDATA                                 orddcm_ct_darefs_fk2|orddata                                                                 8               > ORDDCM_DICT_ATTRS|ORDDATA                              orddcm_ct_darefs_fk1|orddata
                                                                9                 > ORDDCM_PRV_ATTRS|ORDDATA                             orddcm_dict_attrs_fk2|orddata
                                                               10                   > ORDDCM_DOCS|ORDDATA*                               orddcm_prv_attrs_fk1|orddata
                                                               10                   > ORDDCM_VR_DT_MAP|ORDDATA                           orddcm_prv_attrs_fk2|orddata
                                                               11                     < ORDDCM_PRV_ATTRS_WRK|ORDDATA                     orddcm_prv_attrs_w_fk2|orddata
                                                               12                       < ORDDCM_DICT_ATTRS_WRK|ORDDATA                  orddcm_dict_attrs_w_fk2|orddata
                                                               13                         < ORDDCM_CT_DAREFS_WRK|ORDDATA                 orddcm_ct_darefs_w_fk1|orddata                                                                14                           > ORDDCM_DOCS_WRK|ORDDATA*                   orddcm_ct_darefs_w_fk2|orddata
                                                               13                         > ORDDCM_STD_ATTRS_WRK|ORDDATA                 orddcm_dict_attrs_w_fk1|orddata
                                                               14                           > ORDDCM_DOCS_WRK|ORDDATA*                   orddcm_sd_attrs_w_fk2|orddata
                                                               14                           > ORDDCM_VR_DT_MAP|ORDDATA*                  orddcm_sd_attrs_w_fk1|orddata
                                                               12                       > ORDDCM_DOCS_WRK|ORDDATA*                       orddcm_prv_attrs_w_fk1|orddata
                                                               11                     < ORDDCM_STD_ATTRS|ORDDATA                         orddcm_sd_attrs_fk1|orddata
                                                               12                       < ORDDCM_DICT_ATTRS|ORDDATA*                     orddcm_dict_attrs_fk1|orddata                                                                12                       > ORDDCM_DOCS|ORDDATA*                           orddcm_sd_attrs_fk2|orddata
                                                                7             < ORDDCM_CT_LOCATORPATHS|ORDDATA                           orddcm_ct_lp_fk1|orddata                                                                 8               > ORDDCM_CT_PRED_SET|ORDDATA                             orddcm_ct_lp_fk2|orddata
                                                                9                 < ORDDCM_CT_MACRO_DEP|ORDDATA                          orddcm_ct_md_fk1|orddata                                                                10                   > ORDDCM_CT_PRED_SET|ORDDATA*                        orddcm_ct_md_fk2|orddata
                                                                9                 < ORDDCM_CT_MACRO_PAR|ORDDATA                          orddcm_ct_mp_fk|orddata                                                                 9                 = ORDDCM_CT_PRED_SET|ORDDATA*                          orddcm_ct_ps_fk2|orddata                                                                 9                 > ORDDCM_CT_PRED|ORDDATA                               orddcm_ct_ps_fk1|orddata
                                                               10                   < ORDDCM_CT_ACTION|ORDDATA                           orddcm_ct_a_fk1|orddata
                                                               10                   < ORDDCM_CT_PRED_OPRD|ORDDATA                        orddcm_ct_po_fk|orddata
                                                               10                   < ORDDCM_CT_PRED_PAR|ORDDATA                         orddcm_ct_pp_fk|orddata                                                                10                   = ORDDCM_CT_PRED|ORDDATA*                            orddcm_ct_pred_fk1|orddata                                                                10                   = ORDDCM_CT_PRED|ORDDATA*                            orddcm_ct_pred_fk2|orddata                                                                 9                 > ORDDCM_DOCS|ORDDATA*                                 orddcm_ct_ps_fk3|orddata
                                                                7             < ORDDCM_DOC_REFS|ORDDATA                                  sys_c005130|orddata                                                                 8               > ORDDCM_DOCS|ORDDATA*                                   sys_c005131|orddata
                                                                7             > ORDDCM_DOC_TYPES|ORDDATA                                 orddcm_docs_fk1|orddata
                                                                8               < ORDDCM_DOCS_WRK|ORDDATA*                               orddcm_docs_w_fk1|orddata
                                                                8               < ORDDCM_INSTALL_DOCS|ORDDATA                            orddcm_i_docs_fk1|orddata
                                                                7             < ORDDCM_MAPPING_DOCS|ORDDATA                              orddcm_mapping_docs_fk1|orddata
                                                                8               < ORDDCM_MAPPED_PATHS|ORDDATA                            orddcm_mapped_paths_fk2|orddata
                                                                7             < ORDDCM_RT_PREF_PARAMS|ORDDATA                            orddcm_pref_params_fk1|orddata
                                                                7             < ORDDCM_STORED_TAGS|ORDDATA                               orddcm_stored_tags_fk1|orddata
                                                                7             < ORDDCM_UID_DEFS|ORDDATA                                  orddcm_uid_defs_fk1|orddata
                                                                3     < ORDDCM_CT_LOCATORPATHS_WRK|ORDDATA                               orddcm_ct_lp_w_fk1|orddata                                                                 4       > ORDDCM_CT_PRED_SET_WRK|ORDDATA                                 orddcm_ct_lp_w_fk2|orddata
                                                                5         < ORDDCM_CT_MACRO_DEP_WRK|ORDDATA                              orddcm_ct_md_w_fk1|orddata                                                                 6           > ORDDCM_CT_PRED_SET_WRK|ORDDATA*                            orddcm_ct_md_w_fk2|orddata
                                                                5         < ORDDCM_CT_MACRO_PAR_WRK|ORDDATA                              orddcm_ct_mp_w_fk|orddata                                                                 5         = ORDDCM_CT_PRED_SET_WRK|ORDDATA*                              orddcm_ct_ps_w_fk2|orddata                                                                 5         > ORDDCM_CT_PRED_WRK|ORDDATA                                   orddcm_ct_ps_w_fk1|orddata
                                                                6           < ORDDCM_CT_ACTION_WRK|ORDDATA                               orddcm_ct_a_w_fk1|orddata
                                                                6           < ORDDCM_CT_PRED_OPRD_WRK|ORDDATA                            orddcm_ct_po_w_fk|orddata
                                                                6           < ORDDCM_CT_PRED_PAR_WRK|ORDDATA                             orddcm_ct_pp_w_fk|orddata                                                                 6           = ORDDCM_CT_PRED_WRK|ORDDATA*                                orddcm_ct_pred_w_fk1|orddata                                                                 6           = ORDDCM_CT_PRED_WRK|ORDDATA*                                orddcm_ct_pred_w_fk2|orddata                                                                 5         > ORDDCM_DOCS_WRK|ORDDATA*                                     orddcm_ct_ps_w_fk3|orddata
                                                                3     < ORDDCM_DOC_REFS_WRK|ORDDATA                                      sys_c005428|orddata                                                                 4       > ORDDCM_DOCS_WRK|ORDDATA*                                       sys_c005429|orddata
                                                                3     < ORDDCM_MAPPING_DOCS_WRK|ORDDATA                                  orddcm_mapping_docs_w_fk1|orddata
                                                                4       < ORDDCM_MAPPED_PATHS_WRK|ORDDATA                                orddcm_mapped_paths_w_fk2|orddata
                                                                3     < ORDDCM_RT_PREF_PARAMS_WRK|ORDDATA                                orddcm_pref_params_w_fk1|orddata
                                                                3     < ORDDCM_STORED_TAGS_WRK|ORDDATA                                   orddcm_stored_tags_w_fk1|orddata
                                                                3     < ORDDCM_UID_DEFS_WRK|ORDDATA                                      orddcm_uid_defs_w_fk1|orddata
PLANETS|TEST                                     1       2      0 PLANETS|TEST                                                           ROOT
                                                                1 < PLANET_CLIMATES|TEST                                                 plc_pla_fk|test PLSQL_PROFILER_DATA|BENCH                        2       3      0 PLSQL_PROFILER_DATA|BENCH                                              ROOT                                                                 1 > PLSQL_PROFILER_UNITS|BENCH                                           sys_c0010214|bench
                                                                2   > PLSQL_PROFILER_RUNS|BENCH                                          sys_c0010211|bench
REGISTRY$DEPENDENCIES|SYS                        5       4      0 REGISTRY$DEPENDENCIES|SYS                                              ROOT
                                                                1 > REGISTRY$|SYS                                                        dependencies_fk|sys
                                                                2   < REGISTRY$DEPENDENCIES|SYS*                                         dependencies_req_fk|sys
                                                                2   < REGISTRY$PROGRESS|SYS                                              registry_progress_fk|sys
                                                                2   < REGISTRY$SCHEMAS|SYS                                               registry_schema_fk|sys
                                                                2   = REGISTRY$|SYS*                                                     registry_parent_fk|sys
REPCAT$_AUDIT_ATTRIBUTE|SYSTEM                   5       6      0 REPCAT$_AUDIT_ATTRIBUTE|SYSTEM                                         ROOT
                                                                1 < REPCAT$_AUDIT_COLUMN|SYSTEM                                          repcat$_audit_column_f1|system                                                                 2   > REPCAT$_CONFLICT|SYSTEM                                            repcat$_audit_column_f2|system
                                                                3     < REPCAT$_RESOLUTION|SYSTEM                                        repcat$_resolution_f3|system
                                                                4       < REPCAT$_PARAMETER_COLUMN|SYSTEM                                repcat$_parameter_column_f1|system                                                                 4       > REPCAT$_RESOLUTION_METHOD|SYSTEM                               repcat$_resolution_f1|system
REPCAT$_COLUMN_GROUP|SYSTEM                      1       2      0 REPCAT$_COLUMN_GROUP|SYSTEM                                            ROOT
                                                                1 < REPCAT$_GROUPED_COLUMN|SYSTEM                                        repcat$_grouped_column_f1|system REPCAT$_DDL|SYSTEM                               1       2      0 REPCAT$_DDL|SYSTEM                                                     ROOT                                                                 1 > REPCAT$_REPCATLOG|SYSTEM                                             repcat$_ddl_prnt|system
REPCAT$_INSTANTIATION_DDL|SYSTEM                13      13      0 REPCAT$_INSTANTIATION_DDL|SYSTEM                                       ROOT
                                                                1 > REPCAT$_REFRESH_TEMPLATES|SYSTEM                                     repcat$_instantiation_ddl_fk1|system
                                                                2   < REPCAT$_TEMPLATE_OBJECTS|SYSTEM                                    repcat$_template_objects_fk1|system
                                                                3     < REPCAT$_OBJECT_PARMS|SYSTEM                                      repcat$_object_parms_fk2|system                                                                 4       > REPCAT$_TEMPLATE_PARMS|SYSTEM                                  repcat$_object_parms_fk1|system
                                                                5         > REPCAT$_REFRESH_TEMPLATES|SYSTEM*                            repcat$_template_parms_fk1|system
                                                                5         < REPCAT$_USER_PARM_VALUES|SYSTEM                              repcat$_user_parm_values_fk1|system                                                                 3     > REPCAT$_OBJECT_TYPES|SYSTEM                                      repcat$_template_objects_fk3|system
                                                                4       < REPCAT$_SITE_OBJECTS|SYSTEM                                    repcat$_site_objects_fk1|system                                                                 5         > REPCAT$_TEMPLATE_SITES|SYSTEM                                repcat$_site_object_fk2|system
                                                                2   < REPCAT$_TEMPLATE_REFGROUPS|SYSTEM                                  repcat$_template_refgroups_fk1|system                                                                 2   > REPCAT$_TEMPLATE_STATUS|SYSTEM                                     repcat$_refresh_templates_fk2|system
                                                                2   > REPCAT$_TEMPLATE_TYPES|SYSTEM                                      repcat$_refresh_templates_fk1|system
                                                                2   < REPCAT$_USER_AUTHORIZATIONS|SYSTEM                                 repcat$_user_authorization_fk2|system
REPCAT$_PRIORITY_GROUP|SYSTEM                    1       2      0 REPCAT$_PRIORITY_GROUP|SYSTEM                                          ROOT
                                                                1 < REPCAT$_PRIORITY|SYSTEM                                              repcat$_priority_f1|system
ROADS|TEST                                       1       2      0 ROADS|TEST                                                             ROOT
                                                                1 < ROAD_EVENTS|TEST                                                     rev_roa_fk|test SCHEDULER$_JOB_OUTPUT|SYS                        1       2      0 SCHEDULER$_JOB_OUTPUT|SYS                                              ROOT                                                                 1 > SCHEDULER$_JOB_RUN_DETAILS|SYS                                       scheduler$_job_output_fk|sys
SDO_COORD_AXES|MDSYS                            30      14      0 SDO_COORD_AXES|MDSYS                                                   ROOT
                                                                1 > SDO_COORD_AXIS_NAMES|MDSYS                                           coord_axis_foreign_axis|mdsys
                                                                1 > SDO_COORD_SYS|MDSYS                                                  coord_axis_foreign_cs|mdsys
                                                                2   < SDO_COORD_REF_SYS|MDSYS                                            coord_ref_sys_foreign_cs|mdsys
                                                                3     < SDO_COORD_OPS|MDSYS                                              coord_operation_foreign_source|mdsys                                                                 4       = SDO_COORD_OPS|MDSYS*                                           coord_operation_foreign_legacy|mdsys                                                                 4       > SDO_COORD_OP_METHODS|MDSYS                                     coord_operation_foreign_method|mdsys
                                                                5         < SDO_COORD_OP_PARAM_USE|MDSYS                                 coord_op_para_use_foreign_meth|mdsys                                                                 6           > SDO_COORD_OP_PARAMS|MDSYS                                  coord_op_para_use_foreign_para|mdsys
                                                                7             < SDO_COORD_OP_PARAM_VALS|MDSYS                            coord_op_para_val_foreign_para|mdsys                                                                 8               > SDO_COORD_OPS|MDSYS*                                   coord_op_para_val_foreign_op|mdsys
                                                                8               > SDO_COORD_OP_METHODS|MDSYS*                            coord_op_para_val_foreign_meth|mdsys
                                                                8               > SDO_UNITS_OF_MEASURE|MDSYS                             coord_op_para_val_foreign_uom|mdsys
                                                                9                 < SDO_COORD_AXES|MDSYS*                                coord_axis_foreign_uom|mdsys                                                                 9                 > SDO_ELLIPSOIDS|MDSYS                                 ellipsoid_foreign_legacy|mdsys
                                                               10                   < SDO_DATUMS|MDSYS                                   datum_foreign_ellipsoid|mdsys
                                                               11                     < SDO_COORD_REF_SYS|MDSYS*                         coord_ref_sys_foreign_datum|mdsys                                                                11                     = SDO_DATUMS|MDSYS*                                datum_foreign_legacy|mdsys                                                                11                     > SDO_PRIME_MERIDIANS|MDSYS                        datum_foreign_meridian|mdsys
                                                               12                       > SDO_UNITS_OF_MEASURE|MDSYS*                    prime_meridian_foreign_uom|mdsys
                                                               10                   > SDO_UNITS_OF_MEASURE|MDSYS*                        ellipsoid_foreign_uom|mdsys
                                                                9                 = SDO_UNITS_OF_MEASURE|MDSYS*                          unit_of_measure_foreign_legacy|mdsys
                                                                9                 = SDO_UNITS_OF_MEASURE|MDSYS*                          unit_of_measure_foreign_uom|mdsys
                                                                4       > SDO_COORD_REF_SYS|MDSYS*                                       coord_operation_foreign_target|mdsys
                                                                4       < SDO_COORD_REF_SYS|MDSYS*                                       coord_ref_sys_foreign_proj|mdsys
                                                                3     < SDO_COORD_OP_PATHS|MDSYS                                         coord_op_path_foreign_source|mdsys                                                                 4       > SDO_COORD_REF_SYS|MDSYS*                                       coord_op_path_foreign_target|mdsys
                                                                3     = SDO_COORD_REF_SYS|MDSYS*                                         coord_ref_sys_foreign_geog|mdsys
                                                                3     = SDO_COORD_REF_SYS|MDSYS*                                         coord_ref_sys_foreign_horiz|mdsys
                                                                3     = SDO_COORD_REF_SYS|MDSYS*                                         coord_ref_sys_foreign_legacy|mdsys
                                                                3     = SDO_COORD_REF_SYS|MDSYS*                                         coord_ref_sys_foreign_vert|mdsys
SDO_WS_CONFERENCE_PARTICIPANTS|MDSYS             1       2      0 SDO_WS_CONFERENCE_PARTICIPANTS|MDSYS                                   ROOT
                                                                1 > SDO_WS_CONFERENCE|MDSYS                                              sdo_ws_conf_part_fk|mdsys
TSDP_ASSOCIATION$|SYS                            8       9      0 TSDP_ASSOCIATION$|SYS                                                  ROOT
                                                                1 > TSDP_POLICY$|SYS                                                     tsdp_association$fkpo|sys
                                                                2   < TSDP_SUBPOL$|SYS                                                   tsdp_subpol$fk|sys
                                                                3     < TSDP_CONDITION$|SYS                                              tsdp_condition$fk|sys
                                                                3     < TSDP_PARAMETER$|SYS                                              tsdp_parameter$fk|sys
                                                                3     < TSDP_PROTECTION$|SYS                                             tsdp_protection$fkpc|sys                                                                 4       > TSDP_SENSITIVE_DATA$|SYS                                       tsdp_protection$fksd|sys
                                                                1 > TSDP_SENSITIVE_TYPE$|SYS                                             tsdp_association$fkst|sys
                                                                2   > TSDP_SOURCE$|SYS                                                   tsdp_sensitive_type$fk|sys
WFS_FEATUREINSTANCEMETADATA$|MDSYS               6       7      0 WFS_FEATUREINSTANCEMETADATA$|MDSYS                                     ROOT
                                                                1 > WFS_FEATURETYPE$|MDSYS                                               sys_c006201|mdsys
                                                                2   < WFS_FEATURETYPEATTRS$|MDSYS                                        sys_c006202|mdsys
                                                                2   < WFS_FEATURETYPENESTEDSDOS$|MDSYS                                   sys_c006206|mdsys
                                                                2   < WFS_FEATURETYPESIMPLETAGATTRS$|MDSYS                               sys_c006203|mdsys
                                                                2   < WFS_FEATURETYPETAGS$|MDSYS                                         sys_c006200|mdsys
                                                                2   < WFS_FEATURETYPEXMLCOLINFO$|MDSYS                                   sys_c006205|mdsys
WI$_CAPTURE_FILE|SYS                            10       9      0 WI$_CAPTURE_FILE|SYS                                                   ROOT
                                                                1 < WI$_EXECUTION_ORDER|SYS                                              wi$_execution_order_fk1|sys                                                                 2   > WI$_TEMPLATE|SYS                                                   wi$_execution_order_fk2|sys
                                                                3     < WI$_FREQUENT_PATTERN_ITEM|SYS                                    wi$_frequent_pattern_item_fk2|sys                                                                 4       > WI$_FREQUENT_PATTERN|SYS                                       wi$_frequent_pattern_item_fk1|sys
                                                                5         > WI$_JOB|SYS                                                  wi$_frequent_pattern_fk1|sys
                                                                6           < WI$_CAPTURE_FILE|SYS*                                      wi$_capture_file_fk1|sys
                                                                6           < WI$_FREQUENT_PATTERN_METADATA|SYS                          wi$_freq_pattern_metadata_fk1|sys
                                                                6           < WI$_TEMPLATE|SYS*                                          wi$_template_fk1|sys
                                                                3     < WI$_OBJECT|SYS                                                   wi$_object_fk1|sys
                                                                3     < WI$_STATEMENT|SYS                                                wi$_statement_fk1|sys
WRM$_DATABASE_INSTANCE|SYS                       1       2      0 WRM$_DATABASE_INSTANCE|SYS                                             ROOT
                                                                1 < WRM$_SNAPSHOT|SYS                                                    wrm$_snapshot_fk|sys
WWV_FLOWS|APEX_040200                          334     264      0 WWV_FLOWS|APEX_040200                                                  ROOT
                                                                1 < WWV_FLOW_APP_COMMENTS|APEX_040200                                    wwv_flow_app_comments_fk|apex_040200
                                                                1 < WWV_FLOW_AUTHENTICATIONS|APEX_040200                                 wwv_flow_authentications_fk|apex_040200
                                                                2   < WWV_FLOWS|APEX_040200*                                             wwv_flows_fk_authentication|apex_040200
                                                                1 < WWV_FLOW_BANNER|APEX_040200                                          wwv_flow_banner_fk|apex_040200
                                                                1 < WWV_FLOW_BUTTON_TEMPLATES|APEX_040200                                wwv_flow_buttont_fk|apex_040200
                                                                2   < WWV_FLOW_PAGE_PLUG_TEMPLATES|APEX_040200                           wwv_flow_plug_temp_button_fk|apex_040200                                                                 3     > WWV_FLOWS|APEX_040200*                                           wwv_flow_plug_temp_fk|apex_040200
                                                                3     > WWV_FLOW_FIELD_TEMPLATES|APEX_040200                             wwv_flow_plug_temp_field_fk|apex_040200
                                                                4       > WWV_FLOWS|APEX_040200*                                         wwv_flow_field_temp_f_fk|apex_040200
                                                                4       < WWV_FLOW_PAGE_PLUG_TEMPLATES|APEX_040200*                      wwv_flow_plug_temp_req_fld_fk|apex_040200
                                                                3     < WWV_FLOW_PLUG_TMPL_DISP_POINTS|APEX_040200                       wwv_plug_tmpl_dp_parent_fk|apex_040200                                                                 4       > WWV_FLOWS|APEX_040200*                                         wwv_plug_tmpl_dp_fk|apex_040200
                                                                1 < WWV_FLOW_CALS|APEX_040200                                            wwv_flow_cal_to_flow_fk|apex_040200                                                                 2   > WWV_FLOW_PAGE_PLUGS|APEX_040200                                    wwv_flow_plug_calendar_fk|apex_040200
                                                                3     > WWV_FLOWS|APEX_040200*                                           wwv_flow_plug_to_flow_fk|apex_040200
                                                                3     < WWV_FLOW_FLASH_CHARTS_5|APEX_040200                              wwv_flow_flash_charts_5_fk2|apex_040200                                                                 4       > WWV_FLOWS|APEX_040200*                                         wwv_flow_flash_charts_5_fk|apex_040200
                                                                4       < WWV_FLOW_FLASH_CHART5_SERIES|APEX_040200                       wwv_flow_flash_5_series_fk|apex_040200
                                                                4       < WWV_FLOW_FLASH_CHARTS_5_DASH|APEX_040200                       wwv_flow_flash_charts5_dash_fk|apex_040200
                                                                3     < WWV_FLOW_FLASH_CHARTS|APEX_040200                                wwv_flow_flash_charts_fk2|apex_040200                                                                 4       > WWV_FLOWS|APEX_040200*                                         wwv_flow_flash_charts_fk|apex_040200
                                                                4       < WWV_FLOW_FLASH_CHART_SERIES|APEX_040200                        wwv_flow_flash_chart_series_fk|apex_040200
                                                                3     < WWV_FLOW_PAGE_DA_ACTIONS|APEX_040200                             wwv_flow_page_da_a_ar_fk|apex_040200                                                                 4       > WWV_FLOW_PAGE_DA_EVENTS|APEX_040200                            wwv_flow_page_da_a_evnt_fk|apex_040200
                                                                5         > WWV_FLOWS|APEX_040200*                                       wwv_flow_page_da_e_flow_fk|apex_040200
                                                                5         > WWV_FLOW_PAGE_PLUGS|APEX_040200*                             wwv_flow_page_da_e_tr_fk|apex_040200
                                                                5         > WWV_FLOW_STEPS|APEX_040200                                   wwv_flow_page_da_e_page_fk|apex_040200
                                                                6           > WWV_FLOWS|APEX_040200*                                     wwv_flow_step_flow_fk|apex_040200
                                                                6           < WWV_FLOW_PAGE_DA_ACTIONS|APEX_040200*                      wwv_flow_page_da_a_page_fk|apex_040200
                                                                6           < WWV_FLOW_PAGE_PLUGS|APEX_040200*                           wwv_flow_plug_to_page_fk|apex_040200
                                                                6           < WWV_FLOW_STEP_BRANCHES|APEX_040200                         wwv_flow_step_branches_fk2|apex_040200                                                                 7             > WWV_FLOWS|APEX_040200*                                   wwv_flow_step_branches_fk|apex_040200
                                                                7             < WWV_FLOW_STEP_BRANCH_ARGS|APEX_040200                    wwv_flow_step_branch_args_fk|apex_040200
                                                                6           < WWV_FLOW_STEP_BUTTONS|APEX_040200                          wwv_flow_step_buttons_fk2|apex_040200                                                                 7             > WWV_FLOWS|APEX_040200*                                   wwv_flow_step_buttons_fk1|apex_040200
                                                                7             > WWV_FLOW_PAGE_PLUGS|APEX_040200*                         wwv_flow_step_buttons_plug_fk|apex_040200
                                                                6           < WWV_FLOW_STEP_COMPUTATIONS|APEX_040200                     wwv_flow_step_comp_fk2|apex_040200                                                                 7             > WWV_FLOWS|APEX_040200*                                   wwv_flow_step_comp_fk|apex_040200
                                                                6           < WWV_FLOW_STEP_ITEMS|APEX_040200                            wwv_flow_step_items_fk2|apex_040200                                                                 7             > WWV_FLOWS|APEX_040200*                                   wwv_flow_step_items_fk|apex_040200
                                                                7             > WWV_FLOW_PAGE_PLUGS|APEX_040200*                         wwv_flow_step_items_plug_fk|apex_040200
                                                                7             < WWV_FLOW_STEP_ITEM_HELP|APEX_040200                      wwv_flow_item_helptext_fk|apex_040200                                                                 8               > WWV_FLOWS|APEX_040200*                                 wwv_flow_page_helptext_fk|apex_040200
                                                                6           < WWV_FLOW_STEP_PROCESSING|APEX_040200                       wwv_flow_step_proc_fk2|apex_040200                                                                 7             > WWV_FLOWS|APEX_040200*                                   wwv_flow_step_proc_fk|apex_040200
                                                                7             < WWV_FLOW_CALS|APEX_040200*                               wwv_flow_step_process_fk|apex_040200                                                                 7             > WWV_FLOW_PAGE_PLUGS|APEX_040200*                         wwv_flow_step_proc_reg_fk|apex_040200
                                                                7             < WWV_FLOW_WS_PROCESS_PARMS_MAP|APEX_040200                wwv_flow_ws_map_fk2|apex_040200                                                                 8               > WWV_FLOW_WS_PARAMETERS|APEX_040200                     wwv_flows_ws_map_fk1|apex_040200
                                                                9                 > WWV_FLOW_WS_OPERATIONS|APEX_040200                   wwv_flow_ws_parms_fk|apex_040200
                                                               10                   > WWV_FLOW_SHARED_WEB_SERVICES|APEX_040200           wwv_flow_ws_opers_fk|apex_040200
                                                               11                     > WWV_FLOWS|APEX_040200*                           wwv_flow_ws_fk|apex_040200
                                                                6           < WWV_FLOW_STEP_VALIDATIONS|APEX_040200                      wwv_flow_step_val_fk2|apex_040200                                                                 7             > WWV_FLOWS|APEX_040200*                                   wwv_flow_step_val_fk|apex_040200
                                                                7             > WWV_FLOW_PAGE_PLUGS|APEX_040200*                         wwv_flow_step_val_to_reg_fk|apex_040200
                                                                6           > WWV_FLOW_USER_INTERFACES|APEX_040200                       wwv_flow_step_ui_fk|apex_040200
                                                                7             > WWV_FLOWS|APEX_040200*                                   wwv_flow_ui_flow_fk|apex_040200
                                                                7             > WWV_FLOW_STEPS|APEX_040200*                              wwv_flow_user_int_page_fk|apex_040200
                                                                7             > WWV_FLOW_UI_TYPES|APEX_040200                            wwv_flow_ui_type_fk|apex_040200
                                                                8               < WWV_FLOW_THEMES|APEX_040200                            wwv_flow_theme_ui_type_fk|apex_040200                                                                 9                 > WWV_FLOWS|APEX_040200*                               wwv_flow_themes_2f_fk|apex_040200
                                                                8               = WWV_FLOW_UI_TYPES|APEX_040200*                         wwv_flow_ui_type_based_on_fk|apex_040200
                                                                8               < WWV_FLOW_UI_TYPE_FEATURES|APEX_040200                  wwv_flow_ui_type_feature_fk1|apex_040200                                                                 9                 > WWV_FLOW_BUILDER_FEATURES|APEX_040200                wwv_flow_ui_type_feature_fk2|apex_040200
                                                                3     < WWV_FLOW_PAGE_GENERIC_ATTR|APEX_040200                           wwv_flow_genattr_to_region_fk|apex_040200
                                                                3     = WWV_FLOW_PAGE_PLUGS|APEX_040200*                                 wwv_flow_plug_parent_fk|apex_040200
                                                                3     < WWV_FLOW_QUERY_DEFINITION|APEX_040200                            query_def_to_region_fk|apex_040200
                                                                4       < WWV_FLOW_QUERY_COLUMN|APEX_040200                              query_column_to_query_fk|apex_040200                                                                 5         > WWV_FLOW_QUERY_OBJECT|APEX_040200                            query_column_to_qry_object_fk|apex_040200
                                                                6           > WWV_FLOW_QUERY_DEFINITION|APEX_040200*                     query_object_to_query_fk|apex_040200
                                                                4       < WWV_FLOW_QUERY_CONDITION|APEX_040200                           query_condition_to_query_fk|apex_040200
                                                                3     < WWV_FLOW_REGION_CHART_SER_ATTR|APEX_040200                       wwv_flow_seattr_to_region_fk|apex_040200
                                                                3     < WWV_FLOW_REGION_REPORT_COLUMN|APEX_040200                        report_column_to_region_fk|apex_040200
                                                                3     < WWV_FLOW_REGION_REPORT_FILTER|APEX_040200                        sys_c007367|apex_040200
                                                                3     < WWV_FLOW_REGION_UPD_RPT_COLS|APEX_040200                         wwv_flow_urc_to_plug_fk|apex_040200                                                                 4       > WWV_FLOWS|APEX_040200*                                         wwv_flow_urc_to_flow_fk|apex_040200
                                                                3     < WWV_FLOW_TREE_REGIONS|APEX_040200                                wwv_flow_treeregion_fk2|apex_040200                                                                 4       > WWV_FLOWS|APEX_040200*                                         wwv_flow_treeregion_fk|apex_040200
                                                                3     < WWV_FLOW_WORKSHEETS|APEX_040200                                  wwv_flow_worksheets_reg_fk|apex_040200                                                                 4       > WWV_FLOWS|APEX_040200*                                         wwv_flow_worksheets_flow_fk|apex_040200
                                                                4       < WWV_FLOW_WORKSHEET_COLUMNS|APEX_040200                         wwv_flow_worksheet_columns_fk|apex_040200                                                                 5         > WWV_FLOWS|APEX_040200*                                       wwv_flow_worksheet_col_fk|apex_040200
                                                                5         > WWV_FLOW_WORKSHEET_COL_GROUPS|APEX_040200                    wwv_flow_worksheet_col_grps_fk|apex_040200
                                                                6           > WWV_FLOWS|APEX_040200*                                     wwv_flow_worksheet_col_grp_fk|apex_040200
                                                                6           > WWV_FLOW_WORKSHEETS|APEX_040200*                           wwv_flow_worksheet_col_grws_fk|apex_040200
                                                                6           > WWV_FLOW_WS_WEBSHEET_ATTR|APEX_040200                      wwv_flow_worksheet_col_grp_fk2|apex_040200
                                                                7             > WWV_FLOW_WORKSHEETS|APEX_040200*                         wwwv_flow_ws_websheet_attr_fk|apex_040200
                                                                7             < WWV_FLOW_WORKSHEET_COLUMNS|APEX_040200*                  wwv_flow_worksheet_col_fk2|apex_040200
                                                                7             < WWV_FLOW_WORKSHEET_COMPUTATION|APEX_040200               wwv_flow_ws_computation_fk|apex_040200                                                                 8               > WWV_FLOW_WORKSHEET_RPTS|APEX_040200                    wwv_flow_ws_comp_cols_fk|apex_040200
                                                                9                 > WWV_FLOW_WORKSHEET_CATEGORIES|APEX_040200            wwv_flow_worksheet_rpts_fk|apex_040200
                                                               10                   > WWV_FLOWS|APEX_040200*                             wwv_flow_worksheet_cat_fk2|apex_040200
                                                                9                 < WWV_FLOW_WORKSHEET_CONDITIONS|APEX_040200            wwv_flow_worksheet_cond_fk|apex_040200                                                                10                   > WWV_FLOW_WS_WEBSHEET_ATTR|APEX_040200*             wwv_flow_ws_condition_fk|apex_040200
                                                                9                 < WWV_FLOW_WORKSHEET_GROUP_BY|APEX_040200              wwv_flow_ws_groupby_fk2|apex_040200                                                                10                   > WWV_FLOW_WS_WEBSHEET_ATTR|APEX_040200*             wwv_flow_ws_groupby_fk|apex_040200
                                                                9                 < WWV_FLOW_WORKSHEET_NOTIFY|APEX_040200                wwv_flow_worksheet_notify_fk2|apex_040200                                                                10                   > WWV_FLOW_WS_WEBSHEET_ATTR|APEX_040200*             wwv_flow_worksheet_notify_fk4|apex_040200
                                                                9                 > WWV_FLOW_WS_WEBSHEET_ATTR|APEX_040200*               wwv_flow_ws_rpt_fk|apex_040200
                                                                7             < WWV_FLOW_WORKSHEET_LOVS|APEX_040200                      wwv_flow_worksheet_lovs_fk2|apex_040200                                                                 8               > WWV_FLOW_WORKSHEETS|APEX_040200*                       wwv_flow_worksheet_lovs_fk|apex_040200
                                                                8               < WWV_FLOW_WORKSHEET_LOV_ENTRIES|APEX_040200             wwv_flow_worksheet_lov_ent_fk2|apex_040200                                                                 9                 > WWV_FLOW_WORKSHEETS|APEX_040200*                     wwv_flow_worksheet_lov_ent_fk|apex_040200
                                                                9                 > WWV_FLOW_WS_WEBSHEET_ATTR|APEX_040200*               wwv_flow_worksheet_lov_ent_fk3|apex_040200
                                                                7             > WWV_FLOW_WS_APPLICATIONS|APEX_040200                     wwv_flow_ws_websheet_attr_fk2|apex_040200
                                                                8               < WWV_FLOW_PKG_APP_MAP|APEX_040200                       wwv_flow_pkg_app_map_fk2|apex_040200                                                                 9                 > WWV_FLOWS|APEX_040200*                               wwv_flow_pkg_app_map_fk|apex_040200
                                                                8               < WWV_FLOW_WS_APP_SUG_OBJECTS|APEX_040200                wwv_flow_ws_app_so_fk1|apex_040200
                                                                8               < WWV_FLOW_WS_COL_VALIDATIONS|APEX_040200                wwv_flow_ws_col_val_fk3|apex_040200                                                                 9                 > WWV_FLOW_WORKSHEETS|APEX_040200*                     wwv_flow_ws_col_val_fk|apex_040200
                                                                9                 > WWV_FLOW_WS_WEBSHEET_ATTR|APEX_040200*               wwv_flow_ws_col_val_fk2|apex_040200
                                                                8               < WWV_FLOW_WS_CUSTOM_AUTH_SETUPS|APEX_040200             wwv_flow_ws_auth_setups_fk|apex_040200
                                                                8               < WWV_FLOW_WS_DATA_GRID_Q|APEX_040200                    wwv_flow_ws_data_grid_q_fk|apex_040200                                                                 9                 > WWV_FLOW_WS_WEBPAGES|APEX_040200                     wwv_flow_ws_data_grid_q_fk2|apex_040200
                                                               10                   > WWV_FLOW_WS_APPLICATIONS|APEX_040200*              wwv_flow_ws_webpages_fk|apex_040200
                                                               10                   = WWV_FLOW_WS_WEBPAGES|APEX_040200*                  wwv_flow_ws_webpages_fk2|apex_040200
                                                                1 < WWV_FLOW_CAL_TEMPLATES|APEX_040200                                   wwv_flow_cal_templ_to_flow_fk|apex_040200
                                                                1 < WWV_FLOW_COMPUTATIONS|APEX_040200                                    wwv_flow_computations_fk|apex_040200
                                                                1 < WWV_FLOW_CUSTOM_AUTH_SETUPS|APEX_040200                              wwv_flow_auth_setups_fk|apex_040200
                                                                1 < WWV_FLOW_DYNAMIC_TRANSLATIONS$|APEX_040200                           wwv_flow_dynamic_trans_fk1|apex_040200
                                                                1 < WWV_FLOW_ENTRY_POINTS|APEX_040200                                    wwv_flow_entry_points_fk|apex_040200
                                                                2   < WWV_FLOW_ENTRY_POINT_ARGS|APEX_040200                              wwv_flow_entry_point_args_fk|apex_040200
                                                                1 < WWV_FLOW_ICON_BAR_ATTRIBUTES|APEX_040200                             wwv_flow_iconbarattr_fk|apex_040200
                                                                1 < WWV_FLOW_ICON_BAR|APEX_040200                                        wwv_flow_icon_bar_fk|apex_040200
                                                                1 < WWV_FLOW_INSTALL_BUILD_OPT|APEX_040200                               wwv_flow_install_build_opt_fk|apex_040200                                                                 2   > WWV_FLOW_INSTALL|APEX_040200                                       wwv_flow_install_build_opt_fk3|apex_040200
                                                                3     > WWV_FLOWS|APEX_040200*                                           wwv_flow_install_fk|apex_040200
                                                                3     < WWV_FLOW_INSTALL_CHECKS|APEX_040200                              wwv_flow_install_checks_fk3|apex_040200                                                                 4       > WWV_FLOWS|APEX_040200*                                         wwv_flow_install_checks_fk|apex_040200
                                                                3     < WWV_FLOW_INSTALL_SCRIPTS|APEX_040200                             wwv_flow_install_scripts_fk3|apex_040200                                                                 4       > WWV_FLOWS|APEX_040200*                                         wwv_flow_install_scripts_fk|apex_040200
                                                                2   > WWV_FLOW_PATCHES|APEX_040200                                       wwv_flow_install_build_opt_fk4|apex_040200
                                                                3     > WWV_FLOWS|APEX_040200*                                           wwv_flow_patches_fk|apex_040200
                                                                1 < WWV_FLOW_ITEMS|APEX_040200                                           wwv_flow_items_fk|apex_040200
                                                                1 < WWV_FLOW_LANGUAGE_MAP|APEX_040200                                    wwv_flow_lang_flow_id_fk|apex_040200
                                                                1 < WWV_FLOW_LISTS_OF_VALUES$|APEX_040200                                wwv_flow_lov_fk|apex_040200
                                                                2   < WWV_FLOW_LIST_OF_VALUES_DATA|APEX_040200                           wwv_flow_lov_data_fk|apex_040200
                                                                2   < WWV_FLOW_LOAD_TABLES|APEX_040200                                   wwv_flow_load_tab_fk2|apex_040200                                                                 3     > WWV_FLOWS|APEX_040200*                                           wwv_flow_load_tab_fk1|apex_040200
                                                                3     < WWV_FLOW_LOAD_TABLE_LOOKUPS|APEX_040200                          wwv_flow_load_tab_lk_fk2|apex_040200                                                                 4       > WWV_FLOWS|APEX_040200*                                         wwv_flow_load_tab_lk_fk1|apex_040200
                                                                3     < WWV_FLOW_LOAD_TABLE_RULES|APEX_040200                            wwv_flow_load_tab_rule_fk2|apex_040200                                                                 4       > WWV_FLOWS|APEX_040200*                                         wwv_flow_load_tab_rule_fk1|apex_040200
                                                                1 < WWV_FLOW_LISTS|APEX_040200                                           wwv_flow_lists_flow_fk|apex_040200
                                                                2   < WWV_FLOW_LIST_ITEMS|APEX_040200                                    wwv_flow_list_items_fk|apex_040200
                                                                3     = WWV_FLOW_LIST_ITEMS|APEX_040200*                                 parent_list_item_fk|apex_040200
                                                                1 < WWV_FLOW_LIST_TEMPLATES|APEX_040200                                  wwv_flow_list_template_fk|apex_040200
                                                                1 < WWV_FLOW_LOCK_PAGE|APEX_040200                                       sys_c007221|apex_040200
                                                                1 < WWV_FLOW_MENUS|APEX_040200                                           wwv_flow_menus_flow_fk|apex_040200
                                                                2   < WWV_FLOW_MENU_OPTIONS|APEX_040200                                  wwv_flow_opt_menus_fk|apex_040200
                                                                1 < WWV_FLOW_MENU_TEMPLATES|APEX_040200                                  wwv_flow_menus_t_flow_fk|apex_040200
                                                                1 < WWV_FLOW_MESSAGES$|APEX_040200                                       wwv_flow_messages_fk|apex_040200
                                                                1 < WWV_FLOW_PAGES_RESERVED|APEX_040200                                  wwv_flow_pages_reserved_fk|apex_040200
                                                                1 < WWV_FLOW_PAGE_CACHE|APEX_040200                                      wwv_flow_page_cache_fk|apex_040200
                                                                2   < WWV_FLOW_PAGE_CODE_CACHE|APEX_040200                               wwv_flow_page_code_cache_fk|apex_040200
                                                                1 < WWV_FLOW_PAGE_GROUPS|APEX_040200                                     sys_c007397|apex_040200
                                                                1 < WWV_FLOW_PAGE_SUBMISSIONS|APEX_040200                                wwv_flow_page_sub_fk|apex_040200                                                                 2   > WWV_FLOW_SESSIONS$|APEX_040200                                     wwv_flow_page_sub_sess_fk|apex_040200
                                                                3     < WWV_FLOW_COLLECTIONS$|APEX_040200                                wwv_flow_collection_fk|apex_040200
                                                                4       < WWV_FLOW_COLLECTION_MEMBERS$|APEX_040200                       wwv_flow_collection_membes_fk|apex_040200
                                                                3     < WWV_FLOW_DATA|APEX_040200                                        wwv_flow_data_session_fk|apex_040200
                                                                3     < WWV_FLOW_REQUEST_VERIFICATIONS|APEX_040200                       wwv_flow_request_verif_fk|apex_040200
                                                                3     < WWV_FLOW_RT$USER_SESSIONS|APEX_040200                            wwv_flow_rt$user_sess_fk1|apex_040200                                                                 4       > WWV_FLOW_RT$APPROVALS|APEX_040200                              wwv_flow_rt$user_sess_fk|apex_040200
                                                                5         < WWV_FLOW_RT$APPROVAL_PRIVS|APEX_040200                       wwv_flow_rt$app_privs_fk|apex_040200                                                                 6           > WWV_FLOW_RT$PRIVILEGES|APEX_040200                         wwv_flow_rt$app_privs_fk2|apex_040200
                                                                7             < WWV_FLOW_RT$CLIENT_PRIVILEGES|APEX_040200                wwv_flow_rt$client_privs_fk2|apex_040200                                                                 8               > WWV_FLOW_RT$CLIENTS|APEX_040200                        wwv_flow_rt$client_privs_fk|apex_040200
                                                                9                 > WWV_FLOWS|APEX_040200*                               wwv_flow_rt$clients_appid_fk|apex_040200
                                                                9                 < WWV_FLOW_RT$APPROVALS|APEX_040200*                   wwv_flow_rt$approvals_fk|apex_040200
                                                                7             < WWV_FLOW_RT$HANDLERS|APEX_040200                         wwv_flow_rt$handlers_priv_fk|apex_040200
                                                                8               < WWV_FLOW_RT$ERRORS|APEX_040200                         wwv_flow_rt$errors_handler_fk|apex_040200
                                                                8               < WWV_FLOW_RT$PARAMETERS|APEX_040200                     wwv_flow_rt$params_handler_fk|apex_040200                                                                 8               > WWV_FLOW_RT$TEMPLATES|APEX_040200                      wwv_flow_rt$handlers_temps_fk|apex_040200
                                                                9                 > WWV_FLOW_RT$MODULES|APEX_040200                      wwv_flow_rt$temps_mod_fk|apex_040200
                                                               10                   > WWV_FLOW_RT$PRIVILEGES|APEX_040200*                wwv_flow_rt$modules_priv_fk|apex_040200
                                                                7             < WWV_FLOW_RT$PRIVILEGE_GROUPS|APEX_040200                 wwv_flow_rt$priv_groups_fk|apex_040200                                                                 8               > WWV_FLOW_FND_USER_GROUPS|APEX_040200                   wwv_flow_rt$priv_groups_fk2|apex_040200
                                                                9                 < WWV_FLOW_FND_GROUP_USERS|APEX_040200                 wwv_flow_fnd_gu_int_g_fk|apex_040200
                                                                5         < WWV_FLOW_RT$PENDING_APPROVALS|APEX_040200                    wwv_flow_rt$pend_apprv_fk|apex_040200
                                                                3     < WWV_FLOW_SC_TRANS|APEX_040200                                    wwv_flow_sc_trans_fk2|apex_040200
                                                                3     < WWV_FLOW_TREE_STATE|APEX_040200                                  wwv_flow_tree_state$fk|apex_040200
                                                                1 < WWV_FLOW_PAGE_TMPL_DISP_POINTS|APEX_040200                           wwv_page_tmpl_dp_fk|apex_040200                                                                 2   > WWV_FLOW_TEMPLATES|APEX_040200                                     wwv_page_tmpl_dp_parent_fk|apex_040200
                                                                3     > WWV_FLOWS|APEX_040200*                                           wwv_flow_templates_fk|apex_040200
                                                                1 < WWV_FLOW_PLUGINS|APEX_040200                                         wwv_flow_plugin_flow_fk|apex_040200
                                                                2   < WWV_FLOW_PLUGIN_ATTRIBUTES|APEX_040200                             wwv_flow_plugin_attr_parent_fk|apex_040200                                                                 3     > WWV_FLOWS|APEX_040200*                                           wwv_flow_plugin_attr_flow_fk|apex_040200
                                                                3     = WWV_FLOW_PLUGIN_ATTRIBUTES|APEX_040200*                          wwv_flow_plugin_attr_depend_fk|apex_040200
                                                                3     < WWV_FLOW_PLUGIN_ATTR_VALUES|APEX_040200                          wwv_flow_plugin_attrv_attr_fk|apex_040200                                                                 4       > WWV_FLOWS|APEX_040200*                                         wwv_flow_plugin_attrv_flow_fk|apex_040200
                                                                2   < WWV_FLOW_PLUGIN_EVENTS|APEX_040200                                 wwv_flow_plugin_evnt_parent_fk|apex_040200                                                                 3     > WWV_FLOWS|APEX_040200*                                           wwv_flow_plugin_evnt_flow_fk|apex_040200
                                                                2   < WWV_FLOW_PLUGIN_FILES|APEX_040200                                  wwv_flow_plugin_file_parent_fk|apex_040200                                                                 3     > WWV_FLOWS|APEX_040200*                                           wwv_flow_plugin_file_flow_fk|apex_040200
                                                                1 < WWV_FLOW_PLUGIN_SETTINGS|APEX_040200                                 wwv_flow_plugin_set_flow_fk|apex_040200
                                                                1 < WWV_FLOW_POPUP_LOV_TEMPLATE|APEX_040200                              wwv_flow_fk_poplov_temp|apex_040200
                                                                1 < WWV_FLOW_PROCESSING|APEX_040200                                      wwv_flow_processing_fk|apex_040200
                                                                1 < WWV_FLOW_REPORT_LAYOUTS|APEX_040200                                  wwv_flow_report_layoutse_fk|apex_040200
                                                                1 < WWV_FLOW_REQUIRED_ROLES|APEX_040200                                  wwv_flow_req_roles_fk|apex_040200
                                                                1 < WWV_FLOW_ROW_TEMPLATES|APEX_040200                                   wwv_flow_row_template_fk|apex_040200
                                                                1 < WWV_FLOW_SECURITY_SCHEMES|APEX_040200                                wwv_flow_sec_schemes_fk|apex_040200
                                                                1 < WWV_FLOW_SHARED_QRY_SQL_STMTS|APEX_040200                            wwv_flow_sqry_sql_flow_fk|apex_040200                                                                 2   > WWV_FLOW_SHARED_QUERIES|APEX_040200                                wwv_flow_sqry_sql_sqry_fk|apex_040200
                                                                3     > WWV_FLOWS|APEX_040200*                                           wwv_flow_shdqry_flow_fk|apex_040200
                                                                1 < WWV_FLOW_SHORTCUTS|APEX_040200                                       wwv_flow_shortcuts_to_flow_fk|apex_040200
                                                                1 < WWV_FLOW_TABS|APEX_040200                                            wwv_flow_tabs_fk|apex_040200
                                                                1 < WWV_FLOW_TEMPLATE_PREFERENCES|APEX_040200                            wwv_flow_templ_pref_fk|apex_040200
                                                                1 < WWV_FLOW_THEME_DISPLAY_POINTS|APEX_040200                            wwv_theme_disp_point_fk|apex_040200
                                                                1 < WWV_FLOW_THEME_STYLES|APEX_040200                                    wwv_flow_theme_style_flow_fk|apex_040200
                                                                1 < WWV_FLOW_TOPLEVEL_TABS|APEX_040200                                   wwv_flow_toplev_tab_fk|apex_040200
                                                                1 < WWV_FLOW_TRANSLATABLE_TEXT$|APEX_040200                              wwv_flow_trans_text_fk|apex_040200
                                                                1 < WWV_FLOW_TREES|APEX_040200                                           wwv_flow_tree_fk|apex_040200
                                                                1 < WWV_FLOW_VALIDATIONS|APEX_040200                                     wwv_flow_val_fk|apex_040200
                                                                1 < WWV_MIG_GENERATED_APPLICATIONS|APEX_040200                           wwv_mig_gen_app_flow_id_fk|apex_040200                                                                 2   > WWV_MIG_PROJECTS|APEX_040200                                       wwv_mig_gen_app_proj_id_fk|apex_040200
                                                                3     < WWV_MIG_ACCESS|APEX_040200                                       wwv_mig_acc_fk|apex_040200
                                                                3     < WWV_MIG_FORMS|APEX_040200                                        wwv_mig_forms_project_id_fk|apex_040200
                                                                4       < WWV_MIG_FRM_MODULES|APEX_040200                                wwv_mig_frm_modules_file_id_fk|apex_040200
                                                                5         < WWV_MIG_FRM_FORMMODULES|APEX_040200                          wwv_mig_frm_frmmdl_mdl_id_fk|apex_040200
                                                                6           < WWV_MIG_FRM_ALERTS|APEX_040200                             wwv_mig_frm_alrt_frmmdl_id_fk|apex_040200
                                                                6           < WWV_MIG_FRM_ATTACHEDLIBRARY|APEX_040200                    wwv_mig_frm_atlib_frmmdl_id_fk|apex_040200
                                                                6           < WWV_MIG_FRM_BLOCKS|APEX_040200                             wwv_mig_frm_blk_frmmdl_id_fk|apex_040200
                                                                7             < WWV_MIG_FRM_BLK_DSA|APEX_040200                          wwv_mig_frm_blk_dsa_blk_id_fk|apex_040200
                                                                7             < WWV_MIG_FRM_BLK_DSC|APEX_040200                          wwv_mig_frm_blk_dsc_blk_id_fk|apex_040200
                                                                7             < WWV_MIG_FRM_BLK_ITEMS|APEX_040200                        wwv_mig_frm_bi_blk_id_fk|apex_040200
                                                                8               < WWV_MIG_FRM_BLK_ITEM_LIE|APEX_040200                   wwv_mig_frm_bi_lie_item_id_fk|apex_040200
                                                                8               < WWV_MIG_FRM_BLK_ITEM_RADIO|APEX_040200                 wwv_mig_frm_bir_item_id_fk|apex_040200
                                                                8               < WWV_MIG_FRM_BLK_ITEM_TRIGGERS|APEX_040200              wwv_mig_frm_bi_trg_item_id_fk|apex_040200
                                                                8               < WWV_MIG_FRM_REV_BLK_ITEMS|APEX_040200                  wwv_mig_frm_rev_bi_item_id_fk|apex_040200
                                                                7             < WWV_MIG_FRM_BLK_RELATIONS|APEX_040200                    wwv_mig_frm_blk_rel_blk_id_fk|apex_040200
                                                                7             < WWV_MIG_FRM_BLK_TRIGGERS|APEX_040200                     wwv_mig_frm_blk_trg_blk_id_fk|apex_040200
                                                                7             < WWV_MIG_FRM_REV_BLOCKS|APEX_040200                       wwv_mig_frm_rev_blocks_id_fk|apex_040200
                                                                6           < WWV_MIG_FRM_CANVAS|APEX_040200                             wwv_mig_frm_canvs_frmmdl_id_fk|apex_040200
                                                                7             < WWV_MIG_FRM_CNVS_GRAPHICS|APEX_040200                    wwv_mig_frm_cg_cnvs_id_fk|apex_040200
                                                                8               < WWV_MIG_FRM_CNVG_COMPOUNDTEXT|APEX_040200              wwv_mig_frm_cpdtxt_grphs_id_fk|apex_040200
                                                                9                 < WWV_MIG_FRM_CPDTXT_TEXTSEGMENT|APEX_040200           wwv_mig_frm_txtsgmt_cpd_id_fk|apex_040200
                                                                7             < WWV_MIG_FRM_CNVS_TABPAGE|APEX_040200                     wwv_mig_frm_ctp_cnvs_id_fk|apex_040200
                                                                6           < WWV_MIG_FRM_COORDINATES|APEX_040200                        wwv_mig_frm_crdnt_frmmdl_id_fk|apex_040200
                                                                6           < WWV_MIG_FRM_EDITOR|APEX_040200                             wwv_mig_frm_edtr_frmmdl_id_fk|apex_040200
                                                                6           < WWV_MIG_FRM_FMB_MENU|APEX_040200                           wwv_mig_frm_menu_frmmdl_id_fk|apex_040200
                                                                7             < WWV_MIG_FRM_FMB_MENU_MENUITEM|APEX_040200                wwv_mig_fmb_menuitem_menuid_fk|apex_040200
                                                                8               < WWV_MIG_FRM_FMB_MENUITEM_ROLE|APEX_040200              wwv_mig_fmb_mnuitemrl_mitm_fk|apex_040200
                                                                6           < WWV_MIG_FRM_LOV|APEX_040200                                wwv_mig_frm_lov_frmmdl_id_fk|apex_040200
                                                                7             < WWV_MIG_FRM_LOVCOLUMNMAPPING|APEX_040200                 wwv_mig_frm_lvcm_frmmdl_id_fk|apex_040200
                                                                8               < WWV_MIG_FRM_REV_LOVCOLMAPS|APEX_040200                 wwv_mig_frm_rev_lcm_id_fk|apex_040200
                                                                7             < WWV_MIG_FRM_REV_LOV|APEX_040200                          wwv_mig_frm_rev_lov_id_fk|apex_040200
                                                                6           < WWV_MIG_FRM_MODULEPARAMETER|APEX_040200                    wwv_mig_frm_mdlpr_frmmdl_id_fk|apex_040200
                                                                6           < WWV_MIG_FRM_OBJECTGROUP|APEX_040200                        wwv_mig_frm_objgp_frmmdl_id_fk|apex_040200
                                                                7             < WWV_MIG_FRM_OBJECTGROUPCHILD|APEX_040200                 wwv_mig_frm_objgpc_objgp_id_fk|apex_040200
                                                                6           < WWV_MIG_FRM_PROGRAMUNIT|APEX_040200                        wwv_mig_frm_pgut_frmmdl_id_fk|apex_040200
                                                                6           < WWV_MIG_FRM_PROPERTYCLASS|APEX_040200                      wwv_mig_frm_ppcl_frmmdl_id_fk|apex_040200
                                                                6           < WWV_MIG_FRM_RECORDGROUPS|APEX_040200                       wwv_mig_frm_recgp_frmmdl_id_fk|apex_040200
                                                                7             < WWV_MIG_FRM_RECORDGROUPCOLUMN|APEX_040200                wwv_mig_frm_rgc_recgp_id_fk|apex_040200
                                                                6           < WWV_MIG_FRM_REPORT|APEX_040200                             wwv_mig_frm_rpt_frmmdl_id_fk|apex_040200
                                                                6           < WWV_MIG_FRM_REV_FORMMODULES|APEX_040200                    wwv_mig_frm_rev_frmmdl_id_fk|apex_040200
                                                                6           < WWV_MIG_FRM_TRIGGERS|APEX_040200                           wwv_mig_frm_trg_frmmdl_id_fk|apex_040200
                                                                6           < WWV_MIG_FRM_VISUALATTRIBUTES|APEX_040200                   wwv_mig_frm_visat_frmmdl_id_fk|apex_040200
                                                                6           < WWV_MIG_FRM_WINDOWS|APEX_040200                            wwv_mig_frm_wndow_frmmdl_id_fk|apex_040200
                                                                3     < WWV_MIG_FRM_MENUS|APEX_040200                                    wwv_mig_menus_project_id_fk|apex_040200
                                                                4       < WWV_MIG_FRM_MENUS_MODULES|APEX_040200                          wwv_mig_mnu_modules_file_id_fk|apex_040200
                                                                5         < WWV_MIG_FRM_MENUS_MENUMODULES|APEX_040200                    wwv_mig_mnu_mnumdl_mdl_id_fk|apex_040200
                                                                6           < WWV_MIG_FRM_MENUSMODULEROLES|APEX_040200                   wwv_mig_mmodrole_id_fk|apex_040200
                                                                6           < WWV_MIG_FRM_MENUS_PROGRAMUNIT|APEX_040200                  wwv_mig_mnu_progunit_id_fk|apex_040200
                                                                6           < WWV_MIG_FRM_MENU|APEX_040200                               wwv_mig_mnu_id_fk|apex_040200
                                                                7             < WWV_MIG_FRM_MENU_MENUITEM|APEX_040200                    wwv_mig_mnuitem_id_fk|apex_040200
                                                                8               < WWV_MIG_FRM_MENUITEM_ROLE|APEX_040200                  wwv_mig_mnuitemrole_id_fk|apex_040200
                                                                3     < WWV_MIG_FRM_REV_APEX_APP|APEX_040200                             wwv_mig_frm_rev_apex_app_fk|apex_040200
                                                                3     < WWV_MIG_OLB|APEX_040200                                          wwv_mig_olb_project_id_fk|apex_040200
                                                                4       < WWV_MIG_OLB_MODULES|APEX_040200                                wwv_mig_olb_modules_file_id_fk|apex_040200
                                                                5         < WWV_MIG_OLB_OBJECTLIBRARY|APEX_040200                        wwv_mig_olb_objlib_mdl_id_fk|apex_040200
                                                                6           < WWV_MIG_OLB_BLOCK|APEX_040200                              wwv_mig_olb_block_objlib_id_fk|apex_040200
                                                                7             < WWV_MIG_OLB_BLK_DATASOURCECOL|APEX_040200                wwv_mig_olb_blk_dsc_blk_id_fk|apex_040200
                                                                7             < WWV_MIG_OLB_BLK_ITEM|APEX_040200                         wwv_mig_olb_blk_item_blk_id_fk|apex_040200
                                                                8               < WWV_MIG_OLB_BLK_ITEM_LIE|APEX_040200                   wwv_mig_olb_bil_item_id_fk|apex_040200
                                                                8               < WWV_MIG_OLB_BLK_ITEM_TRIGGER|APEX_040200               wwv_mig_olb_bit_item_id_fk|apex_040200
                                                                7             < WWV_MIG_OLB_BLK_TRIGGER|APEX_040200                      wwv_mig_olb_blk_trgr_blk_id_fk|apex_040200
                                                                6           < WWV_MIG_OLB_CANVAS|APEX_040200                             wwv_mig_olb_canvs_objlib_id_fk|apex_040200
                                                                7             < WWV_MIG_OLB_CNVS_GRAPHICS|APEX_040200                    wwv_mig_olb_cg_cnvs_id_fk|apex_040200
                                                                8               < WWV_MIG_OLB_CG_COMPOUNDTEXT|APEX_040200                wwv_mig_olb_cg_ct_grphs_id_fk|apex_040200
                                                                9                 < WWV_MIG_OLB_CG_CT_TEXTSEGMENT|APEX_040200            wwv_mig_olb_cg_ct_ts_ct_id_fk|apex_040200
                                                                6           < WWV_MIG_OLB_OBJECTLIBRARYTAB|APEX_040200                   wwv_mig_olb_olt_objlib_id_fk|apex_040200
                                                                7             < WWV_MIG_OLB_OLT_ALERT|APEX_040200                        wwv_mig_olb_olt_alrt_olt_id_fk|apex_040200
                                                                7             < WWV_MIG_OLB_OLT_BLOCK|APEX_040200                        wwv_mig_olb_t_block_olt_id_fk|apex_040200
                                                                8               < WWV_MIG_OLB_OLT_BLK_ITEM|APEX_040200                   wwv_mig_olb_olt_bi_blk_id_fk|apex_040200
                                                                9                 < WWV_MIG_OLB_OLT_BLK_ITEM_TRIGR|APEX_040200           wwv_mig_olb_olt_bit_item_id_fk|apex_040200
                                                                7             < WWV_MIG_OLB_OLT_CANVAS|APEX_040200                       wwv_mig_olb_t_canvas_olt_id_fk|apex_040200
                                                                8               < WWV_MIG_OLB_OLT_CNVS_GRAPHICS|APEX_040200              wwv_mig_olb_olt_cg_cnvs_id_fk|apex_040200
                                                                7             < WWV_MIG_OLB_OLT_GRAPHICS|APEX_040200                     wwv_mig_olb_t_grphcs_olt_id_fk|apex_040200
                                                                7             < WWV_MIG_OLB_OLT_ITEM|APEX_040200                         wwv_mig_olb_olt_item_olt_id_fk|apex_040200
                                                                7             < WWV_MIG_OLB_OLT_MENU|APEX_040200                         wwv_mig_olb_olt_menu_olt_id_fk|apex_040200
                                                                8               < WWV_MIG_OLB_OLT_MENU_MENUITEM|APEX_040200              wwv_mig_olb_olt_mmi_menu_id_fk|apex_040200
                                                                7             < WWV_MIG_OLB_OLT_OBJECTGROUP|APEX_040200                  wwv_mig_olb_t_objgrp_olt_id_fk|apex_040200
                                                                8               < WWV_MIG_OLB_OLT_OB_OBJGRPCHILD|APEX_040200             wwv_mig_olb_olt_ob_ogc_obid_fk|apex_040200
                                                                7             < WWV_MIG_OLB_OLT_REPORT|APEX_040200                       wwv_mig_olb_t_report_olt_id_fk|apex_040200
                                                                7             < WWV_MIG_OLB_OLT_TABPAGE|APEX_040200                      wwv_mig_olb_t_tabpage_oltid_fk|apex_040200
                                                                8               < WWV_MIG_OLB_OLT_TABPG_GRAPHICS|APEX_040200             wwv_mig_olb_olt_tpg_tp_id_fk|apex_040200
                                                                9                 < WWV_MIG_OLB_T_TP_G_GRAPHICS|APEX_040200              wwv_mig_olb_t_tp_gg_g_id_fk|apex_040200
                                                               10                   < WWV_MIG_OLB_T_TP_GG_CPDTXT|APEX_040200             wwv_mig_olb_t_tp_gg_ct_g_id_fk|apex_040200
                                                               11                     < WWV_MIG_OLB_T_TP_GG_CT_TXTSGT|APEX_040200        wwv_mig_olb_ttpggctts_ctid_fk|apex_040200
                                                               10                   < WWV_MIG_OLB_T_TP_GG_GRAPHICS|APEX_040200           wwv_mig_olb_t_tp_ggg_g_id_fk|apex_040200
                                                               11                     < WWV_MIG_OLB_T_TP_GGG_CPDTXT|APEX_040200          wwv_mig_olb_ttp_ggg_ct_gid_fk|apex_040200
                                                               12                       < WWV_MIG_OLB_T_TP_GGG_CT_TXTSGT|APEX_040200     wwv_mig_olb_ttpgggctts_ctid_fk|apex_040200
                                                               11                     < WWV_MIG_OLB_T_TP_GGG_GRAPHICS|APEX_040200        wwv_mig_olb_t_tp_gggg_g_id_fk|apex_040200
                                                               12                       < WWV_MIG_OLB_T_TP_GGGG_CPDTXT|APEX_040200       wwv_mig_olb_ttpggggct_g_id_fk|apex_040200
                                                               13                         < WWV_MIG_OLB_T_TP_GGGG_CT_TXSGT|APEX_040200   wwv_mig_olb_ttpggggcts_ctid_fk|apex_040200
                                                               12                       < WWV_MIG_OLB_T_TP_GGGG_GRAPHICS|APEX_040200     wwv_mig_olb_ttpggggg_g_id_fk|apex_040200
                                                               13                         < WWV_MIG_OLB_T_TP_GGGGG_CPDTXT|APEX_040200    wwv_mig_olb_ttpgggggct_g_id_fk|apex_040200
                                                               14                           < WWV_MIG_OLB_T_TP_GGGGG_CT_TXST|APEX_040200 wwv_mig_olb_ttp5gcts_ct_id_fk|apex_040200
                                                                7             < WWV_MIG_OLB_OLT_VISUALATTRBUTE|APEX_040200               wwv_mig_olb_olt_va_olt_id_fk|apex_040200
                                                                7             < WWV_MIG_OLB_OLT_WINDOW|APEX_040200                       wwv_mig_olb_olt_wndow_oltid_fk|apex_040200
                                                                6           < WWV_MIG_OLB_PROGRAMUNIT|APEX_040200                        wwv_mig_olb_pu_objlib_id_fk|apex_040200
                                                                6           < WWV_MIG_OLB_PROPERTYCLASS|APEX_040200                      wwv_mig_olb_pc_objlib_id_fk|apex_040200
                                                                6           < WWV_MIG_OLB_VISUALATTRIBUTE|APEX_040200                    wwv_mig_olb_va_objlib_id_fk|apex_040200
                                                                6           < WWV_MIG_OLB_WINDOW|APEX_040200                             wwv_mig_olb_wndow_objlib_id_fk|apex_040200
                                                                3     < WWV_MIG_PLSQL_LIBS|APEX_040200                                   wwv_mig_plls_project_id_fk|apex_040200
                                                                3     < WWV_MIG_PROJECT_COMPONENTS|APEX_040200                           wwv_mig_proj_comp_fk|apex_040200
                                                                3     < WWV_MIG_PROJECT_TRIGGERS|APEX_040200                             wwv_mig_proj_trig_fk|apex_040200
                                                                3     < WWV_MIG_RPTS|APEX_040200                                         wwv_mig_rpts_project_id_fk|apex_040200
                                                                4       < WWV_MIG_REPORT|APEX_040200                                     wwv_mig_rep_file_id_fk|apex_040200
                                                                5         < WWV_MIG_RPT_DATA|APEX_040200                                 wwv_mig_repdata_id_fk|apex_040200
                                                                6           < WWV_MIG_RPT_DATASRC|APEX_040200                            wwv_mig_repsrc_id_fk|apex_040200
                                                                7             < WWV_MIG_RPT_DATASRC_GRP|APEX_040200                      wwv_mig_grp_id_fk|apex_040200
                                                                8               < WWV_MIG_RPT_GRP_DATAITEM|APEX_040200                   wwv_mig_grp_dataitem_id_fk|apex_040200
                                                                9                 < WWV_MIG_RPT_GRP_DATAITEM_DESC|APEX_040200            wwv_mig_grp_itemdesc_id_fk|apex_040200
                                                                9                 < WWV_MIG_RPT_GRP_DATAITEM_PRIV|APEX_040200            wwv_mig_grp_itempriv_id_fk|apex_040200
                                                                8               < WWV_MIG_RPT_GRP_FIELD|APEX_040200                      wwv_mig_grp_fld_id_fk|apex_040200
                                                                8               < WWV_MIG_RPT_GRP_FILTER|APEX_040200                     wwv_mig_grp_fltr_id_fk|apex_040200
                                                                8               < WWV_MIG_RPT_GRP_FORMULA|APEX_040200                    wwv_mig_grp_form_id_fk|apex_040200
                                                                8               < WWV_MIG_RPT_GRP_ROWDELIM|APEX_040200                   wwv_mig_grp_row_id_fk|apex_040200
                                                                8               < WWV_MIG_RPT_GRP_SUMMARY|APEX_040200                    wwv_mig_grp_sum_id_fk|apex_040200
                                                                7             < WWV_MIG_RPT_DATASRC_SELECT|APEX_040200                   wwv_mig_select_id_fk|apex_040200
                                                                6           < WWV_MIG_RPT_DATA_SUMMARY|APEX_040200                       wwv_mig_repsum_id_fk|apex_040200
                                                                5         < WWV_MIG_RPT_REPORTPRIVATE|APEX_040200                        wwv_mig_rptpriv_id_fk|apex_040200
WWV_FLOW_ADVISOR_CATEGORIES|APEX_040200          2       3      0 WWV_FLOW_ADVISOR_CATEGORIES|APEX_040200                                ROOT
                                                                1 < WWV_FLOW_ADVISOR_CHECKS|APEX_040200                                  wwv_flow_adv_chk_cat_fk|apex_040200
                                                                2   < WWV_FLOW_ADVISOR_CHECK_MSGS|APEX_040200                            wwv_flow_adv_chk_msg_check_fk|apex_040200
WWV_FLOW_BUGS|APEX_040200                       13      11      0 WWV_FLOW_BUGS|APEX_040200                                              ROOT
                                                                1 < WWV_FLOW_TEAMDEV_TAG_CLOUD|APEX_040200                               wwv_flow_teamdev_tc_b|apex_040200                                                                 2   > WWV_FLOW_FEATURES|APEX_040200                                      wwv_flow_teamdev_tc_f|apex_040200
                                                                3     = WWV_FLOW_FEATURES|APEX_040200*                                   wwv_flow_features_par_feat_fk|apex_040200
                                                                3     < WWV_FLOW_FEATURE_HISTORY|APEX_040200                             wwv_flow_feature_hist_fk|apex_040200
                                                                3     < WWV_FLOW_FEATURE_PROGRESS|APEX_040200                            wwv_flow_feature_prog_fk|apex_040200
                                                                3     < WWV_FLOW_TEAM_FILES|APEX_040200                                  wwv_flow_team_files_fk1|apex_040200                                                                 4       > WWV_FLOW_EVENTS|APEX_040200                                    wwv_flow_team_files_fk3|apex_040200
                                                                4       > WWV_FLOW_FEEDBACK|APEX_040200                                  wwv_flow_team_files_fk4|apex_040200
                                                                5         < WWV_FLOW_FEEDBACK_FOLLOWUP|APEX_040200                       wwv_flow_feedback_fup_fk|apex_040200
                                                                5         < WWV_FLOW_TEAM_FILES|APEX_040200*                             wwv_flow_team_files_fk5|apex_040200                                                                 4       > WWV_FLOW_TASKS|APEX_040200                                     wwv_flow_team_files_fk2|apex_040200
                                                                5         < WWV_FLOW_TASK_PROGRESS|APEX_040200                           wwv_flow_task_prog_fk|apex_040200
                                                                5         < WWV_FLOW_TEAMDEV_TAG_CLOUD|APEX_040200*                      wwv_flow_teamdev_tc_t|apex_040200 WWV_FLOW_DATA_LOAD_BAD_LOG|APEX_040200           1       2      0 WWV_FLOW_DATA_LOAD_BAD_LOG|APEX_040200                                 ROOT                                                                 1 > WWV_FLOW_DATA_LOAD_UNLOAD|APEX_040200                                wwv_flow_data_load_bad_log_fk1|apex_040200
WWV_FLOW_DICTIONARY_VIEWS|APEX_040200            1       1      0 WWV_FLOW_DICTIONARY_VIEWS|APEX_040200                                  ROOT
                                                                1 = WWV_FLOW_DICTIONARY_VIEWS|APEX_040200*                               wwv_flow_dict_view_parent_fk|apex_040200
WWV_FLOW_FILE_OBJECTS$|FLOWS_FILES               5       6      0 WWV_FLOW_FILE_OBJECTS$|FLOWS_FILES                                     ROOT
                                                                1 < WWV_FLOW_IMPORT_EXPORT|APEX_040200                                   wwv_flow_import_export_fk|apex_040200
                                                                1 < WWV_FLOW_SW_BINDS|APEX_040200                                        wwv_flow_sw_bind_fk|apex_040200
                                                                1 < WWV_FLOW_SW_RESULTS|APEX_040200                                      wwv_flow_sw_result_fk|apex_040200
                                                                2   < WWV_FLOW_SW_DETAIL_RESULTS|APEX_040200                             wwv_flow_sw_d_result_fk|apex_040200
                                                                1 < WWV_FLOW_SW_STMTS|APEX_040200                                        wwv_flow_sw_stmts_fk|apex_040200 WWV_FLOW_FLASH_MAP_FILES|APEX_040200             2       3      0 WWV_FLOW_FLASH_MAP_FILES|APEX_040200                                   ROOT                                                                 1 > WWV_FLOW_FLASH_MAP_FOLDERS|APEX_040200                               wwv_flow_flash_map_files_fk|apex_040200
                                                                1 < WWV_FLOW_FLASH_MAP_REGIONS|APEX_040200                               wwv_flow_flash_map_reg_fk|apex_040200 WWV_FLOW_HNT_ARGUMENT_INFO|APEX_040200           1       2      0 WWV_FLOW_HNT_ARGUMENT_INFO|APEX_040200                                 ROOT                                                                 1 > WWV_FLOW_HNT_PROCEDURE_INFO|APEX_040200                              wwv_flow_hnt_arg_info_proc_fk|apex_040200
WWV_FLOW_HNT_COLUMN_DICT|APEX_040200             1       2      0 WWV_FLOW_HNT_COLUMN_DICT|APEX_040200                                   ROOT
                                                                1 < WWV_FLOW_HNT_COL_DICT_SYN|APEX_040200                                wwv_flow_hnt_col_dict_syn_fk|apex_040200 WWV_FLOW_HNT_COLUMN_INFO|APEX_040200             4       4      0 WWV_FLOW_HNT_COLUMN_INFO|APEX_040200                                   ROOT                                                                 1 > WWV_FLOW_HNT_GROUPS|APEX_040200                                      wwv_flow_hnt_col_info_grp_fk|apex_040200
                                                                2   > WWV_FLOW_HNT_TABLE_INFO|APEX_040200                                wwv_flow_hnt_groups_tab_fk|apex_040200
                                                                3     < WWV_FLOW_HNT_COLUMN_INFO|APEX_040200*                            wwv_flow_hnt_col_info_tab_fk|apex_040200
                                                                1 < WWV_FLOW_HNT_LOV_DATA|APEX_040200                                    wwv_flow_hnt_lov_data_col_fk|apex_040200 WWV_FLOW_MAIL_ATTACHMENTS|APEX_040200            1       2      0 WWV_FLOW_MAIL_ATTACHMENTS|APEX_040200                                  ROOT                                                                 1 > WWV_FLOW_MAIL_QUEUE|APEX_040200                                      wwv_flow_mail_attachments_fk1|apex_040200
WWV_FLOW_MODELS|APEX_040200                      4       4      0 WWV_FLOW_MODELS|APEX_040200                                            ROOT
                                                                1 < WWV_FLOW_MODEL_PAGES|APEX_040200                                     wwv_flow_model_pages_fk|apex_040200
                                                                2   = WWV_FLOW_MODEL_PAGES|APEX_040200*                                  wwv_flow_model_pages_fk2|apex_040200
                                                                2   < WWV_FLOW_MODEL_PAGE_REGIONS|APEX_040200                            wwv_flow_mpr_fk|apex_040200
                                                                3     < WWV_FLOW_MODEL_PAGE_COLS|APEX_040200                             wwv_flow_model_page_cols_fk|apex_040200 WWV_FLOW_PKG_APPLICATIONS|APEX_040200            4       3      0 WWV_FLOW_PKG_APPLICATIONS|APEX_040200                                  ROOT                                                                 1 > WWV_FLOW_PKG_APP_CATEGORIES|APEX_040200                              wwv_flow_pkg_app_fk1|apex_040200
                                                                2   < WWV_FLOW_PKG_APPLICATIONS|APEX_040200*                             wwv_flow_pkg_app_fk2|apex_040200
                                                                2   < WWV_FLOW_PKG_APPLICATIONS|APEX_040200*                             wwv_flow_pkg_app_fk3|apex_040200
                                                                1 < WWV_FLOW_PKG_APP_IMAGES|APEX_040200                                  wwv_flow_pkg_app_images_fk1|apex_040200 WWV_FLOW_QB_SAVED_COND|APEX_040200               3       4      0 WWV_FLOW_QB_SAVED_COND|APEX_040200                                     ROOT                                                                 1 > WWV_FLOW_QB_SAVED_QUERY|APEX_040200                                  sys_c007435|apex_040200
                                                                2   < WWV_FLOW_QB_SAVED_JOIN|APEX_040200                                 sys_c007442|apex_040200
                                                                2   < WWV_FLOW_QB_SAVED_TABS|APEX_040200                                 sys_c007449|apex_040200
WWV_FLOW_RESTRICTED_SCHEMAS|APEX_040200          1       2      0 WWV_FLOW_RESTRICTED_SCHEMAS|APEX_040200                                ROOT
                                                                1 < WWV_FLOW_RSCHEMA_EXCEPTIONS|APEX_040200                              wwv_flow_rschema_exceptions_fk|apex_040200 WWV_MIG_FRM_OLB_XMLTAGTABLEMAP|APEX_040200       1       1      0 WWV_MIG_FRM_OLB_XMLTAGTABLEMAP|APEX_040200                             ROOT                                                                 1 = WWV_MIG_FRM_OLB_XMLTAGTABLEMAP|APEX_040200*                          wwv_mig_olb_xmltagtablemap_fk|apex_040200 WWV_MIG_FRM_XMLTAGTABLEMAP|APEX_040200           1       1      0 WWV_MIG_FRM_XMLTAGTABLEMAP|APEX_040200                                 ROOT                                                                 1 = WWV_MIG_FRM_XMLTAGTABLEMAP|APEX_040200*                              wwv_mig_frm_xmltagtablemap_fk|apex_040200 WWV_MIG_MENU_XMLTAGTABLEMAP|APEX_040200          1       1      0 WWV_MIG_MENU_XMLTAGTABLEMAP|APEX_040200                                ROOT                                                                 1 = WWV_MIG_MENU_XMLTAGTABLEMAP|APEX_040200*                             wwv_mig_mnu_xmltagtablemap_fk|apex_040200 WWV_MIG_RPT_XMLTAGTABLEMAP|APEX_040200           1       1      0 WWV_MIG_RPT_XMLTAGTABLEMAP|APEX_040200                                 ROOT                                                                 1 = WWV_MIG_RPT_XMLTAGTABLEMAP|APEX_040200*                              wwv_mig_rpt_xmltagtablemap_fk|apex_040200 WWV_PURGE_DATAFILES|APEX_040200                  4       5      0 WWV_PURGE_DATAFILES|APEX_040200                                        ROOT                                                                 1 > WWV_PURGE_WORKSPACES|APEX_040200                                     wwv_purge_datafiles_fk1|apex_040200
                                                                2   < WWV_PURGE_EMAILS|APEX_040200                                       wwv_purge_emails_fk1|apex_040200
                                                                3     < WWV_PURGE_WORKSPACE_RESPONSES|APEX_040200                        wwv_purge_workspace_resp_fk1|apex_040200
                                                                2   < WWV_PURGE_SCHEMAS|APEX_040200                                      wwv_purge_schemas_fk1|apex_040200 XS$ACE_PRIV|SYS                                 36      25      0 XS$ACE_PRIV|SYS                                                        ROOT                                                                 1 > XS$ACE|SYS                                                           xs$ace_priv_fk1|sys
                                                                2   > XS$ACL|SYS                                                         xs$ace_fk1|sys
                                                                3     < XS$ACL_PARAM|SYS                                                 xs$acl_param_fk2|sys                                                                 4       > XS$POLICY_PARAM|SYS                                            xs$acl_param_fk1|sys
                                                                5         > XS$DSEC|SYS                                                  xs$policy_param_fk1|sys
                                                                6           < XS$ATTR_SEC|SYS                                            xs$attr_sec_fk1|sys                                                                 7             > XS$OBJ|SYS                                               xs$attr_sec_fk2|sys
                                                                8               < XS$ACE_PRIV|SYS*                                       xs$ace_priv_fk2|sys
                                                                8               < XS$ACL|SYS*                                            xs$acl_fk1|sys
                                                                8               < XS$ACL|SYS*                                            xs$acl_fk2|sys
                                                                8               < XS$ACL|SYS*                                            xs$acl_fk3|sys
                                                                8               < XS$AGGR_PRIV|SYS                                       xs$aggr_priv_fk2|sys
                                                                8               < XS$DSEC|SYS*                                           xs$dsec_fk|sys
                                                                8               < XS$INSTSET_ACL|SYS                                     xs$instset_acl_fk2|sys                                                                 9                 > XS$INSTSET_RULE|SYS                                  xs$instset_acl_fk1|sys
                                                               10                   > XS$INSTSET_LIST|SYS                                xs$instset_rule_fk|sys
                                                               11                     > XS$DSEC|SYS*                                     xs$dsec_instset_fk|sys
                                                               11                     < XS$INSTSET_INH|SYS                               xs$instset_inh_fk|sys
                                                               12                       < XS$INSTSET_INH_KEY|SYS                         xs$instset_inh_key_fk|sys
                                                                8               < XS$NSTMPL|SYS                                          xs$nstmpl_fk1|sys                                                                 9                 > XS$ACL|SYS*                                          xs$nstmp1_fk2|sys
                                                                9                 < XS$NSTMPL_ATTR|SYS                                   xs$nstmpl_attr_fk|sys
                                                                8               < XS$PRIN|SYS                                            xs$prin_fk1|sys
                                                                9                 < XS$PROXY_ROLE|SYS                                    xs$proxy_role_fk2|sys                                                                10                   > XS$OBJ|SYS*                                        xs$proxy_role_fk1|sys
                                                                9                 < XS$ROLE_GRANT|SYS                                    xs$role_grant_fk1|sys                                                                10                   > XS$PRIN|SYS*                                       xs$role_grant_fk2|sys
                                                                8               < XS$PRIV|SYS                                            xs$priv_fk1|sys                                                                 9                 > XS$SECCLS|SYS                                        xs$priv_fk2|sys
                                                               10                   > XS$OBJ|SYS*                                        xs$seccls_fk1|sys
                                                               10                   < XS$SECCLS_H|SYS                                    xs$seccls_h_fk1|sys                                                                11                     > XS$OBJ|SYS*                                      xs$seccls_h_fk2|sys
                                                                8               < XS$ROLESET_ROLES|SYS                                   xs$roleset_roles_fk2|sys                                                                 9                 > XS$ROLESET|SYS                                       xs$roleset_roles_fk1|sys
                                                               10                   > XS$OBJ|SYS*                                        xs$roleset_fk|sys
                                                                8               > XS$TENANT|SYS                                          xs$obj_fk|sys

815 rows selected.

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

Network                                     #Links  #Nodes    Max Lev
------------------------------------------ ------- ------- ----------
WWV_FLOW_HNT_ARGUMENT_INFO|APEX_040200           2       2          1
AQ$_INTERNET_AGENTS|SYSTEM                       2       2          1
WWV_FLOW_DICTIONARY_VIEWS|APEX_040200            2       1          1
WWV_FLOW_DATA_LOAD_BAD_LOG|APEX_040200           2       2          1
ATTRIBUTE_TRANSFORMATIONS$|SYS                   2       2          1
WWV_MIG_RPT_XMLTAGTABLEMAP|APEX_040200           2       1          1
CLOUD|GSMADMIN_INTERNAL                          2       2          1
CSW_DOMAININFO$|MDSYS                            2       2          1
DAM_CONFIG_PARAM$|SYS                            2       2          1
DBFS$_MOUNTS|SYS                                 2       2          1
DBFS_SFS$_FSTP|SYS                               2       2          1
WWV_MIG_MENU_XMLTAGTABLEMAP|APEX_040200          2       1          1
WWV_MIG_FRM_XMLTAGTABLEMAP|APEX_040200           2       1          1
DBMS_PARALLEL_EXECUTE_CHUNKS$|SYS                2       2          1
DEPT|SCOTT                                       2       2          1
WWV_MIG_FRM_OLB_XMLTAGTABLEMAP|APEX_040200       2       1          1
FLIGHTS|TEST                                     2       2          1
WWV_FLOW_RESTRICTED_SCHEMAS|APEX_040200          2       2          1
MVIEW$_ADV_BASETABLE|SYSTEM                      2       2          1
OGIS_GEOMETRY_COLUMNS|MDSYS                      2       2          1
OLS_DIR_BUSINESSES|MDSYS                         2       2          1
WWV_FLOW_MAIL_ATTACHMENTS|APEX_040200            2       2          1
PLANETS|TEST                                     2       2          1
WWV_FLOW_HNT_COLUMN_DICT|APEX_040200             2       2          1
REPCAT$_COLUMN_GROUP|SYSTEM                      2       2          1
REPCAT$_DDL|SYSTEM                               2       2          1
REPCAT$_PRIORITY_GROUP|SYSTEM                    2       2          1
ROADS|TEST                                       2       2          1
SCHEDULER$_JOB_OUTPUT|SYS                        2       2          1
SDO_WS_CONFERENCE_PARTICIPANTS|MDSYS             2       2          1
WRM$_DATABASE_INSTANCE|SYS                       2       2          1
APEX$ARCHIVE_CONTENTS|APEX_040200                2       2          1
WWV_FLOW_FLASH_MAP_FILES|APEX_040200             3       3          1
WWV_FLOW_ADVISOR_CATEGORIES|APEX_040200          3       3          2
BSLN_BASELINES|DBSNMP                            3       3          1
ARCS|TEST                                        3       2          2
PLSQL_PROFILER_DATA|BENCH                        3       3          2
HS$_PARALLEL_HISTOGRAM_DATA|SYS                  4       4          2
DBFS_SFS$_FS|SYS                                 4       4          2
DBMSHP_FUNCTION_INFO|BENCH                       4       3          2
WWV_FLOW_QB_SAVED_COND|APEX_040200               4       4          2
OLS_DIR_CATEGORIES|MDSYS                         4       3          1
WWV_PURGE_DATAFILES|APEX_040200                  5       5          3
APEX$_WS_FILES|APEX_040200                       5       5          2
WWV_FLOW_PKG_APPLICATIONS|APEX_040200            5       3          2
WWV_FLOW_MODELS|APEX_040200                      5       4          3
DR$THS_BT|CTXSYS                                 5       4          2
WWV_FLOW_HNT_COLUMN_INFO|APEX_040200             5       4          3
REGISTRY$DEPENDENCIES|SYS                        6       4          2
REPCAT$_AUDIT_ATTRIBUTE|SYSTEM                   6       6          4
WWV_FLOW_FILE_OBJECTS$|FLOWS_FILES               6       6          2
WFS_FEATUREINSTANCEMETADATA$|MDSYS               7       7          2
DATABASE_POOL_ADMIN|GSMADMIN_INTERNAL            7       5          5
TSDP_ASSOCIATION$|SYS                            9       9          4
BENCH_RUNS|BENCH                                10       9          5
CHANNELS|SH                                     11       8          5
WI$_CAPTURE_FILE|SYS                            11       9          6
HS$_BASE_CAPS|SYS                               12      10          8
WWV_FLOW_BUGS|APEX_040200                       14      11          5
REPCAT$_INSTANTIATION_DDL|SYSTEM                14      13          5
MVIEW$_ADV_AJG|SYSTEM                           15      13          4
DEF$_CALLDEST|SYSTEM                            15      14          6
COUNTRIES|HR                                    22      16         10
OLS$AUDIT|LBACSYS                               22      14          7
CODE$|DVSYS                                     26      20          7
SDO_COORD_AXES|MDSYS                            31      14         12
XS$ACE_PRIV|SYS                                 37      25         12
ORDDCM_ANON_ACTION_TYPES|ORDDATA                70      47         14
WWV_FLOWS|APEX_040200                          335     264         14

69 rows selected.

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

 #Nodes  #Networks
------- ----------
      1          5
      2         28
      3          7
      4          7
      5          3
      6          2
      7          1
      8          1
      9          3
     10          1
     11          1
     13          2
     14          3
     16          1
     20          1
     25          1
     47          1
    264          1

18 rows selected.

Elapsed: 00:00:00.17

Diagram of a Foreign Key Subnetwork
This diagram shows the trajectory that the algorithm took through the subnetwork of HR tables that includes the COUNTRIES table, with tree links in red, and loop closing links in blue. It may help to understand the working of the algorithm.
Networks - PLSQL, v1.0 - HR

Test Network 2: Friendship network of Brightkite users

I took my second, much larger test network from this site:
Friendship network of Brightkite users

The page describes the network as having 58,228 nodes and 214,078 links, but the data set has 428,156 links, with each pair of nodes that is linked having links provided in both directions. My package traverses links in either direction so I did not require the second link, and copied only one of the links into a table for the network analysis. I created primary key and indexes that I deemed appropriate and gathered statistics on the table.

Output for Brightkite Network
The detailed output with 214,625 records took 103 seconds, while the two summary outputs took 27 and 23 seconds. Most of the detailed execution time is of course due to the writing of the records to file. The output is too large to embed in full, so I cut out most of the detailed output.

links_v based on Net_Brightkite

View dropped.


View created.

Network detail

Network     #Links  #Nodes    Lev Node                                                                   Link
---------- ------- ------- ------ ---------------------------------------------------------------------- ----------
0           212945   56739      0 0                                                                      ROOT
                                1 > 1                                                                    135
                                2   > 123                                                                955
                                3     < 11                                                               961
                                4       < 0*                                                             15                                 4       > 124                                                            974
                                5         < 1*                                                           969
                                5         < 123*                                                         982                                 5         > 125                                                          988
                                6           < 1*                                                         983
                                6           < 11*                                                        986                                 6           > 127                                                        993
                                7             < 1*                                                       990
                                7             < 11*                                                      992
                                7             < 5                                                        991
                                8               < 0*                                                     142
                                8               < 1*                                                     143                                 8               > 11*                                                    18
                                8               > 123*                                                   958
                                8               > 124*                                                   972
                                8               > 125*                                                   984
                                8               > 129                                                    996
                                9                 < 1*                                                   995
                                9                 < 125*                                                 999                                 9                 > 131                                                  1010
                               10                   < 1*                                                 1007                                10                   > 133                                                1024
                               11                     < 1*                                               1018
                               11                     < 129*                                             1023                                11                     > 2915                                             15317
                               12                       > 10857                                          77629
                               13                         < 1446                                         77626                                14                           > 10334                                      92481
                               15                             < 10198                                    92510                                16                               > 10332                                  91634
                               17                                 > 10333                                92473
                               18                                   > 10336                              92550
                               19                                     < 10331                            92548                                20                                       > 10338                          92638
                               21                                         < 10332*                       92639                                21                                         > 10342                        93374
                               22                                           < 10336*                     93373                                22                                           > 10344                      93470
                               23                                             < 10331*                   93469                                23                                             > 10345                    93502
                               24                                               < 10331*                 93499
                               24                                               < 10338*                 93500
                               24                                               < 10342*                 93501                                24                                               > 10349                  95200
                               25                                                 < 10331*               95191
                               25                                                 < 10332*               95192
                               25                                                 < 10333*               95193
                               25                                                 < 10334*               95194
                               25                                                 < 10336*               95195
                               25                                                 < 10337                95196
                               26                                                   < 10336*             92600                                26                                                   > 10340              93311
                               27                                                     < 10336*           93310                                27                                                     > 10346            94326
                               28                                                       < 10200          94320
                               29                                                         < 2812         89521                                30                                                           > 10198*     89503
                               30                                                           > 10332*     91600
                               30                                                           > 10333*     91656
.
. (extracted for brevity)
.
				
				7             > 871                                                      5496
                                8               < 11*                                                    5495                                 7             > 873                                                      5499
                                8               < 11*                                                    5498                                 6           > 6553                                                       54725
                                5         > 6548                                                         54712
                                5         > 6550                                                         54718
                                4       > 859                                                            5471
                                4       > 862                                                            5477
                                4       > 869                                                            5493
                                4       > 870                                                            5494
                                4       > 872                                                            5497
                                3     > 6535                                                             53954
                                4       > 34947                                                          140148
                                3     > 6536                                                             53955
                                3     > 6537                                                             54701
                                3     > 6538                                                             54702
                                3     > 6539                                                             54703
                                3     > 6540                                                             54704
                                3     > 6541                                                             54705
                                3     > 6543                                                             54706
                                3     > 6545                                                             54708
                                3     > 6546                                                             54709
                                2   > 126                                                                989
                                3     > 141                                                              1100
                                4       < 1*                                                             1099                                 2   > 128                                                                994
                                1 > 107                                                                  673
                                1 > 73                                                                   432
10020            1       2      0 10020                                                                  ROOT
                                1 > 40400                                                                206894
10061            3       4      0 10061                                                                  ROOT
                                1 > 40442                                                                207014
                                1 > 40443                                                                207015
                                2   > 54793                                                              197339
10454            1       2      0 10454                                                                  ROOT
                                1 > 40962                                                                211394
10541            1       2      0 10541                                                                  ROOT
                                1 > 41084                                                                211598
10569            1       2      0 10569                                                                  ROOT
                                1 > 41147                                                                211688
10572            1       2      0 10572                                                                  ROOT
                                1 > 41148                                                                211689
11030            2       3      0 11030                                                                  ROOT
                                1 > 41526                                                                189843
                                1 > 41527                                                                189844
11053            2       3      0 11053                                                                  ROOT
                                1 > 17537                                                                124571
                                1 > 41557                                                                189900
11136            1       2      0 11136                                                                  ROOT
                                1 > 27830                                                                172081
11615            3       3      0 11615                                                                  ROOT
                                1 > 42164                                                                194725
                                2   > 42165                                                              194727
                                3     < 11615*                                                           194726 11628           13      10      0 11628                                                                  ROOT                                 1 > 26719                                                                182224
                                2   > 42195                                                              194766
                                3     < 11628*                                                           194765
                                3     < 42193                                                            194767
                                4       < 11628*                                                         194762                                 4       > 42194                                                          194764
                                5         < 11628*                                                       194763                                 5         > 42195*                                                       194768
                                1 > 42188                                                                194757
                                1 > 42189                                                                194758
                                1 > 42190                                                                194759
                                1 > 42191                                                                194760
                                1 > 42192                                                                194761
11686            1       2      0 11686                                                                  ROOT
                                1 > 42284                                                                196157
11687            5       5      0 11687                                                                  ROOT
                                1 > 13207                                                                79434
                                2   > 43916                                                              210413
                                3     > 43917                                                            210415
                                4       < 13207*                                                         210414
                                2   < 7637                                                               79433 11713            1       2      0 11713                                                                  ROOT                                 1 > 40482                                                                208266
11770            1       2      0 11770                                                                  ROOT
                                1 > 13304                                                                80582
11778            2       3      0 11778                                                                  ROOT
                                1 > 40832                                                                210039
                                1 > 42426                                                                197700
11802            1       2      0 11802                                                                  ROOT
                                1 > 27316                                                                165028
11831            1       2      0 11831                                                                  ROOT
                                1 > 26846                                                                182516
11945            4       4      0 11945                                                                  ROOT
                                1 > 13842                                                                134375
                                2   > 42671                                                              199448
                                3     < 11945*                                                           199447                                 2   > 42672                                                              199449
11982            3       4      0 11982                                                                  ROOT
                                1 > 42736                                                                200800
                                2   > 55250                                                              199061
                                2   > 55251                                                              199062
12004            1       2      0 12004                                                                  ROOT
                                1 > 42778                                                                200897
12063            4       4      0 12063                                                                  ROOT
                                1 > 42874                                                                202418
                                2   > 42876                                                              202421
                                3     < 12063*                                                           202420                                 1 > 42875                                                                202419
12095            1       2      0 12095                                                                  ROOT
                                1 > 42933                                                                202516
12115            2       3      0 12115                                                                  ROOT
                                1 > 42964                                                                202586
                                2   > 53624                                                              191170
12145            2       3      0 12145                                                                  ROOT
                                1 > 42999                                                                203879
                                1 > 43000                                                                203880
12592            1       2      0 12592                                                                  ROOT
                                1 > 17004                                                                135534
12593            1       2      0 12593                                                                  ROOT
                                1 > 43361                                                                205795
12601            1       2      0 12601                                                                  ROOT
                                1 > 43367                                                                205802
12709            1       2      0 12709                                                                  ROOT
                                1 > 43438                                                                207113
12780            1       2      0 12780                                                                  ROOT
                                1 < 361                                                                  70125 12781            7       5      0 12781                                                                  ROOT                                 1 > 43503                                                                207232
                                2   > 43504                                                              207234
                                3     < 12781*                                                           207233                                 3     > 55481                                                            185736
                                4       < 43503*                                                         185735                                 3     > 55482                                                            185738
                                4       < 43503*                                                         185737 13125            2       3      0 13125                                                                  ROOT                                 1 > 41059                                                                211552
                                2   > 54899                                                              197454
13150            1       2      0 13150                                                                  ROOT
                                1 > 43850                                                                210327
13152            2       3      0 13152                                                                  ROOT
                                1 > 13412                                                                65309
                                1 > 43851                                                                210328
13188            3       4      0 13188                                                                  ROOT
                                1 > 13197                                                                79386
                                1 > 43895                                                                210381
                                2   > 55583                                                              185879
13237            1       2      0 13237                                                                  ROOT
                                1 > 43973                                                                210493
13277            1       2      0 13277                                                                  ROOT
                                1 > 13284                                                                80519
13321            5       6      0 13321                                                                  ROOT
                                1 > 13563                                                                68463
                                2   > 44299                                                              213314
                                2   > 44300                                                              213315
                                2   > 44301                                                              213316
                                1 > 41602                                                                189980
13409            1       2      0 13409                                                                  ROOT
                                1 > 36374                                                                151029
13423            1       2      0 13423                                                                  ROOT
                                1 > 44127                                                                211897
13441            3       4      0 13441                                                                  ROOT
                                1 > 44159                                                                211938
                                1 > 44160                                                                211939
                                1 > 44161                                                                211940
13496           10       8      0 13496                                                                  ROOT
                                1 > 44228                                                                212038
                                2   > 55671                                                              185988
                                3     > 55672                                                            185990
                                4       < 44228*                                                         185989                                 2   > 55673                                                              185991
                                2   > 55674                                                              185992
                                3     > 55675                                                            185994
                                4       < 44228*                                                         185993                                 4       > 55676                                                          185996
                                5         < 44228*                                                       185995 13508            1       2      0 13508                                                                  ROOT                                 1 > 44235                                                                212045
13516            1       2      0 13516                                                                  ROOT
                                1 > 44241                                                                212052
13519            1       2      0 13519                                                                  ROOT
                                1 > 44247                                                                212058
13521            1       2      0 13521                                                                  ROOT
                                1 > 44248                                                                212059
13542            3       4      0 13542                                                                  ROOT
                                1 > 44268                                                                212093
                                2   > 55684                                                              186004
                                2   > 55685                                                              186005
13544            2       3      0 13544                                                                  ROOT
                                1 > 44275                                                                212105
                                2   > 55687                                                              186007
13608            2       3      0 13608                                                                  ROOT
                                1 > 44352                                                                213393
                                1 > 44353                                                                213394
13708            2       3      0 13708                                                                  ROOT
                                1 > 35547                                                                144721
                                2   > 53642                                                              191189
13813            5       4      0 13813                                                                  ROOT
                                1 > 44466                                                                213572
                                2   > 44467                                                              213574
                                3     < 13813*                                                           213573                                 3     > 44468                                                            213576
                                4       < 44466*                                                         213575 13846            3       3      0 13846                                                                  ROOT                                 1 > 44528                                                                213677
                                2   > 44529                                                              213679
                                3     < 13846*                                                           213678 1469             2       3      0 1469                                                                   ROOT                                 1 > 20244                                                                110822
                                2   > 48178                                                              213748
14692            1       2      0 14692                                                                  ROOT
                                1 > 45193                                                                194940
15577            1       2      0 15577                                                                  ROOT
                                1 > 45714                                                                198098
15579            3       3      0 15579                                                                  ROOT
                                1 > 45717                                                                198103
                                2   > 45718                                                              198105
                                3     < 15579*                                                           198104 15636            1       2      0 15636                                                                  ROOT                                 1 > 45766                                                                198188
15658            2       3      0 15658                                                                  ROOT
                                1 > 45775                                                                198198
                                2   > 56016                                                              186375
15663            2       3      0 15663                                                                  ROOT
                                1 > 28650                                                                181215
                                1 > 45779                                                                198205
15670            1       2      0 15670                                                                  ROOT
                                1 > 45785                                                                198213
15675            6       6      0 15675                                                                  ROOT
                                1 > 15678                                                                136346
                                2   > 37514                                                              158682
                                2   > 45788                                                              198217
                                3     < 15675*                                                           198216                                 1 > 45787                                                                198215
                                1 > 45789                                                                198218
15689            1       2      0 15689                                                                  ROOT
                                1 > 45800                                                                198234
16399            2       3      0 16399                                                                  ROOT
                                1 > 46195                                                                201208
                                1 > 46196                                                                201209
16525            2       3      0 16525                                                                  ROOT
                                1 > 46293                                                                201380
                                1 > 46294                                                                201381
16526            2       3      0 16526                                                                  ROOT
                                1 > 46295                                                                201382
                                1 > 46296                                                                201383
16794            1       2      0 16794                                                                  ROOT
                                1 > 46442                                                                202723
16825            2       3      0 16825                                                                  ROOT
                                1 > 16826                                                                134322
                                2   > 46457                                                              202742
16827            1       2      0 16827                                                                  ROOT
                                1 > 46458                                                                202743
17012            1       2      0 17012                                                                  ROOT
                                1 > 46469                                                                202756
1704             1       2      0 1704                                                                   ROOT
                                1 > 21114                                                                102970
17047            1       2      0 17047                                                                  ROOT
                                1 > 36999                                                                155474
17062            1       2      0 17062                                                                  ROOT
                                1 > 17065                                                                135663
17074            1       2      0 17074                                                                  ROOT
                                1 > 46518                                                                202834
17084            3       4      0 17084                                                                  ROOT
                                1 > 46523                                                                202843
                                2   > 56157                                                              186530
                                2   > 56158                                                              186531
17256            2       3      0 17256                                                                  ROOT
                                1 > 46647                                                                204245
                                1 < 813                                                                  120656 17287            1       2      0 17287                                                                  ROOT                                 1 > 26319                                                                177029
1731             1       2      0 1731                                                                   ROOT
                                1 > 21183                                                                103185
17401            2       3      0 17401                                                                  ROOT
                                1 > 46765                                                                204433
                                1 < 850                                                                  123169 17459            2       3      0 17459                                                                  ROOT                                 1 > 46784                                                                204462
                                1 > 46785                                                                204463
18379            1       2      0 18379                                                                  ROOT
                                1 > 47262                                                                207545
18420            6       6      0 18420                                                                  ROOT
                                1 > 47291                                                                207578
                                2   < 47290                                                              207579                                 2   > 56269                                                              186649
                                1 > 47292                                                                207580
                                2   > 47293                                                              207582
                                3     < 18420*                                                           207581 18476            3       3      0 18476                                                                  ROOT                                 1 > 47311                                                                207604
                                2   > 47312                                                              207606
                                3     < 18476*                                                           207605 18776            1       2      0 18776                                                                  ROOT                                 1 > 47479                                                                209033
19029            1       2      0 19029                                                                  ROOT
                                1 > 47589                                                                209189
19907            2       3      0 19907                                                                  ROOT
                                1 > 47951                                                                210876
                                2   > 56377                                                              186770
19925            1       2      0 19925                                                                  ROOT
                                1 > 47953                                                                210878
20119            5       6      0 20119                                                                  ROOT
                                1 > 48086                                                                212360
                                2   > 56414                                                              186815
                                2   > 56415                                                              186816
                                2   > 56416                                                              186817
                                1 > 48087                                                                212361
20137            1       2      0 20137                                                                  ROOT
                                1 > 48100                                                                212382
20143            2       3      0 20143                                                                  ROOT
                                1 > 48108                                                                212391
                                1 > 48109                                                                212392
20149            1       2      0 20149                                                                  ROOT
                                1 > 48120                                                                212404
20150            1       2      0 20150                                                                  ROOT
                                1 > 48121                                                                212405
21785            1       2      0 21785                                                                  ROOT
                                1 > 48786                                                                190587
21795            1       2      0 21795                                                                  ROOT
                                1 > 48787                                                                190588
21823            5       4      0 21823                                                                  ROOT
                                1 > 48792                                                                190594
                                2   > 48793                                                              190596
                                3     < 21823*                                                           190595                                 3     > 56528                                                            186954
                                4       < 48792*                                                         186953 22211            1       2      0 22211                                                                  ROOT                                 1 > 48904                                                                190750
22386            3       4      0 22386                                                                  ROOT
                                1 > 48959                                                                190818
                                1 > 48960                                                                190819
                                1 > 48961                                                                190820
22850            1       2      0 22850                                                                  ROOT
                                1 > 49168                                                                192303
22949            4       4      0 22949                                                                  ROOT
                                1 > 49200                                                                192352
                                2   > 49201                                                              192354
                                3     < 22949*                                                           192353                                 2   > 56579                                                              187007
24435            1       2      0 24435                                                                  ROOT
                                1 > 49761                                                                195562
24477            1       2      0 24477                                                                  ROOT
                                1 > 49778                                                                195580
24642            1       2      0 24642                                                                  ROOT
                                1 > 49852                                                                196899
24937            5       5      0 24937                                                                  ROOT
                                1 > 50011                                                                197113
                                1 > 50012                                                                197114
                                2   > 50014                                                              197117
                                3     < 24937*                                                           197116                                 1 > 50013                                                                197115
26072            1       2      0 26072                                                                  ROOT
                                1 > 50470                                                                200114
26403            1       2      0 26403                                                                  ROOT
                                1 > 50578                                                                200255
26418            1       2      0 26418                                                                  ROOT
                                1 > 50583                                                                200262
26460            9       7      0 26460                                                                  ROOT
                                1 > 27747                                                                170819
                                1 > 50605                                                                200286
                                2   > 50609                                                              200292
                                3     < 26460*                                                           200291
                                3     < 50607                                                            200293
                                4       < 26460*                                                         200288                                 4       > 50608                                                          200290
                                5         < 26460*                                                       200289                                 1 > 50606                                                                200287
26630            3       4      0 26630                                                                  ROOT
                                1 > 50671                                                                201521
                                2   > 56815                                                              187279
                                2   > 56816                                                              187280
26641            1       2      0 26641                                                                  ROOT
                                1 > 50678                                                                201530
26744            1       2      0 26744                                                                  ROOT
                                1 > 50724                                                                201604
26766            1       2      0 26766                                                                  ROOT
                                1 > 50730                                                                201609
26803            1       2      0 26803                                                                  ROOT
                                1 > 50743                                                                201625
26977            1       2      0 26977                                                                  ROOT
                                1 > 50775                                                                201661
26979            1       2      0 26979                                                                  ROOT
                                1 > 50776                                                                201662
27113            1       2      0 27113                                                                  ROOT
                                1 > 50817                                                                201717
27134            1       2      0 27134                                                                  ROOT
                                1 > 50824                                                                201725
27187            4       5      0 27187                                                                  ROOT
                                1 > 36938                                                                154207
                                2   < 7559                                                               154206                                 3     > 36936                                                            154204
                                3     > 36937                                                            154205
27336            2       3      0 27336                                                                  ROOT
                                1 > 50892                                                                201822
                                2   > 56861                                                              187325
27342            1       2      0 27342                                                                  ROOT
                                1 > 50899                                                                201832
27442            1       2      0 27442                                                                  ROOT
                                1 > 50940                                                                201889
27481            1       2      0 27481                                                                  ROOT
                                1 > 50947                                                                203034
27487            1       2      0 27487                                                                  ROOT
                                1 > 50949                                                                203036
27490            5       5      0 27490                                                                  ROOT
                                1 > 50951                                                                203038
                                2   > 56878                                                              187346
                                3     > 56880                                                            187349
                                4       < 50951*                                                         187348                                 2   > 56879                                                              187347
27542            4       4      0 27542                                                                  ROOT
                                1 > 50980                                                                203083
                                2   > 50981                                                              203085
                                3     < 27542*                                                           203084                                 2   > 56893                                                              187362
27545            1       2      0 27545                                                                  ROOT
                                1 > 50982                                                                203086
27548            1       2      0 27548                                                                  ROOT
                                1 > 50987                                                                203094
27572            6       7      0 27572                                                                  ROOT
                                1 > 51006                                                                203118
                                1 > 51007                                                                203119
                                1 > 51008                                                                203120
                                1 > 51009                                                                203121
                                2   > 56898                                                              187367
                                1 > 51010                                                                203122
27621           25      10      0 27621                                                                  ROOT
                                1 > 51047                                                                203177
                                2   > 56915                                                              187385
                                3     > 56917                                                            187388
                                4       < 51047*                                                         187387
                                4       < 56916                                                          187389
                                5         < 51047*                                                       187386                                 5         > 56918                                                        187392
                                6           < 51047*                                                     187390
                                6           < 56915*                                                     187391
                                6           < 56917*                                                     187393                                 6           > 56919                                                      187397
                                7             < 51047*                                                   187394
                                7             < 56915*                                                   187395
                                7             < 56917*                                                   187396                                 7             > 56920                                                    187402
                                8               < 51047*                                                 187398
                                8               < 56915*                                                 187399
                                8               < 56917*                                                 187400
                                8               < 56918*                                                 187401                                 8               > 56921                                                  187407
                                9                 < 51047*                                               187403
                                9                 < 56915*                                               187404
                                9                 < 56917*                                               187405
                                9                 < 56918*                                               187406                                 2   > 56922                                                              187408
27737            1       2      0 27737                                                                  ROOT
                                1 > 51091                                                                203240
27761            3       3      0 27761                                                                  ROOT
                                1 > 51107                                                                203257
                                2   > 51108                                                              203259
                                3     < 27761*                                                           203258 27763            1       2      0 27763                                                                  ROOT                                 1 > 51109                                                                203260
27765            1       2      0 27765                                                                  ROOT
                                1 > 51110                                                                203261
27771            2       3      0 27771                                                                  ROOT
                                1 > 51111                                                                203262
                                1 < 9603                                                                 171954 27788            1       2      0 27788                                                                  ROOT                                 1 > 51119                                                                203271
27789            1       2      0 27789                                                                  ROOT
                                1 > 51120                                                                203272
27790            1       2      0 27790                                                                  ROOT
                                1 > 51121                                                                203273
27831            1       2      0 27831                                                                  ROOT
                                1 > 27926                                                                173361
27838            1       2      0 27838                                                                  ROOT
                                1 > 51143                                                                203302
27844            2       3      0 27844                                                                  ROOT
                                1 > 51147                                                                203315
                                1 > 51148                                                                203316
27880            1       2      0 27880                                                                  ROOT
                                1 > 51152                                                                203320
27882            1       2      0 27882                                                                  ROOT
                                1 > 51153                                                                203321
27888            1       2      0 27888                                                                  ROOT
                                1 > 51155                                                                203323
27894            1       2      0 27894                                                                  ROOT
                                1 > 51156                                                                203324
27897            1       2      0 27897                                                                  ROOT
                                1 > 51158                                                                203327
27915            1       2      0 27915                                                                  ROOT
                                1 > 51165                                                                203337
27933            2       3      0 27933                                                                  ROOT
                                1 > 51167                                                                203339
                                1 > 51168                                                                203340
27943            1       2      0 27943                                                                  ROOT
                                1 > 51170                                                                203342
27960            1       2      0 27960                                                                  ROOT
                                1 > 51178                                                                203355
27988            6       7      0 27988                                                                  ROOT
                                1 < 3107                                                                 173478                                 2   > 27989                                                              173479
                                2   > 9506                                                               90402
                                1 > 51194                                                                203374
                                2   > 56955                                                              187443
                                2   > 56956                                                              187444
28061            1       2      0 28061                                                                  ROOT
                                1 > 51236                                                                204652
28073            1       2      0 28073                                                                  ROOT
                                1 > 51238                                                                204654
28125            1       2      0 28125                                                                  ROOT
                                1 > 51261                                                                204696
28145            1       2      0 28145                                                                  ROOT
                                1 > 41990                                                                193070
28192            1       2      0 28192                                                                  ROOT
                                1 > 51297                                                                204757
28211            1       2      0 28211                                                                  ROOT
                                1 > 51301                                                                204763
28297            2       3      0 28297                                                                  ROOT
                                1 > 51313                                                                204777
                                1 > 51314                                                                204778
28430            1       2      0 28430                                                                  ROOT
                                1 > 51349                                                                204819
28517            1       2      0 28517                                                                  ROOT
                                1 > 51388                                                                204865
28518            3       4      0 28518                                                                  ROOT
                                1 > 51389                                                                204866
                                1 > 51390                                                                204867
                                1 > 51391                                                                204868
28522            3       4      0 28522                                                                  ROOT
                                1 > 51394                                                                204871
                                1 > 51395                                                                204872
                                2   > 56981                                                              187470
28523            3       4      0 28523                                                                  ROOT
                                1 > 51396                                                                204873
                                2   > 56982                                                              187471
                                1 > 51397                                                                204874
28527            2       3      0 28527                                                                  ROOT
                                1 > 36758                                                                153905
                                1 > 37951                                                                162947
28531            1       2      0 28531                                                                  ROOT
                                1 > 51401                                                                204878
28547            1       2      0 28547                                                                  ROOT
                                1 > 51409                                                                204885
28548            1       2      0 28548                                                                  ROOT
                                1 > 51410                                                                204886
28551            1       2      0 28551                                                                  ROOT
                                1 > 51413                                                                204888
28557            1       2      0 28557                                                                  ROOT
                                1 > 51420                                                                204907
28560            1       2      0 28560                                                                  ROOT
                                1 > 51421                                                                204908
28607            2       3      0 28607                                                                  ROOT
                                1 > 51446                                                                204945
                                1 > 51447                                                                204946
28826            1       2      0 28826                                                                  ROOT
                                1 > 51519                                                                206265
28842            1       2      0 28842                                                                  ROOT
                                1 > 51532                                                                206279
28891            1       2      0 28891                                                                  ROOT
                                1 > 51562                                                                206318
28894            2       3      0 28894                                                                  ROOT
                                1 > 51563                                                                206319
                                1 > 51564                                                                206320
29024            5       6      0 29024                                                                  ROOT
                                1 > 37722                                                                160197
                                2   > 37909                                                              161730
                                2   > 54205                                                              194231
                                2   > 54206                                                              194232
                                2   < 8038                                                               160196 29117            1       2      0 29117                                                                  ROOT                                 1 > 51629                                                                206405
29341            3       3      0 29341                                                                  ROOT
                                1 > 29342                                                                171035
                                2   < 3403                                                               171034                                 3     > 29341*                                                           171033
29759            1       2      0 29759                                                                  ROOT
                                1 > 51871                                                                207897
29850            1       2      0 29850                                                                  ROOT
                                1 > 51905                                                                207939
29851            1       2      0 29851                                                                  ROOT
                                1 > 50614                                                                200297
29852            1       2      0 29852                                                                  ROOT
                                1 > 51906                                                                207940
29853            3       4      0 29853                                                                  ROOT
                                1 > 51907                                                                207941
                                1 > 51908                                                                207942
                                1 > 51909                                                                207943
29858            3       3      0 29858                                                                  ROOT
                                1 > 51911                                                                207947
                                2   > 51912                                                              207949
                                3     < 29858*                                                           207948 29867            1       2      0 29867                                                                  ROOT                                 1 > 51916                                                                207953
29876            1       2      0 29876                                                                  ROOT
                                1 > 51925                                                                207961
29893            1       2      0 29893                                                                  ROOT
                                1 > 51931                                                                207969
29895            1       2      0 29895                                                                  ROOT
                                1 > 51932                                                                207970
29898            5       5      0 29898                                                                  ROOT
                                1 > 51934                                                                207971
                                2   < 51933                                                              207972                                 3     > 57071                                                            187563
                                3     > 57072                                                            187564
                                4       < 51934*                                                         187565 29901            2       3      0 29901                                                                  ROOT                                 1 > 35577                                                                144761
                                1 > 51935                                                                207973
29902            4       4      0 29902                                                                  ROOT
                                1 > 51936                                                                207974
                                2   > 51937                                                              207976
                                3     < 29902*                                                           207975                                 3     > 57075                                                            187566
29916            1       2      0 29916                                                                  ROOT
                                1 > 51945                                                                207985
30075            1       2      0 30075                                                                  ROOT
                                1 > 51979                                                                208026
30473            1       2      0 30473                                                                  ROOT
                                1 > 52103                                                                208181
31960            2       3      0 31960                                                                  ROOT
                                1 > 52531                                                                211063
                                2   > 57190                                                              187690
32410            2       3      0 32410                                                                  ROOT
                                1 > 52720                                                                211344
                                2   > 57227                                                              187729
33215            2       3      0 33215                                                                  ROOT
                                1 > 52960                                                                212795
                                1 > 52961                                                                212796
34215            1       2      0 34215                                                                  ROOT
                                1 > 53231                                                                189451
34428            3       4      0 34428                                                                  ROOT
                                1 > 53291                                                                189528
                                2   > 57316                                                              187824
                                1 > 53292                                                                189529
35114            1       2      0 35114                                                                  ROOT
                                1 > 53503                                                                191044
35129            1       2      0 35129                                                                  ROOT
                                1 > 53515                                                                191053
35189            3       4      0 35189                                                                  ROOT
                                1 > 53524                                                                191064
                                2   > 57350                                                              187859
                                1 > 53525                                                                191065
35196            1       2      0 35196                                                                  ROOT
                                1 > 53527                                                                191067
35283            2       3      0 35283                                                                  ROOT
                                1 > 53549                                                                191091
                                1 > 53550                                                                191092
35299            1       2      0 35299                                                                  ROOT
                                1 > 53561                                                                191104
35302            1       2      0 35302                                                                  ROOT
                                1 > 53563                                                                191106
35326            1       2      0 35326                                                                  ROOT
                                1 > 53568                                                                191111
35378            2       3      0 35378                                                                  ROOT
                                1 > 53594                                                                191142
                                1 > 53595                                                                191143
35381            1       2      0 35381                                                                  ROOT
                                1 > 53596                                                                191144
35394            1       2      0 35394                                                                  ROOT
                                1 > 53601                                                                191149
35440            2       3      0 35440                                                                  ROOT
                                1 > 44249                                                                212060
                                2   < 37918                                                              212061 35456            1       2      0 35456                                                                  ROOT                                 1 > 53613                                                                191162
35464            1       2      0 35464                                                                  ROOT
                                1 > 53615                                                                191164
35474            1       2      0 35474                                                                  ROOT
                                1 > 53617                                                                191166
35481            1       2      0 35481                                                                  ROOT
                                1 > 38326                                                                142051
35484            2       3      0 35484                                                                  ROOT
                                1 > 53625                                                                191171
                                1 > 53626                                                                191172
35540            2       3      0 35540                                                                  ROOT
                                1 > 53639                                                                191186
                                1 > 53640                                                                191187
35558            1       2      0 35558                                                                  ROOT
                                1 > 53645                                                                191192
35581            2       3      0 35581                                                                  ROOT
                                1 > 53653                                                                191200
                                1 > 53654                                                                191201
35608            1       2      0 35608                                                                  ROOT
                                1 > 53660                                                                191208
35609            1       2      0 35609                                                                  ROOT
                                1 > 53661                                                                191209
35661            4       5      0 35661                                                                  ROOT
                                1 > 53671                                                                191220
                                2   > 57372                                                              187880
                                3     > 58030                                                            188637
                                1 > 53672                                                                191221
35748            1       2      0 35748                                                                  ROOT
                                1 > 53684                                                                191233
35751            1       2      0 35751                                                                  ROOT
                                1 > 53687                                                                191235
35755            1       2      0 35755                                                                  ROOT
                                1 > 53688                                                                191236
35759            1       2      0 35759                                                                  ROOT
                                1 > 46206                                                                201221
35763            1       2      0 35763                                                                  ROOT
                                1 > 53689                                                                191237
35766            1       2      0 35766                                                                  ROOT
                                1 > 49404                                                                193820
35767            1       2      0 35767                                                                  ROOT
                                1 > 53690                                                                191238
35769            1       2      0 35769                                                                  ROOT
                                1 > 53692                                                                191241
35772            2       3      0 35772                                                                  ROOT
                                1 > 53696                                                                191246
                                1 > 53697                                                                191247
35781            2       3      0 35781                                                                  ROOT
                                1 > 53700                                                                191250
                                2   > 57376                                                              187884
35784            1       2      0 35784                                                                  ROOT
                                1 > 53701                                                                191251
35790           10      11      0 35790                                                                  ROOT
                                1 > 35792                                                                146323
                                2   < 35791                                                              146324                                 3     > 43770                                                            208945
                                2   > 35793                                                              146325
                                3     > 43773                                                            208948
                                2   > 43772                                                              208947
                                3     > 55557                                                            185848
                                1 > 43771                                                                208946
                                1 > 53704                                                                191254
                                1 > 53705                                                                191255
35803            1       2      0 35803                                                                  ROOT
                                1 < 6945                                                                 146340 35938            2       3      0 35938                                                                  ROOT                                 1 > 53740                                                                192495
                                1 > 53741                                                                192496
35953            1       2      0 35953                                                                  ROOT
                                1 < 7020                                                                 147809 36004            1       2      0 36004                                                                  ROOT                                 1 > 53760                                                                192518
36006            4       5      0 36006                                                                  ROOT
                                1 > 53763                                                                192521
                                2   > 57387                                                              187895
                                1 > 53764                                                                192522
                                1 > 53765                                                                192523
36008            1       2      0 36008                                                                  ROOT
                                1 > 53767                                                                192526
36022            1       2      0 36022                                                                  ROOT
                                1 > 53777                                                                192538
36031            3       4      0 36031                                                                  ROOT
                                1 > 53784                                                                192545
                                2   > 57389                                                              187897
                                2   > 57390                                                              187898
36033            1       2      0 36033                                                                  ROOT
                                1 > 53787                                                                192548
36185            5       5      0 36185                                                                  ROOT
                                1 > 53833                                                                192606
                                2   > 57399                                                              187907
                                3     > 57400                                                            187909
                                4       < 53833*                                                         187908                                 3     > 58037                                                            188643
36253            3       4      0 36253                                                                  ROOT
                                1 > 53846                                                                192620
                                2   > 57404                                                              187916
                                1 > 53847                                                                192621
36272            1       2      0 36272                                                                  ROOT
                                1 > 44014                                                                210540
36328            3       4      0 36328                                                                  ROOT
                                1 > 53867                                                                192645
                                1 > 53868                                                                192646
                                1 > 53869                                                                192647
36375            1       2      0 36375                                                                  ROOT
                                1 > 53880                                                                192659
36378            1       2      0 36378                                                                  ROOT
                                1 > 53881                                                                192660
36382            2       3      0 36382                                                                  ROOT
                                1 > 53883                                                                192662
                                2   < 36383                                                              192663 36385            1       2      0 36385                                                                  ROOT                                 1 > 53884                                                                192664
36399            1       2      0 36399                                                                  ROOT
                                1 > 53487                                                                191024
36405            1       2      0 36405                                                                  ROOT
                                1 < 7264                                                                 151063 36533            1       2      0 36533                                                                  ROOT                                 1 > 53908                                                                192694
36612            1       2      0 36612                                                                  ROOT
                                1 > 53923                                                                192711
36652            2       3      0 36652                                                                  ROOT
                                1 > 53937                                                                192728
                                2   > 57419                                                              187929
36821            1       2      0 36821                                                                  ROOT
                                1 > 53975                                                                192770
36919            1       2      0 36919                                                                  ROOT
                                1 > 53988                                                                192783
36965            4       4      0 36965                                                                  ROOT
                                1 > 41327                                                                213153
                                2   < 41326                                                              213154                                 2   > 41328                                                              213156
                                3     < 36965*                                                           213155 36981            1       2      0 36981                                                                  ROOT                                 1 > 54010                                                                192809
37044            2       3      0 37044                                                                  ROOT
                                1 > 54025                                                                192829
                                2   > 57438                                                              187950
37084            1       2      0 37084                                                                  ROOT
                                1 > 54037                                                                192843
37108            1       2      0 37108                                                                  ROOT
                                1 < 7638                                                                 155669 37247            1       2      0 37247                                                                  ROOT                                 1 > 54073                                                                194065
37270            4       4      0 37270                                                                  ROOT
                                1 > 54079                                                                194071
                                2   > 54080                                                              194073
                                3     < 37270*                                                           194072                                 2   > 57445                                                              187957
37277            1       2      0 37277                                                                  ROOT
                                1 > 54081                                                                194074
37342           10       6      0 37342                                                                  ROOT
                                1 > 54091                                                                194084
                                2   > 54092                                                              194086
                                3     < 37342*                                                           194085                                 3     > 54093                                                            194089
                                4       < 37342*                                                         194087
                                4       < 54091*                                                         194088                                 2   > 54094                                                              194091
                                3     < 37342*                                                           194090                                 2   > 54095                                                              194093
                                3     < 37342*                                                           194092 37346            1       2      0 37346                                                                  ROOT                                 1 > 54097                                                                194095
37348            1       2      0 37348                                                                  ROOT
                                1 < 7775                                                                 157227
37351            1       2      0 37351                                                                  ROOT
                                1 < 7777                                                                 157234 37420            1       2      0 37420                                                                  ROOT                                 1 > 54126                                                                194139
37421            1       2      0 37421                                                                  ROOT
                                1 > 54127                                                                194140
37515            1       2      0 37515                                                                  ROOT
                                1 > 54145                                                                194159
37516            1       2      0 37516                                                                  ROOT
                                1 > 54146                                                                194160
37585            1       2      0 37585                                                                  ROOT
                                1 > 54165                                                                194185
37689            1       2      0 37689                                                                  ROOT
                                1 < 8026                                                                 160140 37715            1       2      0 37715                                                                  ROOT                                 1 > 53607                                                                191155
37916            1       2      0 37916                                                                  ROOT
                                1 > 54252                                                                194287
37953            1       2      0 37953                                                                  ROOT
                                1 > 53560                                                                191103
38033            1       2      0 38033                                                                  ROOT
                                1 < 8218                                                                 163161 38066            1       2      0 38066                                                                  ROOT                                 1 > 54301                                                                194354
38281            1       2      0 38281                                                                  ROOT
                                1 < 8404                                                                 140828 38328            1       2      0 38328                                                                  ROOT                                 1 > 43779                                                                208954
38829            1       2      0 38829                                                                  ROOT
                                1 < 8738                                                                 145346 38856            1       2      0 38856                                                                  ROOT                                 1 > 38857                                                                145386
39024            1       2      0 39024                                                                  ROOT
                                1 > 54494                                                                195793
39188            1       2      0 39188                                                                  ROOT
                                1 > 39190                                                                148484
39294            1       2      0 39294                                                                  ROOT
                                1 > 54547                                                                195855
39619            1       2      0 39619                                                                  ROOT
                                1 < 9256                                                                 202005
39628            1       2      0 39628                                                                  ROOT
                                1 < 9276                                                                 202019 39723            1       2      0 39723                                                                  ROOT                                 1 > 54633                                                                195952
39736            1       2      0 39736                                                                  ROOT
                                1 > 48737                                                                190514
39741            3       4      0 39741                                                                  ROOT
                                1 > 54636                                                                195956
                                1 > 54637                                                                195957
                                1 > 54638                                                                195958
39762            1       2      0 39762                                                                  ROOT
                                1 > 54644                                                                195965
39775            2       3      0 39775                                                                  ROOT
                                1 > 54646                                                                195967
                                2   > 57529                                                              188056
39785            1       2      0 39785                                                                  ROOT
                                1 > 54647                                                                195968
39820            1       2      0 39820                                                                  ROOT
                                1 > 53513                                                                191052
39979            1       2      0 39979                                                                  ROOT
                                1 > 54680                                                                196005
40009            3       3      0 40009                                                                  ROOT
                                1 > 54684                                                                196009
                                2   > 54685                                                              196011
                                3     < 40009*                                                           196010 40137            1       2      0 40137                                                                  ROOT                                 1 > 54730                                                                197267
40189            1       2      0 40189                                                                  ROOT
                                1 > 54735                                                                197272
40212            2       3      0 40212                                                                  ROOT
                                1 > 54741                                                                197275
                                1 > 54742                                                                197276
40325            4       5      0 40325                                                                  ROOT
                                1 > 54762                                                                197301
                                2   > 57570                                                              188126
                                2   > 57571                                                              188127
                                1 > 54763                                                                197302
40326            1       2      0 40326                                                                  ROOT
                                1 < 9963                                                                 206790 40365            1       2      0 40365                                                                  ROOT                                 1 > 54772                                                                197310
40368            1       2      0 40368                                                                  ROOT
                                1 > 54773                                                                197311
40377            1       2      0 40377                                                                  ROOT
                                1 > 54774                                                                197312
40813            1       2      0 40813                                                                  ROOT
                                1 > 54838                                                                197386
40814            1       2      0 40814                                                                  ROOT
                                1 > 54839                                                                197387
40842            1       2      0 40842                                                                  ROOT
                                1 > 54840                                                                197388
40847            1       2      0 40847                                                                  ROOT
                                1 > 54843                                                                197390
40853            1       2      0 40853                                                                  ROOT
                                1 > 54845                                                                197392
40856            3       4      0 40856                                                                  ROOT
                                1 > 54846                                                                197393
                                2   > 57593                                                              188149
                                3     > 58067                                                            188683
40859            1       2      0 40859                                                                  ROOT
                                1 > 54847                                                                197394
40879            2       3      0 40879                                                                  ROOT
                                1 > 54850                                                                197400
                                1 > 54851                                                                197401
40880            1       2      0 40880                                                                  ROOT
                                1 > 54852                                                                197402
40882            1       2      0 40882                                                                  ROOT
                                1 > 54854                                                                197404
40886            1       2      0 40886                                                                  ROOT
                                1 > 44198                                                                211997
40890            2       3      0 40890                                                                  ROOT
                                1 > 54855                                                                197405
                                2   > 57594                                                              188150
40896            4       4      0 40896                                                                  ROOT
                                1 > 54856                                                                197406
                                2   > 57595                                                              188151
                                3     > 57596                                                            188153
                                4       < 54856*                                                         188152 40898            4       4      0 40898                                                                  ROOT                                 1 > 54857                                                                197407
                                2   > 57597                                                              188154
                                3     > 57598                                                            188156
                                4       < 54857*                                                         188155 40907            1       2      0 40907                                                                  ROOT                                 1 > 54860                                                                197411
40917            9       9      0 40917                                                                  ROOT
                                1 > 54861                                                                197412
                                2   > 57599                                                              188157
                                3     > 57600                                                            188159
                                4       < 54861*                                                         188158                                 2   > 57601                                                              188160
                                2   > 57602                                                              188161
                                3     > 58068                                                            188684
                                2   > 57603                                                              188162
                                2   > 57604                                                              188163
40918            1       2      0 40918                                                                  ROOT
                                1 > 54862                                                                197413
40925            1       2      0 40925                                                                  ROOT
                                1 > 54865                                                                197415
40926            3       4      0 40926                                                                  ROOT
                                1 > 54866                                                                197416
                                1 > 54867                                                                197417
                                1 > 54868                                                                197418
40927            1       2      0 40927                                                                  ROOT
                                1 > 52038                                                                208097
41026            1       2      0 41026                                                                  ROOT
                                1 > 54893                                                                197448
41172            1       2      0 41172                                                                  ROOT
                                1 > 54922                                                                197484
41212            1       2      0 41212                                                                  ROOT
                                1 > 54837                                                                197385
41304            3       4      0 41304                                                                  ROOT
                                1 > 54935                                                                197498
                                1 > 54936                                                                197499
                                1 > 54937                                                                197500
41312            1       2      0 41312                                                                  ROOT
                                1 > 54944                                                                197507
41342            1       2      0 41342                                                                  ROOT
                                1 > 54957                                                                197524
41354            1       2      0 41354                                                                  ROOT
                                1 > 54958                                                                197525
41599            1       2      0 41599                                                                  ROOT
                                1 > 55001                                                                197568
41608            2       3      0 41608                                                                  ROOT
                                1 > 55003                                                                197570
                                2   > 55664                                                              185981
41919            1       2      0 41919                                                                  ROOT
                                1 > 55059                                                                197631
41992            1       2      0 41992                                                                  ROOT
                                1 > 55073                                                                198841
42002            1       2      0 42002                                                                  ROOT
                                1 > 55083                                                                198864
42003            1       2      0 42003                                                                  ROOT
                                1 > 55084                                                                198865
42033            1       2      0 42033                                                                  ROOT
                                1 > 42034                                                                193161
42186            1       2      0 42186                                                                  ROOT
                                1 > 55113                                                                198896
42252            1       2      0 42252                                                                  ROOT
                                1 > 55132                                                                198921
42474            2       3      0 42474                                                                  ROOT
                                1 > 55182                                                                198988
                                2   > 57645                                                              188203
42494            1       2      0 42494                                                                  ROOT
                                1 > 55188                                                                198994
42517            1       2      0 42517                                                                  ROOT
                                1 > 55197                                                                199004
43247            3       4      0 43247                                                                  ROOT
                                1 > 55401                                                                185668
                                2   > 57680                                                              188242
                                2   > 57681                                                              188243
43584            1       2      0 43584                                                                  ROOT
                                1 > 55497                                                                185755
43749            1       2      0 43749                                                                  ROOT
                                1 > 55555                                                                185846
43805            2       3      0 43805                                                                  ROOT
                                1 > 55563                                                                185854
                                1 > 55564                                                                185855
43942           27      11      0 43942                                                                  ROOT
                                1 > 54717                                                                197257
                                2   > 55599                                                              185898
                                3     < 43942*                                                           185897
                                3     < 55593                                                            185899
                                3     < 55594                                                            185900                                 4       > 55595                                                          185890
                                5         > 55597                                                        185893
                                6           < 55594*                                                     185892                                 6           > 55598                                                      185896
                                7             < 55594*                                                   185894
                                7             < 55595*                                                   185895                                 7             > 55599*                                                   185904
                                7             > 55600                                                    185908
                                8               < 55594*                                                 185905
                                8               < 55595*                                                 185906
                                8               < 55597*                                                 185907
                                8               < 55599*                                                 185909                                 8               > 57744                                                  188332
                                9                 < 55594*                                               188327
                                9                 < 55595*                                               188328
                                9                 < 55597*                                               188329
                                9                 < 55598*                                               188330
                                9                 < 55599*                                               188331                                 6           > 55599*                                                     185903
                                5         > 55599*                                                       185901
                                3     < 55596                                                            185902
                                4       < 43942*                                                         185891 43955            1       2      0 43955                                                                  ROOT                                 1 > 55602                                                                185911
43968            2       3      0 43968                                                                  ROOT
                                1 > 55606                                                                185916
                                2   > 57746                                                              188334
43977            2       3      0 43977                                                                  ROOT
                                1 > 55609                                                                185918
                                2   > 57748                                                              188336
44008            1       2      0 44008                                                                  ROOT
                                1 > 55615                                                                185927
44009            2       3      0 44009                                                                  ROOT
                                1 > 55616                                                                185928
                                2   > 57749                                                              188337
44011            1       2      0 44011                                                                  ROOT
                                1 > 55617                                                                185929
44013            3       3      0 44013                                                                  ROOT
                                1 > 55618                                                                185930
                                2   > 55619                                                              185932
                                3     < 44013*                                                           185931 44017            1       2      0 44017                                                                  ROOT                                 1 > 55620                                                                185933
44023            1       2      0 44023                                                                  ROOT
                                1 > 55624                                                                185939
44084            1       2      0 44084                                                                  ROOT
                                1 > 55644                                                                185961
44086            1       2      0 44086                                                                  ROOT
                                1 > 55645                                                                185962
44091            1       2      0 44091                                                                  ROOT
                                1 > 53610                                                                191159
44122            1       2      0 44122                                                                  ROOT
                                1 > 55652                                                                185970
44123            1       2      0 44123                                                                  ROOT
                                1 > 55653                                                                185971
44128            3       4      0 44128                                                                  ROOT
                                1 > 55655                                                                185972
                                2   > 57757                                                              188345
                                3     > 58099                                                            188718
44189            2       3      0 44189                                                                  ROOT
                                1 > 55661                                                                185978
                                2   > 57758                                                              188346
44191            1       2      0 44191                                                                  ROOT
                                1 > 55662                                                                185979
44201            1       2      0 44201                                                                  ROOT
                                1 > 55667                                                                185984
44203            2       3      0 44203                                                                  ROOT
                                1 > 55668                                                                185985
                                2   > 57759                                                              188347
44231            2       3      0 44231                                                                  ROOT
                                1 > 55677                                                                185997
                                1 > 55678                                                                185998
44250            1       2      0 44250                                                                  ROOT
                                1 > 53599                                                                191147
44251            1       2      0 44251                                                                  ROOT
                                1 > 55682                                                                186002
44274            1       2      0 44274                                                                  ROOT
                                1 > 55686                                                                186006
44308            9       5      0 44308                                                                  ROOT
                                1 > 55695                                                                186015
                                2   > 55696                                                              186017
                                3     < 44308*                                                           186016                                 3     > 55697                                                            186020
                                4       < 44308*                                                         186018
                                4       < 55695*                                                         186019                                 4       > 55698                                                          186023
                                5         < 44308*                                                       186021
                                5         < 55696*                                                       186022 45010            1       2      0 45010                                                                  ROOT                                 1 > 55865                                                                186211
45014            1       2      0 45014                                                                  ROOT
                                1 > 55866                                                                186212
45052            1       2      0 45052                                                                  ROOT
                                1 > 55878                                                                186223
45101            1       2      0 45101                                                                  ROOT
                                1 > 55891                                                                186239
45505            2       3      0 45505                                                                  ROOT
                                1 > 55979                                                                186335
                                2   > 57809                                                              188400
45690            1       2      0 45690                                                                  ROOT
                                1 > 56005                                                                186362
45913            1       2      0 45913                                                                  ROOT
                                1 > 45914                                                                199621
46025            1       2      0 46025                                                                  ROOT
                                1 > 56061                                                                186425
46127            1       2      0 46127                                                                  ROOT
                                1 > 56084                                                                186450
46455            1       2      0 46455                                                                  ROOT
                                1 > 56142                                                                186512
46639            2       3      0 46639                                                                  ROOT
                                1 > 55339                                                                185595
                                1 > 56175                                                                186548
46770            1       2      0 46770                                                                  ROOT
                                1 > 50528                                                                200191
46932            1       2      0 46932                                                                  ROOT
                                1 > 56219                                                                186594
47011            1       2      0 47011                                                                  ROOT
                                1 > 56231                                                                186606
47267            1       2      0 47267                                                                  ROOT
                                1 > 47296                                                                207585
47277            1       2      0 47277                                                                  ROOT
                                1 > 56267                                                                186647
47364            1       2      0 47364                                                                  ROOT
                                1 > 56279                                                                186659
47436            1       2      0 47436                                                                  ROOT
                                1 > 56286                                                                186666
47486            1       2      0 47486                                                                  ROOT
                                1 > 56295                                                                186675
48021            1       2      0 48021                                                                  ROOT
                                1 > 55064                                                                198833
48035            1       2      0 48035                                                                  ROOT
                                1 > 56402                                                                186801
48504            1       2      0 48504                                                                  ROOT
                                1 > 56479                                                                186903
48614            4       5      0 48614                                                                  ROOT
                                1 > 56500                                                                186924
                                2   > 57874                                                              188475
                                1 > 56501                                                                186925
                                1 > 56502                                                                186926
48664            1       2      0 48664                                                                  ROOT
                                1 > 56511                                                                186936
48913            1       2      0 48913                                                                  ROOT
                                1 > 56547                                                                186973
48980            2       3      0 48980                                                                  ROOT
                                1 > 56551                                                                186977
                                2   > 57878                                                              188479
49284            1       2      0 49284                                                                  ROOT
                                1 > 56596                                                                187026
49552            1       2      0 49552                                                                  ROOT
                                1 > 56639                                                                187072
49595            2       3      0 49595                                                                  ROOT
                                1 > 56646                                                                187079
                                2   > 57894                                                              188495
49878            1       2      0 49878                                                                  ROOT
                                1 > 56692                                                                187148
50472            3       3      0 50472                                                                  ROOT
                                1 > 56785                                                                187248
                                2   > 56786                                                              187250
                                3     < 50472*                                                           187249 50504            1       2      0 50504                                                                  ROOT                                 1 > 56790                                                                187253
50508            5       6      0 50508                                                                  ROOT
                                1 > 50509                                                                200166
                                1 > 56791                                                                187254
                                1 > 56792                                                                187255
                                1 > 56793                                                                187256
                                1 > 56794                                                                187257
50530            1       2      0 50530                                                                  ROOT
                                1 > 56797                                                                187260
50610            1       2      0 50610                                                                  ROOT
                                1 > 54722                                                                197259
50691            1       2      0 50691                                                                  ROOT
                                1 > 56820                                                                187282
50728            1       2      0 50728                                                                  ROOT
                                1 > 56826                                                                187289
50729            1       2      0 50729                                                                  ROOT
                                1 > 56827                                                                187290
50746            1       2      0 50746                                                                  ROOT
                                1 > 56829                                                                187292
50805            2       3      0 50805                                                                  ROOT
                                1 > 56838                                                                187302
                                2   > 57931                                                              188533
50806            1       2      0 50806                                                                  ROOT
                                1 > 56839                                                                187303
50885            2       3      0 50885                                                                  ROOT
                                1 > 56859                                                                187323
                                2   > 57934                                                              188536
51020            2       3      0 51020                                                                  ROOT
                                1 > 56902                                                                187371
                                2   > 57947                                                              188549
51082            1       2      0 51082                                                                  ROOT
                                1 > 56931                                                                187419
51095            1       2      0 51095                                                                  ROOT
                                1 > 56932                                                                187420
51294            1       2      0 51294                                                                  ROOT
                                1 > 56966                                                                187454
51295            1       2      0 51295                                                                  ROOT
                                1 > 56967                                                                187455
51358            1       2      0 51358                                                                  ROOT
                                1 > 56976                                                                187464
51407            1       2      0 51407                                                                  ROOT
                                1 > 56983                                                                187472
51439            2       3      0 51439                                                                  ROOT
                                1 > 56990                                                                187479
                                1 > 56991                                                                187480
51575            1       2      0 51575                                                                  ROOT
                                1 > 57002                                                                187491
51696            2       3      0 51696                                                                  ROOT
                                1 > 57027                                                                187518
                                1 > 57028                                                                187519
51697            2       3      0 51697                                                                  ROOT
                                1 > 57029                                                                187520
                                1 > 57030                                                                187521
51778            1       2      0 51778                                                                  ROOT
                                1 > 57042                                                                187533
51903            1       2      0 51903                                                                  ROOT
                                1 > 57066                                                                187559
51944           94      49      0 51944                                                                  ROOT
                                1 > 57077                                                                187568
                                2   > 57969                                                              188571
                                3     > 57970                                                            188573
                                4       < 57077*                                                         188572                                 4       > 58155                                                          188780
                                5         < 57969*                                                       188779                                 5         > 58157                                                        188785
                                6           < 57969*                                                     188783
                                6           < 57970*                                                     188784                                 4       > 58158                                                          188787
                                5         < 57969*                                                       188786
                                5         < 58154                                                        188788
                                6           < 57969*                                                     188778                                 6           > 58156                                                      188782
                                7             < 57969*                                                   188781                                 7             > 58158*                                                   188789
                                6           > 58208                                                      185385
                                6           > 58209                                                      185386
                                3     > 57971                                                            188575
                                4       < 57077*                                                         188574                                 3     > 58151                                                            188772
                                4       > 58152                                                          188774
                                5         < 57969*                                                       188773                                 5         > 58153                                                        188777
                                6           < 57969*                                                     188775
                                6           < 58151*                                                     188776                                 6           > 58159                                                      188793
                                7             < 57969*                                                   188790
                                7             < 58151*                                                   188791
                                7             < 58152*                                                   188792                                 7             > 58160                                                    188798
                                8               < 57969*                                                 188794
                                8               < 58151*                                                 188795
                                8               < 58152*                                                 188796
                                8               < 58153*                                                 188797                                 8               > 58161                                                  188804
                                9                 < 57969*                                               188799
                                9                 < 58151*                                               188800
                                9                 < 58152*                                               188801
                                9                 < 58153*                                               188802
                                9                 < 58159*                                               188803                                 9                 > 58204                                                185376
                               10                   < 58151*                                             185372
                               10                   < 58153*                                             185373
                               10                   < 58159*                                             185374
                               10                   < 58160*                                             185375                                10                   > 58206                                              185383
                               11                     < 58152*                                           185378
                               11                     < 58153*                                           185379
                               11                     < 58159*                                           185380
                               11                     < 58160*                                           185381
                               11                     < 58161*                                           185382                                 8               > 58210                                                  185387
                                9                 > 58222                                                185401
                                8               > 58211                                                  185388
                                9                 > 58212                                                185390
                               10                   < 58160*                                             185389                                10                   > 58223                                              185402
                                7             > 58200                                                    185362
                                8               < 58151*                                                 185361                                 5         > 58205                                                        185377
                                6           > 58219                                                      185398
                                7             > 58224                                                    185403
                                6           > 58220                                                      185399
                                7             > 58225                                                    185404
                                8               > 58226                                                  185406
                                9                 < 58220*                                               185405                                 8               > 58227                                                  185407
                                6           > 58221                                                      185400
                                5         > 58207                                                        185384
                                4       > 58195                                                          188837
                                5         > 58199                                                        185360
                                6           < 58151*                                                     185359                                 6           > 58202                                                      185366
                                7             < 58151*                                                   185364
                                7             < 58195*                                                   185365
                                7             < 58201                                                    185367
                                8               < 58151*                                                 185363                                 5         > 58218                                                        185397
                                4       > 58196                                                          185354
                                5         > 58197                                                        185356
                                6           < 58151*                                                     185355                                 6           > 58198                                                      185358
                                7             < 58151*                                                   185357                                 7             > 58203                                                    185371
                                8               < 58151*                                                 185368
                                8               < 58196*                                                 185369
                                8               < 58197*                                                 185370                                 2   > 57972                                                              188576
                                3     > 57973                                                            188578
                                4       < 57077*                                                         188577                                 3     > 58162                                                            188805
                                2   > 57974                                                              188579
                                3     > 58163                                                            188806
52712            1       2      0 52712                                                                  ROOT
                                1 > 57224                                                                187725
53283            1       2      0 53283                                                                  ROOT
                                1 > 57312                                                                187820
53490            1       2      0 53490                                                                  ROOT
                                1 > 57339                                                                187847
53510            2       3      0 53510                                                                  ROOT
                                1 > 53511                                                                191050
                                1 > 53512                                                                191051
53514            1       2      0 53514                                                                  ROOT
                                1 > 57346                                                                187855
53618            2       3      0 53618                                                                  ROOT
                                1 > 57365                                                                187873
                                2   > 58027                                                              188634
53622            1       2      0 53622                                                                  ROOT
                                1 > 57366                                                                187874
53623            1       2      0 53623                                                                  ROOT
                                1 > 57367                                                                187875
53698            1       2      0 53698                                                                  ROOT
                                1 > 57375                                                                187883
53712            1       2      0 53712                                                                  ROOT
                                1 > 57379                                                                187887
53799            4       5      0 53799                                                                  ROOT
                                1 > 56828                                                                187291
                                1 > 57392                                                                187900
                                2   > 58034                                                              188640
                                1 > 57393                                                                187901
53824            1       2      0 53824                                                                  ROOT
                                1 > 57397                                                                187905
53839            1       2      0 53839                                                                  ROOT
                                1 > 53840                                                                192614
53853            2       3      0 53853                                                                  ROOT
                                1 > 57409                                                                187920
                                1 > 57410                                                                187921
53999            1       2      0 53999                                                                  ROOT
                                1 > 57430                                                                187941
54087            2       3      0 54087                                                                  ROOT
                                1 > 57446                                                                187958
                                2   > 58049                                                              188660
54481           14       6      0 54481                                                                  ROOT
                                1 > 57502                                                                188019
                                2   > 57503                                                              188021
                                3     < 54481*                                                           188020                                 3     > 57504                                                            188024
                                4       < 54481*                                                         188022
                                4       < 57502*                                                         188023                                 4       > 57505                                                          188028
                                5         < 54481*                                                       188025
                                5         < 57502*                                                       188026
                                5         < 57503*                                                       188027                                 5         > 57506                                                        188032
                                6           < 54481*                                                     188029
                                6           < 57502*                                                     188030
                                6           < 57503*                                                     188031 54676            3       4      0 54676                                                                  ROOT                                 1 > 57531                                                                188058
                                1 > 57532                                                                188059
                                1 > 57533                                                                188060
54678            7       5      0 54678                                                                  ROOT
                                1 > 57535                                                                188062
                                2   > 57536                                                              188064
                                3     < 54678*                                                           188063                                 3     > 57537                                                            188067
                                4       < 54678*                                                         188065
                                4       < 57535*                                                         188066                                 2   > 58056                                                              188668
54711           10       5      0 54711                                                                  ROOT
                                1 > 57542                                                                188072
                                2   > 57543                                                              188074
                                3     < 54711*                                                           188073                                 3     > 57544                                                            188077
                                4       < 54711*                                                         188075
                                4       < 57542*                                                         188076                                 4       > 57545                                                          188081
                                5         < 54711*                                                       188078
                                5         < 57542*                                                       188079
                                5         < 57543*                                                       188080 54715            1       2      0 54715                                                                  ROOT                                 1 > 54716                                                                197256
54719            1       2      0 54719                                                                  ROOT
                                1 > 57548                                                                188083
54720            1       2      0 54720                                                                  ROOT
                                1 > 57549                                                                188084
54721            1       2      0 54721                                                                  ROOT
                                1 > 57550                                                                188085
54723            1       2      0 54723                                                                  ROOT
                                1 > 57552                                                                188086
54724            8       5      0 54724                                                                  ROOT
                                1 > 57553                                                                188087
                                2   > 57554                                                              188089
                                3     < 54724*                                                           188088                                 3     > 58058                                                            188671
                                4       < 57553*                                                         188670                                 4       > 58059                                                          188674
                                5         < 57553*                                                       188672
                                5         < 57554*                                                       188673 54736            4       5      0 54736                                                                  ROOT                                 1 > 57556                                                                188091
                                1 > 57557                                                                188092
                                2   > 58060                                                              188675
                                1 > 57558                                                                188093
54737            1       2      0 54737                                                                  ROOT
                                1 > 57559