Dimensional Benchmarking of SQL for Fixed-Depth Hierarchies

In my recent article,Dimensional Benchmarking of Bracket Parsing SQL I showed how it was much more efficient to to solve a particular database querying problem using a database function than by two other pure SQL methods. I have also written articles using recursive PL/SQL functions to traverse network or hierarchical data structures, such as PL/SQL Pipelined Function for Network Analysis.

Networks or hierarchies of arbitrary depth are difficult to traverse in SQL without using recursion. However, there also exist hierarchies of fixed and fairly small depths, and these can be traversed either recursively or by a sequence of joins for each of the levels. In this article I compare the performance characteristics of three traversal methods, two recursive and one non-recursive, using my own benchmarking package (A Framework for Dimensional Benchmarking of SQL Performance), on a test problem of a fixed level organization structure hierarchy, with 5 levels for performance testing and 3 levels for functional testing.

The three queries tested were:

  • JNS_QRY: Sequence of joins
  • PLF_QRY: Recursive pipelined function
  • RSF_QRY: Recursive subquery factors

Fixed Level Hierarchy Problem Definition

A hierarchy is assumed in which there are a number of root records, and at each level a parent can have multiple child records and a child can also have multiple parents. Each level in the hierarchy corresponds to an entity of a particular type. Each parent-child record is associated with a numerical factor, and the products of these propagate down the levels.

The problem considered is to report all root/leaf combinations with their associated products. There may of course be multiple paths between any root and leaf, and in a real world example one would likely want to aggregate. However, in order to keep it simple and focus on the traversal performance, I do not perform any aggregation.

Test Data Structure

Tables

CREATE TABLE orgs ( id              NUMBER NOT NULL, 
                    org_level       NUMBER NOT NULL, 
                    org_name        VARCHAR2(100) NOT NULL,
                    CONSTRAINT      org_pk PRIMARY KEY (id))
/
DROP TABLE org_structure
/
CREATE TABLE org_structure (
                    id              NUMBER NOT NULL, 
                    struct_level    NUMBER NOT NULL, 
                    org_id          NUMBER NOT NULL, 
                    child_org_id    NUMBER NOT NULL,
                    fact            NUMBER,
                    CONSTRAINT      ost_pk PRIMARY KEY (id))
/
CREATE INDEX ost_N1 ON org_structure (org_id)
/
CREATE INDEX ost_N2 ON org_structure (child_org_id)
/

Functional Test Data

To simplify functional validation a 3-level hierarchy was taken, with a relatively small number of records. The functional test data were generated by the same automated approach used for performance testing. The fact number was obtained as a random number betwee 0 and 1, and to keep it simple, duplicate pairs were permitted.

The test data were parametrised by width and depth as follows (the exact logic is a little complicated, but can be seen in the code itself):

  • Width corresponds to a percentage increase in the number of child entities relative to the number of parents
  • Depth corresponds to the proportion of the parent entity records a child is (randomly) assigned. Each child has a minimum of 1 parent (lowest depth), and a maximum of all parent entities (highest depth)
Test Data

orgs

        ID  ORG_LEVEL ORG_NAME
---------- ---------- ----------------------------------------------------------------------------------------------------
         1          1 L1 Org 1
         2            L1 Org 2
         3            L1 Org 3
         4          2 L2 Org 1
         5            L2 Org 2
         6            L2 Org 3
         7            L2 Org 4
         8            L2 Org 5
         9            L2 Org 6
        10          3 L3 Org 1
        11            L3 Org 2
        12            L3 Org 3
        13            L3 Org 4
        14            L3 Org 5
        15            L3 Org 6
        16            L3 Org 7
        17            L3 Org 8
        18            L3 Org 9
        19            L3 Org 10
        20            L3 Org 11
        21            L3 Org 12

21 rows selected.

org_structure

        ID STRUCT_LEVEL     ORG_ID CHILD_ORG_ID       FACT
---------- ------------ ---------- ------------ ----------
        25            1          2            4 .765337854
        26                       1            5 .157198428
        27                       2            6 .012739872
        28                       3            7  .75268798
        29                       2            8 .647269295
        30                       2            9 .972586624
         1            2          6           10 .290389829
         2                       7           10 .717844734
         3                       6           11 .909068079
         4                       7           11 .876644977
         5                       9           12  .93576597
         6                       6           12 .097462542
         7                       8           13 .316926046
         8                       8           13 .169842496
         9                       6           14 .765946795
        10                       4           14 .831552357
        11                       8           15 .110940017
        12                       7           15 .295163716
        13                       5           16 .171097557
        14                       5           16 .827432202
        15                       7           17 .339382023
        16                       7           17 .644889466
        17                       7           18 .955594058
        18                       5           18 .668546163
        19                       7           19 .785709973
        20                       6           19 .507321616
        21                       8           20 .511548918
        22                       7           20 .523510327
        23                       6           21 .242612715
        24                       5           21 .561006179

30 rows selected.

Result

ROOT_ORG   LEAF_ORG   FACT_PRODUCT
---------- ---------- ------------
L1 Org 1   L3 Org 12          0.09
L1 Org 1   L3 Org 7           0.03
L1 Org 1   L3 Org 7           0.13
L1 Org 1   L3 Org 9           0.11
L1 Org 2   L3 Org 1           0.00
L1 Org 2   L3 Org 10          0.01
L1 Org 2   L3 Org 11          0.33
L1 Org 2   L3 Org 12          0.00
L1 Org 2   L3 Org 2           0.01
L1 Org 2   L3 Org 3           0.00
L1 Org 2   L3 Org 3           0.91
L1 Org 2   L3 Org 4           0.11
L1 Org 2   L3 Org 4           0.21
L1 Org 2   L3 Org 5           0.01
L1 Org 2   L3 Org 5           0.64
L1 Org 2   L3 Org 6           0.07
L1 Org 3   L3 Org 1           0.54
L1 Org 3   L3 Org 10          0.59
L1 Org 3   L3 Org 11          0.39
L1 Org 3   L3 Org 2           0.66
L1 Org 3   L3 Org 6           0.22
L1 Org 3   L3 Org 8           0.26
L1 Org 3   L3 Org 8           0.49
L1 Org 3   L3 Org 9           0.72

24 rows selected.

All queries returned the expected results above.

Performance Test Data

The performance test data were created in the same way as the functional test data, but with 5 levels, and with 10 root organizations.

The test data sets used a grid of width and depth values of (100, 120, 140, 160, 180), which resulted in output records as below:

Sequence of joins (JNS_QRY)

SELECT o1.org_name root_org,
       o5.org_name leaf_org,
       s1.fact * s2.fact * s3.fact * s4.fact fact_product
  FROM org_structure s1
  JOIN org_structure s2
    ON s2.org_id = s1.child_org_id
  JOIN org_structure s3
    ON s3.org_id = s2.child_org_id
  JOIN org_structure s4
    ON s4.org_id = s3.child_org_id
  JOIN orgs o1
    ON o1.id = s1.org_id
  JOIN orgs o5
    ON o5.id = s4.child_org_id
 WHERE s1.struct_level = 1
 ORDER BY o1.org_name, o5.org_name, s1.fact * s2.fact * s3.fact * s4.fact

Plan hash value: 914261573

----------------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation               | Name          | Starts | E-Rows | A-Rows |   A-Time   | Buffers | Reads  | Writes |  OMem |  1Mem | Used-Mem | Used-Tmp|
----------------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT        |               |      1 |        |   3330K|00:00:11.12 |     718 |  51157 |  51157 |       |       |          |         |
|   1 |  SORT ORDER BY          |               |      1 |   3905K|   3330K|00:00:11.12 |     718 |  51157 |  51157 |   454M|  7031K|  163M (1)|     400K|
|*  2 |   HASH JOIN             |               |      1 |   3905K|   3330K|00:00:01.76 |     714 |      0 |      0 |  1483K|  1483K| 1524K (0)|         |
|   3 |    TABLE ACCESS FULL    | ORGS          |      1 |    944 |    944 |00:00:00.01 |       7 |      0 |      0 |       |       |          |         |
|*  4 |    HASH JOIN            |               |      1 |   3905K|   3330K|00:00:00.45 |     707 |      0 |      0 |  2733K|  1562K| 4103K (0)|         |
|   5 |     TABLE ACCESS FULL   | ORG_STRUCTURE |      1 |  27288 |  27288 |00:00:00.01 |     175 |      0 |      0 |       |       |          |         |
|*  6 |     HASH JOIN           |               |      1 |    133K|  30520 |00:00:00.02 |     532 |      0 |      0 |   917K|   917K| 3834K (0)|         |
|*  7 |      HASH JOIN          |               |      1 |   4575 |    780 |00:00:00.01 |     357 |      0 |      0 |  1062K|  1062K| 1260K (0)|         |
|*  8 |       HASH JOIN         |               |      1 |     56 |     56 |00:00:00.01 |     182 |      0 |      0 |  1185K|  1185K| 1184K (0)|         |
|*  9 |        TABLE ACCESS FULL| ORG_STRUCTURE |      1 |     56 |     56 |00:00:00.01 |     175 |      0 |      0 |       |       |          |         |
|  10 |        TABLE ACCESS FULL| ORGS          |      1 |    944 |    944 |00:00:00.01 |       7 |      0 |      0 |       |       |          |         |
|  11 |       TABLE ACCESS FULL | ORG_STRUCTURE |      1 |  27288 |  27288 |00:00:00.01 |     175 |      0 |      0 |       |       |          |         |
|  12 |      TABLE ACCESS FULL  | ORG_STRUCTURE |      1 |  27288 |  27288 |00:00:00.01 |     175 |      0 |      0 |       |       |          |         |
----------------------------------------------------------------------------------------------------------------------------------------------------------

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

   2 - access("O5"."ID"="S4"."CHILD_ORG_ID")
   4 - access("S4"."ORG_ID"="S3"."CHILD_ORG_ID")
   6 - access("S3"."ORG_ID"="S2"."CHILD_ORG_ID")
   7 - access("S2"."ORG_ID"="S1"."CHILD_ORG_ID")
   8 - access("O1"."ID"="S1"."ORG_ID")
   9 - filter("S1"."STRUCT_LEVEL"=1)

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

Notes on JNS_QRY

It is interesting to note that all joins in the execution plan are hash joins, and in the sequence you would expect. The first three are in the default join 'sub-order' that defines whether the joined table or the prior rowset (the default) is used to form the hash table, while the last two are in the reverse order, corresponding to the swap_join_inputs hint. I wrote a short note on that subject, A Note on Oracle Join Orders and Hints, last year, and have now written an article using the largest data point in the current problem to explore performance variation across the possible sub-orders.

Recursive pipelined function (PLF_QRY)

CREATE OR REPLACE TYPE org_struct_rec_type IS OBJECT (struct_level NUMBER, org_id NUMBER, fact_product NUMBER);
/
CREATE TYPE org_struct_lis_type IS VARRAY(32767) OF org_struct_rec_type;
/
CREATE OR REPLACE FUNCTION Org_Products (p_org_id PLS_INTEGER, p_fact_product NUMBER) RETURN org_struct_lis_type PIPELINED IS
  l_org_struct_lis  org_struct_lis_type;
BEGIN

  FOR rec_org_struct IN (
      SELECT child_org_id,
             p_fact_product * fact fact_product,
             struct_level
      FROM org_structure
      WHERE org_id = p_org_id) LOOP

    PIPE ROW (org_struct_rec_type (rec_org_struct.struct_level, rec_org_struct.child_org_id, rec_org_struct.fact_product));

    FOR rec_org_struct_child IN (SELECT struct_level, org_id, fact_product FROM TABLE (Org_Products (rec_org_struct.child_org_id, rec_org_struct.fact_product))) LOOP

      PIPE ROW (org_struct_rec_type (rec_org_struct_child.struct_level, rec_org_struct_child.org_id, rec_org_struct_child.fact_product));

    END LOOP;

  END LOOP;

END  Org_Products;

SELECT o1.org_name root_org,
       o5.org_name leaf_org,
       t.fact_product fact_product
  FROM org_structure s
  CROSS APPLY TABLE (Org_Products (s.child_org_id, s.fact)) t
  JOIN orgs o1
    ON o1.id = s.org_id
  JOIN orgs o5
    ON o5.id = t.org_id
 WHERE s.struct_level = 1
   AND t.struct_level = 4
 ORDER BY o1.org_name, o5.org_name, t.fact_product

Plan hash value: 1216100769

-----------------------------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                            | Name          | Starts | E-Rows | A-Rows |   A-Time   | Buffers | Reads  | Writes |  OMem |  1Mem | Used-Mem | Used-Tmp|
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                     |               |      1 |        |   3330K|00:03:38.10 |    9072K|  51163 |  51163 |       |       |          |         |
|   1 |  SORT ORDER BY                       |               |      1 |   4574 |   3330K|00:03:38.10 |    9072K|  51163 |  51163 |   455M|  7037K|  163M (1)|     400K|
|*  2 |   HASH JOIN                          |               |      1 |   4574 |   3330K|00:03:15.00 |    9072K|      0 |      0 |  1483K|  1483K| 1489K (0)|         |
|   3 |    TABLE ACCESS FULL                 | ORGS          |      1 |    944 |    944 |00:00:00.01 |       7 |      0 |      0 |       |       |          |         |
|   4 |    NESTED LOOPS                      |               |      1 |   4574 |   3330K|00:03:13.28 |    9072K|      0 |      0 |       |       |          |         |
|*  5 |     HASH JOIN                        |               |      1 |     56 |     56 |00:00:00.01 |     182 |      0 |      0 |  1160K|  1160K| 1199K (0)|         |
|*  6 |      TABLE ACCESS FULL               | ORG_STRUCTURE |      1 |     56 |     56 |00:00:00.01 |     175 |      0 |      0 |       |       |          |         |
|   7 |      TABLE ACCESS FULL               | ORGS          |      1 |    944 |    944 |00:00:00.01 |       7 |      0 |      0 |       |       |          |         |
|*  8 |     COLLECTION ITERATOR PICKLER FETCH| ORG_PRODUCTS  |     56 |     82 |   3330K|00:03:12.84 |    9072K|      0 |      0 |       |       |          |         |
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------

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

   2 - access("O5"."ID"=VALUE(KOKBF$))
   5 - access("O1"."ID"="S"."ORG_ID")
   6 - filter("S"."STRUCT_LEVEL"=1)
   8 - filter(VALUE(KOKBF$)=4)

Outer Loop Function Query - Explan Plan only

SELECT child_org_id,
       fact fact_product,
       struct_level
  FROM org_structure
  WHERE org_id = 1

Query Plan
---------------------------------------------------
SELECT STATEMENT   Cost = 41
  TABLE ACCESS BY INDEX ROWID BATCHED ORG_STRUCTURE
    INDEX RANGE SCAN OST_N1

Notes on PLF_QRY

For simplicity a stand-alone database function was used here. The query execution plan was obtained by the benchmarking framework and the highest data point plan listed. The query within the function was extracted and an explain Plan performed manually, which showed the expected index range scan.

Recursive subquery factors (RSF_QRY)

WITH rsf (root_org_id, child_org_id, fact_product, lev) AS
(
SELECT org_id, child_org_id, fact, 1
  FROM org_structure
 WHERE struct_level = 1
UNION ALL
SELECT r.root_org_id,
       s.child_org_id,
       r.fact_product * s.fact,
       r.lev + 1
  FROM rsf r
  JOIN org_structure s
    ON s.org_id = r.child_org_id
)
SELECT o1.org_name root_org,
       o5.org_name leaf_org,
       r.fact_product fact_product
  FROM rsf r
  JOIN orgs o1
    ON o1.id = r.root_org_id
  JOIN orgs o5
    ON o5.id = r.child_org_id
 WHERE r.lev = 4
 ORDER BY o1.org_name, o5.org_name, r.fact_product

Plan hash value: 248371385

-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                    | Name          | Starts | E-Rows | A-Rows |   A-Time   | Buffers | Reads  | Writes |  OMem |  1Mem | Used-Mem | Used-Tmp|
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                             |               |      1 |        |   3330K|00:00:55.92 |      39M|  73843 |  93808 |       |       |          |         |
|   1 |  SORT ORDER BY                               |               |      1 |   4631 |   3330K|00:00:55.92 |      39M|  73843 |  93808 |   454M|  7030K|  162M (1)|     400K|
|*  2 |   HASH JOIN                                  |               |      1 |   4631 |   3330K|00:00:45.06 |      39M|  22678 |  42643 |  1519K|  1519K| 1555K (0)|         |
|   3 |    TABLE ACCESS FULL                         | ORGS          |      1 |    944 |    944 |00:00:00.01 |       7 |      0 |      0 |       |       |          |         |
|*  4 |    HASH JOIN                                 |               |      1 |   4631 |   3330K|00:00:43.14 |      39M|  22678 |  42643 |  1519K|  1519K| 1546K (0)|         |
|   5 |     TABLE ACCESS FULL                        | ORGS          |      1 |    944 |    944 |00:00:00.01 |       7 |      0 |      0 |       |       |          |         |
|*  6 |     VIEW                                     |               |      1 |   4631 |   3330K|00:00:41.58 |      39M|  22678 |  42643 |       |       |          |         |
|   7 |      UNION ALL (RECURSIVE WITH) BREADTH FIRST|               |      1 |        |   3361K|00:00:40.72 |      39M|  22678 |  42643 |   173M|  4426K|   97M (0)|         |
|*  8 |       TABLE ACCESS FULL                      | ORG_STRUCTURE |      1 |     56 |     56 |00:00:00.01 |     175 |      0 |      0 |       |       |          |         |
|*  9 |       HASH JOIN                              |               |      4 |   4575 |   3361K|00:00:06.43 |     701 |  22678 |  22935 |   282M|    10M|   56M (1)|     191K|
|  10 |        RECURSIVE WITH PUMP                   |               |      4 |        |   3361K|00:00:00.56 |       1 |  19708 |      0 |       |       |          |         |
|  11 |        TABLE ACCESS FULL                     | ORG_STRUCTURE |      4 |  27288 |    109K|00:00:00.02 |     700 |      0 |      0 |       |       |          |         |
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------

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

   2 - access("O5"."ID"="R"."CHILD_ORG_ID")
   4 - access("O1"."ID"="R"."ROOT_ORG_ID")
   6 - filter("R"."LEV"=4)
   8 - filter("STRUCT_LEVEL"=1)
   9 - access("S"."ORG_ID"="R"."CHILD_ORG_ID")

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

Notes on RSF_QRY

This uses a v11.2 feature.

Performance Testing Results

Deep Slice Elapsed Times [d=180, w=(100, 120, 140, 160, 180)]

  • JNS_QRY is faster than RSF_QRY, which is faster than PLF_QRY at all data points
  • PLF_QRY tracks the number of output records very closely. This is likely because the function executes a query at every node in the hierarchy that uses an indexed search.
  • The pure SQL methods scale better through being able to do full table scans, and avoiding multiple query executions

Deep Slice Elapsed - CPU Times

The elapsed time minus the CPU times are shown in the first graph below, followed by the disk writes. The disk writes (and reads) are computed as the maximum values across the explain plan at the given data point, and are obtained from the system view v$sql_plan_statistics_all. The benchmarking framework gathers these and other statistics automatically.

  • The graphs show how the elapsed time minus CPU times track the disk accesses reasonably well
  • RSF_QRY does nearly twice as much disk writes as the other two

Wide Slice Results [w=180, d=(100, 120, 140, 160, 180)]

The performance characteristics of the three methods across the wide slice data points are pretty similar to those across the deep slice. The graphs are shown below.

Conclusions

  • For the example problem taken, the most efficient way to traverse fixed-level hierarchies is by a sequence of joins
  • Recursive methods are significantly worse, and the recursive function is especially inefficient because it performs large numbers of query executions using indexed searches, instead of full scans
  • The execution plans for the join sequence query gives an example of a sequence of hash joins with different choices of 'join inputs'. It may be interesting to explore the different performance characteristics of the possible choices using hints in a subsequent article (Benchmarking of Hash Join Options in SQL for Fixed-Depth Hierarchies)
  • The output log is attached, and all code is on my GitHub project, GitHub: dim_bench_sql_oracle

Batch_Org






Dimensional Benchmarking of Bracket Parsing SQL

I noticed an interesting thread on OTN recently, Matching ( in a string. It's about using SQL to find matching bracket pairs (technically 'parentheses' but 'brackets' is shorter, and it makes no difference to the SQL). Incidentally, I found recently that nested bracket expressions are a nice way of compactly representing the structure of complex hash join execution plans, A Note on Oracle Join Orders and Hints.

I thought it would be interesting to run some of the solution queries through my benchmarking package to test performance (A Framework for Dimensional Benchmarking of SQL Performance). I decided to consider only the queries that addressed multiple records, and the form of the problem that requires returning record uid, opening and closing bracket positions, plus the substring enclosed. These were by 'mathguy' and 'Peter vd Zwan', and I made very minor tweaks for consistency. I also wrote a query myself using PL/SQL in an inline SQL function using the new (v12.1) 'WITH Function' functionality, and copied this to a version using a pipelined database function to check for any performance differences. The four queries tested were then:

  • CBL_QRY, mathguy: Connect By, Analytics, Regex
  • MRB_QRY, Peter vd Zwan: Connect By, Match_Recognize
  • WFB_QRY, me: With PL/SQL Function, Arrays
  • PFB_QRY, me: Pipelined PL/SQL Function, Arrays

Bracket Pair Definition

Consider a function (BrDiff) defined at each character position as the difference between the number of opening and closing brackets to the left of, or at, that position.

A closing bracket closes an opening bracket if it is the first closing bracket where BrDiff is 1 less than BrDiff at the opening bracket. If all brackets are in some pair, then the expression can be considered well-formed.

This can be illustrated with a diagram for the fourth functional example below.

Test Problem

BRACKET_STRINGS Table

CREATE TABLE bracket_strings (id NUMBER, str VARCHAR2(4000))
/

Functional Test Data

I took four of mathguy's test records, excluding the (deliberately) badly-formed strings, and which included some embedded returns:

Test Data

     ID STR
------- ----------------------------------------
      1  ((Hello ( Hi Hi hi ( A B C ( D)) (EF)
        why Whwy whyhhh )
        )
        )

      2 (1+3*(3-1) + 3*(2+1))
      3 ()()*(())a()(())
      4 b0(b1(b2(b3(x))(xy)))

Result

     ID      O_POS      C_POS STR
------- ---------- ---------- ----------------------------------------
      1          2         60 ((Hello ( Hi Hi hi ( A B C ( D)) (EF)
                              why Whwy whyhhh )
                              )
                              )

      1          3         58 (Hello ( Hi Hi hi ( A B C ( D)) (EF)
                              why Whwy whyhhh )
                              )

      1         10         56 ( Hi Hi hi ( A B C ( D)) (EF)
                              why Whwy whyhhh )

      1         21         33 ( A B C ( D))
      1         29         32 ( D)
      1         35         38 (EF)
      2          1         21 (1+3*(3-1) + 3*(2+1))
      2          6         10 (3-1)
      2         16         20 (2+1)
      3          1          2 ()
      3          3          4 ()
      3          6          9 (())
      3          7          8 ()
      3         11         12 ()
      3         13         16 (())
      3         14         15 ()
      4          3         21 (b1(b2(b3(x))(xy)))
      4          6         20 (b2(b3(x))(xy))
      4          9         15 (b3(x))
      4         12         14 (x)
      4         16         19 (xy)

21 rows selected.

All queries returned the expected results above.

Performance Test Data

Each test set consisted of 100 records with the str column containing the brackets expression dependent on width (w) and depth (d) parameters, as follows:

  • Each str column contains w bracket pairs
  • The str column begins with a 3-character record number
  • After the record number, the str column begins with d opening brackets with 3 characters of text, like: '(001', etc., followed by the d closing brackets, then the remaining w-d pairs in an unnested sequence, like '(001)'

When w=d the pairs are fully nested, and when d=0 there is no nesting, just a sequence of '(123)' stringss.

This choice of test data sets allows us to see if both number of brackets, and bracket nesting have any effect on performance.

  • Depth fixed, at small width point; width varies: d=100, w=(100, 200, 300, 400)
  • Width fixed at high depth point; depth varies: w=400, d=(0, 100, 200, 300, 400)

The output from the test queries therefore consists of 100*w records with a record identifier and a bracketed string. For performance testing purposes the benchmarking framework writes the results to a file in csv format, while counting only the query steps in the query timing results.

All the queries showed strong time correlation with width, with smaller correlation with depth.

Connect By, Analytics, Regex Query (CBL_QRY)

WITH    d ( id, str, pos ) as (
      select id, str, regexp_instr(str, '', 1, level)
      from   bracket_strings
      connect by level <= length(str) - length(translate(str, 'x()', 'x'))
             and prior id = id
             and prior sys_guid() is not null
    ),
    p ( id, str, pos, flag, l_ct, ct ) as (
      select id, str, pos, case substr(str, pos, 1) when '(' then 1 else -1 end,
             sum(case substr(str, pos, 1) when '(' then 1         end) over (partition by id order by pos),
             sum(case substr(str, pos, 1) when '(' then 1 else -1 end) over (partition by id order by pos)
      from   d
    ),
    f ( id, str, pos, flag, l_ct, ct, o_ct ) as (
      select id, str, pos, flag, l_ct, ct + case flag when 1 then 0 else 1 end as ct,
             row_number() over (partition by id, flag, ct order by pos)
      from   p
    )
select   /*+ CBL_QRY gather_plan_statistics */ id,
        min(case when flag =  1 then pos end) as o_pos,
        min(case when flag = -1 then pos end) as c_pos,
                                Substr (str, min(case when flag =  1 then pos end), min(case when flag = -1 then pos end) - min(case when flag =  1 then pos end) + 1) str
from    f
group by id, str, ct, o_ct
order by 1, 2

Plan hash value: 2736674058

------------------------------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                           | Name            | Starts | E-Rows | A-Rows |   A-Time   | Buffers | Reads  | Writes |  OMem |  1Mem | Used-Mem | Used-Tmp|
------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                    |                 |      1 |        |  40000 |00:00:16.30 |      43 |  40000 |  40000 |       |       |          |         |
|   1 |  SORT ORDER BY                      |                 |      1 |    100 |  40000 |00:00:16.30 |      43 |  40000 |  40000 |    21M|  1702K|   19M (0)|         |
|   2 |   HASH GROUP BY                     |                 |      1 |    100 |  40000 |00:00:16.24 |      43 |  40000 |  40000 |    85M|  7293K|   85M (0)|         |
|   3 |    VIEW                             |                 |      1 |    100 |  80000 |00:01:19.35 |      43 |  40000 |  40000 |       |       |          |         |
|   4 |     WINDOW SORT                     |                 |      1 |    100 |  80000 |00:01:19.27 |      43 |  40000 |  40000 |   175M|  4458K|   97M (1)|     157K|
|   5 |      VIEW                           |                 |      1 |    100 |  80000 |00:01:05.90 |      40 |  20000 |  20000 |       |       |          |         |
|   6 |       WINDOW SORT                   |                 |      1 |    100 |  80000 |00:01:05.86 |      40 |  20000 |  20000 |   175M|  4457K|   97M (0)|     157K|
|   7 |        VIEW                         |                 |      1 |    100 |  80000 |00:00:09.77 |      38 |      0 |      0 |       |       |          |         |
|*  8 |         CONNECT BY WITHOUT FILTERING|                 |      1 |        |  80000 |00:00:02.26 |      38 |      0 |      0 |   267K|   267K|  237K (0)|         |
|   9 |          TABLE ACCESS FULL          | BRACKET_STRINGS |      1 |    100 |    100 |00:00:00.01 |      38 |      0 |      0 |       |       |          |         |
------------------------------------------------------------------------------------------------------------------------------------------------------------------------

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

   8 - access("ID"=PRIOR NULL)

Notes on CBL_QRY

Subquery d uses regexp_instr with connect by to generate rows for each bracket.

Connect By, Match_Recognize Query (MRB_QRY)

WITH b as
(
select
  substr(str,level,1) s
  ,level n
  ,id
  ,str
from
  bracket_strings
connect by
id =  prior id
and substr(str,level,1) is not null
and prior sys_guid() is not null
)
select  /*+ MRB_QRY gather_plan_statistics */ 
  id
  ,o_pos
  ,c_pos
  ,substr(str,o_pos,c_pos - o_pos + 1) str
from
b
MATCH_RECOGNIZE (
partition by id
ORDER BY n
MEASURES 
  str as str
  ,FIRST( N) AS o_pos
  ,LAST( N) AS c_pos
one ROW PER MATCH
AFTER MATCH SKIP to next row
PATTERN (ob (ob | nb | cb)*? lcb)
DEFINE
  ob as ob.s = '('
  ,cb as cb.s = ')'
  ,nb as nb.s not in ('(',')')
  ,lcb as lcb.s = ')' and (count(ob.s) = count(cb.s) + 1)
) MR

Plan hash value: 2214599770

-----------------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                        | Name            | Starts | E-Rows | A-Rows |   A-Time   | Buffers | Reads  | Writes |  OMem |  1Mem | Used-Mem |
-----------------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                 |                 |      1 |        |  40000 |00:03:38.26 |      40 |   4473K|  50075 |       |       |          |
|   1 |  SORT ORDER BY                   |                 |      1 |    100 |  40000 |00:03:38.26 |      40 |   4473K|  50075 |    21M|  1702K|   19M (0)|
|   2 |   VIEW                           |                 |      1 |    100 |  40000 |00:04:48.17 |      40 |   4473K|  50075 |       |       |          |
|   3 |    MATCH RECOGNIZE SORT          |                 |      1 |    100 |  40000 |00:04:48.16 |      40 |   4473K|  50075 |   440M|  6922K|  163M (0)|
|   4 |     VIEW                         |                 |      1 |    100 |    200K|00:00:04.65 |      38 |      0 |      0 |       |       |          |
|*  5 |      CONNECT BY WITHOUT FILTERING|                 |      1 |        |    200K|00:00:04.54 |      38 |      0 |      0 |   267K|   267K|  237K (0)|
|   6 |       TABLE ACCESS FULL          | BRACKET_STRINGS |      1 |    100 |    100 |00:00:00.01 |      38 |      0 |      0 |       |       |          |
-----------------------------------------------------------------------------------------------------------------------------------------------------------

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

   5 - access("ID"=PRIOR NULL)

Notes on MRB_QRY

This uses the v12.1 feature Match_Recognize operating on the charcaters in the string after conversion to rows.

With PL/SQL Function, Arrays Query (WFB_QRY)

WITH FUNCTION Parse_Brackets (p_str VARCHAR2) RETURN bra_lis_type IS /* WFB_QRY */ 
  c_n_ob       CONSTANT PLS_INTEGER := Length (p_str) - Length (Replace (p_str, '(', ''));
  l_ob_lis              SYS.ODCINumberList := SYS.ODCINumberList();
  l_cb_lis              SYS.ODCINumberList := SYS.ODCINumberList();
  TYPE b_rec_type   IS  RECORD (pos INTEGER, diff INTEGER);
  TYPE b_lis_type   IS  VARRAY(32767) OF b_rec_type;
  l_b_lis               b_lis_type := b_lis_type(NULL);
  l_bra_lis             bra_lis_type := bra_lis_type();
  n_b                   PLS_INTEGER := 0;
  n_ob                  PLS_INTEGER := 0;
  n_cb                  PLS_INTEGER := 0;
  l_chr                 VARCHAR2(1);
  l_o_diff              PLS_INTEGER;
BEGIN

  IF c_n_ob = 0 THEN
    RETURN NULL;
  END IF;
  l_ob_lis.EXTEND (c_n_ob);
  l_bra_lis.EXTEND (c_n_ob);
  l_cb_lis.EXTEND (c_n_ob);
  l_b_lis.EXTEND (c_n_ob + c_n_ob);
 
  FOR i IN 1..Length (p_str) LOOP
 
    l_chr := Substr (p_str, i, 1);
    IF l_chr NOT IN ('(', ')') THEN CONTINUE; END IF;

    n_b := n_b + 1;
    l_b_lis(n_b).pos := i;
 
    IF l_chr = '(' THEN
      n_ob := n_ob + 1;
      l_ob_lis(n_ob) := n_b;
    ELSE
      n_cb := n_cb + 1;
      l_cb_lis(n_cb) := n_b;
    END IF;

    l_b_lis(n_b).diff := n_ob - n_cb;
 
  END LOOP;

  FOR i IN 1..n_ob LOOP

    l_o_diff := l_b_lis (l_ob_lis(i)).diff;
    FOR j IN 1..n_cb LOOP

      IF l_b_lis (l_cb_lis(j)).pos < l_b_lis (l_ob_lis(i)).pos THEN CONTINUE; END IF;
      IF l_o_diff = l_b_lis (l_cb_lis(j)).diff + 1 THEN

        l_bra_lis(i) := bra_rec_type (l_b_lis(l_ob_lis(i)).pos, l_b_lis(l_cb_lis(j)).pos, Substr (p_str, l_b_lis(l_ob_lis(i)).pos, l_b_lis(l_cb_lis(j)).pos - l_b_lis(l_ob_lis(i)).pos + 1));
        EXIT;

      END IF;

    END LOOP;
 
  END LOOP;
  RETURN l_bra_lis;

END;
SELECT
    b.id, t.o_pos, t.c_pos, t.str
  FROM bracket_strings b
  OUTER APPLY TABLE (Parse_Brackets (b.str)) t
 ORDER BY 1, 2

Notes on WFB_QRY

This uses the v12.1 feature whereby a PL/SQL function can be included directly in a query.

Pipelined PL/SQL Function, Arrays Query (PFB_QRY)

WFB_QRY - Pipelined Function

CREATE OR REPLACE TYPE bra_rec_type IS OBJECT (o_pos INTEGER, c_pos INTEGER, str VARCHAR2(4000));
/
CREATE TYPE bra_lis_type IS VARRAY(4000) OF bra_rec_type;
/
FUNCTION Parse_Brackets (p_str VARCHAR2) RETURN bra_lis_type PIPELINED IS
  c_n_ob       CONSTANT PLS_INTEGER := Length (p_str) - Length (Replace (p_str, '(', ''));
  l_ob_lis              SYS.ODCINumberList := SYS.ODCINumberList();
  l_cb_lis              SYS.ODCINumberList := SYS.ODCINumberList();
  TYPE b_rec_type   IS  RECORD (pos INTEGER, diff INTEGER);
  TYPE b_lis_type   IS  VARRAY(32767) OF b_rec_type;
  l_b_lis               b_lis_type := b_lis_type(NULL);
  l_bra_lis             bra_lis_type := bra_lis_type();
  n_b                   PLS_INTEGER := 0;
  n_ob                  PLS_INTEGER := 0;
  n_cb                  PLS_INTEGER := 0;
  l_chr                 VARCHAR2(1);
  l_o_diff              PLS_INTEGER;
BEGIN

  IF c_n_ob = 0 THEN
    RETURN;
  END IF;
  l_ob_lis.EXTEND (c_n_ob);
  l_bra_lis.EXTEND (c_n_ob);
  l_cb_lis.EXTEND (c_n_ob);
  l_b_lis.EXTEND (c_n_ob + c_n_ob);
 
  FOR i IN 1..Length (p_str) LOOP
 
    l_chr := Substr (p_str, i, 1);
    IF l_chr NOT IN ('(', ')') THEN CONTINUE; END IF;

    n_b := n_b + 1;
    l_b_lis(n_b).pos := i;
 
    IF l_chr = '(' THEN
      n_ob := n_ob + 1;
      l_ob_lis(n_ob) := n_b;
    ELSE
      n_cb := n_cb + 1;
      l_cb_lis(n_cb) := n_b;
    END IF;

    l_b_lis(n_b).diff := n_ob - n_cb;
 
  END LOOP;

  FOR i IN 1..n_ob LOOP

    l_o_diff := l_b_lis (l_ob_lis(i)).diff;
    FOR j IN 1..n_cb LOOP

      IF l_b_lis (l_cb_lis(j)).pos < l_b_lis (l_ob_lis(i)).pos THEN CONTINUE; END IF;
      IF l_o_diff = l_b_lis (l_cb_lis(j)).diff + 1 THEN

        PIPE ROW (bra_rec_type (l_b_lis(l_ob_lis(i)).pos, l_b_lis(l_cb_lis(j)).pos, Substr (p_str, l_b_lis(l_ob_lis(i)).pos, l_b_lis(l_cb_lis(j)).pos - l_b_lis(l_ob_lis(i)).pos + 1)));
        EXIT;

      END IF;

    END LOOP;
 
  END LOOP;

END Parse_Brackets;

Plan hash value: 3367347570

---------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                            | Name            | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
---------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                     |                 |      1 |        |  40000 |00:00:01.17 |      38 |       |       |          |
|   1 |  SORT ORDER BY                       |                 |      1 |    816K|  40000 |00:00:01.17 |      38 |    21M|  1702K|   19M (0)|
|   2 |   NESTED LOOPS OUTER                 |                 |      1 |    816K|  40000 |00:00:16.80 |      38 |       |       |          |
|   3 |    TABLE ACCESS FULL                 | BRACKET_STRINGS |      1 |    100 |    100 |00:00:00.01 |      38 |       |       |          |
|   4 |    VIEW                              | VW_LAT_D4FD8C38 |    100 |   8168 |  40000 |00:00:01.13 |       0 |       |       |          |
|   5 |     COLLECTION ITERATOR PICKLER FETCH| PARSE_BRACKETS  |    100 |   8168 |  40000 |00:00:01.10 |       0 |       |       |          |
---------------------------------------------------------------------------------------------------------------------------------------------

PFB_QRY - Query

SELECT  /*+ PFB_QRY gather_plan_statistics */
        b.id        id, 
        t.o_pos     o_pos, 
        t.c_pos     c_pos,
        t.str       str
  FROM bracket_strings b
  OUTER APPLY TABLE (Strings.Parse_Brackets (b.str)) t
 ORDER BY b.id, t.o_pos

Plan hash value: 3367347570

---------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                            | Name            | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
---------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                     |                 |      1 |        |  40000 |00:00:01.15 |      38 |       |       |          |
|   1 |  SORT ORDER BY                       |                 |      1 |    816K|  40000 |00:00:01.15 |      38 |    21M|  1702K|   19M (0)|
|   2 |   NESTED LOOPS OUTER                 |                 |      1 |    816K|  40000 |00:00:01.95 |      38 |       |       |          |
|   3 |    TABLE ACCESS FULL                 | BRACKET_STRINGS |      1 |    100 |    100 |00:00:00.01 |      38 |       |       |          |
|   4 |    VIEW                              | VW_LAT_D4FD8C38 |    100 |   8168 |  40000 |00:00:01.51 |       0 |       |       |          |
|   5 |     COLLECTION ITERATOR PICKLER FETCH| PARSE_BRACKETS  |    100 |   8168 |  40000 |00:00:01.50 |       0 |       |       |          |
---------------------------------------------------------------------------------------------------------------------------------------------

Notes on PFB_QRY

This uses PL/SQL pipelined database function which is called in the query.

Performance Testing Results

Key

If CPU time (y) is proportional to the varying dimension (x), for data points 1 and 2, we would have:

y = kx

and so, for any two data points 1 and 2:

y2.x1/(y1.x2) = 1

We can take the actual value of the linear ratio as a marker for linear proportionality or not.

If CPU time (y) is proportional to the varying dimension (x), for data points 1 and 2, we would have:

y = kx.x

and so, for any two data points 1 and 2:

y2.x1.x1/(y1.x2.x2) = 1

We can take the actual value of the quadratic ratio as a marker for quadratic proportionality or not.

  • LRTB = Ratio to best time at high data point
  • RTP_L = Linear ratio as defined above, averaged over successive data points
  • RTP_Q = Quadratic ratio as defined above, averaged over successive data points

Depth fixed, at small width point; width varies: d=100, w=(100, 200, 300, 400)

Notes on Results for Fixed Depth

  • CPU time increases with width for all queries at above a linear rate
  • CBL_QRY is significantly faster than MRB_QRY, which appears to be rising quadratically
  • Both WFB_QRY and PFB_QRY are much faster than the non-PL/SQL queries
  • PFB_QRY is slightly faster than WFB_QRY. This could be regarded as too small a difference to be significant, but is consistent across the data points, despite the context switching with database function calls

Width fixed at high depth point; depth varies: w=400, d=(0, 100, 200, 300, 400)

Notes on Results for Fixed Width

  • CPU time increases with depth for all queries although at a sublinear rate
  • CBL_QRY has a big jump in CPU time between 0 and 100, where nesting starts to come in, and was actually faster than CBL_QRY without nesting






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 20101, 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.

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                                                                188094
54739            1       2      0 54739                                                                  ROOT
                                1 > 57560                                                                188095
54756           28       8      0 54756                                                                  ROOT
                                1 > 57561                                                                188096
                                2   > 57562                                                              188098
                                3     < 54756*                                                           188097                                 3     > 57563                                                            188101
                                4       < 54756*                                                         188099
                                4       < 57561*                                                         188100                                 4       > 57564                                                          188105
                                5         < 54756*                                                       188102
                                5         < 57561*                                                       188103
                                5         < 57562*                                                       188104                                 5         > 57565                                                        188110
                                6           < 54756*                                                     188106
                                6           < 57561*                                                     188107
                                6           < 57562*                                                     188108
                                6           < 57563*                                                     188109                                 6           > 57566                                                      188116
                                7             < 54756*                                                   188111
                                7             < 57561*                                                   188112
                                7             < 57562*                                                   188113
                                7             < 57563*                                                   188114
                                7             < 57564*                                                   188115                                 7             > 57567                                                    188123
                                8               < 54756*                                                 188117
                                8               < 57561*                                                 188118
                                8               < 57562*                                                 188119
                                8               < 57563*                                                 188120
                                8               < 57564*                                                 188121
                                8               < 57565*                                                 188122 54758            2       3      0 54758                                                                  ROOT                                 1 > 57568                                                                188124
                                1 > 57569                                                                188125
54765            1       2      0 54765                                                                  ROOT
                                1 > 57572                                                                188128
54841            1       2      0 54841                                                                  ROOT
                                1 > 57592                                                                188148
54864            1       2      0 54864                                                                  ROOT
                                1 > 57605                                                                188164
54871            1       2      0 54871                                                                  ROOT
                                1 > 54872                                                                197423
54896            1       2      0 54896                                                                  ROOT
                                1 > 57606                                                                188165
54897            1       2      0 54897                                                                  ROOT
                                1 > 57607                                                                188166
54974            1       2      0 54974                                                                  ROOT
                                1 > 54975                                                                197541
55071            1       2      0 55071                                                                  ROOT
                                1 > 57623                                                                188181
55081            2       3      0 55081                                                                  ROOT
                                1 > 57624                                                                188182
                                1 > 57625                                                                188183
55082            2       3      0 55082                                                                  ROOT
                                1 > 57627                                                                188184
                                1 > 57628                                                                188185
55204            1       2      0 55204                                                                  ROOT
                                1 > 57647                                                                188205
55205            1       2      0 55205                                                                  ROOT
                                1 > 55207                                                                199011
55206            6       4      0 55206                                                                  ROOT
                                1 > 57648                                                                188206
                                2   > 57649                                                              188208
                                3     < 55206*                                                           188207                                 3     > 57650                                                            188211
                                4       < 55206*                                                         188209
                                4       < 57648*                                                         188210 55410            1       2      0 55410                                                                  ROOT                                 1 > 57683                                                                188245
55411            1       2      0 55411                                                                  ROOT
                                1 > 57684                                                                188246
55412            1       2      0 55412                                                                  ROOT
                                1 > 57685                                                                188247
55415            1       2      0 55415                                                                  ROOT
                                1 > 57686                                                                188248
55416            1       2      0 55416                                                                  ROOT
                                1 > 57688                                                                188249
55417            2       3      0 55417                                                                  ROOT
                                1 > 57690                                                                188250
                                2   > 58082                                                              188700
55418            1       2      0 55418                                                                  ROOT
                                1 > 57691                                                                188251
55420            2       3      0 55420                                                                  ROOT
                                1 > 57693                                                                188252
                                2   > 58084                                                              188702
55421            1       2      0 55421                                                                  ROOT
                                1 > 57694                                                                188253
55422            1       2      0 55422                                                                  ROOT
                                1 > 57695                                                                188254
55424            5       5      0 55424                                                                  ROOT
                                1 > 55428                                                                185685
                                2   > 55429                                                              185687
                                3     < 55424*                                                           185686                                 1 > 55430                                                                185688
                                1 > 55431                                                                185689
55425            3       3      0 55425                                                                  ROOT
                                1 > 55426                                                                185682
                                2   > 55427                                                              185684
                                3     < 55425*                                                           185683 55432            1       2      0 55432                                                                  ROOT                                 1 > 57697                                                                188255
55434            2       3      0 55434                                                                  ROOT
                                1 > 57699                                                                188256
                                1 > 57700                                                                188257
55436            1       2      0 55436                                                                  ROOT
                                1 > 57701                                                                188258
55437            1       2      0 55437                                                                  ROOT
                                1 > 57702                                                                188259
55439            2       3      0 55439                                                                  ROOT
                                1 > 57703                                                                188260
                                2   > 58087                                                              188705
55440            1       2      0 55440                                                                  ROOT
                                1 > 55441                                                                185692
55442            1       2      0 55442                                                                  ROOT
                                1 > 57704                                                                188261
55532            1       2      0 55532                                                                  ROOT
                                1 > 57728                                                                188310
55607            1       2      0 55607                                                                  ROOT
                                1 > 57747                                                                188335
55639            1       2      0 55639                                                                  ROOT
                                1 > 57754                                                                188342
55654            1       2      0 55654                                                                  ROOT
                                1 > 57756                                                                188344
55871            2       3      0 55871                                                                  ROOT
                                1 > 57790                                                                188378
                                1 > 57791                                                                188379
55942            1       2      0 55942                                                                  ROOT
                                1 > 57801                                                                188391
56020            3       3      0 56020                                                                  ROOT
                                1 > 57816                                                                188412
                                2   > 57817                                                              188414
                                3     < 56020*                                                           188413 56090            3       4      0 56090                                                                  ROOT                                 1 > 57825                                                                188422
                                2   > 58114                                                              188733
                                2   > 58115                                                              188734
56126            1       2      0 56126                                                                  ROOT
                                1 > 57828                                                                188425
56143            1       2      0 56143                                                                  ROOT
                                1 > 57831                                                                188428
56144            3       3      0 56144                                                                  ROOT
                                1 > 57832                                                                188429
                                2   > 57833                                                              188431
                                3     < 56144*                                                           188430 56150            3       4      0 56150                                                                  ROOT                                 1 > 57834                                                                188432
                                1 > 57835                                                                188433
                                1 > 57836                                                                188434
56185            1       2      0 56185                                                                  ROOT
                                1 > 57841                                                                188439
56221            1       2      0 56221                                                                  ROOT
                                1 > 57846                                                                188444
56315            1       2      0 56315                                                                  ROOT
                                1 > 57851                                                                188449
56420            1       2      0 56420                                                                  ROOT
                                1 > 56421                                                                186822
56587            6       6      0 56587                                                                  ROOT
                                1 > 57889                                                                188490
                                2   > 58126                                                              188744
                                3     > 58127                                                            188746
                                4       < 57889*                                                         188745                                 4       > 58184                                                          188826
                                1 > 57890                                                                188491
56747            4       5      0 56747                                                                  ROOT
                                1 > 57916                                                                188518
                                2   > 58136                                                              188756
                                3     > 58186                                                            188828
                                2   > 58137                                                              188757
56787            1       2      0 56787                                                                  ROOT
                                1 > 57921                                                                188523
56817            1       2      0 56817                                                                  ROOT
                                1 > 57924                                                                188526
56819            1       2      0 56819                                                                  ROOT
                                1 > 57925                                                                188527
56855            2       3      0 56855                                                                  ROOT
                                1 > 57933                                                                188535
                                2   > 58139                                                              188759
56888            1       2      0 56888                                                                  ROOT
                                1 > 56889                                                                187359
56890            1       2      0 56890                                                                  ROOT
                                1 > 57943                                                                188545
57068            1       2      0 57068                                                                  ROOT
                                1 > 57963                                                                188564
57073            2       3      0 57073                                                                  ROOT
                                1 > 57964                                                                188565
                                1 > 57965                                                                188566
57074            5       5      0 57074                                                                  ROOT
                                1 > 57966                                                                188567
                                1 > 57967                                                                188568
                                2   > 57968                                                              188570
                                3     < 57074*                                                           188569                                 2   > 58150                                                              188771
57258            1       2      0 57258                                                                  ROOT
                                1 > 58007                                                                188613
57308            1       2      0 57308                                                                  ROOT
                                1 > 58017                                                                188623
57319            2       3      0 57319                                                                  ROOT
                                1 > 58018                                                                188624
                                2   > 58171                                                              188814
57359            3       3      0 57359                                                                  ROOT
                                1 > 58024                                                                188630
                                2   > 58025                                                              188632
                                3     < 57359*                                                           188631 57364            1       2      0 57364                                                                  ROOT                                 1 > 58026                                                                188633
57406            1       2      0 57406                                                                  ROOT
                                1 > 58042                                                                188654
57412            1       2      0 57412                                                                  ROOT
                                1 > 58046                                                                188657
57413            1       2      0 57413                                                                  ROOT
                                1 > 58047                                                                188658
57458            1       2      0 57458                                                                  ROOT
                                1 > 58050                                                                188661
57546            1       2      0 57546                                                                  ROOT
                                1 > 57547                                                                188082
57551            1       2      0 57551                                                                  ROOT
                                1 > 58057                                                                188669
57582            3       3      0 57582                                                                  ROOT
                                1 > 58063                                                                188678
                                2   > 58064                                                              188680
                                3     < 57582*                                                           188679 57591            2       3      0 57591                                                                  ROOT                                 1 > 58065                                                                188681
                                1 > 58066                                                                188682
57613            1       2      0 57613                                                                  ROOT
                                1 > 58069                                                                188685
57626            4       4      0 57626                                                                  ROOT
                                1 > 58072                                                                188688
                                2   > 58073                                                              188690
                                3     < 57626*                                                           188689                                 1 > 58074                                                                188691
57687            3       4      0 57687                                                                  ROOT
                                1 > 58080                                                                188698
                                2   > 58175                                                              188818
                                3     > 58213                                                            185391
57689            2       3      0 57689                                                                  ROOT
                                1 > 58081                                                                188699
                                2   > 58176                                                              188819
57692            2       3      0 57692                                                                  ROOT
                                1 > 58083                                                                188701
                                2   > 58177                                                              188820
57696            1       2      0 57696                                                                  ROOT
                                1 > 58085                                                                188703
57698            1       2      0 57698                                                                  ROOT
                                1 > 58086                                                                188704
57824            1       2      0 57824                                                                  ROOT
                                1 > 58113                                                                188732
57953            5       5      0 57953                                                                  ROOT
                                1 > 58142                                                                188762
                                2   > 58143                                                              188764
                                3     < 57953*                                                           188763                                 2   > 58189                                                              188831
                                2   > 58190                                                              188832
58033            1       2      0 58033                                                                  ROOT
                                1 > 58172                                                                188815
58045            1       2      0 58045                                                                  ROOT
                                1 > 58174                                                                188817
58090            1       2      0 58090                                                                  ROOT
                                1 > 58178                                                                188821
58118            1       2      0 58118                                                                  ROOT
                                1 > 58119                                                                188737
58182            3       3      0 58182                                                                  ROOT
                                1 > 58183                                                                188825
                                2   > 58214                                                              185393
                                3     < 58182*                                                           185392 6542             1       2      0 6542                                                                   ROOT                                 1 > 6544                                                                 54707

214625 rows selected.

Elapsed: 00:01:42.58
Network summary 1 - by network

Network     #Links  #Nodes    Max Lev
---------- ------- ------- ----------
10020            2       2          1
10454            2       2          1
10541            2       2          1
10569            2       2          1
10572            2       2          1
11136            2       2          1
11686            2       2          1
11713            2       2          1
11770            2       2          1
11802            2       2          1
11831            2       2          1
12004            2       2          1
12095            2       2          1
12592            2       2          1
12593            2       2          1
12601            2       2          1
12709            2       2          1
12780            2       2          1
13150            2       2          1
13237            2       2          1
13277            2       2          1
13409            2       2          1
13423            2       2          1
13508            2       2          1
13516            2       2          1
13519            2       2          1
13521            2       2          1
14692            2       2          1
15577            2       2          1
15636            2       2          1
15670            2       2          1
15689            2       2          1
16794            2       2          1
16827            2       2          1
17012            2       2          1
1704             2       2          1
17047            2       2          1
17062            2       2          1
17074            2       2          1
17287            2       2          1
1731             2       2          1
18379            2       2          1
18776            2       2          1
19029            2       2          1
19925            2       2          1
20137            2       2          1
20149            2       2          1
20150            2       2          1
21785            2       2          1
21795            2       2          1
22211            2       2          1
22850            2       2          1
24435            2       2          1
24477            2       2          1
24642            2       2          1
26072            2       2          1
26403            2       2          1
26418            2       2          1
26641            2       2          1
26744            2       2          1
26766            2       2          1
26803            2       2          1
26977            2       2          1
26979            2       2          1
27113            2       2          1
27134            2       2          1
27342            2       2          1
27442            2       2          1
27481            2       2          1
27487            2       2          1
27545            2       2          1
27548            2       2          1
27737            2       2          1
27763            2       2          1
27765            2       2          1
27788            2       2          1
27789            2       2          1
27790            2       2          1
27831            2       2          1
27838            2       2          1
27880            2       2          1
27882            2       2          1
27888            2       2          1
27894            2       2          1
27897            2       2          1
27915            2       2          1
27943            2       2          1
27960            2       2          1
28061            2       2          1
28073            2       2          1
28125            2       2          1
28145            2       2          1
28192            2       2          1
28211            2       2          1
28430            2       2          1
28517            2       2          1
28531            2       2          1
28547            2       2          1
28548            2       2          1
28551            2       2          1
28557            2       2          1
28560            2       2          1
28826            2       2          1
28842            2       2          1
28891            2       2          1
29117            2       2          1
29759            2       2          1
29850            2       2          1
29851            2       2          1
29852            2       2          1
29867            2       2          1
29876            2       2          1
29893            2       2          1
29895            2       2          1
29916            2       2          1
30075            2       2          1
30473            2       2          1
34215            2       2          1
35114            2       2          1
35129            2       2          1
35196            2       2          1
35299            2       2          1
35302            2       2          1
35326            2       2          1
35381            2       2          1
35394            2       2          1
35456            2       2          1
35464            2       2          1
35474            2       2          1
35481            2       2          1
35558            2       2          1
35608            2       2          1
35609            2       2          1
35748            2       2          1
35751            2       2          1
35755            2       2          1
35759            2       2          1
35763            2       2          1
35766            2       2          1
35767            2       2          1
35769            2       2          1
35784            2       2          1
35803            2       2          1
35953            2       2          1
36004            2       2          1
36008            2       2          1
36022            2       2          1
36033            2       2          1
36272            2       2          1
36375            2       2          1
36378            2       2          1
36385            2       2          1
36399            2       2          1
36405            2       2          1
36533            2       2          1
36612            2       2          1
36821            2       2          1
36919            2       2          1
36981            2       2          1
37084            2       2          1
37108            2       2          1
37247            2       2          1
37277            2       2          1
37346            2       2          1
37348            2       2          1
37351            2       2          1
37420            2       2          1
37421            2       2          1
37515            2       2          1
37516            2       2          1
37585            2       2          1
37689            2       2          1
37715            2       2          1
37916            2       2          1
37953            2       2          1
38033            2       2          1
38066            2       2          1
38281            2       2          1
38328            2       2          1
38829            2       2          1
38856            2       2          1
39024            2       2          1
39188            2       2          1
39294            2       2          1
39619            2       2          1
39628            2       2          1
39723            2       2          1
39736            2       2          1
39762            2       2          1
39785            2       2          1
39820            2       2          1
39979            2       2          1
40137            2       2          1
40189            2       2          1
40326            2       2          1
40365            2       2          1
40368            2       2          1
40377            2       2          1
40813            2       2          1
40814            2       2          1
40842            2       2          1
40847            2       2          1
40853            2       2          1
40859            2       2          1
40880            2       2          1
40882            2       2          1
40886            2       2          1
40907            2       2          1
40918            2       2          1
40925            2       2          1
40927            2       2          1
41026            2       2          1
41172            2       2          1
41212            2       2          1
41312            2       2          1
41342            2       2          1
41354            2       2          1
41599            2       2          1
41919            2       2          1
41992            2       2          1
42002            2       2          1
42003            2       2          1
42033            2       2          1
42186            2       2          1
42252            2       2          1
42494            2       2          1
42517            2       2          1
43584            2       2          1
43749            2       2          1
43955            2       2          1
44008            2       2          1
44011            2       2          1
44017            2       2          1
44023            2       2          1
44084            2       2          1
44086            2       2          1
44091            2       2          1
44122            2       2          1
44123            2       2          1
44191            2       2          1
44201            2       2          1
44250            2       2          1
44251            2       2          1
44274            2       2          1
45010            2       2          1
45014            2       2          1
45052            2       2          1
45101            2       2          1
45690            2       2          1
45913            2       2          1
46025            2       2          1
46127            2       2          1
46455            2       2          1
46770            2       2          1
46932            2       2          1
47011            2       2          1
47267            2       2          1
47277            2       2          1
47364            2       2          1
47436            2       2          1
47486            2       2          1
48021            2       2          1
48035            2       2          1
48504            2       2          1
48664            2       2          1
48913            2       2          1
49284            2       2          1
49552            2       2          1
49878            2       2          1
50504            2       2          1
50530            2       2          1
50610            2       2          1
50691            2       2          1
50728            2       2          1
50729            2       2          1
50746            2       2          1
50806            2       2          1
51082            2       2          1
51095            2       2          1
51294            2       2          1
51295            2       2          1
51358            2       2          1
51407            2       2          1
51575            2       2          1
51778            2       2          1
51903            2       2          1
52712            2       2          1
53283            2       2          1
53490            2       2          1
53514            2       2          1
53622            2       2          1
53623            2       2          1
53698            2       2          1
53712            2       2          1
53824            2       2          1
53839            2       2          1
53999            2       2          1
54715            2       2          1
54719            2       2          1
54720            2       2          1
54721            2       2          1
54723            2       2          1
54737            2       2          1
54739            2       2          1
54765            2       2          1
54841            2       2          1
54864            2       2          1
54871            2       2          1
54896            2       2          1
54897            2       2          1
54974            2       2          1
55071            2       2          1
55204            2       2          1
55205            2       2          1
55410            2       2          1
55411            2       2          1
55412            2       2          1
55415            2       2          1
55416            2       2          1
55418            2       2          1
55421            2       2          1
55422            2       2          1
55432            2       2          1
55436            2       2          1
55437            2       2          1
55440            2       2          1
55442            2       2          1
55532            2       2          1
55607            2       2          1
55639            2       2          1
55654            2       2          1
55942            2       2          1
56126            2       2          1
56143            2       2          1
56185            2       2          1
56221            2       2          1
56315            2       2          1
56420            2       2          1
56787            2       2          1
56817            2       2          1
56819            2       2          1
56888            2       2          1
56890            2       2          1
57068            2       2          1
57258            2       2          1
57308            2       2          1
57364            2       2          1
57406            2       2          1
57412            2       2          1
57413            2       2          1
57458            2       2          1
57546            2       2          1
57551            2       2          1
57613            2       2          1
57696            2       2          1
57698            2       2          1
57824            2       2          1
58033            2       2          1
58045            2       2          1
58090            2       2          1
58118            2       2          1
6542             2       2          1
12145            3       3          1
13125            3       3          2
13152            3       3          1
13544            3       3          2
13608            3       3          1
13708            3       3          2
1469             3       3          2
15658            3       3          2
15663            3       3          1
16399            3       3          1
16525            3       3          1
16526            3       3          1
16825            3       3          2
17256            3       3          1
17401            3       3          1
17459            3       3          1
19907            3       3          2
20143            3       3          1
27336            3       3          2
27771            3       3          1
27844            3       3          1
27933            3       3          1
28297            3       3          1
45505            3       3          2
46639            3       3          1
48980            3       3          2
49595            3       3          2
50805            3       3          2
50885            3       3          2
51020            3       3          2
51439            3       3          1
51696            3       3          1
51697            3       3          1
53510            3       3          1
53618            3       3          2
53853            3       3          1
54087            3       3          2
54758            3       3          1
55081            3       3          1
55082            3       3          1
55417            3       3          2
55420            3       3          2
55434            3       3          1
55439            3       3          2
55871            3       3          1
56855            3       3          2
57073            3       3          1
57319            3       3          2
57591            3       3          1
57689            3       3          2
57692            3       3          2
28527            3       3          1
28607            3       3          1
28894            3       3          1
29901            3       3          1
31960            3       3          2
32410            3       3          2
33215            3       3          1
35283            3       3          1
35378            3       3          1
35440            3       3          2
35484            3       3          1
35540            3       3          1
35581            3       3          1
35772            3       3          1
35781            3       3          2
35938            3       3          1
36382            3       3          2
36652            3       3          2
37044            3       3          2
39775            3       3          2
40212            3       3          1
40879            3       3          1
40890            3       3          2
41608            3       3          2
42474            3       3          2
43805            3       3          1
43968            3       3          2
43977            3       3          2
44009            3       3          2
44189            3       3          2
44203            3       3          2
44231            3       3          1
11030            3       3          1
11053            3       3          1
11778            3       3          1
12115            3       3          2
50472            4       3          3
54676            4       4          1
55425            4       3          3
56020            4       3          3
56090            4       4          2
56144            4       3          3
56150            4       4          1
57359            4       3          3
57582            4       3          3
57687            4       4          3
58182            4       3          3
29341            4       3          3
29853            4       4          1
29858            4       3          3
34428            4       4          2
35189            4       4          2
36031            4       4          2
36253            4       4          2
36328            4       4          1
39741            4       4          1
40009            4       3          3
40856            4       4          3
40926            4       4          1
41304            4       4          1
43247            4       4          2
44013            4       3          3
44128            4       4          3
10061            4       4          2
11615            4       3          3
11982            4       4          2
13188            4       4          2
13441            4       4          1
13542            4       4          2
13846            4       3          3
15579            4       3          3
17084            4       4          2
18476            4       3          3
22386            4       4          1
26630            4       4          2
27761            4       3          3
28518            4       4          1
28522            4       4          2
28523            4       4          2
40325            5       5          2
48614            5       5          2
37270            5       4          3
36965            5       4          3
22949            5       4          3
36006            5       5          2
54736            5       5          2
35661            5       5          3
29902            5       4          3
11945            5       4          3
27187            5       5          3
53799            5       5          2
40898            5       4          4
56747            5       5          3
27542            5       4          3
57626            5       4          3
12063            5       4          3
40896            5       4          4
36185            6       5          4
20119            6       6          2
29898            6       5          4
29024            6       6          2
57953            6       5          3
57074            6       5          3
55424            6       5          3
27490            6       5          4
21823            6       4          4
24937            6       5          3
50508            6       6          1
13813            6       4          4
13321            6       6          2
11687            6       5          4
15675            7       6          3
55206            7       4          4
18420            7       6          3
27572            7       7          2
56587            7       6          4
27988            7       7          2
54678            8       5          4
12781            8       5          4
54724            9       5          5
26460           10       7          5
40917           10       9          4
44308           10       5          5
13496           11       8          5
35790           11      11          3
54711           11       5          5
37342           11       6          4
11628           14      10          5
54481           15       6          6
27621           26      10          9
43942           28      11          9
54756           29       8          8
51944           95      49         11
0           212946   56739      15225

547 rows selected.

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

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

12 rows selected.

Elapsed: 00:00:23.13






SQL for the Balanced Number Partitioning Problem

I noticed a post on AskTom recently that referred to an SQL solution to a version of the so-called Bin Fitting problem, where even distribution is the aim. The solution, How do I solve a Bin Fitting problem in an SQL statement?, uses Oracle's Model clause, and, as the poster of the link observed, has the drawback that the number of bins is embedded in the query structure. I thought it might be interesting to find solutions without that drawback, so that the number of bins could be passed to the query as a bind variable. I came up with three solutions using different techniques, starting here.

An interesting article in American Scientist, The Easiest Hard Problem, notes that the problem is NP-complete, or certifiably hard, but that simple greedy heuristics often produce a good solution, including one used by schoolboys to pick football teams. The article uses the more descriptive term for the problem of balanced number partitioning, and notes some practical applications. The Model clause solution implements a multiple-bin version of the main Greedy Algorithm, while my non-Model SQL solutions implement variants of it that allow other techniques to be used, one of which is very simple and fast: this implements the team picking heuristic for multiple teams.

Another poster, Stew Ashton, suggested a simple change to my Model solution that improved performance, and I use this modified version here. He also suggested that using PL/SQL might be faster, and I have added my own simple PL/SQL implementation of the Greedy Algorithm, as well as a second version of the recursive subquery factoring solution that performs better than the first.

This article explains the solutions, considers two simple examples to illustrate them, and reports on performance testing across dimensions of number of items and number of bins. These show that the solutions exhibit either linear or quadratic variation in execution time with number of items, and some methods are sensitive to the number of bins while others are not.

After I had posted my solutions on the AskTom thread, I came across a thread on OTN, need help to resolve this issue, that requested a solution to a form of bin fitting problem where the bins have fixed capacity and the number of bins required must be determined. I realised that my solutions could easily be extended to add that feature, and posted extended versions of two of the solutions there. I have added a section here for this.

Updated, 5 June 2013: added Model and RSF diagrams

Greedy Algorithm Variants

Say there are N bins and M items.

Greedy Algorithm (GDY)
Set bin sizes zero
Loop over items in descending order of size

  • Add item to current smallest bin
  • Calculate new bin size

End Loop

Greedy Algorithm with Batched Rebalancing (GBR)
Set bin sizes zero
Loop over items in descending order of size in batches of N items

  • Assign batch to N bins, with bins in ascending order of size
  • Calculate new bin sizes

End Loop

Greedy Algorithm with No Rebalancing - or, Team Picking Algorithm (TPA)
Assign items to bins cyclically by bin sequence in descending order of item size

Two Examples

Example: Four Items
Binfit, v1.3 - 4-items
Here we see that the Greedy Algorithm finds the perfect solution, with no difference in bin size, but the two variants have a difference of two.
Example: Six Items
Binfit, v1.3 - 6-items
Here we see that none of the algorithms finds the perfect solution. Both the standard Greedy Algorithm and its batched variant give a difference of two, while the variant without rebalancing gives a difference of four.

SQL Solutions

Original Model for GDY
See the link above for the SQL for the problem with three bins only.

The author has two measures for each bin and implements the GDY algorithm using CASE expressions and aggregation within the rules. The idea is to iterate over the items in descending order of size, setting the item bin to the bin with current smallest value. I use the word 'bin' for his 'bucket'. Some notes:

  • Dimension by row number, ordered by item value
  • Add measures for the iteration, it, and number of iterations required, counter
  • Add measures for the bin name, bucket_name, and current minimum bin value, min_tmp (only first entry used)
  • Add measures for each item bin value, bucket_1-3, being the item value if it's in that bin, else zero
  • Add measures for each bin running sum, pbucket_1-3, being the current value of each bin (only first two entries used)
  • The current minimum bin value, bin_tmp[1] is computed as the least of the running sums
  • The current item bin value is set to the item value for the bin whose value matches the minimum just computed, and null for the others
  • The current bin name is set similarly to be the bin matching the minimum
  • The new running sums are computed for each bin

Brendan's Generic Model for GDY

SELECT item_name, bin, item_value, Max (bin_value) OVER (PARTITION BY bin) bin_value
  FROM (
SELECT * FROM items
  MODEL 
    DIMENSION BY (Row_Number() OVER (ORDER BY item_value DESC) rn)
    MEASURES (item_name, 
              item_value,
              Row_Number() OVER (ORDER BY item_value DESC) bin,
              item_value bin_value,
              Row_Number() OVER (ORDER BY item_value DESC) rn_m,
              0 min_bin,
              Count(*) OVER () - :N_BINS - 1 n_iters
    )
    RULES ITERATE(100000) UNTIL (ITERATION_NUMBER >= n_iters[1]) (
      min_bin[1] = Min(rn_m) KEEP (DENSE_RANK FIRST ORDER BY bin_value)[rn <= :N_BINS],
      bin[ITERATION_NUMBER + :N_BINS + 1] = min_bin[1],
      bin_value[min_bin[1]] = bin_value[CV()] + Nvl (item_value[ITERATION_NUMBER + :N_BINS + 1], 0)
    )
)
 WHERE item_name IS NOT NULL
 ORDER BY item_value DESC

My Model solution works for any number of bins, passing the number of bins as a bind variable. The key idea here is to use values in the first N rows of a generic bin value measure to store all the running bin values, rather than as individual measures. I have included two modifications suggested by Stew in the AskTom thread.

  • Dimension by row number, ordered by item value
  • Initialise a bin measure to the row number (the first N items will remain fixed)
  • Initialise a bin value measure to item value (only first N entries used)
  • Add the row number as a measure, rn_m, in addition to a dimension, for referencing purposes
  • Add a min_bin measure for current minimum bin index (first entry only)
  • Add a measure for the number of iterations required, n_iters
  • The first N items are correctly binned in the measure initialisation
  • Set the minimum bin index using analytic Min function with KEEP clause over the first N rows of bin value
  • Set the bin for the current item to this index
  • Update the bin value for the corresponding bin only

Binfit, v1.3 - MOD

Recursive Subquery Factor for GBR

WITH bins AS (
       SELECT LEVEL bin, :N_BINS n_bins FROM DUAL CONNECT BY LEVEL <= :N_BINS
), items_desc AS (
       SELECT item_name, item_value, Row_Number () OVER (ORDER BY item_value DESC) rn
         FROM items
), rsf (bin, item_name, item_value, bin_value, lev, bin_rank, n_bins) AS (
SELECT b.bin,
       i.item_name, 
       i.item_value, 
       i.item_value,
       1,
       b.n_bins - i.rn + 1,
       b.n_bins
  FROM bins b
  JOIN items_desc i
    ON i.rn = b.bin
 UNION ALL
SELECT r.bin,
       i.item_name, 
       i.item_value, 
       r.bin_value + i.item_value,
       r.lev + 1,
       Row_Number () OVER (ORDER BY r.bin_value + i.item_value),
       r.n_bins
  FROM rsf r
  JOIN items_desc i
    ON i.rn = r.bin_rank + r.lev * r.n_bins
)
SELECT r.item_name,
       r.bin, r.item_value, r.bin_value
  FROM rsf r
 ORDER BY item_value DESC

The idea here is to use recursive subquery factors to iterate through the items in batches of N items, assigning each item to a bin according to the rank of the bin on the previous iteration.

  • Initial subquery factors form record sets for the bins and for the items with their ranks in descending order of value
  • The anchor branch assign bins to the first N items, assigning the item values to a bin value field, and setting the bin rank in ascending order of this bin value
  • The recursive branch joins the batch of items to the record in the previous batch whose bin rank matches that of the item in the reverse sense (so largest item goes to smallest bin etc.)
  • The analytic Row_Number function computes the updated bin ranks, and the bin values are updated by simple addition

Binfit, v1.3 - RSF

Recursive Subquery Factor for GBR with Temporary Table
Create Table and Index

DROP TABLE items_desc_temp
/
CREATE GLOBAL TEMPORARY TABLE items_desc_temp (
   item_name  VARCHAR2(30) NOT NULL,  
   item_value NUMBER(8) NOT NULL,
   rn         NUMBER
)
ON COMMIT DELETE ROWS
/
CREATE INDEX items_desc_temp_N1 ON items_desc_temp (rn)
/

Insert into Temporary Table

INSERT INTO items_desc_temp
SELECT item_name, item_value, Row_Number () OVER (ORDER BY item_value DESC) rn
  FROM items;

RSF Query with Temporary Table

WITH bins AS (
       SELECT LEVEL bin, :N_BINS n_bins FROM DUAL CONNECT BY LEVEL <= :N_BINS
), rsf (bin, item_name, item_value, bin_value, lev, bin_rank, n_bins) AS (
SELECT b.bin,
       i.item_name, 
       i.item_value, 
       i.item_value,
       1,
       b.n_bins - i.rn + 1,
       b.n_bins
  FROM bins b
  JOIN items_desc_temp i
    ON i.rn = b.bin
 UNION ALL
SELECT r.bin,
       i.item_name, 
       i.item_value, 
       r.bin_value + i.item_value,
       r.lev + 1,
       Row_Number () OVER (ORDER BY r.bin_value + i.item_value),
       r.n_bins
  FROM rsf r
  JOIN items_desc_temp i
    ON i.rn = r.bin_rank + r.lev * r.n_bins
)
SELECT item_name, bin, item_value, bin_value
  FROM rsf
 ORDER BY item_value DESC

The idea here is that in the initial RSF query a subquery factor of items was joined on a calculated field, so the whole record set had to be read, and performance could be improved by putting that initial record set into an indexed temporary table ahead of the main query. We'll see in the performance testing section that this changes quadratic variation with problem size into linear variation.

Plain Old SQL Solution for TPA

WITH items_desc AS (
       SELECT item_name, item_value, 
              Mod (Row_Number () OVER (ORDER BY item_value DESC), :N_BINS) + 1 bin
         FROM items
)
SELECT item_name, bin, item_value, Sum (item_value) OVER (PARTITION BY bin) bin_total
  FROM items_desc
 ORDER BY item_value DESC

The idea here is that the TPA algorithm can be implemented in simple SQL using analyic functions.

  • The subquery factor assigns the bins by taking the item rank in descending order of value and applying the modulo (N) function
  • The main query returns the bin totals in addition by analytic summing by bin

Pipelined Function for GDY
Package

CREATE OR REPLACE PACKAGE Bin_Fit AS

TYPE bin_fit_rec_type IS RECORD (item_name VARCHAR2(100), item_value NUMBER, bin NUMBER);
TYPE bin_fit_list_type IS VARRAY(1000) OF bin_fit_rec_type;

TYPE bin_fit_cur_rec_type IS RECORD (item_name VARCHAR2(100), item_value NUMBER);
TYPE bin_fit_cur_type IS REF CURSOR RETURN bin_fit_cur_rec_type;

FUNCTION Items_Binned (p_items_cur bin_fit_cur_type, p_n_bins PLS_INTEGER) RETURN bin_fit_list_type PIPELINED;

END Bin_Fit;
/
CREATE OR REPLACE PACKAGE BODY Bin_Fit AS

c_big_value                 CONSTANT NUMBER := 100000000;
TYPE bin_fit_cur_list_type  IS VARRAY(100) OF bin_fit_cur_rec_type;

FUNCTION Items_Binned (p_items_cur bin_fit_cur_type, p_n_bins PLS_INTEGER) RETURN bin_fit_list_type PIPELINED IS

  l_min_bin              PLS_INTEGER := 1;
  l_min_bin_val             NUMBER;
  l_bins                    SYS.ODCINumberList := SYS.ODCINumberList();
  l_bin_fit_cur_rec         bin_fit_cur_rec_type;
  l_bin_fit_rec             bin_fit_rec_type;
  l_bin_fit_cur_list        bin_fit_cur_list_type;

BEGIN

  l_bins.Extend (p_n_bins);
  FOR i IN 1..p_n_bins LOOP
    l_bins(i) := 0;
  END LOOP;

  LOOP

    FETCH p_items_cur BULK COLLECT INTO l_bin_fit_cur_list LIMIT 100;
    EXIT WHEN l_bin_fit_cur_list.COUNT = 0;

    FOR j IN 1..l_bin_fit_cur_list.COUNT LOOP

      l_bin_fit_rec.item_name := l_bin_fit_cur_list(j).item_name;
      l_bin_fit_rec.item_value := l_bin_fit_cur_list(j).item_value;
      l_bin_fit_rec.bin := l_min_bin;

      PIPE ROW (l_bin_fit_rec);
      l_bins(l_min_bin) := l_bins(l_min_bin) + l_bin_fit_cur_list(j).item_value;

      l_min_bin_val := c_big_value;
      FOR i IN 1..p_n_bins LOOP

        IF l_bins(i) < l_min_bin_val THEN
          l_min_bin := i;
          l_min_bin_val := l_bins(i);
        END IF;

      END LOOP;

    END LOOP;

  END LOOP;

END Items_Binned;

SQL Query

SELECT item_name, bin, item_value, Sum (item_value) OVER (PARTITION BY bin) bin_value
  FROM TABLE (Bin_Fit.Items_Binned (
                     CURSOR (SELECT item_name, item_value FROM items ORDER BY item_value DESC), 
                     :N_BINS))
 ORDER BY item_value DESC

The idea here is that procedural algorithms can often be implemented more efficiently in PL/SQL than in SQL.

  • The first parameter to the function is a strongly-typed reference cursor
  • The SQL call passes in a SELECT statement wrapped in the CURSOR keyword, so the function can be used for any set of records that returns name and numeric value pairs
  • The item records are fetched in batches of 100 using the LIMIT clause to improves efficiency

Performance Testing
I tested performance of the various queries using my own benchmarking framework across grids of data points, with two data sets to split the queries into two sets based on performance.

Query Modifications for Performance Testing

  • The RSF query with staging table was run within a pipelined function in order to easily include the insert in the timings
  • A system context was used to pass the bind variables as the framework runs the queries from PL/SQL, not from SQL*Plus
  • I found that calculating the bin values using analytic sums, as in the code above, affected performance, so I removed this for clarity of results, outputting only item name, value and bin

Test Data Sets
For a given depth parameter, d, random numbers were inserted within the range 0-d for d-1 records. The insert was:

 INSERT INTO items
  SELECT 'item-' || n, DBMS_Random.Value (0, p_point_deep) FROM  
  (SELECT LEVEL n FROM DUAL CONNECT BY LEVEL < p_point_deep);

The number of bins was passed as a width parameter, but note that the original, linked Model solution, MODO, hard-codes the number of bins to 3.

Test Results

Data Set 1 - Small
This was used for the following queries:

  • MODO - Original Model for GDY
  • MODB - Brendan's Generic Model for GDY
  • RSFQ - Recursive Subquery Factor for GBR
 Depth         W3         W3         W3
Run Type=MODO
 D1000       1.03       1.77       1.05
 D2000       3.98       6.46       5.38
 D4000      15.79       20.7      25.58
 D8000      63.18      88.75      92.27
D16000      364.2     347.74     351.99
Run Type=MODB
 Depth         W3         W6        W12
 D1000        .27        .42        .27
 D2000          1       1.58       1.59
 D4000       3.86        3.8       6.19
 D8000      23.26      24.57      17.19
D16000      82.29      92.04      96.02
Run Type=RSFQ
 D1000       3.24       3.17       1.53
 D2000       8.58       9.68       8.02
 D4000      25.65      24.07      23.17
 D8000      111.3     108.25      98.33
D16000     471.17     407.65     399.99

Slice W3
The results show:

  • Quadratic variation of CPU time with number of items
  • Little variation of CPU time with number of bins, although RSFQ seems to show some decline
  • RSFQ is slightly slower than MODO, while my version of Model, MODB is about 4 times faster than MODO

Data Set 2 - Large
This was used for the following queries:

  • RSFT - Recursive Subquery Factor for GBR with Temporary Table
  • POSS - Plain Old SQL Solution for TPA
  • PLFN - Pipelined Function for GDY

This table gives the CPU times in seconds across the data set:

  Depth       W100      W1000     W10000
Run Type=PLFN
 D20000        .31       1.92      19.25
 D40000        .65       3.87      55.78
 D80000       1.28       7.72      92.83
D160000       2.67      16.59     214.96
D320000       5.29      38.68      418.7
D640000      11.61      84.57      823.9
Run Type=POSS
 D20000        .09        .13        .13
 D40000        .18        .21        .18
 D80000        .27        .36         .6
D160000        .74       1.07        .83
D320000       1.36       1.58       1.58
D640000       3.13       3.97       4.04
Run Type=RSFT
 D20000        .78        .78        .84
 D40000       1.41       1.54        1.7
 D80000       3.02       3.39       4.88
D160000       6.11       9.56       8.42
D320000      13.05      18.93      20.84
D640000      41.62      40.98      41.09

Slice W100

Slice W10000
The results show:

  • Linear variation of CPU time with number of items
  • Little variation of CPU time with number of bins for POSS and RSFT, but roughly linear variation for PLFN
  • These linear methods are much faster than the earlier quadratic ones for larger numbers of items
  • Its approximate proportionality of time to number of bins means that, while PLFN is faster than RSFT for small number of bins, it becomes slower from around 50 bins for our problem
  • The proportionality to number of bins for PLFN presumably arises from the step to find the bin of minimum value
  • The lack of proportionality to number of bins for RSFT may appear surprising since it performs a sort of the bins iteratively: However, while the work for this sort is likely to be proportional to the number of bins, the number of iterations is inversely proportional and thus cancels out the variation

Solution Quality

The methods reported above implement three underlying algorithms, none of which guarantees an optimal solution. In order to get an idea of how the quality compares, I created new versions of the second set of queries using analytic functions to output the difference between minimum and maximum bin values, with percentage of the maximum also output. I ran these on the same grid, and report below the results for the four corners.

Method:			PLFN		RSFT		POSS
Point:	W100/D20000
Diff/%:			72/.004%	72/.004%	19,825/1%
Point:	W100/D640000
Diff/%:			60/.000003%	60/.000003%	633499/.03%
Point:	W10000/D20000
Diff/%:			189/.9%		180/.9%		19,995/67%
Point:	W10000/D640000
Diff/%:			695/.003%	695/.003%	639,933/3%

The results indicate that GDY (Greedy Algorithm) and GBR (Greedy Algorithm with Batched Rebalancing) generally give very similar quality results, while TPA (Team Picking Algorithm) tends to be quite a lot worse.

Extended Problem: Finding the Number of Bins Required

An important extension to the problem is when the bins have fixed capacity, and it is desired to find the minimum number of bins, then spread the items evenly between them. As mentioned at the start, I posted extensions to two of my solutions on an OTN thread, and I reproduce them here. It turns out to be quite easy to make the extension. The remainder of this section is just lifted from my OTN post and refers to the table of the original poster.

Start OTN Extract
So how do we determine the number of bins? The total quantity divided by bin capacity, rounded up, gives a lower bound on the number of bins needed. The actual number required may be larger, but mostly it will be within a very small range from the lower bound, I believe (I suspect it will nearly always be the lower bound). A good practical solution, therefore, would be to compute the solutions for a base number, plus one or more increments, and this can be done with negligible extra work (although Model might be an exception, I haven't tried it). Then the bin totals can be computed, and the first solution that meets the constraints can be used. I took two bin sets here.

SQL POS

WITH items AS (
       SELECT sl_pm_code item_name, sl_wt item_amt, sl_qty item_qty,
              Ceil (Sum(sl_qty) OVER () / :MAX_QTY) n_bins
         FROM ow_ship_det
), items_desc AS (
       SELECT item_name, item_amt, item_qty, n_bins,
              Mod (Row_Number () OVER (ORDER BY item_qty DESC), n_bins) bin_1,
              Mod (Row_Number () OVER (ORDER BY item_qty DESC), n_bins + 1) bin_2
         FROM items
)
SELECT item_name, item_amt, item_qty, 
       CASE bin_1 WHEN 0 THEN n_bins ELSE bin_1 END bin_1, 
       CASE bin_2 WHEN 0 THEN n_bins + 1 ELSE bin_2 END bin_2, 
       Sum (item_amt) OVER (PARTITION BY bin_1) bin_1_amt,
       Sum (item_qty) OVER (PARTITION BY bin_1) bin_1_qty,
       Sum (item_amt) OVER (PARTITION BY bin_2) bin_2_amt,
       Sum (item_qty) OVER (PARTITION BY bin_2) bin_2_qty
  FROM items_desc
 ORDER BY item_qty DESC, bin_1, bin_2

SQL Pipelined

SELECT osd.sl_pm_code item_name, osd.sl_wt item_amt, osd.sl_qty item_qty, 
       tab.bin_1, tab.bin_2, 
       Sum (osd.sl_wt) OVER (PARTITION BY tab.bin_1) bin_1_amt,
       Sum (osd.sl_qty) OVER (PARTITION BY tab.bin_1) bin_1_qty,
       Sum (osd.sl_wt) OVER (PARTITION BY tab.bin_2) bin_2_amt,
       Sum (osd.sl_qty) OVER (PARTITION BY tab.bin_2) bin_2_qty
  FROM ow_ship_det osd
  JOIN TABLE (Bin_Even.Items_Binned (
                     CURSOR (SELECT sl_pm_code item_name, sl_qty item_value,
                                    Sum(sl_qty) OVER () item_total
                               FROM ow_ship_det
                              ORDER BY sl_qty DESC, sl_wt DESC),
                     :MAX_QTY)) tab
    ON tab.item_name = osd.sl_pm_code
 ORDER BY osd.sl_qty DESC, tab.bin_1

Pipelined Function

CREATE OR REPLACE PACKAGE Bin_Even AS

TYPE bin_even_rec_type IS RECORD (item_name VARCHAR2(100), item_value NUMBER, bin_1 NUMBER, bin_2 NUMBER);
TYPE bin_even_list_type IS VARRAY(1000) OF bin_even_rec_type;

TYPE bin_even_cur_rec_type IS RECORD (item_name VARCHAR2(100), item_value NUMBER, item_total NUMBER);
TYPE bin_even_cur_type IS REF CURSOR RETURN bin_even_cur_rec_type;

FUNCTION Items_Binned (p_items_cur bin_even_cur_type, p_bin_max NUMBER) RETURN bin_even_list_type PIPELINED;

END Bin_Even;
/
SHO ERR
CREATE OR REPLACE PACKAGE BODY Bin_Even AS

c_big_value                 CONSTANT NUMBER := 100000000;
c_n_bin_sets                CONSTANT NUMBER := 2;

TYPE bin_even_cur_list_type IS VARRAY(100) OF bin_even_cur_rec_type;
TYPE num_lol_list_type      IS VARRAY(100) OF SYS.ODCINumberList;

FUNCTION Items_Binned (p_items_cur bin_even_cur_type, p_bin_max NUMBER) RETURN bin_even_list_type PIPELINED IS

  l_min_bin                 SYS.ODCINumberList := SYS.ODCINumberList (1, 1);
  l_min_bin_val             SYS.ODCINumberList := SYS.ODCINumberList (c_big_value, c_big_value);
  l_bins                    num_lol_list_type := num_lol_list_type (SYS.ODCINumberList(), SYS.ODCINumberList());

  l_bin_even_cur_rec        bin_even_cur_rec_type;
  l_bin_even_rec            bin_even_rec_type;
  l_bin_even_cur_list       bin_even_cur_list_type;

  l_n_bins                  PLS_INTEGER;
  l_n_bins_base             PLS_INTEGER;
  l_is_first_fetch          BOOLEAN := TRUE;

BEGIN

  LOOP

    FETCH p_items_cur BULK COLLECT INTO l_bin_even_cur_list LIMIT 100;
    EXIT WHEN l_Bin_Even_cur_list.COUNT = 0;
    IF l_is_first_fetch THEN

      l_n_bins_base := Ceil (l_Bin_Even_cur_list(1).item_total / p_bin_max) - 1;

      l_is_first_fetch := FALSE;

      l_n_bins := l_n_bins_base;
      FOR i IN 1..c_n_bin_sets LOOP

        l_n_bins := l_n_bins + 1;
        l_bins(i).Extend (l_n_bins);
        FOR k IN 1..l_n_bins LOOP
          l_bins(i)(k) := 0;
        END LOOP;

      END LOOP;

    END IF;

    FOR j IN 1..l_Bin_Even_cur_list.COUNT LOOP

      l_bin_even_rec.item_name := l_bin_even_cur_list(j).item_name;
      l_bin_even_rec.item_value := l_bin_even_cur_list(j).item_value;
      l_bin_even_rec.bin_1 := l_min_bin(1);
      l_bin_even_rec.bin_2 := l_min_bin(2);

      PIPE ROW (l_bin_even_rec);

      l_n_bins := l_n_bins_base;
      FOR i IN 1..c_n_bin_sets LOOP
        l_n_bins := l_n_bins + 1;
        l_bins(i)(l_min_bin(i)) := l_bins(i)(l_min_bin(i)) + l_Bin_Even_cur_list(j).item_value;

        l_min_bin_val(i) := c_big_value;
        FOR k IN 1..l_n_bins LOOP

          IF l_bins(i)(k) < l_min_bin_val(i) THEN
            l_min_bin(i) := k;
            l_min_bin_val(i) := l_bins(i)(k);
          END IF;

        END LOOP;

      END LOOP;

    END LOOP;

  END LOOP;

END Items_Binned;

END Bin_Even;

Output POS
Note BIN_1 means bin set 1, which turns out to have 4 bins, while bin set 2 then necessarily has 5.

ITEM_NAME         ITEM_AMT   ITEM_QTY      BIN_1      BIN_2  BIN_1_AMT  BIN_1_QTY  BIN_2_AMT  BIN_2_QTY
--------------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ----------
1239606-1080          4024        266          1          1      25562        995      17482        827
1239606-1045          1880        192          2          2      19394        886      14568        732
1239606-1044          1567        160          3          3      18115        835      14097        688
1239606-1081          2118        140          4          4      18988        793      17130        657
1239606-2094          5741         96          1          5      25562        995      18782        605
...
1239606-2107            80          3          4          2      18988        793      14568        732
1239606-2084           122          3          4          3      18988        793      14097        688
1239606-2110           210          2          2          3      19394        886      14097        688
1239606-4022           212          2          3          4      18115        835      17130        657
1239606-4021           212          2          4          5      18988        793      18782        605

Output Pipelined

ITEM_NAME         ITEM_AMT   ITEM_QTY      BIN_1      BIN_2  BIN_1_AMT  BIN_1_QTY  BIN_2_AMT  BIN_2_QTY
--------------- ---------- ---------- ---------- ---------- ---------- ---------- ---------- ----------
1239606-1080          4024        266          1          1      20627        878      15805        703
1239606-1045          1880        192          2          2      18220        877      16176        703
1239606-1044          1567        160          3          3      20425        878      15651        701
1239606-1081          2118        140          4          4      22787        876      14797        701
1239606-2094          5741         96          4          5      22787        876      19630        701
...
1239606-2089            80          3          4          1      22787        876      15805        703
1239606-2112           141          3          4          2      22787        876      16176        703
1239606-4022           212          2          1          1      20627        878      15805        703
1239606-4021           212          2          2          1      18220        877      15805        703
1239606-2110           210          2          3          2      20425        878      16176        703

End OTN Extract

Conclusions

  • Various solutions for the balanced number partitioning problem have been presented, using Oracle's Model clause, Recursive Subquery Factoring, Pipelined Functions and simple SQL
  • The performance characteristics of these solutions have been tested across a range of data sets
  • As is often the case, the best solution depends on the shape and size of the data set
  • A simple extension has been shown to allow determining the number of bins required in the bin-fitting interpretation of the problem
  • Replacing a WITH clause with a staging table can be a useful technique to allow indexed scans






An SQL Solution for the Multiple Knapsack Problem (SKP-m)

In my last article, A Simple SQL Solution for the Knapsack Problem (SKP-1), I presented an SQL solution for the well known knapsack problem in its simpler 1-knapsack form (and it is advisable to read the first article before this one). Here I present an SQL solution for the problem in its more difficult multiple-knapsack form. The solution is a modified version of one I posted on OTN, SQL Query for mapping a set of batches to a class rooms group, and I describe two versions of it, one in pure SQL, and another that includes a database function. The earlier article provided the solutions as comma-separated strings of item identifiers, and in this article also the solutions are first obtained as delimited strings. However, as there are now containers as well as items, we extend the SQL to provide solutions with item and container names in separate fields within records for each container-item pair. The solution is presented, as before, more for its theoretical interest than for practical applicability. Much research has been done on procedural algorithms for this important, but computationally difficult class of problems.

We will consider the same simple example problem as in the earlier article, having four items, but now with two containers with individual weight limits of 8 and 10. As noted in the earlier article, the problem can be considered as that of assigning each item to one of the containers, or to none, leading directly to the expression for the number of not necessarily feasible assignment sets for the example. We can again depict the 24 possible item combinations in a diagram, with the container limits added.

Multi, v1.1 - CombisWe can see that there is one optimal solution in this case, in which items 1 and 3 are assigned to container 1, while items 2 and 4 are assigned to container 2, with a profit of 100. How to find it using SQL?

SQL Solution
The solution to the single knapsack problem worked by joining items recursively in increasing order of item id, accumulating the total weights and profits, and terminating a sequence when no more items can be added within the weight limit. The item sequences were accumulated as comma-separated strings, and the optimal solutions obtained by analytic ranking of the profits.

For the multiple knapsack problem, it's not quite as simple, but a similar approach may be a good starting point. Previously our anchor branch in the recursion selected all items below the single maximum weight, but we now have containers with individual weights. If we now join the containers table we can find all items falling within the maximum weights by container. The recursion can then proceed to find all feasible item combinations by container. Here is the SQL for this:

WITH rsf_itm (con_id, max_weight, itm_id, lev, tot_weight, tot_profit, path) AS (
SELECT c.id, 
       c.max_weight,
       i.id,
       0,
       i.item_weight,
       i.item_profit, 
       ',' || i.id || ','
  FROM items i
  JOIN containers c
    ON i.item_weight <= c.max_weight
 UNION ALL
SELECT r.con_id,
       r.max_weight,
       i.id, 
       r.lev + 1, 
       r.tot_weight + i.item_weight,
       r.tot_profit + i.item_profit,
       r.path || i.id || ','
  FROM rsf_itm r
  JOIN items i
    ON i.id > r.itm_id
   AND r.tot_weight + i.item_weight <= r.max_weight
 ORDER BY 1, 2
) SEARCH DEPTH FIRST BY con_id, itm_id SET line_no
SELECT con_id,
       max_weight,
       LPad (To_Char(itm_id), 2*lev + 1, ' ') itm_id, 
       path itm_path,
       tot_weight, tot_profit
  FROM rsf_itm
 ORDER BY line_no

and here is the resulting output:

CON_ID MAX_WEIGHT ITM_ID ITM_PATH    TOT_WEIGHT TOT_PROFIT
------ ---------- ------ ----------- ---------- ----------
     1          8 1      ,1,                  3         10
                    2    ,1,2,                7         30
                    3    ,1,3,                8         40
                  2      ,2,                  4         20
                  3      ,3,                  5         30
                  4      ,4,                  6         40
     2         10 1      ,1,                  3         10
                    2    ,1,2,                7         30
                    3    ,1,3,                8         40
                    4    ,1,4,                9         50
                  2      ,2,                  4         20
                    3    ,2,3,                9         50
                    4    ,2,4,               10         60
                  3      ,3,                  5         30
                  4      ,4,                  6         40

15 rows selected.

Looking at this, we can see that the overall solution will comprise one feasible combination of items for each container, with the constraint that no item appears in more than one container. This suggests that we could perform a second recursion in a similar way to the first, but this time using the results of the first as input, and joining the feasible combinations of containers of higher id only. If we again accumulate the sequence in a delimited string, regular expression functionality could be used to avoid joining combinations with items already included. The following SQL does this recursion:

WITH rsf_itm (con_id, max_weight, itm_id, tot_weight, tot_profit, path) AS (
SELECT c.id, 
       c.max_weight,
       i.id, 
       i.item_weight,
       i.item_profit, 
       ',' || i.id || ','
  FROM items i
  JOIN containers c
    ON i.item_weight <= c.max_weight
 UNION ALL
SELECT r.con_id,
       r.max_weight,
       i.id, 
       r.tot_weight + i.item_weight,
       r.tot_profit + i.item_profit,
       r.path || i.id || ','
  FROM rsf_itm r
  JOIN items i
    ON i.id > r.itm_id
   AND r.tot_weight + i.item_weight <= r.max_weight
)
, rsf_con (con_id, con_itm_set, con_itm_path, lev, tot_weight, tot_profit) AS (
SELECT con_id,
       ':' || con_id || ':' || path,
       ':' || con_id || ':' || path,
       0,
       tot_weight,
       tot_profit
  FROM rsf_itm
 UNION ALL
SELECT r_i.con_id,
       ':' || r_i.con_id || ':' || r_i.path,
       r_c.con_itm_path ||  ':' || r_i.con_id || ':' || r_i.path,
       r_c.lev + 1, 
       r_c.tot_weight + r_i.tot_weight,
       r_c.tot_profit + r_i.tot_profit
  FROM rsf_con r_c
  JOIN rsf_itm r_i
    ON r_i.con_id > r_c.con_id
 WHERE RegExp_Instr (r_c.con_itm_path || r_i.path, ',(\d+),.*?,\1,') = 0
) SEARCH DEPTH FIRST BY con_id SET line_no
SELECT
       LPad (' ', 2*lev, ' ') || con_itm_set con_itm_set,
       con_itm_path,
       tot_weight, tot_profit
  FROM rsf_con
 ORDER BY line_no

Notice the use of RegExp_Instr, which takes the current sequence with potential new combination appended as its source string, and looks for a match against the search string ',(\d+),.*?,\1,'. The function returns 0 if no match is found, meaning no duplicate item was found. The sequence includes the container id using a different delimiter, a colon, at the start of each combination. The search string can be explained as follows:

,(\d+), = a sequence of one or more digits with a comma either side, and the digit sequence saved for referencing
.*?,\1, = a sequence of any characters, followed by the saved digit sequence within commas. The ? specifies a non-greedy search, meaning stop searching as soon as a match is found

The result of the query is:

CON_ITM_SET          CON_ITM_PATH         TOT_WEIGHT TOT_PROFIT
-------------------- -------------------- ---------- ----------
:1:,1,               :1:,1,                        3         10
  :2:,2,             :1:,1,:2:,2,                  7         30
  :2:,3,             :1:,1,:2:,3,                  8         40
  :2:,4,             :1:,1,:2:,4,                  9         50
  :2:,2,3,           :1:,1,:2:,2,3,               12         60
  :2:,2,4,           :1:,1,:2:,2,4,               13         70
:1:,2,               :1:,2,                        4         20
  :2:,1,             :1:,2,:2:,1,                  7         30
  :2:,3,             :1:,2,:2:,3,                  9         50
  :2:,1,3,           :1:,2,:2:,1,3,               12         60
  :2:,4,             :1:,2,:2:,4,                 10         60
  :2:,1,4,           :1:,2,:2:,1,4,               13         70
:1:,1,2,             :1:,1,2,                      7         30
  :2:,3,             :1:,1,2,:2:,3,               12         60
  :2:,4,             :1:,1,2,:2:,4,               13         70
:1:,3,               :1:,3,                        5         30
  :2:,1,             :1:,3,:2:,1,                  8         40
  :2:,2,             :1:,3,:2:,2,                  9         50
  :2:,1,2,           :1:,3,:2:,1,2,               12         60
  :2:,4,             :1:,3,:2:,4,                 11         70
  :2:,1,4,           :1:,3,:2:,1,4,               14         80
  :2:,2,4,           :1:,3,:2:,2,4,               15         90
:1:,1,3,             :1:,1,3,                      8         40
  :2:,2,             :1:,1,3,:2:,2,               12         60
  :2:,4,             :1:,1,3,:2:,4,               14         80
  :2:,2,4,           :1:,1,3,:2:,2,4,             18        100
:1:,4,               :1:,4,                        6         40
  :2:,1,             :1:,4,:2:,1,                  9         50
  :2:,2,             :1:,4,:2:,2,                 10         60
  :2:,1,2,           :1:,4,:2:,1,2,               13         70
  :2:,3,             :1:,4,:2:,3,                 11         70
  :2:,1,3,           :1:,4,:2:,1,3,               14         80
  :2:,2,3,           :1:,4,:2:,2,3,               15         90
:2:,1,               :2:,1,                        3         10
:2:,2,               :2:,2,                        4         20
:2:,1,2,             :2:,1,2,                      7         30
:2:,3,               :2:,3,                        5         30
:2:,1,3,             :2:,1,3,                      8         40
:2:,4,               :2:,4,                        6         40
:2:,1,4,             :2:,1,4,                      9         50
:2:,2,3,             :2:,2,3,                      9         50
:2:,2,4,             :2:,2,4,                     10         60

42 rows selected.

We can see that the optimal solutions can be obtained from the output again using analytic ranking by profit, and in this case the solution with a profit of 100 is the optimal one, with sequence ':1:,1,3,:2:,2,4,'. In the full solution, as well as selecting out the top-ranking solutions, we have extended the query to output the items and containers by name, in distinct fields with a record for every solution/container/item combination. For the example problem above, the output is:

    SOL_ID S_WT  S_PR  C_ID C_NAME          M_WT C_WT  I_ID I_NAME     I_WT I_PR
---------- ---- ----- ----- --------------- ---- ---- ----- ---------- ---- ----
         1   18   100     1 Item 1             8    8     1 Item 1        3   10
                                                          3 Item 3        5   30
                          2 Item 2            10   10     2 Item 2        4   20
                                                          4 Item 4        6   40

SQL-Only Solution - XSQL
There are various techniques in SQL for splitting string columns into multiple rows and columns. We will take one of the more straightforward ones that uses the DUAL table with CONNECT BY to generate rows against which to anchor the string-parsing.

WITH rsf_itm (con_id, max_weight, itm_id, lev, tot_weight, tot_profit, path) AS (
SELECT c.id, 
       c.max_weight,
       i.id, 
       0, 
       i.item_weight,
       i.item_profit, 
       ',' || i.id || ','
  FROM items i
  JOIN containers c
    ON i.item_weight <= c.max_weight
 UNION ALL
SELECT r.con_id,
       r.max_weight,
       i.id, 
       r.lev + 1, 
       r.tot_weight + i.item_weight,
       r.tot_profit + i.item_profit,
       r.path || i.id || ','
  FROM rsf_itm r
  JOIN items i
    ON i.id > r.itm_id
   AND r.tot_weight + i.item_weight <= r.max_weight
)
, rsf_con (con_id, con_path, itm_path, tot_weight, tot_profit, lev) AS (
SELECT con_id,
       To_Char(con_id),
       ':' || con_id || '-' || (lev + 1) || ':' || path,
       tot_weight,
       tot_profit,
       0
  FROM rsf_itm
 UNION ALL
SELECT r_i.con_id,
       r_c.con_path || ',' || r_i.con_id,
       r_c.itm_path ||  ':' || r_i.con_id || '-' || (r_i.lev + 1) || ':' || r_i.path,
       r_c.tot_weight + r_i.tot_weight,
       r_c.tot_profit + r_i.tot_profit,
       r_c.lev + 1
  FROM rsf_con r_c
  JOIN rsf_itm r_i
    ON r_i.con_id > r_c.con_id
   AND RegExp_Instr (r_c.itm_path || r_i.path, ',(\d+),.*?,\1,') = 0
)
, paths_ranked AS (
SELECT itm_path || ':' itm_path, tot_weight, tot_profit, lev + 1 n_cons,
       Rank () OVER (ORDER BY tot_profit DESC) rnk
  FROM rsf_con
), best_paths AS (
SELECT itm_path, tot_weight, tot_profit, n_cons,
       Row_Number () OVER (ORDER BY tot_weight DESC) sol_id
  FROM paths_ranked
 WHERE rnk = 1
), row_gen AS (
SELECT LEVEL lev
  FROM DUAL
CONNECT BY LEVEL <= (SELECT Count(*) FROM items)
), con_v AS (
SELECT  r.lev con_ind, b.sol_id, b.tot_weight, b.tot_profit,
        Substr (b.itm_path, Instr (b.itm_path, ':', 1, 2*r.lev - 1) + 1, 
                            Instr (b.itm_path, ':', 1, 2*r.lev) - Instr (b.itm_path, ':', 1, 2*r.lev - 1) - 1)
           con_nit_id,
        Substr (b.itm_path, Instr (b.itm_path, ':', 1, 2*r.lev) + 1, 
                            Instr (b.itm_path, ':', 1, 2*r.lev + 1) - Instr (b.itm_path, ':', 1, 2*r.lev) - 1)
           itm_str
  FROM best_paths b
  JOIN row_gen r
    ON r.lev <= b.n_cons
), con_split AS (
SELECT sol_id, tot_weight, tot_profit,
       Substr (con_nit_id, 1, Instr (con_nit_id, '-', 1) - 1) con_id,
       Substr (con_nit_id, Instr (con_nit_id, '-', 1) + 1) n_items,
       itm_str
  FROM con_v
), itm_v AS (
SELECT  c.sol_id, c.con_id, c.tot_weight, c.tot_profit,
        Substr (c.itm_str, Instr (c.itm_str, ',', 1, r.lev) + 1, 
                            Instr (c.itm_str, ',', 1, r.lev + 1) - Instr (c.itm_str, ',', 1, r.lev) - 1)
           itm_id
  FROM con_split c
  JOIN row_gen r
    ON r.lev <= c.n_items
)
SELECT 
/* SEL */
       v.sol_id sol_id,
       v.tot_weight s_wt, 
       v.tot_profit s_pr, 
       c.id c_id, 
       c.name c_name, 
       c.max_weight m_wt,
       Sum (i.item_weight) OVER (PARTITION BY v.sol_id, c.id) c_wt,
       i.id i_id, 
       i.name i_name, 
       i.item_weight i_wt, 
       i.item_profit i_pr
/* SEL */
  FROM itm_v v
  JOIN containers c
    ON c.id = To_Number (v.con_id)
  JOIN items i
    ON i.id = To_Number (v.itm_id)
 ORDER BY sol_id, con_id, itm_id

SQL with Function Solution - XFUN
The SQL techniques for string-splitting are quite cumbersome, and a better approach may be the use of a pipelined function that allows the string-parsing to be done in PL/SQL, a procedural language that is better suited to the task.

WITH rsf_itm (con_id, max_weight, itm_id, tot_weight, tot_profit, path) AS (
SELECT c.id, 
       c.max_weight,
       i.id, 
       i.item_weight,
       i.item_profit, 
       ',' || i.id || ','
  FROM items i
  JOIN containers c
    ON i.item_weight <= c.max_weight
 UNION ALL
SELECT r.con_id,
       r.max_weight,
       i.id, 
       r.tot_weight + i.item_weight,
       r.tot_profit + i.item_profit,
       r.path || i.id || ','
  FROM rsf_itm r
  JOIN items i
    ON i.id > r.itm_id
   AND r.tot_weight + i.item_weight <= r.max_weight
 ORDER BY 1, 2
)
, rsf_con (con_id, itm_path, tot_weight, tot_profit) AS (
SELECT con_id,
       ':' || con_id || ':' || path,
       tot_weight,
       tot_profit
  FROM rsf_itm
 UNION ALL
SELECT r_i.con_id,
       r_c.itm_path ||  ':' || r_i.con_id || ':' || r_i.path,
       r_c.tot_weight + r_i.tot_weight,
       r_c.tot_profit + r_i.tot_profit
  FROM rsf_con r_c
  JOIN rsf_itm r_i
    ON r_i.con_id > r_c.con_id
   AND RegExp_Instr (r_c.itm_path || r_i.path, ',(\d+),.*?,\1,') = 0
)
, paths_ranked AS (
SELECT itm_path || ':' itm_path, tot_weight, tot_profit, Rank () OVER (ORDER BY tot_profit DESC) rn,
       Row_Number () OVER (ORDER BY tot_profit DESC, tot_weight DESC) sol_id
  FROM rsf_con
), itm_v AS (
SELECT s.con_id, s.itm_id, p.itm_path, p.tot_weight, p.tot_profit, p.sol_id
  FROM paths_ranked p
 CROSS JOIN TABLE (Multi.Split_String (p.itm_path)) s
 WHERE rn = 1
)
SELECT v.sol_id sol_id,
       v.tot_weight s_wt, 
       v.tot_profit s_pr, 
       c.id c_id, 
       c.name c_name, 
       c.max_weight m_wt,
       Sum (i.item_weight) OVER (PARTITION BY v.sol_id, c.id) c_wt,
       i.id i_id, 
       i.name i_name, 
       i.item_weight i_wt, 
       i.item_profit i_pr
  FROM itm_v v
  JOIN containers c
    ON c.id = To_Number (v.con_id)
  JOIN items i
    ON i.id = To_Number (v.itm_id)
 ORDER BY sol_id, con_id, itm_id

Pipelined Database Function

CREATE OR REPLACE TYPE con_itm_type AS OBJECT (con_id NUMBER, itm_id NUMBER);
/
CREATE OR REPLACE TYPE con_itm_list_type AS VARRAY(100) OF con_itm_type;
/
CREATE OR REPLACE PACKAGE BODY Multi IS

FUNCTION Split_String (p_string VARCHAR2) RETURN con_itm_list_type PIPELINED IS

  l_pos_colon_1           PLS_INTEGER := 1;
  l_pos_colon_2           PLS_INTEGER;
  l_pos_comma_1           PLS_INTEGER;
  l_pos_comma_2           PLS_INTEGER;
  l_con                   PLS_INTEGER;
  l_itm                   PLS_INTEGER;

BEGIN

  LOOP

    l_pos_colon_2 := Instr (p_string, ':', l_pos_colon_1 + 1, 1);
    EXIT WHEN l_pos_colon_2 = 0;

    l_con := To_Number (Substr (p_string, l_pos_colon_1 + 1, l_pos_colon_2 - l_pos_colon_1 - 1));
    l_pos_colon_1 := Instr (p_string, ':', l_pos_colon_2 + 1, 1);
    l_pos_comma_1 := l_pos_colon_2 + 1;

    LOOP

      l_pos_comma_2 := Instr (p_string, ',', l_pos_comma_1 + 1, 1);
      EXIT WHEN l_pos_comma_2 = 0 OR l_pos_comma_2 > l_pos_colon_1;

      l_itm := To_Number (Substr (p_string, l_pos_comma_1 + 1, l_pos_comma_2 - l_pos_comma_1 - 1));
      PIPE ROW (con_itm_type (l_con, l_itm));
      l_pos_comma_1 := l_pos_comma_2;
 
    END LOOP;

  END LOOP;

END Split_String;

END Multi;

Query Structure Diagram (embedded directly)
The QSD shows both queries in a single diagram as the early query blocks are almost the same (the main difference is that the strings contain a bit more information for XSQL to facilitate the later splitting). The directly-embedded version shows the whole query, but it may be hard to read the detail, so it is followed by a larger, scrollable version within Excel.
QSD shwoing both versions of SQL

Query Structure Diagram (embedded via Excel)
This is the larger, scrollable version.

Performance Analysis
As in the previous article, we will see how the solution methods perform as problem size varies, using my own performance benchmarking framework.

Test Data Sets
Test data sets are generated as follows, in terms of two integer parameters, w and d:

  • Insert w containers with sequential ids and random maximum weights between 1 and 100
  • Insert d items with sequential ids and random weights and profits in the ranges 1-60 and 1-10000, respectively, via Oracle's function DBMS_Random.Value

Test Results
The embedded Excel file below summarises the results obtained over a grid of data points, with w in (1, 2, 3) and d in (8, 10, 12, 14, 16, 18).

The graphs tab below shows 3-d graphs of the number of rows processed and the CPU time for XFUN.

Notes

  • There is not much difference in performance between the two query versions, no doubt because the number of solution records is generally small compared with rows processed in the recursions
  • Notice that the timings correlate well with the rows processed, but not so well with the numbers of base records. The nature of the problem means that some of the randomised data sets turn out to be much harder to solve than others
  • Notice the estimated rows on step 36 of the execution plan for the pipelined function solution. The value of 8168 is a fixed value that Oracle assumes since it has no statistics to go on. We could improve this by using the (undocumented) cardinality hint to provide a smaller estimate
  • I extended my benchmarking framework for this article to report the intermediate numbers of rows processed, as well as the cardinality estimates and derived errors in these estimates (maximum for each plan). It is obvious from the nature of the problem that Oracle's Cost Based Optimiser (CBO) is not going to be able to make good cardinality estimates

Conclusions
Oracle's v11.2 implementation of the Ansii SQL feature recursive subquery factoring provides a means for solving the knapsack problem, in its multiple knapsack form, in SQL. The solution is not practical for large problems, for which procedural techniques that have been extensively researched should be considered. However, the techniques used may be of interest for combinatorial problems that are small enough to be handled in SQL, and for other types of problem in general.






A Simple SQL Solution for the Knapsack Problem (SKP-1)

A poster on OTN (Combination using pl/sql) recently asked for an SQL solution to a problem that turned out to be an example of the well known Knapsack Problem, for the case of a single knapsack. I posted an SQL query as a solution, and also a solution in PL/SQL because the SQL solution uses a feature only available in Oracle v11.2. In this article I explain how the solutions work and provide the results of a performance analysis that involved randomised test problems of varying computational difficulty. I have taken a more general form of problem than the original poster described, and the solutions here have been improved.

Update, 14 July 2013: I used the technique in response to another OTN post here, SQL for the Fantasy Football Knapsack Problem. I have extended the idea there to allow for fast approximate solutions making it viable for larger problems, and have also used a similar idea here, SQL for the Travelling Salesman Problem.

Knapsack Problem (1-Knapsack)
The various forms of knapsack problem have been studied extensively. The problems are known to be computationally difficult and many algorithms have been proposed for both exact and approximate solutions (see reference above). The SQL solution in this article is quite simple and will not be competitive in performance for larger problems in the form described here, but may be interesting for being implemented in pure SQL (and without using Oracle's Model clause, or a purely brute force approach). However, I have later extended the approach to allow for search limiting and have shown this to be viable for larger problems (see links at the top).

The problem can be stated informally, as follows: Given a set of items, each having positive weight and profit attributes, and a weight limit, find the combinations of items that maximise profit within the weight limit. Variant versions include the addition of multiple constraints (easy to handle), and inclusion of multiple knapsacks (more difficult). I also have a solution for the multiple knapsacks version described here (An SQL Solution for the Multiple Knapsack Problem (SKP-m)).

The difficulty of the problem arises from the number of possible combinations increasing exponentially with problem size. The number of these (not necessarily feasible) combinations, N(n,1), can be expressed in terms of the number of items, n, in two ways. First, we can use the well known binomial expression for the number of combinations of r items, summed from to :

N(n,1) =

where

Second, and more simply, we can observe that including an item in the combination, or not, is a binary choice, leading to:

N(n,1) =

This generalises easily to the expression for the multiple knapsack problem, with m knapsacks:

N(n,m) =

This can also be expressed using a binomial series as

N(n,m) =

Here, represents the number of combinations of r items from n, with being the number of assignments of the r items to m containers.

Let's look at a simple example problem having four items, with a weight limit of 9, as shown below:

Items

There are 24 possible combinations of these items, having from 0 to 4 items. These are depicted below:

Combinations

We can see that there are two optimal solutions in this case. How to find them using SQL?

SQL Solution

Oracle's v11.2 implementation of the Ansii standard Recursive Subquery Factoring can be used as the basis for an SQL solution. This would works as follows: Starting from each item in turn, add items recursively while remaining within the weight limit, and considering only items of id greater than the current id. The SQL looks like this, where a marker is added for leaf nodes, following an approach from the Amis technology blog:

WITH rsf (nxt_id, lev, tot_weight, tot_profit, path) AS (
SELECT id nxt_id, 0 lev, item_weight tot_weight, item_profit tot_profit, To_Char (id) path
  FROM items
 UNION ALL
SELECT n.id, 
       r.lev + 1, 
       r.tot_weight + n.item_weight,
       r.tot_profit + n.item_profit,
       r.path || ',' || To_Char (n.id)
  FROM rsf r
  JOIN items n
    ON n.id > r.nxt_id
   AND r.tot_weight + n.item_weight <= 9
) SEARCH DEPTH FIRST BY nxt_id SET line_no 
SELECT LPad (To_Char(nxt_id), lev + 1, '*') node,tot_weight, tot_profit,
       CASE WHEN lev >= Lead (lev, 1, lev) OVER (ORDER BY line_no) THEN 'Y' END is_leaf,
       path
  FROM rsf
 ORDER BY line_no

and the solution like this:

NODE       TOT_WEIGHT TOT_PROFIT I PATH
---------- ---------- ---------- - ------------------------------
1                   3         10   1
*2                  7         30 Y 1,2
*3                  8         40 Y 1,3
*4                  9         50 Y 1,4
2                   4         20   2
*3                  9         50 Y 2,3
3                   5         30 Y 3
4                   6         40 Y 4

8 rows selected.

The output contains 8 records, as opposed to the total of 23 non-null combinations, because only feasible items are joined, and permutations are avoided by the constraint that item ids increase along the path. Given positivity of weight and profit, we know that all solutions must be leaves, and we can represent the tree structure above in the following diagram:
Leaves
We can now use the recursive subquery factor as an input to a main query that selects one of the most profitable solutions, or alternatively to a further subquery factor that ranks the solutions in order of descending profit. In the latter case, the main query can select all the most profitable solutions.

In the solution I posted on the OTN thread, I included a subquery factor to restrict the final query section to leaf nodes only. This was because we know that the solutions must be leaf nodes, and usually it is more efficient to filter out non-solution records as early as possible. However, I later realised that the work involved in the filtering might outweigh the saving for the final section, and this turned out to be the case here, as shown in the performance analysis section below. Here are the two queries, without the leaf node filtering:

Query - KEEP

WITH rsf (id, lev, tot_weight, tot_profit, path) AS (
SELECT id, 0, item_weight, item_profit, To_Char (id)
  FROM items
 UNION ALL
SELECT n.id, 
       r.lev + 1, 
       r.tot_weight + n.item_weight,
       r.tot_profit + n.item_profit,
       r.path || ',' || To_Char (n.id)
  FROM rsf r
  JOIN items n
    ON n.id > r.id
   AND r.tot_weight + n.item_weight <= 100
)
SELECT Max (tot_weight) KEEP (DENSE_RANK LAST ORDER BY tot_profit) tot_weight,
       Max (tot_profit) KEEP (DENSE_RANK LAST ORDER BY tot_profit) tot_profit,
       Max (path) KEEP (DENSE_RANK LAST ORDER BY tot_profit) path,
       (Max (lev) KEEP (DENSE_RANK LAST ORDER BY tot_profit) + 1) n_items
  FROM rsf

Query - RANK

WITH rsf (id, lev, tot_weight, tot_profit, path) AS (
SELECT id, 0, item_weight, item_profit, To_Char (id)
  FROM items
 UNION ALL
SELECT n.id, 
       r.lev + 1, 
       r.tot_weight + n.item_weight,
       r.tot_profit + n.item_profit,
       r.path || ',' || To_Char (n.id)
  FROM rsf r
  JOIN items n
    ON n.id > r.id
   AND r.tot_weight + n.item_weight <= 100
)
, paths_ranked AS (
SELECT tot_weight, tot_profit, path, 
       Dense_Rank () OVER (ORDER BY tot_profit DESC) rnk_profit,
       lev
  FROM rsf
)
SELECT tot_weight tot_weight, 
       tot_profit tot_profit, 
       path path, 
       (lev + 1) n_items
  FROM paths_ranked
 WHERE rnk_profit = 1
 ORDER BY tot_weight DESC

Query Structure Diagram
QSD
It's worth noting that Oracle's proprietary recursive syntax, Connect By, cannot be used in this way because of the need to accumulate weights forward through the recursion. The new Ansii syntax is only available from v11.2 though, and I thought it might be interesting to implement a solution in PL/SQL that would work in earlier versions, following a similar algorithm, again with recursion.

PL/SQL Recursive Solution

This is a version in the form of a pipelined function, as I wanted to compare it with the SQL solutions, and be callable from SQL.
SQL

SELECT COLUMN_VALUE sol
  FROM TABLE (Packing_PLF.Best_Fits (100))
 ORDER BY COLUMN_VALUE

Package

CREATE OR REPLACE PACKAGE BODY Packing_PLF IS

PROCEDURE Write_Log (p_line VARCHAR2) IS
BEGIN
  NULL;
END Write_Log;

FUNCTION Best_Fits (p_weight_limit NUMBER) RETURN SYS.ODCIVarchar2List PIPELINED IS

  TYPE item_type IS RECORD (
                        item_id                 PLS_INTEGER,
                        item_index_parent       PLS_INTEGER,
                        weight_to_node          NUMBER);
  TYPE item_tree_type IS        TABLE OF item_type;
  g_solution_list               SYS.ODCINumberList;

  g_timer                       PLS_INTEGER := Timer_Set.Construct ('Pipelined Recursion');

  i                             PLS_INTEGER := 0;
  j                             PLS_INTEGER := 0;
  g_item_tree                   item_tree_type;
  g_item                        item_type;
  l_weight                      PLS_INTEGER;
  l_weight_new                  PLS_INTEGER;
  l_best_profit                 PLS_INTEGER := -1;
  l_sol                         VARCHAR2(4000);
  l_sol_cnt                     PLS_INTEGER := 0;

  FUNCTION Add_Node (  p_item_id               PLS_INTEGER,
                       p_item_index_parent     PLS_INTEGER, 
                       p_weight_to_node        NUMBER) RETURN PLS_INTEGER IS
  BEGIN

    g_item.item_id := p_item_id;
    g_item.item_index_parent := p_item_index_parent;
    g_item.weight_to_node := p_weight_to_node;
    IF g_item_tree IS NULL THEN

      g_item_tree := item_tree_type (g_item);

    ELSE

      g_item_tree.Extend;
      g_item_tree (g_item_tree.COUNT) := g_item;

    END IF;
    RETURN g_item_tree.COUNT;

  END Add_Node;

  PROCEDURE Do_One_Level (p_tree_index PLS_INTEGER, p_item_id PLS_INTEGER, p_tot_weight PLS_INTEGER, p_tot_profit PLS_INTEGER) IS

    CURSOR c_nxt IS
    SELECT id, item_weight, item_profit
      FROM items
     WHERE id > p_item_id
       AND item_weight + p_tot_weight <= p_weight_limit;
    l_is_leaf           BOOLEAN := TRUE;
    l_index_list        SYS.ODCINumberList;

  BEGIN

    FOR r_nxt IN c_nxt LOOP
      Timer_Set.Increment_Time (g_timer,  'Do_One_Level/r_nxt');

      l_is_leaf := FALSE;
      Do_One_Level (Add_Node (r_nxt.id, p_tree_index, r_nxt.item_weight + p_tot_weight), r_nxt.id, p_tot_weight + r_nxt.item_weight, p_tot_profit + r_nxt.item_profit);
      Timer_Set.Increment_Time (g_timer,  'Do_One_Level/Do_One_Level');

    END LOOP;

    IF l_is_leaf THEN

      IF p_tot_profit > l_best_profit THEN

        g_solution_list := SYS.ODCINumberList (p_tree_index);
        l_best_profit := p_tot_profit;

      ELSIF p_tot_profit = l_best_profit THEN

        g_solution_list.Extend;
        g_solution_list (g_solution_list.COUNT) := p_tree_index;

      END IF;

    END IF;
    Timer_Set.Increment_Time (g_timer,  'Do_One_Level/leaves');

  END Do_One_Level;

BEGIN

  FOR r_itm IN (SELECT id, item_weight, item_profit FROM items) LOOP

    Timer_Set.Increment_Time (g_timer,  'Root fetches');
    Do_One_Level (Add_Node (r_itm.id, 0, r_itm.item_weight), r_itm.id, r_itm.item_weight, r_itm.item_profit);

  END LOOP;

  FOR i IN 1..g_solution_list.COUNT LOOP

    j := g_solution_list(i);
    l_sol := NULL;
    l_weight := g_item_tree (j).weight_to_node;
    WHILE j != 0 LOOP

      l_sol := l_sol || g_item_tree (j).item_id || ', ';
      j :=  g_item_tree (j).item_index_parent;

    END LOOP;
    l_sol_cnt := l_sol_cnt + 1;
    PIPE ROW ('Solution ' || l_sol_cnt || ' (profit ' || l_best_profit || ', weight ' || l_weight || ') : ' || RTrim (l_sol, ', '));

  END LOOP;

  Timer_Set.Increment_Time (g_timer,  'Write output');
  Write_Log ('Profit ' || l_best_profit || ' has ' || l_sol_cnt || ' solutions...');
  Timer_Set.Write_Times (g_timer);

EXCEPTION
  WHEN OTHERS THEN
    Timer_Set.Write_Times (g_timer);
    RAISE;

END Best_Fits;

END Packing_PLF;

Performance Analysis

It will be interesting to see how the solution methods perform as problem size varies, and we will use my own performance benchmarking framework to do this. As the framework is designed to compare performance of SQL queries, I have converted the PL/SQL solution to operate as a pipelined function, and thus be callable from SQL, as noted above. I included a version of the SQL solution, with the leaf filtering mentioned above, XKPLV - this was based on XKEEP, with filtering as in the OTN thread.

Test Data Sets

Test data sets are generated as follows, in terms of two integer parameters, w and d:

Insert w items with sequential ids, and random weights and profits in the ranges 0-d and 0-1000, respectively, via Oracle's function DBMS_Random.Value. The maximum weight is fixed at 100.

Test Results

The embedded Excel file below summarises the results obtained over a grid of data points, with w in (12, 14, 16, 18, 20) and d in (16, 18, 20).

Notes

  • The two versions of the non-leaf SQL solution take pretty much the same time to execute, and are faster than the others
  • The leaf version of the SQL solution (XKPLV) is slower than the non-leaf versions, and becomes much worse in terms of elapsed time for the more difficult problems; the step-change in performance can be seen to be due to its greater memory usage, which spills to disk above a certain level
  • The pipelined function solution is significantly slower than the other solutions in terms of CPU time, and elapsed time, except in the case of the leaf SQL solution when that solution's memory usage spills to disk. The pipelined function continues to use more memory as the problem difficulty rises, until all available memory is consumed, when it throws an error (but this case is not included in the result set above)

Conclusions

Oracle's v11.2 implementation of the Ansii SQL feature recursive subquery factoring provides a simple solution for the knapsack problem, that cannot be achieved with Oracle's older Connect By syntax alone.

The method has been described here in its exact form that is viable only for small problems; however, I have later extended the approach to allow for search limiting and have shown this to be viable for larger problems.






List Aggregation in Oracle - Comparing Three Methods

In my last article, Grouping by Unique Subsequences in Oracle, I compared three solutions to a querying problem in Oracle. I found that a solution using a pipelined function was fastest across a range of test data sets, while another using Oracle’s Model clause turned out to be extremely inefficient, and very unscaleable owing to quadratic variation in execution times.

I mentioned in the article the issue of possible poor cardinality estimates by Oracle’s Cost-Based Optimiser (CBO) for pipelined functions, referencing an article by Adrian Billington, setting cardinality for pipelined and table functions, that considers four techniques for improving these estimates.

In this article, I want to use another, very common, querying problem, to see in more detail how one of these techniques works, namely the dynamic sampling hint, and to compare the performance again of pipelined functions against the Model clause on a second example amenable to both methods.

In previous articles I have generally focussed on elapsed and CPU times to measure performance, but Oracle provides a range of metrics in instrumenting query execution. My benchmarking framework captures many of these, and we'll use them to try to understand the performance variation, again using a 2-dimensional domain of test data. We also capture the execution plans used across the domain and display visually the changes across the domain.

The problem is that of list aggregation, and various solution methods are available depending on one’s Oracle version. In Oracle v11.2 a specific built-in function has been provided, Listagg, and Adrian Billington has compared it with earlier SQL techniques (listagg function in 11g release 2), including a Model solution. He looks only at pure SQL solutions, but we will take both the Model and Listagg solutions, and add in a pipelined function solution. We’ll take a simple test problem using Oracle’s demo HR schema, which will be: Return, for each department, its id, manager name, and a comma-separated, ordered list of its employee names.

Test Data
The HR tables employees and departments were copied structurally to test versions with _t suffixes and records were inserted programmatically by the performance testing packages.

ERD

Listagg Solution
How It Works
The first solution for this problem uses the aggregation function ListAgg, which is new in Oracle v11.2. The query groups employees by department, joins departments to get the name, and employees again to get the manager’s name.

Query Diagram

SQL

SELECT e.department_id,
       m.last_name manager,
       ListAgg (e.last_name, ',') WITHIN GROUP (ORDER BY e.last_name) emp_names
  FROM employees_t e
  JOIN departments_t d
    ON d.department_id = e.department_id
  JOIN employees_t m
    ON m.employee_id = d.manager_id
 GROUP BY 
       e.department_id,
       m.last_name
 ORDER BY e.department_id

Model Solution
How It Works

  1. Within an inline view, form the basic Select, with the department_id column, and append placeholders for the employee list and row number
  2. Add the Model keyword, partitioning by department_id, dimensioning by analytic function Row_Number, ordering by name within department, with name and name list as measures
  3. Define the only rule to prepend the list from the next element with the current name, going backwards (so the first record will be the one you want)
  4. Join the other tables to the inline view in the main query, strip off the last ‘,’, and filter out all except the first record for the department

Query Diagram

SQL

SELECT v.department_id, 
       e.last_name manager,
       RTrim (v.emp_names, ',') emp_names  
  FROM (
SELECT department_id,
       emp_names,
       rn
  FROM employees_t 
    MODEL  
      PARTITION BY (department_id)  
      DIMENSION BY (Row_Number() OVER 
                       (PARTITION BY department_id ORDER BY last_name) rn)
      MEASURES (last_name, CAST(NULL AS VARCHAR2(4000)) emp_names) 
      RULES (
        emp_names[ANY] ORDER BY rn DESC = last_name[CV()] || ',' || emp_names[CV()+1] 
      ) 
) v
  JOIN departments_t d
    ON d.department_id = v.department_id
  JOIN employees_t e
    ON e.employee_id = d.manager_id
 WHERE v.rn = 1 
 ORDER BY v.department_id

Pipelined Function Solution
How It Works
This approach is based on pipelined database functions, which are specified to return array types. Pipelining means that Oracle transparently returns the records in batches while processing continues, thus avoiding memory problems, and returning initial rows more quickly. Within the function there is a simple cursor loop over the employees, joining departments to get the manager id. A string variable accumulates the list of employees, until the department changes, when the record is piped out, and the string reset to the new employee. The last record has to be piped after exiting the loop.

Types
Two database types are specified, the first being an object with fields for the department and manager ids and the employee name list; the second is an array of the nested table form with elements of the first type.

Function Pseudocode

Loop over a cursor selecting the records in order 
    If the department changes or first record then
        If the department changes then
            Pipe the row out
        End if
        Reset variables to current record values
    Else
        Append the current employee name to the name list
    End if
End loop
If the last department is not null then
    Pipe the row out using saved values
End if

SQL
Just select the fields named in the record from the function wrapped in the TABLE keyword, and join employees to get the manager name.

Query Diagram

Function Definition (within package)

FUNCTION Dep_Emps RETURN dep_emps_list_type PIPELINED IS

  l_emp_names	        VARCHAR2(4000);
  old_manager_id        PLS_INTEGER;
  old_department_id     PLS_INTEGER;

BEGIN

  FOR r_val IN (SELECT e.department_id, d.manager_id, e.last_name 
                  FROM employees_t e
                  JOIN departments_t d
                    ON d.department_id = e.department_id
                 ORDER BY e.department_id, e.last_name) LOOP

    IF r_val.department_id != old_department_id OR old_department_id IS NULL THEN

      IF r_val.department_id != old_department_id THEN

        PIPE ROW (dep_emps_type (r_val.department_id, r_val.manager_id, l_emp_names));

      END IF;
      old_department_id := r_val.department_id;
      old_manager_id := r_val.manager_id;
      l_emp_names := r_val.last_name;

    ELSE

      l_emp_names := l_emp_names || ',' || r_val.last_name;

    END IF;

  END LOOP;

  IF old_department_id IS NOT NULL THEN
    PIPE ROW (dep_emps_type (old_department_id, old_manager_id, l_emp_names));
  END IF;

END Dep_Emps;

SQL

SELECT d.department_id,
       e.last_name manager,
       d.emp_names
  FROM TABLE (Stragg.Dep_Emps) d
  JOIN employees_t e
    ON e.employee_id = d.manager_id
 ORDER BY d.department_id

Performance Analysis
As in the previous article, I have benchmarked across a 2-dimensional domain, in this case width being the number of employees per department, and depth the number of departments. For simplicity, a single department, ‘Accounting’, and employee, ‘John Chen’, were used as templates and inserted repeatedly with suffixes on names and new ids.

The three queries above were run on all data points, and in addition the function query was run with a hint: DYNAMIC_SAMPLING (d 5).

Record Counts (total employees and employees per department)

Timings

In the embedded Excel file above, the four solutions are labelled as follows:

  • F = Pipelined Function solution
  • D = Pipelined Function with Dynamic Sampling hint solution
  • L = Listagg solution
  • M = Model solution

For the data points, font colour and fill colour signify:

  • Fill colours correspond to distinct execution plans whose hash values can be found later in the same tab. The formatted outputs can be found in the Plans tab for all distinct plans for selected data points (with hyperlinks)
  • White font signifies that the smallest elapsed time for the given data point occurred for the given solution, for all the tables except CPU time
  • For the CPU time table higher in the tab, white font signifies that the smallest CPU time for the given data point occurred for the given solution
  • Red font indicates that the solution incurred more than 500 disk reads (see the disk reads table later in the tab)

Graphs

Comparison
The CPU time for all four queries increases approximately in proportion with either width or depth dimension when the other is fixed, which is not surprising. The elapsed times are very similar to the CPU times for all except the larger problems using Model, which we’ll discuss in a later section. For the largest data point, the times rank in the following order:

The following points can be made:

  • The function query without the dynamic sampling hint was fastest for the largest data point, and by a significant margin over the next best, Listagg
  • The earlier detailed tables show that this was also true for the triangle of data points starting three points back in each dimension, indicating that this is the case once the problem size gets large enough
  • Similarly, the function query with dynamic sampling was in third place for all these larger problems
  • Model was always the slowest query, generally by a factor of about 8 over the fastest in terms of CPU time, but very much worse in elapsed time for problems above a certain size, and we’ll look at this in more detail next.

Model Performance Discontinuity
In Adrian Billington’s article mentioned above (listagg function in 11g release 2), he took a single large-ish data point for his problem and found that his Model query took 308 seconds compared with 6 seconds for Listagg. He puts the Model performance down to 'an enormous number of direct path reads/writes to/from the temporary tablespace'. In my last article, I also quoted the anonymous author of MODEL Performance Tuning: 'In some cases MODEL query performance can even be so poor that it renders the query unusable. One of the keys to writing efficient and scalable MODEL queries seems to be keeping session memory use to a minimum'.

My benchmarking framework records the metrics from the view v$sql_plan_stats_all, which is used by DBMS_XPlan.Display_Cursor to write the execution plan, and prints to a CSV file aggregates over the plan of several of them, for example: Max (last_disk_reads). These are are shown for the Model solution in the tab displayed below of the embedded Excel file (the next tab has 3-d graphs but they may not display in a browser).

The tables show that memory increases with the problem size in each direction up to a maximum, at which points the number of disk reads jumps from a very low level and then rises with problem size. The maximum memory points have red font. These transitions represent discontinuities where there is a jump in the elapsed times, although CPU times continue to rise smoothly. So while Model is always slower than the other solutions, its much greater use of memory causes the discrepancy to increase dramatically when the processing spills to disk, which is consistent with, and extends, the observations of the authors mentioned.

Model and Listagg Cardinality Estimates
Here is the execution plan for the last data point:

----------------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation               | Name          | Starts | E-Rows | A-Rows |   A-Time   | Buffers | Reads  | Writes |  OMem |  1Mem | Used-Mem | Used-Tmp|
----------------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT        |               |      1 |        |   1024 |00:01:25.46 |    5798 |    164K|    164K|       |       |          |         |
|   1 |  SORT ORDER BY          |               |      1 |    260K|   1024 |00:01:25.46 |    5798 |    164K|    164K|  2320K|   704K| 2062K (0)|         |
|*  2 |   HASH JOIN             |               |      1 |    260K|   1024 |00:01:20.86 |    5798 |    164K|    164K|   909K|   909K| 1230K (0)|         |
|*  3 |    HASH JOIN            |               |      1 |   1024 |   1024 |00:00:00.11 |    2901 |      0 |      0 |   935K|   935K| 1228K (0)|         |
|   4 |     TABLE ACCESS FULL   | DEPARTMENTS_T |      1 |   1024 |   1024 |00:00:00.01 |       6 |      0 |      0 |       |       |          |         |
|   5 |     TABLE ACCESS FULL   | EMPLOYEES_T   |      1 |    260K|    262K|00:00:00.40 |    2895 |      0 |      0 |       |       |          |         |
|*  6 |    VIEW                 |               |      1 |    260K|   1024 |00:01:20.68 |    2897 |    164K|    164K|       |       |          |         |
|   7 |     BUFFER SORT         |               |      1 |    260K|    262K|00:01:19.56 |    2897 |    164K|    164K|   297M|  5726K|   45M (0)|     265K|
|   8 |      SQL MODEL ORDERED  |               |      1 |    260K|    262K|01:28:30.86 |    2895 |    131K|    131K|  1044M|    28M|   51M (1)|         |
|   9 |       WINDOW SORT       |               |      1 |    260K|    262K|00:00:01.01 |    2895 |      0 |      0 |  7140K|  1067K| 6346K (0)|         |
|  10 |        TABLE ACCESS FULL| EMPLOYEES_T   |      1 |    260K|    262K|00:00:00.50 |    2895 |      0 |      0 |       |       |          |         |
----------------------------------------------------------------------------------------------------------------------------------------------------------

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

   2 - access("D"."DEPARTMENT_ID"="V"."DEPARTMENT_ID")
   3 - access("E"."EMPLOYEE_ID"="D"."MANAGER_ID")
   6 - filter("V"."RN"=1)

Notice that at line 6 the cardinality estimate is 260K while the actual rows returned was 1024: The CBO has simply ignored the filtering down to department level by row number, and assumed the number of employees! We may ask whether this mis-estimate has affected the subsequent plan. Well the result set at line 6 makes the second step in a hash join to another row set of actual cardinality 1024, so probably it has not made a significant difference in this case. It’s worth comparing the execution plan for Listagg:

---------------------------------------------------------------------------------------------------------------------------
| Id  | Operation            | Name          | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
---------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT     |               |      1 |        |   1024 |00:00:02.11 |    5796 |       |       |          |
|   1 |  SORT GROUP BY       |               |      1 |    185K|   1024 |00:00:02.11 |    5796 |    15M|  1999K|   14M (0)|
|*  2 |   HASH JOIN          |               |      1 |    260K|    262K|00:00:02.17 |    5796 |   921K|   921K| 1195K (0)|
|*  3 |    HASH JOIN         |               |      1 |   1024 |   1024 |00:00:00.11 |    2901 |   935K|   935K| 1229K (0)|
|   4 |     TABLE ACCESS FULL| DEPARTMENTS_T |      1 |   1024 |   1024 |00:00:00.01 |       6 |       |       |          |
|   5 |     TABLE ACCESS FULL| EMPLOYEES_T   |      1 |    260K|    262K|00:00:00.41 |    2895 |       |       |          |
|   6 |    TABLE ACCESS FULL | EMPLOYEES_T   |      1 |    260K|    262K|00:00:00.46 |    2895 |       |       |          |
---------------------------------------------------------------------------------------------------------------------------

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

   2 - access("D"."DEPARTMENT_ID"="E"."DEPARTMENT_ID")
   3 - access("M"."EMPLOYEE_ID"="D"."MANAGER_ID")

Notice that the cardinality estimates are accurate apart from at line 1 for the Sort Group By, where a similar error has been made in not allowing for the reduction in rows caused by the grouping. Again it doesn’t seem to have affected the plan adversely.

Memory Usage and Buffers
A few observations can be made about these statistics:

  • Buffers is sometimes seen as a good, fundamental measure of performance, but we can see that both function solutions have figures of about 9K, while the other two have very similar figures of about 6K, and these do not correlate well with actual time performance here
  • The buffers figure for Model at the minimum data point is more than half that for the maximum, unlike the other solutions where it is 1-3%. The ratio of records is only 0.2%, so this is hard to understand
  • Similarly, the memory usage for Model starts very high, 3.1M, before rising to its maximum of 54M. For pipelined functions the figures go from 6K to 2.8M, and for Listagg from 29K to 15M

Dynamic Sampling Effects
Here is the execution plan for the pipelined function solution at point (W256-D512), with my own timing output from 'Timer Set...' on:

----------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                           | Name        | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
----------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                    |             |      1 |        |    512 |00:00:00.65 |    6097 |       |       |          |
|   1 |  SORT ORDER BY                      |             |      1 |   8168 |    512 |00:00:00.65 |    6097 |  1186K|   567K| 1054K (0)|
|*  2 |   HASH JOIN                         |             |      1 |   8168 |    512 |00:00:00.62 |    6097 |  1520K|   901K| 1706K (0)|
|   3 |    COLLECTION ITERATOR PICKLER FETCH| DEP_EMPS    |      1 |   8168 |    512 |00:00:00.54 |    3202 |       |       |          |
|   4 |    TABLE ACCESS FULL                | EMPLOYEES_T |      1 |    130K|    131K|00:00:00.20 |    2895 |       |       |          |
----------------------------------------------------------------------------------------------------------------------------------------

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

   2 - access("E"."EMPLOYEE_ID"=VALUE(KOKBF$))

Timer Set: Cursor, Constructed at 23 Sep 2012 07:49:43, written at 07:49:45
===========================================================================
[Timer timed: Elapsed (per call): 0.05 (0.000045), CPU (per call): 0.04 (0.000040), calls: 1000, '***' denotes corrected line below]

Timer                  Elapsed          CPU          Calls        Ela/Call        CPU/Call
-----------------   ----------   ----------   ------------   -------------   -------------
Open cursor               0.01         0.00              1         0.01000         0.00000
First fetch               0.65         0.63              1         0.64700         0.63000
Write to file             0.06         0.06              2         0.03050         0.03000
Remaining fetches         0.00         0.00              1         0.00000         0.00000
Write plan                0.64         0.61              1         0.64200         0.61000
(Other)                   0.11         0.05              1         0.11400         0.05000
-----------------   ----------   ----------   ------------   -------------   -------------
Total                     1.47         1.35              7         0.21057         0.19286
-----------------   ----------   ----------   ------------   -------------   -------------

Here is the output for the pipelined function solution with dynamic sampling at the same point (W256-D512):

-----------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                            | Name        | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-----------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                     |             |      1 |        |    512 |00:00:00.59 |    4228 |       |       |          |
|   1 |  SORT ORDER BY                       |             |      1 |    512 |    512 |00:00:00.59 |    4228 |  1186K|   567K| 1054K (0)|
|   2 |   NESTED LOOPS                       |             |      1 |        |    512 |00:00:00.59 |    4228 |       |       |          |
|   3 |    NESTED LOOPS                      |             |      1 |    512 |    512 |00:00:00.58 |    3716 |       |       |          |
|   4 |     COLLECTION ITERATOR PICKLER FETCH| DEP_EMPS    |      1 |    512 |    512 |00:00:00.56 |    3202 |       |       |          |
|*  5 |     INDEX UNIQUE SCAN                | EMP_PK      |    512 |      1 |    512 |00:00:00.01 |     514 |       |       |          |
|   6 |    TABLE ACCESS BY INDEX ROWID       | EMPLOYEES_T |    512 |      1 |    512 |00:00:00.01 |     512 |       |       |          |
-----------------------------------------------------------------------------------------------------------------------------------------

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

   5 - access("E"."EMPLOYEE_ID"=VALUE(KOKBF$))

Note
-----
   - dynamic sampling used for this statement (level=2)

Timer Set: Cursor, Constructed at 23 Sep 2012 07:49:45, written at 07:49:47
===========================================================================
[Timer timed: Elapsed (per call): 0.05 (0.000045), CPU (per call): 0.05 (0.000050), calls: 1000, '***' denotes corrected line below]

Timer                  Elapsed          CPU          Calls        Ela/Call        CPU/Call
-----------------   ----------   ----------   ------------   -------------   -------------
Open cursor               0.55         0.55              1         0.54500         0.55000
First fetch               0.59         0.57              1         0.59300         0.57000
Write to file             0.06         0.06              2         0.03100         0.03000
Remaining fetches         0.00         0.00              1         0.00000         0.00000
Write plan                0.59         0.58              1         0.59300         0.58000
(Other)                   0.06         0.03              1         0.05800         0.03000
-----------------   ----------   ----------   ------------   -------------   -------------
Total                     1.85         1.79              7         0.26443         0.25571
-----------------   ----------   ----------   ------------   -------------   -------------

Notice that in the plan without dynamic sampling the cardinality estimate for the row set returned from the function is 8168, nearly 8 times the actual rows. When dynamic sampling is added the cardinality estimate is exactly right. Also the times reported in the plan are similar but show dynamic sampling to be faster. How can that be, when the table of results earlier showed the query with dynamic sampling taking nearly twice as long?

My framework breaks down the times for the steps in running the query and writing the results out. From these we see that the difference is largely accounted for by the function query taking only 0.01 seconds to open the cursor while with dynamic sampling it takes .55 seconds. Evidently the dynamic sampling hint is causing a call to the function at the query parsing stage which is not accounted for in the execution plan statistics. (Notice incidentally that Oracle is apparaently performing a deferred open in both cases, where the actual cursor opening is performed at the time of first fetching.)

If one looks at the colour-coded table of elapsed times above, it can be seen that dynamic sampling causes a single plan to be chosen for all data points with depth below 1024, while without the hint two plans are chosen that with dynamic sampling are chosen only at depth 1024. It can also be seen that the dynamic sampling version is faster overall in most cases, but at the highest depth is slower because the non-hinted plan is the same. The default cardinality estimate (8168) was too high until that point.

Conclusions
We have applied three techniques for list aggregation to one specific problem, and for that problem the following concluding remarks can be made:

  • The Model solution is much inferior in performance to both the new Listagg native function, and custom pipelined function solutions
  • The variation in performance has been analysed and for the model solution shown to become dramatically worse when problem size causes earlier in-memory processing to spill to disk
  • The dynamic sampling hint has been applied to the pipelined function solution and shown to give correct cardinality estimates. In our example, the performance effect was negative for the largest problem sizes owing to the overhead involved, but in other cases it was positive
  • We have oberved that both Model and Listagg solutions also have cardinality estimation problems, but have not analysed these further
  • The native Listagg solution is significantly, and surprisingly, slower than the custom pipelined function solution at the largest data points considered

We may say more generally:

  • Performance analysis across a 2-dimensional domain of data sets can provide more insight than just looking at one large zero-dimensional case
  • Microsoft Excel graphs and other functionality have proved very useful in helping to visualise what is happening in terms of performance
  • Our findings tend to bear out a common suspicion of Model clause on performance grounds, and further support the view that pipelined functions can be very performance-effective, used appropriately






Grouping by Unique Subsequences in SQL

Recently a deceptively simple question was asked on Oracle’s OTN PL/SQL forum that most posters initially misunderstood, myself included (Grouping Non Consecutive Rows). The question requested a solution for the problem of assigning group numbers to a sequence of records such that each group held no duplicate values of a particular field, and each group was as long as possible. One of the posters produced a solution involving the Model clause and I tried to find a solution without using that clause, just to see if it could be done. Having found such a solution, not without some difficulty, I then solved the problem via a pipelined PL/SQL function having felt that that would be more efficient than straight SQL.

I think all three solutions have their own interest, especially since forum posters frequently assert, incorrectly, that SQL solutions are always faster than those using PL/SQL. I’ll explain how each solution works in this article and will run them through my benchmarking framework. We’ll see that the PL/SQL solution time increases linearly with sequence length, while the others increase quadratically, and PL/SQL is orders of magnitude faster for even small problem sizes. I used Oracle Database v11.2 XE running on a Samsung X120 dedicated PC.

I use my Query Structure Diagramming technique to illustrate the SQL solutions.

Functional Test Data
The problem data structure is quite simple, and I have defined my own version to emphasise generality, and to include partitioning, which was not part of the initial posting. There is one table with a two-column primary key, and I added an index on the partition field plus the value field.

Table Value_Subseqs

Column Type
part_key* Char(10)
ind* Number
val Char(10)

Index VSB_N1

  • part_key
  • val

Test Cases
Functional testing was done on a number of simple sequences, including the sequence of single characters, ABABB, which is used to illustrate the first solution query.

SQL Pairs Solution

How It Works
The first solution for this problem starts by obtaining the possible start and end points of the groups: all pairs that contain no duplicate. In the table below, the rows represent the possible pairs with X marking each value in the ranges. It’s easy to see the solution for this small test problem and the correct pairs are highlighted in yellow.

From the table it’s possible to work out a solution in SQL, given the pair set. The first correct pair is the longest starting from 1, while each subsequent correct pair is the longest beginning one element after the previous ends. This is of course a kind of tree-walk, which leads to the following solution steps (where everything is implicitly partitioned):

  1. Within a subquery factor, self-join the table with the second record having a higher ind than the first
  2. Add a NOT EXISTS subquery that checks for duplicate val in any pair between the outer potantial start and end point pair, using another self-join
  3. Add in the single element pairs via a UNION
  4. Within another subquery factor, obtain the rank of each pair in terms of its length descending, as well as the starting ind value (if it might not always be 1)
  5. In another subquery factor perform the tree-walk as mentioned, using the condition ‘rank = 1’ to include only the longest ranges from any point
  6. Include the the analytic function Row_Number in the Select list, which will be the group number
  7. The main query selects from the last subquery factor, then joins the original table

Notes
The query is of course likely to be performance-intensive owing to the initial subquery factor with its nested self-joins across ranges.

Query Diagram

Notes
The diagram notation follows and extends notation developed earlier, including my previous blog article, and is intended to be largely self-explanatory. In this diagram, I have added a new notation for joins that are not simple foreign key joins, in which I label the join and use a note to explain it.
Oracle v11.2 introduced Recursive Subquery Factors that extend tree-walk functionality. I used the older Connect By syntax in the query since it works on older versions, but found it easier to represent in the diagram as though it were the newer implementation – the diagram shows what’s happening logically.

SQL

WITH sqf AS (
SELECT p1.part_key, p1.ind ind_1, p2.ind ind_2
  FROM value_subseqs p1
  JOIN value_subseqs p2
    ON p2.ind           > p1.ind
   AND p2.part_key      = p1.part_key
   AND NOT EXISTS (SELECT 1
                     FROM value_subseqs p3
                     JOIN value_subseqs p4
                       ON p4.val        = p3.val
                      AND p4.part_key   = p3.part_key
                    WHERE p3.ind        BETWEEN p1.ind AND p2.ind
                      AND p4.ind        BETWEEN p3.ind + 1 AND p2.ind
                      AND p3.part_key   = p1.part_key
                      AND p4.part_key   = p2.part_key)
 UNION ALL
SELECT part_key, ind, ind
  FROM value_subseqs p1
), rnk AS (
SELECT part_key, ind_1, ind_2,
        Row_Number() OVER (PARTITION BY part_key, ind_1 ORDER BY ind_2 - ind_1 DESC) rn,
        Min(ind_1) OVER (PARTITION BY part_key) ind_1_beg
  FROM sqf
), grp AS (
SELECT part_key, ind_1, ind_2, Row_Number() OVER
       (PARTITION BY part_key ORDER BY ind_1, ind_2) grp_no
  FROM rnk
CONNECT BY ind_1 = PRIOR ind_2 + 1
   AND part_key = PRIOR part_key
   AND rn = 1
 START WITH ind_1 = ind_1_beg AND rn = 1
)
SELECT
    p.part_key,
    p.ind,
    p.val,
    g.grp_no
  FROM grp g
  JOIN value_subseqs p
    ON p.ind            BETWEEN g.ind_1 AND g.ind_2
   AND p.part_key       = g.part_key
 ORDER BY p.part_key, p.ind

Model Solution

How It Works
In the OTN thread several solutions were proposed that used Oracle’s Model clause or recursive subquery factoring, but I think only one was a general solution, since the others used string variables to successively concatenate strings over arbitrary numbers of rows and would break when the 4000 character SQL limit is hit.
The general Model solution (which was not by me, but I’ve reformatted it and applied it to my table) worked by defining two measures, for group start indices and group number. The rules specified two passes for the two measures: The first pass counts the distinct values and compares with the count of all values, between the previous group start and the current index; the second uses the group starts to set the group numbers.

  1. Form the basic Select, with all the table columns required, and append a group number placeholder 
  2. Add the Model keyword, partitioning by part_key, dimensioning by analytic function Row_Number, ordering by ind within part_key, with val, group start and group number as measures
  3. Initialise group start and group number to 1 in the measures clause
  4. Define the first rule to obtain the group start date for all rows after the first as the previous group start, unless there is a difference between the two counts, in which case take the new index.
  5. Define the second rule to obtain the group number for all rows as the previous group number, unless the group start has changed, in which case take the previous group number + 1.

Query Diagram

Notes
Queries with the Model clause have a structure that is rather different from other queries, and the diagram attempts to reflect that structure for these problems. The main query feeds its output into an array processing component with a set of rules that specify how any additional data items (called measures) are to be calculated, in a mostly declarative fashion.
The model box above contains 4 specification types:

  • Partition - processing is to be performed separately by one or more columns; the same meaning as in analytic functions
  • Dimension - columns by which the array is dimensioned; can included analytic functions, as here
  • Measures - remaining columns that may be calculated or updated by the rules, possibly including placeholders from the main query
  • Rules - a set of rules that specify measure calculation; rules are processed sequentially, unless otherwise specified; in the diagram:
    • n - the current dimension value
    • F(n-1,n) - denotes that the value depends on values from previous and current rows (and so on, ‘..’ denotes a range)
    • ^ - denotes that the calculation progresses in ascending order by dimension; this is the default so does not have to be coded

SQL

SELECT
    part_key,
    rn,
    val,
    g grp_no
  FROM value_subseqs
 MODEL
   PARTITION BY (part_key)
   DIMENSION BY (Row_number() OVER (PARTITION BY part_key ORDER BY ind) rn)
   MEASURES (val, 1 g, 1 s)
   RULES (
     s[rn > 1] = CASE COUNT (DISTINCT val)[rn BETWEEN s[CV() - 1] AND CV()]
                   WHEN COUNT (val)[rn BETWEEN s[CV() - 1] AND cv()] THEN s[cv() - 1]
                   ELSE CV(rn)
                 END,
     g[rn > 1] = CASE s[CV()]
                    WHEN s[CV() - 1] THEN g[CV() - 1]
                    ELSE g[CV() - 1] + 1
                 END
   )
 ORDER BY part_key, rn

Pipelined Function Hash Solution

How It Works
This approach is based on pipelined database functions, which are specified to return array types. Pipelining means that Oracle transparently returns the records in batches while processing continues, thus avoiding memory problems, and returning initial rows more quickly. See Pipelined Functions (AskTom) for some other examples of use.
Within the function there is a simple cursor loop over the ordered sequence. A PL/SQL index-by array stores values for the current group, and allows duplicate checking to take place without any additional searching or sorting. The array is reset whenever the group changes.

Types
Two database types are specified, the first being an object with fields for the table columns and an extra field for the group to be derived; the second is an array of the nested table form with elements of the first type.

Function Pseudocode

Loop over a cursor selecting the records in order
	If the partition field value changes then
		Reset group and index-by array
	Else if the current value is already in the index-by array then
		Increment group number and reset index-by array
	End if
	Add the value to the index-by array
	Pipe the row out
End loop

Function Definition (within package)

FUNCTION Hash_Array RETURN value_subseq_list_type PIPELINED IS

  TYPE value_list_type      IS TABLE OF PLS_INTEGER INDEX BY VARCHAR2(4000);
  l_value_list_NULL         value_list_type;
  l_value_list              value_list_type;
  l_group_no                PLS_INTEGER;
  old_part_key              VARCHAR2(10);

BEGIN

  FOR r_val IN (SELECT part_key, ind, val FROM value_subseqs ORDER BY part_key, ind) LOOP

    IF r_val.part_key != old_part_key OR old_part_key IS NULL THEN

      old_part_key := r_val.part_key;
      l_group_no := 1;
      l_value_list := l_value_list_NULL;

    ELSIF l_value_list.Exists (r_val.val) THEN

      l_group_no := l_group_no + 1;
      l_value_list := l_value_list_NULL;

    END IF;

    l_value_list (r_val.val) := 1;
    PIPE ROW (value_subseq_type (r_val.part_key, r_val.ind, r_val.val, l_group_no));

  END LOOP;

END Hash_Array;

SQL
Just select the fields named in the record from the function wrapped in the TABLE keyword.

SELECT
    part_key,
    ind,
    val,
    grp_no
  FROM TABLE (Subseq_Groups.Hash_Array)
 ORDER BY part_key, ind

Pipelined Function Sim Solution
This solution was added after performance testing on the the first data set, below. It is a sort of hybrid between the Model and pipelined function approach created to try to understand the apparent quadratic variation of Model with sequence length noted in testing.

How It Works
This function uses the same database types as the Hash solution, but with the same counting idea as the Model solution within an old-fashioned nested cursor structure that one would not expect to perform efficiently.

Function Pseudocode

Loop over a cursor selecting the records in order
	If the partition field value changes then
		Reset group and group starting index
	Else
		Select counts of val and distinct val from the table between the group starting and current indices
		If difference in counts then
			Increment group number and reset group starting index
		End if
	End if
	Pipe the row out
End loop

Function Definition (within package)

FUNCTION Sim_Model RETURN value_subseq_list_type PIPELINED IS

  l_group_no                PLS_INTEGER;
  l_ind_beg                 PLS_INTEGER;
  l_is_dup                  PLS_INTEGER;
  old_part_key              VARCHAR2(10);

BEGIN

  FOR r_val IN (SELECT part_key, ind, val FROM value_subseqs ORDER BY part_key, ind) LOOP

    IF r_val.part_key != old_part_key OR old_part_key IS NULL THEN

      old_part_key := r_val.part_key;
      l_group_no := 1;
      l_ind_beg := r_val.ind;

    ELSE

      SELECT Count(val) - Count(DISTINCT val)
        INTO l_is_dup
        FROM value_subseqs
       WHERE part_key = r_val.part_key
         AND ind      BETWEEN l_ind_beg AND r_val.ind;

      IF l_is_dup > 0 THEN

        l_group_no := l_group_no + 1;
        l_ind_beg := r_val.ind;

      END IF;

    END IF;

    PIPE ROW (value_subseq_type (r_val.part_key, r_val.ind, r_val.val, l_group_no));

  END LOOP;

END Sim_Model;

SQL
Just select the fields named in the record from the function wrapped in the TABLE keyword.

SELECT
    part_key,
    ind,
    val,
    grp_no
  FROM TABLE (Subseq_Groups.Sim_Model)
 ORDER BY part_key, ind

Performance Analysis
In SQL Pivot and Prune Queries - Keeping an Eye on Performance, in May 2011, I first applied an approach to performance testing of SQL queries whereby the queries are tested across a 2-dimensional domain, using a testing framework developed for that work. The same approach has been followed here, although the framework has been substantially improved and extended since then. In this case it may be of interest to observe performance across the following two dimensions:

  • Number of records per partition key
  • Average group size

However, as I prefer to randomise the test data, the group size is known only after querying the data set, so I will use a proxy dimension instead. The value field will be a string of 20 random capital letters (A-T) of length equal to the proxy dimension. As this length increases so will the average group size. Generally execution time would be expected to be proportional to number of partition keys when the other dimensions are fixed, and I will use 2 partition key values throughout.

Data Set 1
The first data set is chosen to keep the CPU times within reason for all queries, which limits the possible ranges (we’ll eliminate one query later and extend the ranges).

Output Record Counts

Depth/Width

W1

W2

W4

Records/Part>

100

200

400

D1

5

6

5

D2

25

24

24

D3

100

80

89

D4

100

200

267

CPU Times (Seconds)

Query

W1

W2

W4

W/Prior W Average

SQL Pairs

D1

2.11

8.49

33.99

4

D2

4.88

13.66

42.15

2.9

D3

10.3

46.71

255.64

5

D4

10.33

78.25

595.58

7.6

Model

D1

0.32

1.08

4.23

3.6

D2

0.31

1.14

4.23

3.7

D3

0.34

1.16

4.65

3.7

D4

0.36

1.36

4.86

3.7

Hash

D1

0.03

0.03

0.03

1

D2

0

0.01

0.03

2

D3

0.01

0.01

0.02

1.5

D4

0.02

0.01

0.02

1.3


Discussion

We can see immediately that on all data points there is the same performance ranking of the three queries and the differences are extreme. On W4-D4, SQL Pairs takes 123 times as long as Model, which in turn takes 243 times as long as Hash.

SQL Pairs
The Average Ratio figure in the table above is the average ratio between successive columns across the width dimension. On D1 this is 4, meaning that the CPU time has risen by the square of the width factor increase. On D8 it’s 7.6, being almost the cube of the factor. It appears that the performance varies with the square of the sequence length, except when the group size reaches the sequence length, when it becomes the cube. We would not consider this query for real problems when faster alternatives exist.

Model
The Average Ratio figure on all depths is about 3.7, meaning that the CPU time has risen by almost the square of the width factor increase. This is very surprising because, considering the algorithm one would assume to be effected by our query, if the group size remains constant then the work done in computing each group ought to be constant too, and the total work ought to rise by the same factor as the sequence length. We’ll look at this further in our second, larger data set, where we’ll also consider an apparently similar algorithm implemented in PL/SQL.

Hash
The Average Ratio figure varies between 1 and 2, but the CPU times are really too small for the figure to be considered reliable (note that the zero figure for W1-D2 was replaced by 0.005 in order to allow the log graph to include it). We can safely say, though, that this is faster by orders of magnitude even on very small problems, and will again look at a larger data set to see whether more can be said.

Data Set 2 (Second Query Set)
The second data set is chosen to give wider ranges, after excluding the Pairs query. A second function was added to replace it, labelled ‘Sim’ below and described above.

Output Record Counts

Depth/Width

W1

W2

W4

W8

W16

W32

Records/Part>

100

200

400

800

1600

3200

D1

5

5

5

5

5

5

D2

18

25

23

24

25

23

D3

50

80

89

84

119

110

D4

100

200

200

267

356

582

D5

100

200

400

533

1600

2133

D6

100

200

400

800

1600

3200

CPU Times (Seconds)

Query

W1

W2

W4

W8

W16

W32

W/Prior W Average

Hash

D1

0.02

0.01

0.01

0.03

0.06

0.10

1.6

D2

0.02

0.01

0.02

0.04

0.06

0.09

1.5

D3

0.02

0.02

0.02

0.04

0.06

0.09

1.4

D4

0.01

0.02

0.01

0.03

0.06

0.11

1.9

D5

0.01

0.03

0.02

0.05

0.06

0.09

1.8

D6

0.01

0.02

0.01

0.05

0.06

0.09

2.0

Model

D1

0.28

1.01

4.05

16.28

63.34

257.46

3.9

D2

0.27

1.06

4.00

15.97

66.27

249.99

3.9

D3

0.29

1.14

4.24

16.28

62.91

250.50

3.9

D4

0.33

1.24

4.74

17.66

69.00

263.34

3.8

D5

0.33

1.26

5.10

19.17

81.59

314.39

3.9

D6

0.33

1.28

4.99

20.55

80.80

331.38

4.0

Sim

D1

0.25

0.37

0.74

1.70

3.14

6.18

1.9

D2

0.28

0.59

1.21

2.42

4.73

9.28

2.0

D3

0.33

0.67

1.43

2.79

5.86

11.28

2.0

D4

0.34

0.77

1.58

3.15

6.97

14.71

2.1

D5

0.36

0.73

1.69

3.61

9.64

22.58

2.3

D6

0.36

0.73

1.71

3.79

9.43

26.45

2.4


Discussion

We can see immediately that on all data points there is the same performance ranking of the three queries and the differences are extreme. On W32-D6, Model takes 12 times as long as Sim, which in turn takes 294 times as long as Hash, Model being 3,678 slower than Hash. (I have included the elapsed times, which are very close to the CPU times, in the shared XL file above. I think the table data are being read from buffer cache throughout).

Model
The Average Ratio figure on all depths is about 3.9, meaning that the CPU time has risen by almost the square of the width factor increase. It seems that the internal algorithm applied from the Model query here is doing something different from what we would expect, and with dire consequences for performance. For what it's worth, here is the last Execution Plan:

---------------------------------------------------------------------------------------------------------------------------
| Id  | Operation            | Name          | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
---------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT     |               |      1 |        |   6400 |00:05:33.45 |      30 |       |       |          |
|   1 |  SORT ORDER BY       |               |      1 |   6437 |   6400 |00:05:33.45 |      30 |   478K|   448K|  424K (0)|
|   2 |   SQL MODEL ORDERED  |               |      1 |   6437 |   6400 |05:57:01.43 |      30 |  1156K|   974K| 1002K (0)|
|   3 |    WINDOW SORT       |               |      1 |   6437 |   6400 |00:00:00.03 |      30 |   337K|   337K|  299K (0)|
|   4 |     TABLE ACCESS FULL| VALUE_SUBSEQS |      1 |   6437 |   6400 |00:00:00.01 |      30 |       |       |          |
---------------------------------------------------------------------------------------------------------------------------

Hash
The Average Ratio figure varies between 1.4 and 2, but the CPU times are probaby still too small for the figure to be considered reliable. We can again say, though, that this is faster than the Model solution by orders of magnitude even on very small problems and that the CPU time does not appear to be rising faster than linearly, so that the performance advantage will increase with problem size.

Sim
The Average Ratio figure varies between 1.9 and 2.4, and up to D3 is not more than 2, which indicates a pretty exact proportionality between sequence length and CPU time. This is consistent with our expectation of linearity so long as the group sizes are smaller than sequence lengths. For D6, where the group sizes are the same as the sequence lengths, we would expect to see a quadratic term (number of counts doubles, and work done in sorting/counting also doubles, if that is linear), and time in fact trebles between W16 and W32.
The results from this solution support the view that there is some internal implementation problem with Model for this example that is causing its quadratic CPU time variation. In my August 2011 revision of Forming Range-Based Break Groups with Advanced SQL, I noted significant under-performance in a query using analytic functions, that also seemed to due to an internal implementation problem, and found a work-around that made the query perform as expected. I believe both examples illustrate well the power of this kind of dimensional performance analysis.

Model Clause vs Pipelined Functions
I googled model performance problems and the two top-ranked articles are briefly discussed in the first two subsections below.
MODEL Performance Tuning
The author states: ‘In some cases MODEL query performance can even be so poor that it renders the query unusable. One of the keys to writing efficient and scalable MODEL queries seems to be keeping session memory use to a minimum’. Our first case would seem to fall into one of those cases, Model being 3,678 times slower than the function, at 332 seconds, on a problem of only 3,200 records (times two partition keys) and rising quadratically. The article considers the effects of changing various features of a test Model problem on the memory usage, assuming that that is one cause of poor performance.
From Pipelined Function to Model 
This article is interesting in that it takes pretty much the opposite line to my own. For a different problem, the author started with a pipelined function solution, and then went to Model on performance grounds. He says: ‘Since we were returning the rows in a pipelined (streaming) fashion, the performance was fine initially. It was when the function was called constantly and then joined with other tables that we ran into trouble’. The problem he identifies seems to be principally the fact that Oracle’s Cost Based Optimiser (CBO) cannot accurately predict the cardinality of the function, and assigns a default, on his system (as on mine) of 8168. This can cause poor execution plans when joined with other tables. His initial solution was to use the CARDINALITY hint, which worked but is undocumented and inflexible. He also notes possible performance issues caused by Oracle’s translating the PL/SQL table into an SQL result set and goes on to propose a Model solution to avoid this problem. Unfortunately, the author does not provide any results on significant data sets to demonstrate the performance differences. The following article looks specifically at the cardinality issue.
setting cardinality for pipelined and table functions
The author (Adrian Billington) considers four techniques that he labels thus:

  • CARDINALITY hint (9i+) undocumented
  • OPT_ESTIMATE hint (10g+) undocumented
  • DYNAMIC_SAMPLING hint (11.1.0.7+)
  • Extensible Optimiser (10g+)

The first two are not recommended on the grounds of being undocumented. The third option appears quite a lot simpler than the fourth and I will look at that approach in a second example problem, in my next article List Aggregation in Oracle - Comparing Three Methods.

Discussion
The pipelined function approach is plainly much faster than the SQL solutions in this example, but one has to be aware of possible issues such as the cardinality issue mentioned. One also needs to be aware that pure SQL statements are ‘read-consistent’ in Oracle, but this is not the case when functions are called that themselves do SQL.
Context switches between the SQL and PL/SQL engines, as well as the work done in translating between collections and SQL record sets, are often cited as performance reasons for preferring SQL-only solutions. As we have seen though, these issues, while real, can be dwarfed by algorithmic differences.

Conclusions

  • For the subsequence grouping problem addressed, using a pipelined function is faster by far than the SQL-only solutions identified
  • Although widely asserted, the notion that any query processing will be executed more efficiently in pure SQL than in PL/SQL is a myth
  • The Model solution using embedded aggregate Counts is much slower than expected and its quadratic CPU variation suggests performance problems within Oracle’s internal implementation of the Model clause
  • Dimensional performance analysis is very powerful although its use appears to be extremely rare in the Oracle community
  • It is suggested that diagrammatic techniques, such as my Query Structure Diagramming, although also very rarely used, offer important advantages for query documentation and design